January 6, 2012 at 6:01 am
Hi
I need to take a set of records for people with hotel check-in/check-out dates, and display a table that has a column for each date in the range, with a 1 if they need a room that night, or 0 if they don't.
e.g.
PersonID,Name,Checkin,Checkout
1,Fred,2012-01-02,2012-01-05
2,Bob,2012-01-01,2012-01-04
would produce the result:
PersonID,Name,Jan 1 2012,Jan 2 2012,Jan 3 2012,Jan 4 2012,Jan 5 2012
1,Fred,0,1,1,1,0
2,Bob,1,1,1,0,0
(people need a room on the night they check in, but not on the night they check out).
I'm not sure where to start! It looks like something that pivots are meant to address, but don't fully understand them yet, a stored proc or a table-value function. I'm inclined to think the table-value function would give me the most flexibility as I could join PersonID to other tables to get more data about the people if needed.
Any suggestions/similar sample code would be much appreciated.
Nick
January 6, 2012 at 6:09 am
IMO , this sort of formatting should be dealt with at the client level,
use SSRS, excel or whatever to do this.
January 6, 2012 at 6:11 am
nick-1043370 (1/6/2012)
HiI need to take a set of records for people with hotel check-in/check-out dates, and display a table that has a column for each date in the range, with a 1 if they need a room that night, or 0 if they don't.
e.g.
PersonID,Name,Checkin,Checkout
1,Fred,2012-01-02,2012-01-05
2,Bob,2012-01-01,2012-01-04
would produce the result:
PersonID,Name,Jan 1 2012,Jan 2 2012,Jan 3 2012,Jan 4 2012,Jan 5 2012
1,Fred,0,1,1,1,0
2,Bob,1,1,1,0,0
(people need a room on the night they check in, but not on the night they check out).
I'm not sure where to start! It looks like something that pivots are meant to address, but don't fully understand them yet, a stored proc or a table-value function. I'm inclined to think the table-value function would give me the most flexibility as I could join PersonID to other tables to get more data about the people if needed.
Any suggestions/similar sample code would be much appreciated.
Nick
Can you provide some more detail about the date range, Nick?
Will it always be a single month, starting at the 1st? = simple
Random number of days, starting at random DOM = harder.
Cheers
For better assistance in answering your questions, please read this[/url].
Hidden RBAR: Triangular Joins[/url] / The "Numbers" or "Tally" Table: What it is and how it replaces a loop[/url] Jeff Moden[/url]
January 6, 2012 at 6:28 am
Dave - Fair point, but there's a bit of (dull) background as to why I'm looking down other paths...
As it happens we do it in SSRS at the moment, but to keep my post from confusing everyone I didn't mention that once I've got the data returned in column-per-date format I then want to do some calculations, such as room cost, total room cost for all people each night etc.
If I use an SSRS matrix/tablix then I really struggle to then do the calculations because there's no handle to grab on to for each date if the columns are generated at runtime. I would set fixed columns for each date, but need to produce this report quite regularly, for different date ranges each time!
I still want to use SSRS to deliver the results to the user at the end. It would just help if the query behind that report already had a column for each date.
January 6, 2012 at 6:32 am
Hi Chris
The bummer is it's a different date range each time! Ideally I'd like whatever code I use to get the date range in question first, i.e. find the min check-in date and max check-out date from the dataset, and show date columns accordingly.
I didn't think it would be easy!:-)
January 6, 2012 at 6:41 am
nick-1043370 (1/6/2012)
Hi ChrisThe bummer is it's a different date range each time! Ideally I'd like whatever code I use to get the date range in question first, i.e. find the min check-in date and max check-out date from the dataset, and show date columns accordingly.
I didn't think it would be easy!:-)
It's surprisingly easy when you have sample data to work with 😉
Please could you read the article linked to in my sig, Nick? You're new here - welcome aboard - the article will explain to you how best to pose a question for a speedy and accurate reply (which you've done) and how to set up easily-consumable sample data.
Cheers
For better assistance in answering your questions, please read this[/url].
Hidden RBAR: Triangular Joins[/url] / The "Numbers" or "Tally" Table: What it is and how it replaces a loop[/url] Jeff Moden[/url]
January 8, 2012 at 6:48 pm
nick-1043370 (1/6/2012)
HiI need to take a set of records for people with hotel check-in/check-out dates, and display a table that has a column for each date in the range, with a 1 if they need a room that night, or 0 if they don't.
e.g.
PersonID,Name,Checkin,Checkout
1,Fred,2012-01-02,2012-01-05
2,Bob,2012-01-01,2012-01-04
would produce the result:
PersonID,Name,Jan 1 2012,Jan 2 2012,Jan 3 2012,Jan 4 2012,Jan 5 2012
1,Fred,0,1,1,1,0
2,Bob,1,1,1,0,0
(people need a room on the night they check in, but not on the night they check out).
I'm not sure where to start! It looks like something that pivots are meant to address, but don't fully understand them yet, a stored proc or a table-value function. I'm inclined to think the table-value function would give me the most flexibility as I could join PersonID to other tables to get more data about the people if needed.
Any suggestions/similar sample code would be much appreciated.
Nick
Ok... I'm confused. People would almost always need the room for the night they checkin and never need a room for the night they checkout. Why would BOB not need his room for the last two nights and why would Fred not need his room on the day of Checkin (according to the data you posted).
Also, where are you getting THAT bit of information from?
--Jeff Moden
Change is inevitable... Change for the better is not.
January 9, 2012 at 12:46 am
USE tempdb
-- Test data
CREATE TABLE dbo.Reservations
(
PersonID integer NOT NULL,
CheckIn date NOT NULL,
CheckOut date NOT NULL,
CHECK (CheckOut >= CheckIn)
)
GO
INSERT dbo.Reservations
(PersonID, CheckIn, CheckOut)
VALUES
(1, {D '2012-01-02'}, {D '2012-01-05'}),
(2, {D '2012-01-01'}, {D '2012-01-04'})
CREATE TABLE #Unpivoted
(
PersonID integer NOT NULL,
TheDate date NOT NULL,
PRIMARY KEY (TheDate, PersonID),
UNIQUE (PersonID, TheDate)
);
-- Standard in-line numbers table
WITH
N1 AS (SELECT N1.n FROM (VALUES (1),(1),(1),(1),(1),(1),(1),(1),(1),(1)) AS N1 (n)),
N2 AS (SELECT L.n FROM N1 AS L CROSS JOIN N1 AS R),
N3 AS (SELECT L.n FROM N2 AS L CROSS JOIN N2 AS R),
N4 AS (SELECT L.n FROM N3 AS L CROSS JOIN N3 AS R),
Numbers AS (SELECT ROW_NUMBER() OVER (ORDER BY @@SPID) AS n FROM N4)
-- Unpivot so there is one row per reservation date per person
INSERT #Unpivoted
(PersonID, TheDate)
SELECT
R.PersonID,
Occupied.TheDate
FROM dbo.Reservations AS R
CROSS APPLY
(
SELECT TOP(DATEDIFF(DAY, R.CheckIn, R.CheckOut))
DATEADD(DAY,Numbers.n - 1, R.CheckIn)
FROM Numbers
ORDER BY
Numbers.n
) AS Occupied (TheDate)
-- Dynamic SQL for the cross-tab
DECLARE
@sql nvarchar(max) =
N'SELECT U.PersonID ' +
(
-- Construct the dynamic pivot
SELECT
N',SUM(CASE WHEN U.TheDate = ''' +
CA.date_string +
N''' THEN 1 ELSE 0 END) AS ' +
QUOTENAME(CA.date_string)
FROM
(
-- Unique dates in the unpivoted set
SELECT
U.TheDate,
CONVERT(char(8), U.TheDate, 112) AS date_string
FROM #Unpivoted AS U
GROUP BY U.TheDate
) AS CA
ORDER BY
CA.TheDate
FOR XML
PATH (''), TYPE
).value('./text()[1]', 'NVARCHAR(MAX)') +
N' FROM #Unpivoted AS U GROUP BY U.PersonID'
-- For debugging
SELECT @sql
-- Return results
EXECUTE (@SQL)
-- Tidy up
DROP TABLE #Unpivoted
DROP TABLE dbo.Reservations
Output:
Paul White
SQLPerformance.com
SQLkiwi blog
@SQL_Kiwi
January 9, 2012 at 7:04 am
Jeff Moden (1/8/2012)
Ok... I'm confused. People would almost always need the room for the night they checkin and never need a room for the night they checkout. Why would BOB not need his room for the last two nights and why would Fred not need his room on the day of Checkin (according to the data you posted).
Jeff, The OP's data is fine, as is his result set. The thing here is that he wants a column for each day in the report range, whether people were using rooms or not. Thus the 1's and 0's in his output data are correct - Fred checked in on 2nd, NOT the first day of the report.
January 9, 2012 at 10:28 pm
Agh! I totally misread the dates, Bob. Thank you for the correction. More coffee, please. :blush:
With that little revelation, it looks like Paul sussed the problem with his code.
--Jeff Moden
Change is inevitable... Change for the better is not.
January 10, 2012 at 9:55 am
Guys, sorry for the late reply (been out of office). Have just checked out the code Paul posted and it works like a dream! I now just need to get my head fully around it so I can add a few bells and whistles.
Thanks so much for your replies, especially Paul.
I'll post my questions with some proper sample code next time!
Nick
January 10, 2012 at 10:05 am
Nick -
I don't know if it matters, but Paul's solution doesn't quite do what you specified, as it doesn't return data for the last date in the report range when nobody was using a room.
This is a frequent problem I have when I create reports for people - you can't easily report on data that isn't there!
I started to look at an alternative approach, using a recursive CTE to generate a continuous list of dates that covered the report range (that worked a treat, btw), with the intent of then using that in a 'left-join' approach with the occupation data. But 'real work' got in the way, so I didn't get time to finish it.
Anyway - good luck with it all.
Bob
January 10, 2012 at 10:24 am
Bob Cullen-434885 (1/10/2012)
Nick -I don't know if it matters, but Paul's solution doesn't quite do what you specified, as it doesn't return data for the last date in the report range when nobody was using a room.
This is a frequent problem I have when I create reports for people - you can't easily report on data that isn't there!
I started to look at an alternative approach, using a recursive CTE to generate a continuous list of dates that covered the report range (that worked a treat, btw), with the intent of then using that in a 'left-join' approach with the occupation data. But 'real work' got in the way, so I didn't get time to finish it.
Anyway - good luck with it all.
Bob
The issue you describe is different than the missing last date in Pauls code: gaps in data are covered by a dynamic calendar table in Pauls code. To include the last date, just change
SELECT TOP(DATEDIFF(DAY, R.CheckIn, R.CheckOut))
to
SELECT TOP(DATEDIFF(DAY, R.CheckIn, R.CheckOut)+1)
January 10, 2012 at 10:49 am
LutzM (1/10/2012)
an the missing last date in Pauls code: gaps in data are covered by a dynamic calendar table in Pauls code. To include the last date, just change
SELECT TOP(DATEDIFF(DAY, R.CheckIn, R.CheckOut))
to
SELECT TOP(DATEDIFF(DAY, R.CheckIn, R.CheckOut)+1)
Off-by-one errors, my speciality 🙂
Paul White
SQLPerformance.com
SQLkiwi blog
@SQL_Kiwi
January 11, 2012 at 6:51 am
Bob Cullen-434885 (1/10/2012)
I started to look at an alternative approach, using a recursive CTE to generate a continuous list of dates that covered the report range
Jeff Moden has an article that shows how badly recursive CTEs can perform for certain types of tasks and it sounds like yours may fall into that category. Check out his article Hidden RBAR: Counting with Recursive CTE's[/url]
Drew
J. Drew Allen
Business Intelligence Analyst
Philadelphia, PA
Viewing 15 posts - 1 through 15 (of 55 total)
You must be logged in to reply to this topic. Login to reply