September 10, 2010 at 2:44 am
Wondering if there's a way to do a select query without a cursor (although easy enough to do, curious if can be done without one) to do something like this... here's a small scale sample of what I'm trying to do with a select query...
Sample recs in PublicHols table:
26Jan2010,26Jan2010 -- = 1 day
25Apr2010,25Apr2010 -- = 1 day
25Dec2010,26Dec2010 -- = 2 days
Sample results expected:
26Jan2010,1
25Apr2010,1
25Dec2010,1
26Dec2010,1
Sample results at moment without cursor:
26Jan2010,1
25Apr2010,1
25Dec2010,2 -- want this split into 2 records instead
At moment I'm using this but it can return days > 1, so considering cursor to select them broken up into single records:
select
StartDate,
cast(EndDate-StartDate as integer)+1 as Days
from PublicHols
SQL Server 2000 (& 2005)
September 10, 2010 at 2:59 am
This couldn't have come at a better time, Wayne & I had something similar this week. Can you post the ddl for the table, along with a few INSERTs to get some sample data into it?
For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
September 10, 2010 at 11:57 pm
No problem thnx for the posting tip, good idea, I'll do that shortly...
however got this answer from another forum & it works perfectly. . π
select dateadd(dd, n.number, h.StartDate)
from master..spt_values n
join PublicHols h on n.type = 'P'
and dateadd(dd,n.number,StartDate) between h.StartDate and h.EndDate
September 11, 2010 at 12:26 am
Here it is π
--===== If test table exists, drop it
IF OBJECT_ID('TempDB..PublicHols','U') IS NOT NULL
DROP TABLE PublicHols
--===== Create test table
CREATE TABLE PublicHols
(
ID INT IDENTITY(1,1) PRIMARY KEY CLUSTERED,
Descr CHAR(64),
StartDate DATETIME,
EndDate DATETIME
)
--===== Special conditions
SET DATEFORMAT DMY
--===== Insert test data into test table
INSERT INTO PublicHols (Descr,StartDate,EndDate)
SELECT 'Fiestas Patrias','17/09/2007', '19/09/2007'
UNION ALL
SELECT 'Thanksgiving Break','22/11/2007', '23/11/2007'
UNION ALL
SELECT 'Australia Day','26/01/2010', '26/01/2010'
UNION ALL
SELECT 'Anzac Day','25/04/2010', '25/04/2010'
UNION ALL
SELECT 'Christmas Break','25/12/2010', '26/12/2010'
--==== Gather the data
select
h.ID,
h.Descr,
h.StartDate,
h.EndDate,
cast(h.EndDate-h.StartDate as integer)+1 as Days
from PublicHols h
--==== One solution to the problem (from another forum)
select
h.ID,
h.Descr,
dateadd(dd, n.number, h.StartDate) as HolDate,
1 as Days
from master..spt_values n
join PublicHols h on n.type = 'P'
and dateadd(dd,n.number,h.StartDate) between h.StartDate and h.EndDate
September 11, 2010 at 1:53 am
A variation using CROSS APPLY
;WITH cteTally (N) AS
(
SELECT ROW_NUMBER() OVER (ORDER BY (SELECT 0))
FROM master..syscolumns
)
SELECT P.ID, P.Descr, Z.HolDate, 1 AS Days
FROM PublicHols AS P
CROSS APPLY
(
SELECT DATEADD(DAY, N, StartDate) - 1
FROM cteTally
WHERE N < DATEDIFF(DAY, StartDate, EndDate) + 2
) AS Z (HolDate)
ORDER BY HolDate
September 12, 2010 at 1:36 pm
steve-893342 (9/11/2010)
A variation using CROSS APPLY
This is a SQL 7/2000 forum... the cross apply won't work unless posted in the wrong forum.
Wayne
Microsoft Certified Master: SQL Server 2008
Author - SQL Server T-SQL Recipes
September 12, 2010 at 1:46 pm
WayneS (9/12/2010)
steve-893342 (9/11/2010)
A variation using CROSS APPLYThis is a SQL 7/2000 forum... the cross apply won't work unless posted in the wrong forum.
shell_l_d (9/10/2010)
Wondering if there's a way to do a select query without a cursor (although easy enough to do, curious if can be done without one) to do something like this... here's a small scale sample of what I'm trying to do with a select query...SQL Server 2000 (& 2005)
Yeh, but it says &2005 in the original post, right?
September 12, 2010 at 4:20 pm
steve-893342 (9/12/2010)
WayneS (9/12/2010)
steve-893342 (9/11/2010)
A variation using CROSS APPLYThis is a SQL 7/2000 forum... the cross apply won't work unless posted in the wrong forum.
shell_l_d (9/10/2010)
Wondering if there's a way to do a select query without a cursor (although easy enough to do, curious if can be done without one) to do something like this... here's a small scale sample of what I'm trying to do with a select query...SQL Server 2000 (& 2005)
Yeh, but it says &2005 in the original post, right?
I'll grant you that. My interpretation is that it would need to run on both versions.
Wayne
Microsoft Certified Master: SQL Server 2008
Author - SQL Server T-SQL Recipes
Viewing 8 posts - 1 through 7 (of 7 total)
You must be logged in to reply to this topic. Login to reply