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


records within StartDate and EndDate


records within StartDate and EndDate

Author
Message
armaandani
armaandani
Valued Member
Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)

Group: General Forum Members
Points: 50 Visits: 10
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.

StartDate EndDate Place
10/1/12 13/1/12 ABC
14/1/12 17/1/12 XYZ

Then these can be show as in DateTable as

Date Place Time
10/1/12 ABC
11/1/12 ABC
12/1/12 ABC
13/1/12 ABC
14/1/12 XYZ
15/1/12 XYZ
16/1/12 XYZ
17/1/12 XYZ

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.
ShineBoy
ShineBoy
Old Hand
Old Hand (315 reputation)Old Hand (315 reputation)Old Hand (315 reputation)Old Hand (315 reputation)Old Hand (315 reputation)Old Hand (315 reputation)Old Hand (315 reputation)Old Hand (315 reputation)

Group: General Forum Members
Points: 315 Visits: 159
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.
Sean Lange
Sean Lange
SSC Guru
SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)

Group: General Forum Members
Points: 101535 Visits: 18186
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. :-D

_______________________________________________________________

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.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
ShineBoy
ShineBoy
Old Hand
Old Hand (315 reputation)Old Hand (315 reputation)Old Hand (315 reputation)Old Hand (315 reputation)Old Hand (315 reputation)Old Hand (315 reputation)Old Hand (315 reputation)Old Hand (315 reputation)

Group: General Forum Members
Points: 315 Visits: 159
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.
Sean Lange
Sean Lange
SSC Guru
SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)

Group: General Forum Members
Points: 101535 Visits: 18186
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. :-D

_______________________________________________________________

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.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
armaandani
armaandani
Valued Member
Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)Valued Member (50 reputation)

Group: General Forum Members
Points: 50 Visits: 10
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.
Sean Lange
Sean Lange
SSC Guru
SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)SSC Guru (101K reputation)

Group: General Forum Members
Points: 101535 Visits: 18186
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.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
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