Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Populate Quarters table Expand / Collapse
Author
Message
Posted Tuesday, July 31, 2012 7:08 PM
SSChasing Mays

SSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing Mays

Group: General Forum Members
Last Login: Yesterday @ 1:30 PM
Points: 656, Visits: 3,934
Hi All,

I want to populate a table that will contain start and end dates for each quarter. My definition of quarters is standard, four per year, each ending in March, June, September and December. I need to take into account leap years.

CREATE TABLE Quarters
(
StarteDate datetime,
EndDate datetime
)
DECLARE @StarteDate datetime
DECLARE @EndDate datetime

SET @StarteDate = '1/1/2012'
SET @EndDate = '12/31/2020'

Desired output
1/1/2012,3/31/2012
4/1/2012,6/30/2012
7/1/2012,9/30/2012
...
10/31/2020,12/31/2020

Thanks if you would like to offer some assistance...



Post #1338268
Posted Tuesday, July 31, 2012 7:51 PM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Monday, November 17, 2014 4:22 PM
Points: 2,262, Visits: 5,421
Like this?

-- Input variables
DECLARE @StarteDate datetime
DECLARE @EndDate datetime
SET @StarteDate = '1/1/2012'
SET @EndDate = '12/31/2020'

-- local variables and initialization
DECLARE @Diff INT
SELECT @Diff = DATEDIFF (MONTH,@StarteDate,@EndDate)
,@StarteDate = DATEADD( DD,DATEDIFF(DD,0,@StarteDate),0)
,@EndDate = DATEADD( DD,DATEDIFF(DD,0,@EndDate),0)

; WITH Numbers (N) AS
(
SELECT N = 0

UNION ALL

SELECT TOP (@Diff) ROW_NUMBER() OVER (ORDER BY (SELECT NULL))
FROM sys.columns sc1
CROSS JOIN sys.columns sc2
)
, Calendar AS
(
SELECT Dates = DATEADD(MM, N , @StarteDate)
FROM Numbers
)
SELECT QuarterStartDate = Dates
,QuarterEndDate = DATEADD( DD, -1 ,DATEADD(MM,3, Dates))
FROM Calendar Cal
WHERE MONTH(Dates) IN ( 1,4,7,10)

Post #1338278
Posted Tuesday, July 31, 2012 8:48 PM
SSChasing Mays

SSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing MaysSSChasing Mays

Group: General Forum Members
Last Login: Yesterday @ 1:30 PM
Points: 656, Visits: 3,934
Yes exactly like that. Thanks (again) ColdCoffee.

My comment about leap years was clearly non-sensical given my requirements.
Post #1338285
Posted Wednesday, August 1, 2012 3:31 PM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Tuesday, November 18, 2014 12:29 PM
Points: 1,945, Visits: 3,121
A useful idiom is a report period calendar. It gives a name to a range of dates.

CREATE TABLE Report_Periods
(report_name CHAR(10) NOT NULL PRIMARY KEY,
report_start_date DATE NOT NULL,
report_end_date DATE NOT NULL,
CONSTRAINT date_ordering
CHECK (report_start_date <= report_end_date),
etc);

These report periods can overlap; a fiscal quarter will be contained in the range of its fiscal year. There can be gaps between them; we have to wait a year between each “Annual Going out Of Business Sale!” and there might be long stretches of time without any special sales. But we want to know their ranges so that the table is fairly constant once it is created.

I like the MySQL convention of using double zeroes for months and years, That is 'yyyy-mm-00' for a month within a year and 'yyyy-00-00' for the whole year. The advantage is that it will sort with the ISO-8601 data format required by Standard SQL.

For you, I might use '[12][0-9][0-9][0-9]Q[1-4]' as the report period name. It will also help if you will learn to use the ISO-8601 date format. Using local dialects makes you look like a librarian who does not know Dewey Decimal :) Fill out 50 or 100 years of data with a spreadsheet or text editor.


Books in Celko Series for Morgan-Kaufmann Publishing
Analytics and OLAP in SQL
Data and Databases: Concepts in Practice
Data, Measurements and Standards in SQL
SQL for Smarties
SQL Programming Style
SQL Puzzles and Answers
Thinking in Sets
Trees and Hierarchies in SQL
Post #1338856
Posted Wednesday, August 1, 2012 3:42 PM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 10:35 PM
Points: 20,798, Visits: 32,715
CELKO (8/1/2012)
A useful idiom is a report period calendar. It gives a name to a range of dates.

CREATE TABLE Report_Periods
(report_name CHAR(10) NOT NULL PRIMARY KEY,
report_start_date DATE NOT NULL,
report_end_date DATE NOT NULL,
CONSTRAINT date_ordering
CHECK (report_start_date <= report_end_date),
etc);

These report periods can overlap; a fiscal quarter will be contained in the range of its fiscal year. There can be gaps between them; we have to wait a year between each “Annual Going out Of Business Sale!” and there might be long stretches of time without any special sales. But we want to know their ranges so that the table is fairly constant once it is created.

I like the MySQL convention of using double zeroes for months and years, That is 'yyyy-mm-00' for a month within a year and 'yyyy-00-00' for the whole year. The advantage is that it will sort with the ISO-8601 data format required by Standard SQL.

For you, I might use '[12][0-9][0-9][0-9]Q[1-4]' as the report period name. It will also help if you will learn to use the ISO-8601 date format. Using local dialects makes you look like a librarian who does not know Dewey Decimal :) Fill out 50 or 100 years of data with a spreadsheet or text editor.


I have a suggestion Mr. Celko, and it may save you a lot of typing in the future. Look at all your (imho, not so useful) posts and write up a few SQL Spakle articles. then all you need to post is the urls (and you could put those in your sig block, saving more typing) for those articles then add any thread specific comments that may be appropriate.



Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Post #1338866
Posted Wednesday, August 1, 2012 3:47 PM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 10:35 PM
Points: 20,798, Visits: 32,715
Chrissy321 (7/31/2012)
Yes exactly like that. Thanks (again) ColdCoffee.

My comment about leap years was clearly non-sensical given my requirements.


What would you expect for a startdate = '20120201' and an enddate = '20130228'? Yes, I used February, but I'm just trying to figure a few things out as there is more than one way to answer this question.



Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Post #1338870
Posted Wednesday, August 1, 2012 7:52 PM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Tuesday, November 18, 2014 12:29 PM
Points: 1,945, Visits: 3,121
have a suggestion Mr. Celko, and it may save you a lot of typing in the future. Look at all your (imho, not so useful) posts and write up a few SQL Spakle articles. then all you need to post is the urls (and you could put those in your sig block, saving more typing) for those articles then add any thread specific comments that may be appropriate.


I tried posting links to my articles back when I had regular columns in DBP&D and DBMS magazines. People hated that; their response was "but where is my answer? I want it now! I want it here!" If they were willing to click over to an article, they still wanted a summary or to get the generic code re-written to their particular situation. Then the other posters who had not seen the article would gripe about being left out. Or they would read the article and shot off on a tangent from some part of it that did apply to the original topic.

So I built a "cut&paste" set of single topic short replies. This seems to have worked for the last two decades. But you might be right; we did not have places like "Spakle" to leave short stock answers in the old days.

Right now I have about 40 articles on Simple_Talk and ~100 short clips in my stock pile. And ~1200 articles total, but there is redundancy there. Still, that will not fit into a signature block. Remember, my "not so useful posts" have made me one of the best selling SQL author on Earth


Books in Celko Series for Morgan-Kaufmann Publishing
Analytics and OLAP in SQL
Data and Databases: Concepts in Practice
Data, Measurements and Standards in SQL
SQL for Smarties
SQL Programming Style
SQL Puzzles and Answers
Thinking in Sets
Trees and Hierarchies in SQL
Post #1338916
Posted Wednesday, August 1, 2012 8:23 PM


SSC-Insane

SSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-InsaneSSC-Insane

Group: General Forum Members
Last Login: Today @ 10:35 PM
Points: 20,798, Visits: 32,715
CELKO (8/1/2012)
have a suggestion Mr. Celko, and it may save you a lot of typing in the future. Look at all your (imho, not so useful) posts and write up a few SQL Spakle articles. then all you need to post is the urls (and you could put those in your sig block, saving more typing) for those articles then add any thread specific comments that may be appropriate.


I tried posting links to my articles back when I had regular columns in DBP&D and DBMS magazines. People hated that; their response was "but where is my answer? I want it now! I want it here!" If they were willing to click over to an article, they still wanted a summary or to get the generic code re-written to their particular situation. Then the other posters who had not seen the article would gripe about being left out. Or they would read the article and shot off on a tangent from some part of it that did apply to the original topic.

So I built a "cut&paste" set of single topic short replies. This seems to have worked for the last two decades. But you might be right; we did not have places like "Spakle" to leave short stock answers in the old days.

Right now I have about 40 articles on Simple_Talk and ~100 short clips in my stock pile. And ~1200 articles total, but there is redundancy there. Still, that will not fit into a signature block. Remember, my "not so useful posts" have made me one of the best selling SQL author on Earth


Yea, and your not so useful posts have made sure that I will never buy any of your books nor recommend them to any one I know.



Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
Post #1338920
Posted Thursday, August 2, 2012 4:33 PM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Monday, August 4, 2014 1:50 PM
Points: 339, Visits: 386
So what is the point of being the "Super Sql Author", if you "copy & paste" comments that does not answer the interrogant of the fellow posters?.

You once commented one of my scripts and posted a solution that did not adress the actual problem trying to be solved.
Post #1339568
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse