Creating rows based on date range from another table

Collapse
This topic is closed.
X
X
 
  • Time
  • Show
Clear All
new posts
  • rcamarda

    Creating rows based on date range from another table

    I wish to build a table based on values from another table.
    I need to populate a table between two dates from another table. Using
    the START_DT and END_DT, create records between those dates.
    I need a new column that is the days between the date and the MID_DT
    The data I wish to end with would look something like this:

    PERIOD DATE DAY_NO
    200602 2005-07-06 -89
    200602 2005-07-07 -88
    200602 2005-07-08 -87
    <...>
    200602 2005-10-02 -2
    200602 2005-10-03 -1
    200602 2005-10-04 0
    200602 2005-10-05 1
    <...>
    200602 2005-12-18 75

    CREATE TABLE "dbo"."tblDates "
    ("PERIOD" CHAR(6) NOT NULL,
    "START_DT" DATETIME NULL,
    "MID_DT" DATETIME NULL,
    "END_DT" DATETIME NOT NULL)

    INSERT INTO tblDates VALUES('200505' ,2005-04-12,2005-07-05,2005-09-12)
    INSERT INTO tblDates VALUES('200602' ,2005-07-06,2005-10-03,2005-12-18)
    INSERT INTO tblDates VALUES('200603' ,2005-10-04,2006-01-17,2006-03-27)
    INSERT INTO tblDates VALUES('200604' ,2006-01-18,2006-04-10,2006-06-19)
    INSERT INTO tblDates VALUES('200605' ,2006-04-11,2006-07-04,2006-09-11)
    INSERT INTO tblDates VALUES('200702' ,2006-07-05,2006-10-02,2006-12-18)

  • Erland Sommarskog

    #2
    Re: Creating rows based on date range from another table

    rcamarda (robc390@hotmai l.com) writes:
    I wish to build a table based on values from another table.
    I need to populate a table between two dates from another table. Using
    the START_DT and END_DT, create records between those dates.
    I need a new column that is the days between the date and the MID_DT
    The data I wish to end with would look something like this:
    >
    PERIOD DATE DAY_NO
    200602 2005-07-06 -89
    200602 2005-07-07 -88
    200602 2005-07-08 -87
    ><...>
    200602 2005-10-02 -2
    200602 2005-10-03 -1
    200602 2005-10-04 0
    200602 2005-10-05 1
    ><...>
    200602 2005-12-18 75
    >
    CREATE TABLE "dbo"."tblDates "
    ("PERIOD" CHAR(6) NOT NULL,
    "START_DT" DATETIME NULL,
    "MID_DT" DATETIME NULL,
    "END_DT" DATETIME NOT NULL)
    >
    INSERT INTO tblDates VALUES('200505' ,2005-04-12,2005-07-05,2005-09-12)
    INSERT INTO tblDates VALUES('200602' ,2005-07-06,2005-10-03,2005-12-18)
    INSERT INTO tblDates VALUES('200603' ,2005-10-04,2006-01-17,2006-03-27)
    INSERT INTO tblDates VALUES('200604' ,2006-01-18,2006-04-10,2006-06-19)
    INSERT INTO tblDates VALUES('200605' ,2006-04-11,2006-07-04,2006-09-11)
    INSERT INTO tblDates VALUES('200702' ,2006-07-05,2006-10-02,2006-12-18)
    Thanks for posting table definition and data. However, I would appreciate
    if you also tested your repro script before you post. I was puzzled not
    getting any rows back first from my query, but then I realised that
    2005-04-12 2005-09-12. (Run the above folliwed by a SELECT on the
    table to see why.)

    Anyway, as I said in another newsgroup, you need a table of numbers. Here
    is a way to create such a table with a million numbers:

    CREATE TABLE Numbers (Number int NOT NULL PRIMARY KEY);
    WITH digits (d) AS (
    SELECT 1 UNION SELECT 2 UNION SELECT 3 UNION
    SELECT 4 UNION SELECT 5 UNION SELECT 6 UNION
    SELECT 7 UNION SELECT 8 UNION SELECT 9 UNION
    SELECT 0)
    INSERT Numbers (Number)
    SELECT Number
    FROM (SELECT i.d + ii.d * 10 + iii.d * 100 + iv.d * 1000 +
    v.d * 10000 + vi.d * 100000 AS Number
    FROM digits i
    CROSS JOIN digits ii
    CROSS JOIN digits iii
    CROSS JOIN digits iv
    CROSS JOIN digits v
    CROSS JOIN digits vi) AS Numbers
    WHERE Number 0

    Given this table, we can write this query:

    SELECT d.PERIOD, dateadd(DAY, n.Number - 1, d.START_DT),
    datediff(DAY, d.MID_DT, dateadd(DAY, n.Number - 1, d.START_DT))
    FROM tblDates d
    CROSS JOIN Numbers n
    WHERE dateadd(DAY, n.Number - 1, d.START_DT)
    BETWEEN d.START_DT AND d.END_DT
    ORDER BY d.PERIOD, 2


    --
    Erland Sommarskog, SQL Server MVP, esquel@sommarsk og.se

    Books Online for SQL Server 2005 at

    Books Online for SQL Server 2000 at

    Comment

    • rcamarda

      #3
      Re: Creating rows based on date range from another table

      Erland,
      Sorry about the insert, i see that its returning what I did not expect.
      Originally I had the dates quoted, but sql bawked at that. I've been
      trying to fix the insert, but after trying cast and convert, it still
      wont go.
      This gives error about conversion:
      INSERT INTO tblDates VALUES ( '200602',cast(' 2005-07-06' AS
      DATETIME),CAST( '2005-10-03' AS DATETIME), CAST('2005-12-18' AS
      DATETIME))
      AH! Finally got this to work:
      INSERT INTO tblDates VALUES ('200505' ,convert(dateti me,
      '2005-04-12'),convert(da tetime,'2005-07-05'),
      convert(datetim e,'2005-09-12' ))

      Im still trying to grasp the use of the numbers table. I have a D_Day
      table that is the days from 1900 - 2100. Could that be used somehow?
      (1900-01-01 has a surrogate key of 1 and 1900-01-02 is 2 and so forth)
      You solution works, which I am appreciative of, tho it will take me
      working with the code to figure out why :)
      Thanks for teaching me something new!
      Rob




      Erland Sommarskog wrote:
      rcamarda (robc390@hotmai l.com) writes:
      I wish to build a table based on values from another table.
      I need to populate a table between two dates from another table. Using
      the START_DT and END_DT, create records between those dates.
      I need a new column that is the days between the date and the MID_DT
      The data I wish to end with would look something like this:

      PERIOD DATE DAY_NO
      200602 2005-07-06 -89
      200602 2005-07-07 -88
      200602 2005-07-08 -87
      <...>
      200602 2005-10-02 -2
      200602 2005-10-03 -1
      200602 2005-10-04 0
      200602 2005-10-05 1
      <...>
      200602 2005-12-18 75

      CREATE TABLE "dbo"."tblDates "
      ("PERIOD" CHAR(6) NOT NULL,
      "START_DT" DATETIME NULL,
      "MID_DT" DATETIME NULL,
      "END_DT" DATETIME NOT NULL)

      INSERT INTO tblDates VALUES('200505' ,2005-04-12,2005-07-05,2005-09-12)
      INSERT INTO tblDates VALUES('200602' ,2005-07-06,2005-10-03,2005-12-18)
      INSERT INTO tblDates VALUES('200603' ,2005-10-04,2006-01-17,2006-03-27)
      INSERT INTO tblDates VALUES('200604' ,2006-01-18,2006-04-10,2006-06-19)
      INSERT INTO tblDates VALUES('200605' ,2006-04-11,2006-07-04,2006-09-11)
      INSERT INTO tblDates VALUES('200702' ,2006-07-05,2006-10-02,2006-12-18)
      >
      Thanks for posting table definition and data. However, I would appreciate
      if you also tested your repro script before you post. I was puzzled not
      getting any rows back first from my query, but then I realised that
      2005-04-12 2005-09-12. (Run the above folliwed by a SELECT on the
      table to see why.)
      >
      Anyway, as I said in another newsgroup, you need a table of numbers. Here
      is a way to create such a table with a million numbers:
      >
      CREATE TABLE Numbers (Number int NOT NULL PRIMARY KEY);
      WITH digits (d) AS (
      SELECT 1 UNION SELECT 2 UNION SELECT 3 UNION
      SELECT 4 UNION SELECT 5 UNION SELECT 6 UNION
      SELECT 7 UNION SELECT 8 UNION SELECT 9 UNION
      SELECT 0)
      INSERT Numbers (Number)
      SELECT Number
      FROM (SELECT i.d + ii.d * 10 + iii.d * 100 + iv.d * 1000 +
      v.d * 10000 + vi.d * 100000 AS Number
      FROM digits i
      CROSS JOIN digits ii
      CROSS JOIN digits iii
      CROSS JOIN digits iv
      CROSS JOIN digits v
      CROSS JOIN digits vi) AS Numbers
      WHERE Number 0
      >
      Given this table, we can write this query:
      >
      SELECT d.PERIOD, dateadd(DAY, n.Number - 1, d.START_DT),
      datediff(DAY, d.MID_DT, dateadd(DAY, n.Number - 1, d.START_DT))
      FROM tblDates d
      CROSS JOIN Numbers n
      WHERE dateadd(DAY, n.Number - 1, d.START_DT)
      BETWEEN d.START_DT AND d.END_DT
      ORDER BY d.PERIOD, 2
      >
      >
      --
      Erland Sommarskog, SQL Server MVP, esquel@sommarsk og.se
      >
      Books Online for SQL Server 2005 at

      Books Online for SQL Server 2000 at
      http://www.microsoft.com/sql/prodinf...ons/books.mspx

      Comment

      • Erland Sommarskog

        #4
        Re: Creating rows based on date range from another table

        rcamarda (robc390@hotmai l.com) writes:
        Sorry about the insert, i see that its returning what I did not expect.
        Originally I had the dates quoted, but sql bawked at that. I've been
        trying to fix the insert, but after trying cast and convert, it still
        wont go.
        This gives error about conversion:
        INSERT INTO tblDates VALUES ( '200602',cast(' 2005-07-06' AS
        Yes, the above format could fail. There are three date formats in SQL
        Server that are safe:

        YYYYMMDD
        YYYYMMDDTHH:MM: SS[.fff]
        YYYY-MM-DDZ

        Here T and Z stand for themselves.

        Other formats are interpretated depending on DATEFORMAT and LANGUAGE
        setting, and can fail or produced unexpected results if you don't know
        what is going on.
        Im still trying to grasp the use of the numbers table. I have a D_Day
        table that is the days from 1900 - 2100. Could that be used somehow?
        (1900-01-01 has a surrogate key of 1 and 1900-01-02 is 2 and so forth)
        Yes, that dates table is essentially a table of numbers with a different
        names. In fact, it appears that it has all the numbers as well!

        I used a table of numbers, as numbers is the more general concept and
        can be used in more places. But in fact, I added a table of dates to
        our system before I added a table of numbers.

        I leave it as an exercise to you how to use the dates table instead.
        --
        Erland Sommarskog, SQL Server MVP, esquel@sommarsk og.se

        Books Online for SQL Server 2005 at

        Books Online for SQL Server 2000 at

        Comment

        • Ed Murphy

          #5
          Re: Creating rows based on date range from another table

          On Sun, 20 Aug 2006 12:38:11 +0000 (UTC), Erland Sommarskog
          <esquel@sommars kog.sewrote:
          >rcamarda (robc390@hotmai l.com) writes:
          >I wish to build a table based on values from another table.
          >I need to populate a table between two dates from another table. Using
          >the START_DT and END_DT, create records between those dates.
          >I need a new column that is the days between the date and the MID_DT
          >The data I wish to end with would look something like this:
          >>
          >PERIOD DATE DAY_NO
          >200602 2005-07-06 -89
          >200602 2005-07-07 -88
          >200602 2005-07-08 -87
          >><...>
          >200602 2005-10-02 -2
          >200602 2005-10-03 -1
          >200602 2005-10-04 0
          >200602 2005-10-05 1
          >><...>
          >200602 2005-12-18 75
          [snip]
          >INSERT INTO tblDates VALUES('200602' ,2005-07-06,2005-10-03,2005-12-18)
          >Anyway, as I said in another newsgroup, you need a table of numbers. Here
          >is a way to create such a table with a million numbers:
          What are the pros and cons of relying on such a table vs. using a
          WHILE loop? Based on Rob's context of student registrations, let's
          assume we're talking about a maximum of 300 iterations per row in
          the original tblDates table.

          Comment

          • Erland Sommarskog

            #6
            Re: Creating rows based on date range from another table

            Ed Murphy (emurphy42@soca l.rr.com) writes:
            What are the pros and cons of relying on such a table vs. using a
            WHILE loop? Based on Rob's context of student registrations, let's
            assume we're talking about a maximum of 300 iterations per row in
            the original tblDates table.
            The one risk with a table of numbers is that if you run of numbers, you
            will get an incorrect result. That is one reason why I'm reluctant to
            use it, if there are alternative solutions. But for a case like this,
            when you need to fill up a space, a table of numbers - or dates - is what
            you need.

            A loop is more complex to program, and easier go wrong. And as a generic
            solution, you face scalability problems.



            --
            Erland Sommarskog, SQL Server MVP, esquel@sommarsk og.se

            Books Online for SQL Server 2005 at

            Books Online for SQL Server 2000 at

            Comment

            • Ed Murphy

              #7
              Re: Creating rows based on date range from another table

              On Mon, 21 Aug 2006 08:05:49 +0000 (UTC), Erland Sommarskog
              <esquel@sommars kog.sewrote:
              >Ed Murphy (emurphy42@soca l.rr.com) writes:
              >What are the pros and cons of relying on such a table vs. using a
              >WHILE loop? Based on Rob's context of student registrations, let's
              >assume we're talking about a maximum of 300 iterations per row in
              >the original tblDates table.
              >
              >The one risk with a table of numbers is that if you run of numbers, you
              >will get an incorrect result. That is one reason why I'm reluctant to
              >use it, if there are alternative solutions. But for a case like this,
              >when you need to fill up a space, a table of numbers - or dates - is what
              >you need.
              >
              >A loop is more complex to program, and easier go wrong.
              I disagree, but then I have somewhat more experience with imperative
              than functional programming. Consider:

              x = first_date
              while x <= last_date
              insert x, datediff(x, mid_date) into <table>
              x = dateadd(x, 1)
              end while

              versus

              select dateadd(first_d ate, n), n - datediff(mid_da te, first_date)
              into <table>
              from numbers
              where n between 0 and datediff(end_da te, first_date)

              Okay, "where n between <limits>" makes sense as an analogue to a while
              loop, but that stuff in line 1 looks like the stuff of headaches.
              And as a generic
              >solution, you face scalability problems.
              I kind of figured. The query seems easy to get wrong, though, if
              you're not familiar with the pattern; I first wrote it as "where
              dateadd(first_d ate, n) between first_date and last_date", but that
              seems like it'd be a good bit slower.

              Comment

              • Erland Sommarskog

                #8
                Re: Creating rows based on date range from another table

                Ed Murphy (emurphy42@soca l.rr.com) writes:
                I disagree, but then I have somewhat more experience with imperative
                than functional programming. Consider:
                >
                x = first_date
                while x <= last_date
                insert x, datediff(x, mid_date) into <table>
                x = dateadd(x, 1)
                end while
                >
                versus
                >
                select dateadd(first_d ate, n), n - datediff(mid_da te, first_date)
                into <table>
                from numbers
                where n between 0 and datediff(end_da te, first_date)
                >
                Okay, "where n between <limits>" makes sense as an analogue to a while
                loop, but that stuff in line 1 looks like the stuff of headaches.
                Loops are particularly prone to two sorts of errors:

                * They goes on forever, could be because of a sloppy mistake, of because the
                logic is complicated.
                * One-off errors because of incorrect loop conditions.

                One-off errors are easy to make with set-based queries as well, but the
                risk of infinite loops is nothing you have to lose sleep over.

                --
                Erland Sommarskog, SQL Server MVP, esquel@sommarsk og.se

                Books Online for SQL Server 2005 at

                Books Online for SQL Server 2000 at

                Comment

                Working...