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


Help on how to count guests in hotel every day


Help on how to count guests in hotel every day

Author
Message
dwain.c
dwain.c
SSCoach
SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)

Group: General Forum Members
Points: 18087 Visits: 6431
You can probably make a change something like this:


SELECT [Day], MaleGuests=ISNULL(SUM(CASE Gender WHEN 'M' THEN 1 END), 0)
, FemaleGuests=ISNULL(SUM(CASE Gender WHEN 'F' THEN 1 END), 0)





My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

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?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
srienstr
srienstr
Mr or Mrs. 500
Mr or Mrs. 500 (512 reputation)Mr or Mrs. 500 (512 reputation)Mr or Mrs. 500 (512 reputation)Mr or Mrs. 500 (512 reputation)Mr or Mrs. 500 (512 reputation)Mr or Mrs. 500 (512 reputation)Mr or Mrs. 500 (512 reputation)Mr or Mrs. 500 (512 reputation)

Group: General Forum Members
Points: 512 Visits: 459
I would ordinarily add an "Else 0" prior to the End in those case statements rather than the isnull function. Is there a performance difference, or just personal preference?


Puto me cogitare, ergo puto me esse.
I think that I think, therefore I think that I am.
Maple07-598122
Maple07-598122
Grasshopper
Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)

Group: General Forum Members
Points: 14 Visits: 78
I couldn’t get my assignment done without your help. Thank you.
Davio
Davio
SSC-Enthusiastic
SSC-Enthusiastic (121 reputation)SSC-Enthusiastic (121 reputation)SSC-Enthusiastic (121 reputation)SSC-Enthusiastic (121 reputation)SSC-Enthusiastic (121 reputation)SSC-Enthusiastic (121 reputation)SSC-Enthusiastic (121 reputation)SSC-Enthusiastic (121 reputation)

Group: General Forum Members
Points: 121 Visits: 1247
This is very nearly the same type of problem discussed in Phil Factor's SQL Speed Phreak challenge http://ask.sqlservercentral.com/questions/1227/the-subscription-list-sql-problem.html, which is also discussed nicely here http://www.simple-talk.com/sql/performance/writing-efficient-sql-set-based-speed-phreakery/. Besides being a good read, I think that you could use the winning code easily enough, substituting days for months and guests for subscribers.



dwain.c
dwain.c
SSCoach
SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)

Group: General Forum Members
Points: 18087 Visits: 6431
srienstr (1/30/2013)
I would ordinarily add an "Else 0" prior to the End in those case statements rather than the isnull function. Is there a performance difference, or just personal preference?


Actually, you need to use the ISNULL because there may be days when there are no guests.


My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

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?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
dwain.c
dwain.c
SSCoach
SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)

Group: General Forum Members
Points: 18087 Visits: 6431
murgatroid (1/30/2013)
This is very nearly the same type of problem discussed in Phil Factor's SQL Speed Phreak challenge http://ask.sqlservercentral.com/questions/1227/the-subscription-list-sql-problem.html, which is also discussed nicely here http://www.simple-talk.com/sql/performance/writing-efficient-sql-set-based-speed-phreakery/. Besides being a good read, I think that you could use the winning code easily enough, substituting days for months and guests for subscribers.


Heavens to murgatroid!

I'd seen that article and forgotten about it. Thanks for reminding me.


My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

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?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
srienstr
srienstr
Mr or Mrs. 500
Mr or Mrs. 500 (512 reputation)Mr or Mrs. 500 (512 reputation)Mr or Mrs. 500 (512 reputation)Mr or Mrs. 500 (512 reputation)Mr or Mrs. 500 (512 reputation)Mr or Mrs. 500 (512 reputation)Mr or Mrs. 500 (512 reputation)Mr or Mrs. 500 (512 reputation)

Group: General Forum Members
Points: 512 Visits: 459
I get the same results both ways, even for days with no guests of one gender or no guests at all.
CREATE TABLE #Guests (checkin date, checkout date, FullName varchar(50), Gender char(1))

INSERT INTO #Guests
SELECT '10/12/2012', '10/16/2012', 'Corky Doe','M' UNION ALL
SELECT '12/12/2012', '12/17/2012', 'Janice Doe','F' UNION ALL
SELECT '11/12/2012', '11/24/2012', 'Howard Stern','M' UNION ALL
SELECT '12/12/2012', '12/13/2012', 'Abagail Johnson','F' UNION ALL
SELECT '12/12/2012', '12/15/2012', 'Teddy Sanft','M' UNION ALL
SELECT '12/12/2012', '12/18/2012', 'John Overton','M' UNION ALL
SELECT '12/12/2012', '12/19/2012', 'Sally Jenson','F' UNION ALL
SELECT '10/20/2012', '12/12/2012', 'Tiffany Blue','F'

DECLARE @StartOfMonth DATE = '2012-12-01';

WITH Calendar AS (
SELECT TOP (DAY(DATEADD(mm,DATEDIFF(mm,-1,@StartOfMonth),-1)))
[Day]=DATEADD(day, number - 1, @StartOfMonth)
FROM [master].dbo.spt_values Tally
WHERE [Type] = 'P' AND Number BETWEEN 1 AND 31)
SELECT [Day]
, Guests=ISNULL(COUNT(FullName), 0)
, MaleGuests=ISNULL(SUM(CASE Gender WHEN 'M' THEN 1 END), 0)
, FemaleGuests=ISNULL(SUM(CASE Gender WHEN 'F' THEN 1 END), 0)
, Guests2=COUNT(FullName)
, MaleGuests2=SUM(CASE Gender WHEN 'M' THEN 1 else 0 END)
, FemaleGuests2=SUM(CASE Gender WHEN 'F' THEN 1 else 0 END)

FROM Calendar
LEFT JOIN #Guests ON [Day] >= checkin AND [Day] < checkout
GROUP BY [Day]

DROP TABLE #Guests




Puto me cogitare, ergo puto me esse.
I think that I think, therefore I think that I am.
dwain.c
dwain.c
SSCoach
SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)

Group: General Forum Members
Points: 18087 Visits: 6431
srienstr (1/31/2013)
I get the same results both ways, even for days with no guests of one gender or no guests at all.
CREATE TABLE #Guests (checkin date, checkout date, FullName varchar(50), Gender char(1))

INSERT INTO #Guests
SELECT '10/12/2012', '10/16/2012', 'Corky Doe','M' UNION ALL
SELECT '12/12/2012', '12/17/2012', 'Janice Doe','F' UNION ALL
SELECT '11/12/2012', '11/24/2012', 'Howard Stern','M' UNION ALL
SELECT '12/12/2012', '12/13/2012', 'Abagail Johnson','F' UNION ALL
SELECT '12/12/2012', '12/15/2012', 'Teddy Sanft','M' UNION ALL
SELECT '12/12/2012', '12/18/2012', 'John Overton','M' UNION ALL
SELECT '12/12/2012', '12/19/2012', 'Sally Jenson','F' UNION ALL
SELECT '10/20/2012', '12/12/2012', 'Tiffany Blue','F'

DECLARE @StartOfMonth DATE = '2012-12-01';

WITH Calendar AS (
SELECT TOP (DAY(DATEADD(mm,DATEDIFF(mm,-1,@StartOfMonth),-1)))
[Day]=DATEADD(day, number - 1, @StartOfMonth)
FROM [master].dbo.spt_values Tally
WHERE [Type] = 'P' AND Number BETWEEN 1 AND 31)
SELECT [Day]
, Guests=ISNULL(COUNT(FullName), 0)
, MaleGuests=ISNULL(SUM(CASE Gender WHEN 'M' THEN 1 END), 0)
, FemaleGuests=ISNULL(SUM(CASE Gender WHEN 'F' THEN 1 END), 0)
, Guests2=COUNT(FullName)
, MaleGuests2=SUM(CASE Gender WHEN 'M' THEN 1 else 0 END)
, FemaleGuests2=SUM(CASE Gender WHEN 'F' THEN 1 else 0 END)

FROM Calendar
LEFT JOIN #Guests ON [Day] >= checkin AND [Day] < checkout
GROUP BY [Day]

DROP TABLE #Guests



Sorry. I think I gave you a bad answer without thinking to much about it.

I believe the ISNULL was just a carryover from my original solution where it was needed.


My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

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?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
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