April 17, 2013 at 8:48 am
Hi,
I've been trying to think of a way to change the appearance of the following data.
It currently looks like this
ClaimKey ARevDate ARowNumCauseCode
12345678920120101 1Fault
12345678920120201 2NULL
12345678920120301 3NULL
12345678920120401 4NULL
12345678920120501 5Non-Fault
12345678920120601 6NULL
12345678920120701 7NULL
For the purposes of what I want to do after, I need the data to look like this
ClaimKey ARevDate ARowNumCauseCode
12345678920120101 1Fault
12345678920120201 2Fault
12345678920120301 3Fault
12345678920120401 4Fault
12345678920120501 5Non-Fault
12345678920120601 6Non-Fault
12345678920120701 7Non-Fault
So it is basically writing the cause code down the cilumn untill there is a different one.
Any help would be much appreciated, it appears to be easy but i dont seem to be able to do it.
Thanks
Dominic
April 17, 2013 at 9:20 am
WITH MyCTE(ClaimKey ,ARevDate ,ARowNum,CauseCode) AS
(
SELECT 123456789,20120101 ,1,'Fault'
UNION select 123456789,20120201, 2,NULL
UNION select 123456789,20120301 ,3,NULL
UNION select 123456789,20120401 ,4,NULL
UNION select 123456789,20120501 ,5,'Non-Fault'
UNION select 123456789,20120601 ,6,NULL
UNION select 123456789,20120701 ,7,NULL
UNION select 123456789,20120701 ,8,NULL
UNION SELECT 123456789,20120701 ,9,'Fault'
UNION select 123456789,20120701 ,10,NULL
UNION SELECT 123456789,20120701 ,11,'fault'
UNION SELECT 123456789,20120701 ,12,'non fault'
UNION select 123456789,20120701 ,13,NULL
UNION select 123456789,20120701 ,14,NULL
)
--SELECT TOP 1 [mc1].[CauseCode] FROM [MyCTE] [mc1] WHERE NOT [mc1].[CauseCode] IS NULL AND [mc1].[ARowNum] < 1 ORDER BY [mc1].[ARowNum] DESC
SELECT *
, CASE WHEN [mc].[CauseCode] IS NULL THEN (SELECT TOP 1 [mc1].[CauseCode] FROM [MyCTE] [mc1] WHERE NOT [mc1].[CauseCode] IS NULL AND [mc1].[ARowNum] < [mc].[ARowNum] ORDER BY [mc1].[ARowNum] DESC) ELSE mc.[CauseCode] END AS NewCauseCode
FROM [MyCTE] [mc]
April 17, 2013 at 9:48 am
thanks thats brillaint, sorted that issue so I can get on with the rest of it.
Thanks Again!!
April 18, 2013 at 2:37 am
Dominic
Here's another way of doing it. It avoids the correlated subquery in David's solution and so it may perform better. You'll want to test.
John
-- Data
WITH MyCTE(ClaimKey ,ARevDate ,ARowNum,CauseCode) AS (
SELECT 123456789,20120101 ,1,'Fault'
UNION select 123456789,20120201, 2,NULL
UNION select 123456789,20120301 ,3,NULL
UNION select 123456789,20120401 ,4,NULL
UNION select 123456789,20120501 ,5,'Non-Fault'
UNION select 123456789,20120601 ,6,NULL
UNION select 123456789,20120701 ,7,NULL
UNION select 123456789,20120701 ,8,NULL
UNION SELECT 123456789,20120701 ,9,'Fault'
UNION select 123456789,20120701 ,10,NULL
UNION SELECT 123456789,20120701 ,11,'fault'
UNION SELECT 123456789,20120701 ,12,'non fault'
UNION select 123456789,20120701 ,13,NULL
UNION select 123456789,20120701 ,14,NULL
)
-- Number the rows where a code is specified so we can see where it changes
, Numbered (ClaimKey, ARevDate, ARowNum, CauseCode, RowNo) AS (
SELECT ClaimKey, ARevDate, ARowNum, CauseCode,
ROW_NUMBER() OVER (ORDER BY ARowNum)
FROM MyCTE
WHERE CauseCode IS NOT NULL
)
-- Self-join to get ranges with the same code
, ShowNext (ClaimKey, ARevDate, ARowNum, CauseCode, NextRowNum) AS (
SELECT n1.ClaimKey, n1.ARevDate, n1.ARowNum, n1.CauseCode,
COALESCE(n2.ARowNum, (SELECT MAX(ARowNum)+1 FROM MyCTE)) -- add 1 to the highest value for the final number in the range
FROM Numbered n1
LEFT JOIN Numbered n2 -- need LEFT JOIN to capture the final value
ON n1.RowNo = n2.RowNo - 1
)
SELECT m.ClaimKey, m.ARevDate, m.ARowNum,
COALESCE(s.CauseCode,m.CauseCode) CauseCode
FROM MyCTE m
LEFT JOIN ShowNext s
ON m.ARowNum BETWEEN s.ARowNum + 1 AND s.NextRowNum - 1
April 18, 2013 at 8:12 am
that way is even better, I found a flaw with the other way when using multiple claimkeys.
Thanks very much! the other way works fine. Cheers
Viewing 5 posts - 1 through 4 (of 4 total)
You must be logged in to reply to this topic. Login to reply