December 10, 2009 at 3:55 pm
I have the following tables:
Tbl1
(sid int,
cid int)
Tbl2
(oid int,
tnum varchar(10))
Tbl3
(rec_id int identity,
otnum varchar(10),
ntnum varchar(10),
sid int)
Step1:I need to select tbl1.sid using a join of tbl1 & tbl2 based on tbl1.cid=tbl2.oid-working fine
step2:All the selected sid's need to be inserted into Tbl3-woking fine
step3:After this I need to run an update query to remove spaces from tbl2.tnum & also insert each updated record into Tbl3-stuck???
I am implementing this using a cursor as below-but cant formulate the update cursor to do Step 3
DECLARE @STR varchar(20)
DECLARE c1 CURSOR
FOR
SELECT tbl1.sid
FROM tbl1,tbl2
WHERE tbl1.cid=tbl2.oid order by tbl1.sid desc
OPEN c1
FETCH NEXT FROM c1
INTO @STR
WHILE @@FETCH_STATUS = 0
BEGIN
INSERT INTO Tbl3(sid)
VALUES (@str)
FETCH NEXT FROM c1
INTO @STR
END
--step 3 not clear how to loop by using current row
Update Tbl2 set tnum=dbo.sp_trim_space(tnum)
OUTPUT deleted.tnum,inserted.tnum,@str
into tbl3 where <???current row???>
CLOSE c1
Thanks for the help
December 10, 2009 at 8:24 pm
Have you considered using a set-based method instead of the cursor method?
Jason...AKA CirqueDeSQLeil
_______________________________________________
I have given a name to my pain...MCM SQL Server, MVP
SQL RNNR
Posting Performance Based Questions - Gail Shaw[/url]
Learn Extended Events
December 11, 2009 at 2:37 am
Im not aware of the set based method..Can you pls suggest how is that used?
December 11, 2009 at 4:34 am
charu.verma (12/11/2009)
Im not aware of the set based method..Can you pls suggest how is that used?
Like this:
DROP TABLE #Tbl1
DROP TABLE #Tbl2
DROP TABLE #Tbl3
CREATE TABLE #Tbl1 ([sid] int, cid int)
CREATE TABLE #Tbl2 (oid int, tnum varchar(10))
CREATE TABLE #Tbl3 (rec_id int identity, otnum varchar(10), ntnum varchar(10), [sid] int)
INSERT INTO #Tbl1 ([sid], cid)
SELECT 1, 10 UNION ALL
SELECT 2, 20 UNION ALL
SELECT 3, 30 UNION ALL
SELECT 4, 40 UNION ALL
SELECT 5, 50 UNION ALL
SELECT 6, 60 UNION ALL
SELECT 7, 70
INSERT INTO #Tbl2 (oid, tnum)
SELECT 10, '100 0' UNION ALL
SELECT 20, '2000' UNION ALL
SELECT 30, '300 0' UNION ALL
SELECT 40, '4000' UNION ALL
SELECT 50, '500 0'
-- Step1:I need to select tbl1.sid using a join of tbl1 & tbl2 based on tbl1.cid=tbl2.oid-working fine
-- step2:All the selected sid's need to be inserted into Tbl3-woking fine
INSERT INTO #Tbl3 ([sid])
SELECT tbl1.[sid]
FROM #tbl1 tbl1
INNER JOIN #tbl2 tbl2 ON tbl1.cid = tbl2.oid
-- step4:insert each updated record into Tbl3-stuck???
INSERT INTO #Tbl3 ([sid], otnum)
SELECT oid, REPLACE(tnum, ' ', '')
FROM #Tbl2 Tbl2
WHERE tnum LIKE '% %'
-- step3:After this I need to run an update query to remove spaces from tbl2.tnum &
UPDATE #Tbl2
SET tnum = REPLACE(tnum, ' ', '')
WHERE tnum LIKE '% %'
SELECT * FROM #Tbl3
SELECT * FROM #Tbl2
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
December 11, 2009 at 8:04 am
Thanks-but this will not work
The cloumns in Tbl3 have to be deleted tnum of tbl2,formatted tnum returned from fucntion & sid of tbl1 & not oid of tbl2
December 11, 2009 at 8:17 am
charu.verma (12/11/2009)
Thanks-but this will not workThe cloumns in Tbl3 have to be deleted tnum of tbl2,formatted tnum returned from fucntion & sid of tbl1 & not oid of tbl2
The code I provided does exactly what you wanted, according to the instructions Step1, Step2 and Step3 in your first post. If you know for certain what you want to do, then please say so in a clear and unequivocal manner.
Given the data sets which I provided for you, what should your output be?
If the data I provided for you is insufficient, please augment it until it is suitable for testing, using the same code - INSERT INTO .... SELECT.
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
December 11, 2009 at 9:08 am
Thanks Chris for following up.
As for the requirements and desired output, Chris was spot on. If this does not do exactly what you envisioned - we need to have a better explanation.
Jason...AKA CirqueDeSQLeil
_______________________________________________
I have given a name to my pain...MCM SQL Server, MVP
SQL RNNR
Posting Performance Based Questions - Gail Shaw[/url]
Learn Extended Events
December 11, 2009 at 9:12 am
CirquedeSQLeil (12/11/2009)
Thanks Chris for following up.As for the requirements and desired output, Chris was spot on. If this does not do exactly what you envisioned - we need to have a better explanation.
No probs Jason
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Viewing 8 posts - 1 through 7 (of 7 total)
You must be logged in to reply to this topic. Login to reply