January 17, 2013 at 1:05 pm
i have a "Place" table in which i have three coulmns.
StartDate EndDate Place
and i have an another table name as "DateTabe" which has also three coulmns
Date Place Time
i want that the date selected between StartDate and EndDate is made available in 'Date' coulmn which is in DateTable with Place in 'Place' coulmn.
StartDateEndDatePlace
10/1/1213/1/12ABC
14/1/1217/1/12XYZ
Then these can be show as in DateTable as
Date Place Time
10/1/12ABC
11/1/12ABC
12/1/12ABC
13/1/12ABC
14/1/12XYZ
15/1/12XYZ
16/1/12XYZ
17/1/12XYZ
Is it possible? if yes then how?
Please help as i done a lot of search for this but i don't find any help from internet.
January 17, 2013 at 2:13 pm
Almost anything is possible, and certainly this is. Trouble is I can only think of a looping mechanism right now and they are slow, but if you do the thing infrequently or there are not a lot of records then no big deal, should be fine.
Create Table Place (StartDate date not null, EndDate Date not null, Place varchar(5) not null)
go
Insert Into Place (StartDate, EndDate, PLace)
Select '2012/01/10', '2012/01/13', 'ABC'
Union ALL
Select '2012/01/14', '2012/01/17', 'XYZ'
go
Create Table DateTable (DateO date, Place varchar(5), TimeO time)
go
--Take each record in, assign to parameters, then insert records for every date between the startdate and enddate.
--then take next record
-- basically a cursor (for each record in Place) and a while loop for each date between the start and end dates
SET NOCOUNT ON
DECLARE PlaceCur CURSOR READ_ONLY FOR Select StartDate, EndDate, Place from dbo.Place
DECLARE @StartDate Date, @EndDate Date, @Place varchar(5)
OPEN PlaceCur
FETCH NEXT FROM PlaceCur INTO @StartDate, @EndDate, @Place
WHILE (@@fetch_status <> -1)
BEGIN
IF (@@fetch_status <> -2)
BEGIN
WHILE @Startdate <= @EndDate
BEGIN
INSERT INTO DateTable (DateO, Place) Values(@StartDate, @Place)
SET @StartDate = DateAdd(day,1,@StartDate)
END
END
FETCH NEXT FROM PlaceCur INTO @StartDate, @EndDate, @Place
END
CLOSE PlaceCur
DEALLOCATE PlaceCur
GO
Select * from datetable
results just as you want, hope this helps.
January 17, 2013 at 3:43 pm
I would highly recommend you NOT use a cursor for this. You should instead use a tally table. You can read about them, how to set it up and use by reading the article in my signature about splitting strings.
Using the same ddl as previously posted (much thanks for that). This type of thing is something you should post with future questions.
select *, dateadd(d, N, startdate)
from Place p
cross apply tally t
where N <= datediff(d, startDate, enddate) + 1
That is a lot simpler, faster and easier to maintain. 😀
_______________________________________________________________
Need help? Help us help you.
Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.
Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
January 17, 2013 at 4:21 pm
Hey Thanks Sean, I knew there would be a non-cursor/looping method, just didn't know it , now I do, Thanks.
Live and Learn.
January 18, 2013 at 7:04 am
You are welcome. The tally table has been called the "Swiss Army knife of t-sql". It can be used for so many things to avoid looping. Once you understand it and how it works you will be amazed at how frequently you use it. 😀
_______________________________________________________________
Need help? Help us help you.
Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.
Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
January 18, 2013 at 10:05 am
thanks for your rply.
can you tell me about any good article about tally table, how tally tables are created and how they are used. i don't have any about it.
January 18, 2013 at 10:53 am
armaandani (1/18/2013)
thanks for your rply.can you tell me about any good article about tally table, how tally tables are created and how they are used. i don't have any about it.
As I said in my previous post...
You should instead use a tally table. You can read about them, how to set it up and use by reading the article in my signature about splitting strings.
_______________________________________________________________
Need help? Help us help you.
Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.
Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
Viewing 7 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply