Click here to Skip to main content
16,004,406 members
Please Sign up or sign in to vote.
0.00/5 (No votes)
See more:
CustomerID FirstName CreateDate
1 Jonah 2011-09-01 00:00:00.000
2 Jonathan NULL
3 Leno 2014-05-05 00:00:00.000
4 James NULL
5 Tom 2018-05-01 00:00:00.000
6 Harry NULL
7 Ricky NULL
8 Katheriene NULL

Problem : Replace null values on date column from not null value of above.
I am use case statement to get below result but its very slow.
Expected output:
CreateDate CreateDate
2011-09-01 00:00:00.000 2011-09-01 00:00:00.000
NULL 2011-09-01 00:00:00.000
2014-05-05 00:00:00.000 2014-05-05 00:00:00.000
NULL 2014-05-05 00:00:00.000
2018-05-01 00:00:00.000 2018-05-01 00:00:00.000
NULL 2018-05-01 00:00:00.000
NULL 2018-05-01 00:00:00.000
NULL 2018-05-01 00:00:00.000

What I have tried:

SELECT main.CreateDate,CASE WHEN CreateDate IS NULL
THEN (SELECT TOP 1 sub.CreateDate FROM dbo.Customer sub WHERE sub.CustomerID <= main.CustomerID
order by sub.CreateDate desc )
ELSE main.CreateDate
END AS CreateDate
FROM dbo.Customer main;
Posted
Updated 23-Jul-18 7:05am

1 solution

Assuming SQL 2012 or higher, this technique from Dwain Camps might help:
SQL
WITH cteCount As
(
    SELECT
        CustomerID,
        FirstName,
        CreateDate,
        COUNT(CreateDate) OVER (ORDER BY CustomerID) As C
    FROM
        dbo.Customer
),
cteRN As
(
    SELECT
        CustomerID,
        FirstName,
        CreateDate,
        ROW_NUMBER() OVER (PARTITION BY C ORDER BY CustomerID) - 1 As RN
    FROM
        cteCount
)
SELECT
    CustomerID,
    FirstName,
    CreateDate,
    CASE
        WHEN CreateDate Is Not Null THEN CreateDate
        ELSE LAG(CreateDate, RN) OVER (ORDER BY CustomerID, CreateDate)
    END As CreateDate
FROM
    cteRN
ORDER BY
    CustomerID
;

Filling In Missing Values Using the T-SQL Window Frame - Simple Talk[^]
 
Share this answer
 

This content, along with any associated source code and files, is licensed under The Code Project Open License (CPOL)



CodeProject, 20 Bay Street, 11th Floor Toronto, Ontario, Canada M5J 2N8 +1 (416) 849-8900