Archive

Archive for January, 2013

T-SQL : Gaps and Islands Problem

The table below has set of names and their date values, where some of the date values are missing by month for each Name
For example, the name ‘Test1′ have date range like ’01-Apr-2013′,’01-Jun-2013’and ’01-Aug-2013’ and it is clear that a datevalue for the month of may and July are missing.

The query has to find the missing date values and insert them back to the same table for each names available in it

A Sample of Missing record is shown below,

1, ‘Test1′,’01-May-2013’
1, ‘Test1′,’01-July-2013’

DECLARE @table TABLE
  (
     ID         INT,
     Name       VARCHAR(10 ),
     DateValue DATETIME
   )

Insert into @table
Select 1, 'Test1', '01-Apr-2013' 
Union All
Select 1, 'Test1', '01-Jun-2013' 
Union All
Select 1, 'Test1', '01-Aug-2013' 
Union All
Select 2, 'Test2', '01-Jun-2013' 
Union All
Select 2, 'Test2', '01-Aug-2013' 
Union All
Select 2, 'Test2', '01-Oct-2013' 
Union All
Select 3, 'Test3', '01-Sep-2013' 
Union All
Select 3, 'Test3', '01-Nov-2013' 

select * from @table -- Before Inserting


;WITH cte AS
(
SELECT ID, Name,DateValue FROM
(SELECT ID ,Name, Min( DateValue ) DateValue FROM @table GROUP BY ID,Name) x
UNION ALL
SELECT ID, Name,Dateadd (mm , 1, DateValue ) FROM cte b
WHERE EXISTS
(SELECT 1 FROM @table a
WHERE a. ID = b .id
AND b. DateValue<a .DateValue)

)

INSERT INTO @table
SELECT b. ID,
       b .Name,
       b . DateValue
FROM   @table a
       RIGHT JOIN cte b
               ON a. ID = b .ID
                  AND a. DateValue = b .DateValue
WHERE  a. ID IS NULL

SELECT *
FROM   @table
ORDER  BY ID,
          DateValue 
Advertisements
%d bloggers like this: