Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


How to write these values down a column


How to write these values down a column

Author
Message
Dominic_godfrey
Dominic_godfrey
Grasshopper
Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)

Group: General Forum Members
Points: 10 Visits: 126
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 ARowNum CauseCode
123456789 20120101 1 Fault
123456789 20120201 2 NULL
123456789 20120301 3 NULL
123456789 20120401 4 NULL
123456789 20120501 5 Non-Fault
123456789 20120601 6 NULL
123456789 20120701 7 NULL


For the purposes of what I want to do after, I need the data to look like this

ClaimKey ARevDate ARowNum CauseCode
123456789 20120101 1 Fault
123456789 20120201 2 Fault
123456789 20120301 3 Fault
123456789 20120401 4 Fault
123456789 20120501 5 Non-Fault
123456789 20120601 6 Non-Fault
123456789 20120701 7 Non-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
davidandrews13
davidandrews13
SSC Eights!
SSC Eights! (824 reputation)SSC Eights! (824 reputation)SSC Eights! (824 reputation)SSC Eights! (824 reputation)SSC Eights! (824 reputation)SSC Eights! (824 reputation)SSC Eights! (824 reputation)SSC Eights! (824 reputation)

Group: General Forum Members
Points: 824 Visits: 4450
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]


Dominic_godfrey
Dominic_godfrey
Grasshopper
Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)

Group: General Forum Members
Points: 10 Visits: 126
thanks thats brillaint, sorted that issue so I can get on with the rest of it.

Thanks Again!!
John Mitchell-245523
John Mitchell-245523
SSCertifiable
SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)

Group: General Forum Members
Points: 7446 Visits: 15130
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


Dominic_godfrey
Dominic_godfrey
Grasshopper
Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)Grasshopper (10 reputation)

Group: General Forum Members
Points: 10 Visits: 126
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
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search