July 30, 2012 at 10:11 pm
Comments posted to this topic are about the item Set Up Grouping Intervals for Excel (SQL Spackle)
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
July 31, 2012 at 6:21 am
Wow, this is a great article and something that I've wondered about. Thanks!
July 31, 2012 at 6:17 pm
steven.elliottjr (7/31/2012)
Wow, this is a great article and something that I've wondered about. Thanks!
Steven - Glad you found it helpful.
Alas, when I looked at the published article, I found that my final edits to it were not included (probably my fault somehow). I had intended to jazz up the last example. So I'll post that now.
Charting Over Date Periods (Continuous Data)
Handling dates isn’t much different than the above but it does combine some of the features of both. We’ll define 30 intervals this time (2 days per interval). The main difference from FLOAT is there’s no need to fudge the endpoint (we’ll want it to be less than the end date of the final interval) and that the CASTs are to DATETIME, with CONVERT used to get the date into a format we like for the labels (mm/dd/yyyy).
We’ll make this example more interesting by summing our Revenue and Expenses columns and adding a computed margin column.
-- Revised test harness
DECLARE @NumberOfRows INT
,@FStartValue FLOAT
,@FEndValue FLOAT
,@FRange FLOAT
,@IStartValue INT
,@IEndValue INT
,@IRange INT
,@DStartValue DATETIME
,@DEndValue DATETIME
,@DRange INT
SELECT @NumberOfRows = 10000
-- Random FLOATs on the closed interval {275, 850}
,@FStartValue = 275
,@FEndValue = 850
,@FRange = @FEndValue - @FStartValue
-- Random INTs starting at 41 and ending at 160
,@IStartValue = 41
,@IEndValue = 160
,@IRange = @IEndValue - @IStartValue + 1
-- Example: The 30 day interval ending before midnight today
--,@DStartValue = DATEADD(day, -30, DATEADD(day, DATEDIFF(day, 0, GETDATE()), 0))
--,@DEndValue = DATEADD(day, 30, DATEADD(day, -30, DATEADD(day, DATEDIFF(day, 0, GETDATE()), 0)))
--
-- The 60 day interval ending before midnight today
,@DStartValue = DATEADD(day, -60, DATEADD(day, DATEDIFF(day, 0, GETDATE()), 0))
,@DEndValue = DATEADD(day, 60, @DStartValue)
,@DRange = DATEDIFF(day, @DStartValue, @DEndValue)
DECLARE @MyTestTable TABLE
(RandomInteger INT, RandomFloat FLOAT, RandomDate DATETIME, Revenue INT, Expenses INT)
INSERT INTO @MyTestTable
SELECT TOP (@NumberOfRows)
RandomInteger = ABS(CHECKSUM(NEWID())) % @IRange + @IStartValue
,RandomFloat = RAND(CHECKSUM(NEWID())) * @FRange + @FStartValue
,RandomDate = RAND(CHECKSUM(NEWID())) * @DRange + @DStartValue
-- Revenue and Expenses will be used in the final example
,Revenue = ABS(CHECKSUM(NEWID())) % 75 + 50
,Expenses = ABS(CHECKSUM(NEWID())) % 45 + 25
FROM sys.all_columns a1 CROSS JOIN sys.all_columns a2
-- Code for grouping intervals on revenue and margin
DECLARE @NoIntervals INT = 30
;WITH SetUpIntervals AS (
-- Anchor: Initial, placeholder interval for totals
SELECT ID=0
,StartInterval = CAST(NULL AS DATETIME)
,EndInterval = CAST(NULL AS DATETIME)
,Interval = CAST('Total' AS VARCHAR(40))
UNION ALL
-- Anchor: Start interval taken from @DStartValue
SELECT ID=1
,StartInterval = @DStartValue
,EndInterval = 1 + (@DStartValue - 1) + @DRange/@NoIntervals
,Interval=CAST(CONVERT(VARCHAR(10), @DStartValue,101) + ' - ' +
CONVERT(VARCHAR(10), (@DStartValue - 1) + @DRange/@NoIntervals, 101) AS VARCHAR(40))
UNION ALL
-- Recursive: Next interval starts at last EndInterval
SELECT ID + 1
,EndInterval
,EndInterval + @DRange/@NoIntervals
,CAST(CONVERT(VARCHAR(10), EndInterval, 101) + ' - ' +
CONVERT(VARCHAR(10), EndInterval + @DRange/@NoIntervals - 1, 101) AS VARCHAR(40))
FROM SetUpIntervals
WHERE ID > 0 AND ID < @NoIntervals)
--SELECT * FROM SetupIntervals
SELECT c.Interval
,Margin = CASE WHEN Margin IS NULL THEN 0 ELSE Margin END
,Expenses = CASE WHEN Expenses IS NULL THEN 0 ELSE Expenses END
,Revenue = CASE WHEN Revenue IS NULL THEN 0 ELSE Revenue END
FROM SetupIntervals c
LEFT JOIN (
-- Calculate Revenue, Expenses and Margin instead of COUNTing by RandomDate by Intervals
SELECT ID, Margin=SUM(Revenue - Expenses), Revenue=SUM(Revenue), Expenses=SUM(Expenses)
FROM @MyTestTable
-- CROSS APPLY to put RandomDate into Intervals
CROSS APPLY (
SELECT ID
FROM SetUpIntervals
WHERE RandomDate >= StartInterval AND RandomDate < EndInterval) a
-- Use ROLLUP to get a total row in the grouped results set
GROUP BY ID WITH ROLLUP) b
ON ISNULL(b.ID, 0) = c.ID
ORDER BY c.ID
For this case, it is instructive to examine the intervals created by SetUpIntervals. Examining the first and last few records (below), we see that our StartIntervals all align with our Interval labels, however the EndInterval is actually the next day at midnight.
ID StartInterval EndInterval Interval
0 NULL NULL Total
1 2012-04-08 00:00:00.000 2012-04-10 00:00:00.000 04/08/2012 - 04/09/2012
2 2012-04-10 00:00:00.000 2012-04-12 00:00:00.000 04/10/2012 - 04/11/2012
3 2012-04-12 00:00:00.000 2012-04-14 00:00:00.000 04/12/2012 - 04/13/2012
<snip>
28 2012-06-01 00:00:00.000 2012-06-03 00:00:00.000 06/01/2012 - 06/02/2012
29 2012-06-03 00:00:00.000 2012-06-05 00:00:00.000 06/03/2012 - 06/04/2012
30 2012-06-05 00:00:00.000 2012-06-07 00:00:00.000 06/05/2012 - 06/06/2012
Once again, pasting our results into Excel we have a nicely formatted histogram over the desired date range.
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
August 2, 2012 at 11:12 pm
Thank you for the article! Sorry if this is a silly question, but could somebody explain to me what is that little "x" doing on this line:
CROSS APPLY (SELECT EndInterval + @IRange/@NoIntervals) x(EndInt)
August 2, 2012 at 11:55 pm
mishaluba (8/2/2012)
Thank you for the article! Sorry if this is a silly question, but could somebody explain to me what is that little "x" doing on this line:CROSS APPLY (SELECT EndInterval + @IRange/@NoIntervals) x(EndInt)
You're welcome (for the article). 🙂
x is the table alias for (SELECT EndInterval + @IRange/@NoIntervals). EndInt is the alias for the computed field created in that derived table (EndInterval + @IRange/@NoIntervals).
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
August 3, 2012 at 12:33 am
A-a-a-a-ah! Thank you again!
Viewing 6 posts - 1 through 5 (of 5 total)
You must be logged in to reply to this topic. Login to reply