SQL to create Timeslot Table between StartTime and Endtime of a day

  • Hi,

    Need help in dynamically creating a Timeslot table based on office hour StartTime and EndTime((like 2.30pm-4.30pm, timeslots hv to be 30 mins interval) Any help is greatly appreciated.

    Thanks

  • somabk2007 (9/12/2012)


    Hi,

    Need help in dynamically creating a Timeslot table based on office hour StartTime and EndTime((like 2.30pm-4.30pm, timeslots hv to be 30 mins interval) Any help is greatly appreciated.

    Thanks

    Some idea of the justification and the structure would be helpful as you may find we come up with an alternative/better solution.

    Dynamically creating DDL is generally not a good idea.

  • OfficeId WeekdayId StartTime EndTime

    ------------------------------------------------------------------------

    12 2.30pm4.30pm **

    13 4.00pm 6.00pm

    For 30 min timeinterval

    this table should be populated: By dynamically i meant at run time this should be populated for marked **

    Officeid weekdayid Timeslot

    -----------------------------------------

    1 2 2.30pm-3.00pm

    1 2 3.00pm-3.30pm

    1 2 3.30pm-4.00pm

    1 2 4.00pm-4.30pm

  • sbk2007 (9/12/2012)


    OfficeId WeekdayId StartTime EndTime

    ------------------------------------------------------------------------

    12 2.30pm4.30pm **

    13 4.00pm 6.00pm

    For 30 min timeinterval

    this table should be populated: By dynamically i meant at run time this should be populated for marked **

    Officeid weekdayid Timeslot

    -----------------------------------------

    1 2 2.30pm-3.00pm

    1 2 3.00pm-3.30pm

    1 2 3.30pm-4.00pm

    1 2 4.00pm-4.30pm

    I see that you are new around here. It would help greatly if we had ddl (create table statements) and sample data (insert statements) along with desired output based on your sample data.

    Take a look at the first link in my signature for best practices when posting questions. You will be rewarded for your efforts with test and fast code.

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • Assuming you're using a TIME field to store your values, you can use a Tally table and the built-in DATEADD/DATEDIFF functions for this:

    DECLARE @t TABLE

    (OfficeId INT, WeekdayId INT, StartTime TIME, EndTime TIME)

    INSERT INTO @t

    SELECT 1, 2, '14:30', '16:30'

    UNION ALL SELECT 1, 3, '16:00', '18:00'

    ;WITH Tally (n) AS (

    SELECT TOP 100 30*(ROW_NUMBER() OVER (ORDER BY (SELECT NULL))-1)

    FROM sys.all_columns)

    SELECT OfficeID, WeekdayID

    ,TSStart=DATEADD(minute, n, StartTime)

    ,TSEnd=DATEADD(minute, n + 30, StartTime)

    ,Timeslot=CONVERT(VARCHAR(100), DATEADD(minute, n, StartTime), 0) + ' - ' +

    CONVERT(VARCHAR(100), DATEADD(minute, n + 30, StartTime), 0)

    FROM @t

    CROSS APPLY (

    SELECT n

    FROM Tally

    WHERE n BETWEEN 0 AND DATEDIFF(minute, StartTime, DATEADD(minute, -30, EndTime))) a

    ORDER BY OfficeID, WeekdayID, TSStart


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.

    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

  • Thanks so much, well I had already achieved the resultset yesterday (but with loop:)) urs worked liked a breeze without loop!!Thanks again..

  • sbk2007 (9/13/2012)


    Thanks so much, well I had already achieved the resultset yesterday (but with loop:)) urs worked liked a breeze without loop!!Thanks again..

    Important lesson here is that looping should be avoided except in a few cases. More importantly do you understand the code that dwain posted? It is going to be you that gets the phone in the middle of the night when production goes down. That is NOT the time to try to understand the code you got from some guy on the internet that worked at the time.

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • Sean Lange (9/13/2012)


    ...some guy on the internet

    I think I'll change my board name. 🙂


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.

    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

  • dwain.c (9/13/2012)


    Sean Lange (9/13/2012)


    ...some guy on the internet

    I think I'll change my board name. 🙂

    LOL by no means was any disrespect intended good sir. 😀 I of course would be to cite who but the OP has a total of 4 points so I doubt they have any knowledge of you other than the couple of posts in this thread. Under pressure all the OP would be able to come up with is "some guy on the internet". Aww screw it, you know what I mean.

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • Sean Lange (9/13/2012)


    dwain.c (9/13/2012)


    Sean Lange (9/13/2012)


    ...some guy on the internet

    I think I'll change my board name. 🙂

    LOL by no means was any disrespect intended good sir. 😀 I of course would be to cite who but the OP has a total of 4 points so I doubt they have any knowledge of you other than the couple of posts in this thread. Under pressure all the OP would be able to come up with is "some guy on the internet". Aww screw it, you know what I mean.

    No offence taken. I seriously like it.

    Maybe "some a*s*o*e on the internet" would be better though.


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.

    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

Viewing 10 posts - 1 through 9 (of 9 total)

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