January 13, 2016 at 6:59 am
create table #time
(
DatetimeValuedatetime
,SecondOfMinute tinyint
);
declare @TimeVal datetime = cast('1900-01-01 00:00:00' as datetime);
while @TimeVal<dateadd(minute,1,'1900-01-01 23:59:00')
begin
insert into #time
select
dateadd(second,1,@TimeVal)
,DATEPART(second,dateadd(second,1,@TimeVal))
set @TimeVal = dateadd(second,1,@TimeVal)
end
select
DatetimeValue
,SecondOfMinute
,DATEPART(second,DatetimeValue)
from
#time
drop table #time;
I'm intending to use the code above to update a time dimension to include seconds of minutes. It runs in 3 seconds to return 86400 rows and will be used as a one off to do the update. The thing is WHILE loops are bad aren't they. I've had an attempt at using CTE's and CROSS APPLY etc but I can't seem to get right. Don't get me wrong, it does exactly what I want it to do, I just don't like it. Does anybody have any better ideas?
PS I've hard-coded the start and end times above but in the real world I'm selecting the MAX and MIN times from my dimension. There's also an index on the DateTimeValue column.
How to post a question to get the most help http://www.sqlservercentral.com/articles/Best+Practices/61537
January 13, 2016 at 8:11 am
Pun intended... it's "time" that you built something like the following function into your databases.
CREATE FUNCTION [dbo].[fnTally]
/**********************************************************************************************************************
Purpose:
Return a column of BIGINTs from @ZeroOrOne up to and including @MaxN with a max value of 1 Trillion.
As a performance note, it takes about 00:02:10 (hh:mm:ss) to generate 1 Billion numbers to a throw-away variable.
Usage:
--===== Syntax example (Returns BIGINT)
SELECT t.N
FROM dbo.fnTally(@ZeroOrOne,@MaxN) t
;
Notes:
1. Based on Itzik Ben-Gan's cascading CTE (cCTE) method for creating a "readless" Tally Table source of BIGINTs.
Refer to the following URLs for how it works and introduction for how it replaces certain loops.
http://www.sqlservercentral.com/articles/T-SQL/62867/
http://sqlmag.com/sql-server/virtual-auxiliary-table-numbers
2. To start a sequence at 0, @ZeroOrOne must be 0 or NULL. Any other value that's convertable to the BIT data-type
will cause the sequence to start at 1.
3. If @ZeroOrOne = 1 and @MaxN = 0, no rows will be returned.
5. If @MaxN is negative or NULL, a "TOP" error will be returned.
6. @MaxN must be a positive number from >= the value of @ZeroOrOne up to and including 1 Billion. If a larger
number is used, the function will silently truncate after 1 Billion. If you actually need a sequence with
that many values, you should consider using a different tool. ;-)
7. There will be a substantial reduction in performance if "N" is sorted in descending order. If a descending
sort is required, use code similar to the following. Performance will decrease by about 27% but it's still
very fast especially compared with just doing a simple descending sort on "N", which is about 20 times slower.
If @ZeroOrOne is a 0, in this case, remove the "+1" from the code.
DECLARE @MaxN BIGINT;
SELECT @MaxN = 1000;
SELECT DescendingN = @MaxN-N+1
FROM dbo.fnTally(1,@MaxN);
8. There is no performance penalty for sorting "N" in ascending order because the output is explicity sorted by
ROW_NUMBER() OVER (ORDER BY (SELECT NULL))
Revision History:
Rev 00 - Unknown - Jeff Moden
- Initial creation with error handling for @MaxN.
Rev 01 - 09 Feb 2013 - Jeff Moden
- Modified to start at 0 or 1.
Rev 02 - 16 May 2013 - Jeff Moden
- Removed error handling for @MaxN because of exceptional cases.
Rev 03 - 22 Apr 2015 - Jeff Moden
- Modify to handle 1 Trillion rows for experimental purposes.
**********************************************************************************************************************/
(@ZeroOrOne BIT, @MaxN BIGINT)
RETURNS TABLE WITH SCHEMABINDING AS
RETURN WITH
E1(N) AS (SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL
SELECT 1) --10E1 or 10 rows
, E4(N) AS (SELECT 1 FROM E1 a, E1 b, E1 c, E1 d) --10E4 or 10 Thousand rows
,E12(N) AS (SELECT 1 FROM E4 a, E4 b, E4 c) --10E12 or 1 Trillion rows
SELECT N = 0 WHERE ISNULL(@ZeroOrOne,0)= 0 --Conditionally start at 0.
UNION ALL
SELECT TOP(@MaxN) N = ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) FROM E12 -- Values from 1 to @MaxN
;
It's a "Tally" function that replaces a physical Tally Table (sequence of numbers), which can easily be used to replace such loops whether they be one off ad hoc usages, such as yours above, or permanent production solutions.
Read the comments in the function and then build it in your database. I'll be back in a minute to show you how to use it to replace your While Loop above.
--Jeff Moden
Change is inevitable... Change for the better is not.
January 13, 2016 at 8:29 am
Ok. Here's the equivalent solution to your While Loop. The dbo.fnTally function makes it child's play and requires very little typing especially compared to a While Loop solution.
You already understand the concept, so you shouldn't have much of a problem figuring out how this works but, if you do, please do post back with your question(s).
--===== These could be parameters for another iTVF
-- (inline Table Valued Function)
DECLARE @pStartDT DATETIME
,@pEndDT DATETIME
;
SELECT @pStartDT = '1900-01-01 00:00:00'
,@pEndDT = '1900-01-01 23:59:00'
;
--===== Do the same as what your loop does provided you
-- always give it just whole minutes in the parameters.
-- It also prevents the "bleed over" into the next day
SELECT DateTimeValue = DATEADD(ss,t.N,@pStartDT)
,SecondOfMinute = t.N%60
FROM dbo.fnTally(0,DATEDIFF(ss,@pStartDT,@pEndDT)+59) t
;
And, yes, you could also create a Temp Table on-the-fly if you need it. Like this... (added one simple line of code)...
--===== These could be parameters for another iTVF
-- (inline Table Valued Function)
DECLARE @pStartDT DATETIME
,@pEndDT DATETIME
;
SELECT @pStartDT = '1900-01-01 00:00:00'
,@pEndDT = '1900-01-01 23:59:00'
;
--===== Do the same as what your loop does provided you
-- always give it just whole minutes in the parameters.
-- It also prevents the "bleed over" into the next day
SELECT DateTimeValue = DATEADD(ss,t.N,@pStartDT)
,SecondOfMinute = t.N%60
INTO #time --LOOK!!! CREATES THE TEMP TABLE ON-THE-FLY!!!
FROM dbo.fnTally(0,DATEDIFF(ss,@pStartDT,@pEndDT)+59) t
;
--Jeff Moden
Change is inevitable... Change for the better is not.
January 13, 2016 at 8:48 am
Thanks Jeff, that's fantastic.
I've got a Tally table on my laptop but it didn't even cross my mind to use it. I forget how useful they can be. The function version works a treat.
How to post a question to get the most help http://www.sqlservercentral.com/articles/Best+Practices/61537
January 14, 2016 at 2:55 am
After having time to look at that properly, I see exactly what it does.
I can't believe I didn't think of using the Tally table method. I've put one on the Dev box now and the Time dimension update runs in less than a second.
This is definitely a lesson in the usefulness of Tally tables.
Thanks again Jeff.
How to post a question to get the most help http://www.sqlservercentral.com/articles/Best+Practices/61537
January 14, 2016 at 6:19 am
BWFC (1/14/2016)
After having time to look at that properly, I see exactly what it does.I can't believe I didn't think of using the Tally table method. I've put one on the Dev box now and the Time dimension update runs in less than a second.
This is definitely a lesson in the usefulness of Tally tables.
Thanks again Jeff.
My pleasure and thank you for the feedback. Heh... I knew you knew this stuff based on some of your previous posts and just needed a reminder. 🙂
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 6 posts - 1 through 5 (of 5 total)
You must be logged in to reply to this topic. Login to reply