Compress table timelines

  • 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.

    CUSTOMERPLANNBRSUBPLANSTARTDATEENDDATE

    9111111H1111LAC0062014-01-012014-05-31

    9111111H1111OC0102014-06-012999-12-31

    9111112H1111LAC0062014-01-012014-05-31

    9111112H1111LAC0182014-06-012999-12-31

    9111113H1111LAC0062014-01-012999-12-31

    9111114H1111LAC0062014-01-012014-02-28

    9111114H1111LAC0062014-04-012999-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

  • 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

    (

    SELECTCUSTOMER,

    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.

    "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

  • No need to complicate things, the only thing needed here is correct window specification for the row_number function.

    😎

    ;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.

  • Eirikur Eiriksson (7/8/2014)


    No need to complicate things, the only thing needed here is correct window specification for the row_number function.

    😎 ...This brings the cost of execution for this code down to aprox. 5% of the previous code.

    Very well done sir!

    "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

  • 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.

    😎 ...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!

    😎

  • 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) 🙂 🙂 🙂
    Rent Servers for Income (picks and shovels strategy)

Viewing 6 posts - 1 through 5 (of 5 total)

You must be logged in to reply to this topic. Login to reply