January 30, 2013 at 1:20 pm
Hey all,
Given the following:
CREATE TABLE #Transfer
(
ID INT IDENTITY PRIMARY KEY,
OldKey INT,
NewKey INT
)
INSERT INTO #Transfer (OldKey, NewKey)
VALUES (1, 2)
INSERT INTO #Transfer (OldKey, NewKey)
VALUES (2, 3)
INSERT INTO #Transfer (OldKey, NewKey)
VALUES (3, 4)
INSERT INTO #Transfer (OldKey, NewKey)
VALUES (5, 6)
INSERT INTO #Transfer (OldKey, NewKey)
VALUES (6, 7)
IDOldKeyNewKey
112
223
334
456
567
Is there any way to get the following output, *without* resorting to using loops?
SELECT 1 AS OldKey, 4 AS NewKey
UNION
SELECT 2 AS OldKey, 4 AS NewKey
UNION
SELECT 3 AS OldKey, 4 AS NewKey
UNION
SELECT 4 AS OldKey, 4 AS NewKey
UNION
SELECT 5 AS OldKey, 7 AS NewKey
UNION
SELECT 6 AS OldKey, 7 AS NewKey
UNION
SELECT 7 AS OldKey, 7 AS NewKey
OldKeyNewKey
14
24
34
44
57
67
77
January 30, 2013 at 6:18 pm
Yup. Although technically most experts would consider a recursive CTE a loop in disguise.
CREATE TABLE #Transfer
(
ID INT IDENTITY PRIMARY KEY,
OldKey INT,
NewKey INT
)
INSERT INTO #Transfer (OldKey, NewKey)
VALUES (1, 2)
INSERT INTO #Transfer (OldKey, NewKey)
VALUES (2, 3)
INSERT INTO #Transfer (OldKey, NewKey)
VALUES (3, 4)
INSERT INTO #Transfer (OldKey, NewKey)
VALUES (5, 6)
INSERT INTO #Transfer (OldKey, NewKey)
VALUES (6, 7)
;WITH Transfers AS (
SELECT Oldkey=Newkey, Newkey
FROM #Transfer
UNION ALL
SELECT a.Oldkey, a.Newkey
FROM #Transfer a
UNION ALL
SELECT b.Oldkey, a.Newkey
FROM Transfers a
JOIN #Transfer b ON b.NewKey = a.Oldkey
)
SELECT OldKey, NewKey=MAX(NewKey)
FROM Transfers
GROUP BY OldKey
ORDER BY OldKey, NewKey
DROP TABLE #Transfer
My thought question: Have you ever been told that your query runs too fast?
My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.
Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
January 31, 2013 at 9:10 am
excellent - thanks!
Viewing 3 posts - 1 through 2 (of 2 total)
You must be logged in to reply to this topic. Login to reply