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


What were the dates of all the Fridays in this quarter?


What were the dates of all the Fridays in this quarter?

Author
Message
Ashka Modi
Ashka Modi
SSC Veteran
SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)

Group: General Forum Members
Points: 263 Visits: 112
Comments posted to this topic are about the item What were the dates of all the Fridays in this quarter?

Thanks,

Ashka Modi
Software Engineer || credEcard Technologies (india) Pvt. Ltd.
Pete Cox
Pete Cox
SSC-Enthusiastic
SSC-Enthusiastic (186 reputation)SSC-Enthusiastic (186 reputation)SSC-Enthusiastic (186 reputation)SSC-Enthusiastic (186 reputation)SSC-Enthusiastic (186 reputation)SSC-Enthusiastic (186 reputation)SSC-Enthusiastic (186 reputation)SSC-Enthusiastic (186 reputation)

Group: General Forum Members
Points: 186 Visits: 277
Is there a reason why this would be better than selecting rows from a Calendar table?


Have a look at:

http://sqlserver2000.databases.aspfaq.com/why-should-i-consider-using-an-auxiliary-calendar-table.html
Ashka Modi
Ashka Modi
SSC Veteran
SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)

Group: General Forum Members
Points: 263 Visits: 112
Well what you designed is too good. What i created is part of script and to practice it with datetime function with minimum loops included.

While browsing your article i found something which i would like to share with you. I am not much good with sql but all these are my queries:

1) you come up new fashioned query to add large amount of data in table. but what about memory size it will occupy? I have worked on calendar module developed in asp.net, havent seen like created calendar table with all dates in database. If you consider real case scenario this isnt possible.

2) Use of cursor is never been a good idea. cursor includes lot of overhead to query. if you can use if else or for loop just avois cursor.

3) with use of small functions, you can implement all features. you can use table variable instead.

4) what i have learnt is datetime things should never be compared like this: dt >= '20040401' AND dt < '20040501'. This is not efficient way of coding.

I hope you understand my point of view.

Thanks,

Ashka Modi
Software Engineer || credEcard Technologies (india) Pvt. Ltd.
Pete Cox
Pete Cox
SSC-Enthusiastic
SSC-Enthusiastic (186 reputation)SSC-Enthusiastic (186 reputation)SSC-Enthusiastic (186 reputation)SSC-Enthusiastic (186 reputation)SSC-Enthusiastic (186 reputation)SSC-Enthusiastic (186 reputation)SSC-Enthusiastic (186 reputation)SSC-Enthusiastic (186 reputation)

Group: General Forum Members
Points: 186 Visits: 277
Not actually my article, but one I found.

The idea behind it is to incur a single , perhaps large, set-up cost and from then on just use the set-based capabilites that SQLServer is designed for.

Thanks for other the observations , will take them into consideration next time I implement one of these auxiliary calendar tables

cheers
Ashka Modi
Ashka Modi
SSC Veteran
SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)

Group: General Forum Members
Points: 263 Visits: 112
I am so sorry for assume it is your post. Please never mind it. I would like more suggestion and more abstract version of it. what i think is SQL is about making complex logic. and this is tiny piece of it.

Thanks,

Ashka Modi
Software Engineer || credEcard Technologies (india) Pvt. Ltd.
nigel.
nigel.
Hall of Fame
Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)

Group: General Forum Members
Points: 3301 Visits: 2909
Ashka Modi (8/25/2009)

2) Use of cursor is never been a good idea. cursor includes lot of overhead to query. if you can use if else or for loop just avois cursor.


I would avoid all looping constructs in SQL and try and come up with an alternative set-based solution.

I'll be back soon with a suitable alternative method.


4) what i have learnt is datetime things should never be compared like this: dt >= '20040401' AND dt < '20040501'. This is not efficient way of coding.


Why? What is your reasoning? What are the alternatives?

--
Nigel
Useful Links:
How to post data/code on a forum to get the best help
The "Numbers" or "Tally" Table - Jeff Moden

mwebster-1117730
mwebster-1117730
SSC Rookie
SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)

Group: General Forum Members
Points: 37 Visits: 73
Ashka, to answer number 4. With a Calendar table you can use ...
Select * from Calendar
Where Q=3 and Y=2009 and dw=5


to get all of the Fridays in the Quarter.

On my server this takes on average .093 of a second compared to your loop taking about .145
Not a huge amount of time, but every little bit may count. My calendar table also has other functions - I have Fiscal weeks and months along with calendar, frequently I need to connect to a AS/400 database, and it uses a different date format, it's easier and faster to link the data to my calendar table than use a function. I include holidays and workdays to get a count of shipping days in a quarter. There's a lot of flexibility and power that you can't get from a loop.

Mike Webster
Pete Cox
Pete Cox
SSC-Enthusiastic
SSC-Enthusiastic (186 reputation)SSC-Enthusiastic (186 reputation)SSC-Enthusiastic (186 reputation)SSC-Enthusiastic (186 reputation)SSC-Enthusiastic (186 reputation)SSC-Enthusiastic (186 reputation)SSC-Enthusiastic (186 reputation)SSC-Enthusiastic (186 reputation)

Group: General Forum Members
Points: 186 Visits: 277
Agreed, those extra little enhancements are really useful in most situations, and customizable as well.
Different countries having different public holidays is a good example.

One-time Setup and Simple Selects were the alternatives i was interested in proposing
nigel.
nigel.
Hall of Fame
Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)

Group: General Forum Members
Points: 3301 Visits: 2909
Here you go, try this. You'll need a Tally table first (see here):

DECLARE @startDate datetime, @endDate DATETIME

SELECT @startDate = '20090101', -- First day in range
@endDate = '20090401' -- Day *after* last day

--==
--== Note that my tally table starts at 1 hence the N-1 below
--==
SELECT
DATEADD(dd,n-1,@startDate)
FROM
Tally
WHERE
N <= DATEDIFF(dd,@startDate,@endDate) AND
--==
--== Adding the day of the week to the @@DATEFIRST value then doing MOD 7
--== normalizes the result to be independent of the DATEFIRST setting
--== 6 just happens to be Friday
--==
(DATEPART(dw,DATEADD(dd,n-1,@startDate)) + @@DATEFIRST) % 7 = 6




You could put it in a stored procedure with the start date, end date and day of week you're interested in as parameters.

It isn't all that different from using a calendar table. But you seemed concerned about the storage requirements. A Tally table would use less space.

There are other ways without using a tally table - common table expressions and ROW_NUMBER are just two (if you're using 2005 or above).

Nigel

--
Nigel
Useful Links:
How to post data/code on a forum to get the best help
The "Numbers" or "Tally" Table - Jeff Moden

Ashka Modi
Ashka Modi
SSC Veteran
SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)SSC Veteran (263 reputation)

Group: General Forum Members
Points: 263 Visits: 112
My point of view is if you can use "BETWEEN AND" for comparing dates, avoid >,< all such symbols. Isnt it true?

Thanks,

Ashka Modi
Software Engineer || credEcard Technologies (india) Pvt. Ltd.
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