SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Compress table timelines


Compress table timelines

Author
Message
Nilssond
Nilssond
SSCommitted
SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)SSCommitted (1.9K reputation)

Group: General Forum Members
Points: 1889 Visits: 556
Here is data I am working with:

CREATE TABLE HISTORY(CUSTOMER VARCHAR(10), PLANNBR VARCHAR(10), SUBPLAN VARCHAR(3),
STARTDATE DATETIME, ENDDATE DATETIME, HISTORYMONTH VARCHAR(6))



INSERT INTO HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE) VALUES('9111111', 'H1111LAC', '006', '2014-01-01', '2014-05-31', '201401')
INSERT INTO HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE) VALUES('9111111','H1111LAC', '006', '2014-01-01', '2014-05-31', '201402')
INSERT INTO HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE) VALUES('9111111','H1111LAC', '006', '2014-01-01', '2014-05-31', '201403')
INSERT INTO HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE) VALUES('9111111','H1111LAC', '006', '2014-01-01', '2014-05-31', '201404')
INSERT INTO HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE) VALUES('9111111','H1111LAC', '006', '2014-01-01', '2014-05-31', '201405')
INSERT INTO HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE) VALUES('9111111','H1111OC', '010', '06-01-2014', '2999-12-31', '201406')
INSERT INTO HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE) VALUES('9111112', 'H1111LAC', '006', '2014-01-01', '2014-05-31', '201401')
INSERT INTO HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE) VALUES('9111112','H1111LAC', '006', '2014-01-01', '2014-05-31', '201402')
INSERT INTO HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE) VALUES('9111112','H1111LAC', '006', '2014-01-01', '2014-05-31', '201403')
INSERT INTO HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE) VALUES('9111112','H1111LAC', '006', '2014-01-01', '2014-05-31', '201404')
INSERT INTO HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE) VALUES('9111112','H1111LAC', '006', '2014-01-01', '2014-05-31', '201405')
INSERT INTO HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE) VALUES('9111112','H1111LAC', '018', '06-01-2014', '2999-12-31', '201406')
INSERT INTO HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE) VALUES('9111113', 'H1111LAC', '006', '2014-01-01', '2999-12-31', '201401')
INSERT INTO HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE) VALUES('9111113','H1111LAC', '006', '2014-01-01', '2999-12-31', '201402')
INSERT INTO HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE) VALUES('9111113','H1111LAC', '006', '2014-01-01', '2999-12-31', '201403')
INSERT INTO HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE) VALUES('9111113','H1111LAC', '006', '2014-01-01', '2999-12-31', '201404')
INSERT INTO HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE) VALUES('9111113','H1111LAC', '006', '2014-01-01', '2999-12-31', '201405')
INSERT INTO HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE) VALUES('9111113','H1111LAC', '006', '2014-01-01', '2999-12-31', '201406')
INSERT INTO HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE) VALUES('9111114','H1111LAC', '006', '2014-01-01', '2014-02-28', '201402')
INSERT INTO HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE) VALUES('9111114','H1111LAC', '006', '2014-04-01', '2999-12-31', '201404')






I need to compress these segments into records which will look like this. The HistoryMonth column
is not used to make the final determination of records to keep.

CUSTOMER PLANNBR SUBPLAN STARTDATE ENDDATE

9111111 H1111LAC 006 2014-01-01 2014-05-31
9111111 H1111OC 010 2014-06-01 2999-12-31
9111112 H1111LAC 006 2014-01-01 2014-05-31
9111112 H1111LAC 018 2014-06-01 2999-12-31
9111113 H1111LAC 006 2014-01-01 2999-12-31
9111114 H1111LAC 006 2014-01-01 2014-02-28
9111114 H1111LAC 006 2014-04-01 2999-12-31


Customer 9111111 shows a change in both PlanNbr and SubPlan 2014-06-01 Need to show both records
Customer 9111112 shows a change in SubPlan 2014-06-01 - Need to show both records
Customer 9111113 shows no change in PlanNbr or SubPlan - Need to show 1 record
Customer 9111114 show a break between and enddate and next start > 1 day - need to show both records



Alan Burstein
Alan Burstein
SSC-Dedicated
SSC-Dedicated (32K reputation)SSC-Dedicated (32K reputation)SSC-Dedicated (32K reputation)SSC-Dedicated (32K reputation)SSC-Dedicated (32K reputation)SSC-Dedicated (32K reputation)SSC-Dedicated (32K reputation)SSC-Dedicated (32K reputation)

Group: General Forum Members
Points: 32775 Visits: 8581
I cleaned up your sample data and came up with a not so optimal solution . This can be greatly improved by removing the need for the DISTINCT clause. Using MAX with and OVER clause is also not a great practice. All that said, here's my solution:


USE Tempdb
GO

IF OBJECT_ID('tempdb..HISTORY') IS NOT NULL DROP TABLE HISTORY;

CREATE TABLE HISTORY
(
CUSTOMER VARCHAR(10),
PLANNBR VARCHAR(10),
SUBPLAN VARCHAR(3),
STARTDATE DATE,
ENDDATE DATE,
HISTORYMONTH VARCHAR(6));
GO

INSERT INTO HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE, HISTORYMONTH)
VALUES
('9111111', 'H1111LAC', '006', '2014-01-01', '2014-05-31', '201401')
,('9111111','H1111LAC', '006', '2014-01-01', '2014-05-31', '201402')
,('9111111','H1111LAC', '006', '2014-01-01', '2014-05-31', '201403')
,('9111111','H1111LAC', '006', '2014-01-01', '2014-05-31', '201404')
,('9111111','H1111LAC', '006', '2014-01-01', '2014-05-31', '201405')
,('9111111','H1111OC', '010', '06-01-2014', '2999-12-31', '201406')
,('9111112', 'H1111LAC', '006', '2014-01-01', '2014-05-31', '201401')
,('9111112','H1111LAC', '006', '2014-01-01', '2014-05-31', '201402')
,('9111112','H1111LAC', '006', '2014-01-01', '2014-05-31', '201403')
,('9111112','H1111LAC', '006', '2014-01-01', '2014-05-31', '201404')
,('9111112','H1111LAC', '006', '2014-01-01', '2014-05-31', '201405')
,('9111112','H1111LAC', '018', '06-01-2014', '2999-12-31', '201406')
,('9111113', 'H1111LAC', '006', '2014-01-01', '2999-12-31', '201401')
,('9111113','H1111LAC', '006', '2014-01-01', '2999-12-31', '201402')
,('9111113','H1111LAC', '006', '2014-01-01', '2999-12-31', '201403')
,('9111113','H1111LAC', '006', '2014-01-01', '2999-12-31', '201404')
,('9111113','H1111LAC', '006', '2014-01-01', '2999-12-31', '201405')
,('9111113','H1111LAC', '006', '2014-01-01', '2999-12-31', '201406')
,('9111114','H1111LAC', '006', '2014-01-01', '2014-02-28', '201402')
,('9111114','H1111LAC', '006', '2014-04-01', '2999-12-31', '201404');

-- THIS IS WHAT YOU NEED:
WITH cte_History (CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE)
AS
(
SELECT 9111111, 'H1111LAC', '006', '2014-01-01', '2014-05-31' UNION ALL
SELECT 9111111, 'H1111OC', '010', '2014-06-01', '2999-12-31' UNION ALL
SELECT 9111112, 'H1111LAC', '006', '2014-01-01', '2014-05-31' UNION ALL
SELECT 9111112, 'H1111LAC', '018', '2014-06-01', '2999-12-31' UNION ALL
SELECT 9111113, 'H1111LAC', '006', '2014-01-01', '2999-12-31' UNION ALL
SELECT 9111114, 'H1111LAC', '006', '2014-01-01', '2014-02-28' UNION ALL
SELECT 9111114, 'H1111LAC', '006', '2014-04-01', '2999-12-31'
)
SELECT * FROM cte_history;

-- My not-so-optimal solution
WITH base AS
(
SELECT CUSTOMER,
PLANNBR,
SUBPLAN,
STARTDATE
FROM HISTORY
GROUP BY CUSTOMER, PLANNBR, SUBPLAN, STARTDATE
)
SELECT DISTINCT b.*, MAX(ENDDATE) OVER (PARTITION BY b.CUSTOMER, b.PLANNBR, b.SUBPLAN, b.STARTDATE)
FROM base b
CROSS APPLY HISTORY h
WHERE h.CUSTOMER = b.CUSTOMER
AND h.PLANNBR = b.PLANNBR
AND h.SUBPLAN = b.SUBPLAN
AND h.STARTDATE = b.STARTDATE;




Edit: code formatting.

-- Alan Burstein


Helpful links:

Best practices for getting help on SQLServerCentral -- Jeff Moden
How to Post Performance Problems -- Gail Shaw

Nasty fast set-based string manipulation functions:
For splitting strings try DelimitedSplit8K or DelimitedSplit8K_LEAD (SQL Server 2012+)
To split strings based on patterns try PatternSplitCM
Need to clean or transform a string? try NGrams, PatExclude8K, PatReplace8K, DigitsOnlyEE, or Translate8K

I cant stress enough the importance of switching from a sequential files mindset to set-based thinking. After you make the switch, you can spend your time tuning and optimizing your queries instead of maintaining lengthy, poor-performing code. -- Itzik Ben-Gan 2001

Eirikur Eiriksson
Eirikur Eiriksson
SSC Guru
SSC Guru (94K reputation)SSC Guru (94K reputation)SSC Guru (94K reputation)SSC Guru (94K reputation)SSC Guru (94K reputation)SSC Guru (94K reputation)SSC Guru (94K reputation)SSC Guru (94K reputation)

Group: General Forum Members
Points: 94776 Visits: 20693
No need to complicate things, the only thing needed here is correct window specification for the row_number function.
Cool

;WITH HISTORY_BASE AS
(
SELECT
ROW_NUMBER() OVER
(
PARTITION BY HS.CUSTOMER
,HS.PLANNBR
,HS.SUBPLAN
,HS.STARTDATE
,HS.ENDDATE
ORDER BY HS.HISTORYMONTH
) AS CUST_RID
,HS.CUSTOMER
,HS.PLANNBR
,HS.SUBPLAN
,HS.STARTDATE
,HS.ENDDATE
FROM dbo.HISTORY HS
)

SELECT
HB.CUSTOMER
,HB.PLANNBR
,HB.SUBPLAN
,HB.STARTDATE
,HB.ENDDATE
FROM HISTORY_BASE HB
WHERE HB.CUST_RID = 1;



Results
CUSTOMER   PLANNBR    SUBPLAN STARTDATE  ENDDATE
---------- ---------- ------- ---------- ----------
9111111 H1111LAC 006 2014-01-01 2014-05-31
9111111 H1111OC 010 2014-06-01 2999-12-31
9111112 H1111LAC 006 2014-01-01 2014-05-31
9111112 H1111LAC 018 2014-06-01 2999-12-31
9111113 H1111LAC 006 2014-01-01 2999-12-31
9111114 H1111LAC 006 2014-01-01 2014-02-28
9111114 H1111LAC 006 2014-04-01 2999-12-31


This can be improved by adding an index which results in an execution plan without the sort operator, something like this
CREATE UNIQUE NONCLUSTERED INDEX [IDX_DBO_HISTORY_POC_DD] ON [dbo].[HISTORY]
(
[CUSTOMER] ASC,
[PLANNBR] ASC,
[SUBPLAN] ASC,
[STARTDATE] ASC,
[ENDDATE] ASC,
[HISTORYMONTH] ASC
)



This brings the cost of execution for this code down to aprox. 5% of the previous code.
Alan Burstein
Alan Burstein
SSC-Dedicated
SSC-Dedicated (32K reputation)SSC-Dedicated (32K reputation)SSC-Dedicated (32K reputation)SSC-Dedicated (32K reputation)SSC-Dedicated (32K reputation)SSC-Dedicated (32K reputation)SSC-Dedicated (32K reputation)SSC-Dedicated (32K reputation)

Group: General Forum Members
Points: 32775 Visits: 8581
Eirikur Eiriksson (7/8/2014)
No need to complicate things, the only thing needed here is correct window specification for the row_number function.
Cool ...This brings the cost of execution for this code down to aprox. 5% of the previous code.


Very well done sir!

-- Alan Burstein


Helpful links:

Best practices for getting help on SQLServerCentral -- Jeff Moden
How to Post Performance Problems -- Gail Shaw

Nasty fast set-based string manipulation functions:
For splitting strings try DelimitedSplit8K or DelimitedSplit8K_LEAD (SQL Server 2012+)
To split strings based on patterns try PatternSplitCM
Need to clean or transform a string? try NGrams, PatExclude8K, PatReplace8K, DigitsOnlyEE, or Translate8K

I cant stress enough the importance of switching from a sequential files mindset to set-based thinking. After you make the switch, you can spend your time tuning and optimizing your queries instead of maintaining lengthy, poor-performing code. -- Itzik Ben-Gan 2001

Eirikur Eiriksson
Eirikur Eiriksson
SSC Guru
SSC Guru (94K reputation)SSC Guru (94K reputation)SSC Guru (94K reputation)SSC Guru (94K reputation)SSC Guru (94K reputation)SSC Guru (94K reputation)SSC Guru (94K reputation)SSC Guru (94K reputation)

Group: General Forum Members
Points: 94776 Visits: 20693
Alan.B (7/9/2014)
Eirikur Eiriksson (7/8/2014)
No need to complicate things, the only thing needed here is correct window specification for the row_number function.
Cool ...This brings the cost of execution for this code down to aprox. 5% of the previous code.


Very well done sir!

Thanks Alan, appreciate it!
Cool
sgmunson
sgmunson
SSC-Forever
SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)SSC-Forever (43K reputation)

Group: General Forum Members
Points: 43646 Visits: 5422
I'm not even sure you need a row number function. You appear to just be selecting the distinct values for the CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, and ENDDATE, which can allow for use of either DISTINCT or GROUP BY.

Here's the code:


DECLARE @HISTORY AS TABLE (
CUSTOMER VARCHAR(10),
PLANNBR VARCHAR(10),
SUBPLAN VARCHAR(3),
STARTDATE DATETIME,
ENDDATE DATETIME,
HISTORYMONTH VARCHAR(6)
)
INSERT INTO @HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE, HISTORYMONTH) VALUES('9111111', 'H1111LAC', '006', '2014-01-01', '2014-05-31', '201401')
INSERT INTO @HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE, HISTORYMONTH) VALUES('9111111','H1111LAC', '006', '2014-01-01', '2014-05-31', '201402')
INSERT INTO @HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE, HISTORYMONTH) VALUES('9111111','H1111LAC', '006', '2014-01-01', '2014-05-31', '201403')
INSERT INTO @HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE, HISTORYMONTH) VALUES('9111111','H1111LAC', '006', '2014-01-01', '2014-05-31', '201404')
INSERT INTO @HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE, HISTORYMONTH) VALUES('9111111','H1111LAC', '006', '2014-01-01', '2014-05-31', '201405')
INSERT INTO @HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE, HISTORYMONTH) VALUES('9111111','H1111OC', '010', '06-01-2014', '2999-12-31', '201406')
INSERT INTO @HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE, HISTORYMONTH) VALUES('9111112', 'H1111LAC', '006', '2014-01-01', '2014-05-31', '201401')
INSERT INTO @HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE, HISTORYMONTH) VALUES('9111112','H1111LAC', '006', '2014-01-01', '2014-05-31', '201402')
INSERT INTO @HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE, HISTORYMONTH) VALUES('9111112','H1111LAC', '006', '2014-01-01', '2014-05-31', '201403')
INSERT INTO @HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE, HISTORYMONTH) VALUES('9111112','H1111LAC', '006', '2014-01-01', '2014-05-31', '201404')
INSERT INTO @HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE, HISTORYMONTH) VALUES('9111112','H1111LAC', '006', '2014-01-01', '2014-05-31', '201405')
INSERT INTO @HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE, HISTORYMONTH) VALUES('9111112','H1111LAC', '018', '06-01-2014', '2999-12-31', '201406')
INSERT INTO @HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE, HISTORYMONTH) VALUES('9111113', 'H1111LAC', '006', '2014-01-01', '2999-12-31', '201401')
INSERT INTO @HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE, HISTORYMONTH) VALUES('9111113','H1111LAC', '006', '2014-01-01', '2999-12-31', '201402')
INSERT INTO @HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE, HISTORYMONTH) VALUES('9111113','H1111LAC', '006', '2014-01-01', '2999-12-31', '201403')
INSERT INTO @HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE, HISTORYMONTH) VALUES('9111113','H1111LAC', '006', '2014-01-01', '2999-12-31', '201404')
INSERT INTO @HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE, HISTORYMONTH) VALUES('9111113','H1111LAC', '006', '2014-01-01', '2999-12-31', '201405')
INSERT INTO @HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE, HISTORYMONTH) VALUES('9111113','H1111LAC', '006', '2014-01-01', '2999-12-31', '201406')
INSERT INTO @HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE, HISTORYMONTH) VALUES('9111114','H1111LAC', '006', '2014-01-01', '2014-02-28', '201402')
INSERT INTO @HISTORY(CUSTOMER, PLANNBR, SUBPLAN, STARTDATE, ENDDATE, HISTORYMONTH) VALUES('9111114','H1111LAC', '006', '2014-04-01', '2999-12-31', '201404')

SELECT H.CUSTOMER, H.PLANNBR, H.SUBPLAN, H.STARTDATE, H.ENDDATE
FROM @HISTORY AS H
GROUP BY H.CUSTOMER, H.PLANNBR, H.SUBPLAN, H.STARTDATE, H.ENDDATE



Steve
‌(aka sgmunson)
Smile Smile Smile
Health & Nutrition
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