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


get the first and last day of any Year/Month


get the first and last day of any Year/Month

Author
Message
candide
candide
SSC Journeyman
SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)

Group: General Forum Members
Points: 91 Visits: 365
Hi,
i have a view with two columns, lets say SpecYear and SpecMonth, both are integer.
How can I build two new columns with the first and last day of this year/monthPinch

ex.
2013 02 => 2013-02-01 2013-02-28
etc.

thanx

--
candide
________Panta rhei
Sean Lange
Sean Lange
One Orange Chip
One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)

Group: General Forum Members
Points: 26440 Visits: 17557
candide (2/25/2013)
Hi,
i have a view with two columns, lets say SpecYear and SpecMonth, both are integer.
How can I build two new columns with the first and last day of this year/monthPinch

ex.
2013 02 => 2013-02-01 2013-02-28
etc.

thanx



This will work.


declare @Month int = 2, @Year int = 2013

declare @ThisDate datetime
set @ThisDate = cast(@Year as char(4)) + right('0' + cast(@Month as varchar(2)), 2) + '01'
select @ThisDate

select dateadd(mm, datediff(mm, 0, @ThisDate), 0) -- Beginning of this month
select dateadd(day, -1, dateadd(mm, datediff(mm, 0, @ThisDate) + 1, 0)) -- End of this month



Take a look at Lynn's article for a number of datetime routines here. http://www.sqlservercentral.com/blogs/lynnpettis/2009/03/25/some-common-date-routines/

If at all possible you should consider storing datetime information as datetime instead of multiple integer columns.

_______________________________________________________________

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)
Lynn Pettis
Lynn Pettis
SSC-Forever
SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)SSC-Forever (40K reputation)

Group: General Forum Members
Points: 40182 Visits: 38567
This will work:



DECLARE @ThisYear INT,
@ThisMonth INT;
SET @ThisYear = 2013;
SET @ThisMonth = 2;

SELECT
DATEADD(MONTH, @ThisMonth - 1, DATEADD(YEAR, @ThisYear - 1900, CAST('19000101' AS DATETIME))) BOM,
DATEADD(DAY, -1, DATEADD(MONTH, @ThisMonth, DATEADD(YEAR, @ThisYear - 1900, CAST('19000101' AS DATETIME)))) EOM




Cool
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)
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)

Group: General Forum Members
Points: 88040 Visits: 41128
You can also cheat for performance with a little integer math. The 22800 is the year (1900*12). The "0" in the BOM forumula is 1900-01-01. The "-1" in the EOM formula is the day before that. Because of the integer math, it's very fast. I can't remember if it was Michael Valentine Jones or Peter Larsson that I first saw with this forumula.

DECLARE @ThisYear  INT,
@ThisMonth INT;
SELECT @ThisYear = 2013,
@ThisMonth = 2;

SELECT BOM = DATEADD(mm, @ThisYear*12-22800+@ThisMonth-1, 0),
EOM = DATEADD(mm, @ThisYear*12-22800+@ThisMonth ,-1)



Of course, the "-1" in the BOM formula can be distributed to the other constant to make the formula a bit shorter, still.

DECLARE @ThisYear  INT,
@ThisMonth INT;
SELECT @ThisYear = 2012, --Leap Year!
@ThisMonth = 2;

SELECT BOM = DATEADD(mm, @ThisYear*12-22801+@ThisMonth, 0),
EOM = DATEADD(mm, @ThisYear*12-22800+@ThisMonth,-1)



Both will also work correctly for dates before 1900 without modification and Leap Years are also figured correctly.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
candide
candide
SSC Journeyman
SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)SSC Journeyman (91 reputation)

Group: General Forum Members
Points: 91 Visits: 365
Hi,

Jeff's solution works great:-P
exactly what I needed

thanx

--
candide
________Panta rhei
ben.brugman
ben.brugman
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1054 Visits: 2391
And another alternative solution, based on 'strings'

declare @Month int = 2, @Year int = 2013
declare @ThisDate datetime = convert(varchar(8),@year*10000+@month*100+01)

select CONVERT(varchar(7),@thisdate,121)+'-01'
select CONVERT(varchar(7),dateadd(mm,1,@thisdate),121)+'-01'



ben brugman
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)

Group: General Forum Members
Points: 88040 Visits: 41128
ben.brugman (2/26/2013)
And another alternative solution, based on 'strings'

declare @Month int = 2, @Year int = 2013
declare @ThisDate datetime = convert(varchar(8),@year*10000+@month*100+01)

select CONVERT(varchar(7),@thisdate,121)+'-01'
select CONVERT(varchar(7),dateadd(mm,1,@thisdate),121)+'-01'



ben brugman


Just be aware that string conversions of dates will be a bit slower than integer conversions. It'll take a million rows to notice a difference but every bit helps when you're working with large tables or millions of hits each day.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)SSC Guru (88K reputation)

Group: General Forum Members
Points: 88040 Visits: 41128
candide (2/26/2013)
Hi,

Jeff's solution works great:-P
exactly what I needed

thanx


Thank you for the kind feedback. I just want to make sure because you're the one that will have to support it. Do you understand how and why it works?

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
ScottPletcher
ScottPletcher
SSCrazy Eights
SSCrazy Eights (8K reputation)SSCrazy Eights (8K reputation)SSCrazy Eights (8K reputation)SSCrazy Eights (8K reputation)SSCrazy Eights (8K reputation)SSCrazy Eights (8K reputation)SSCrazy Eights (8K reputation)SSCrazy Eights (8K reputation)

Group: General Forum Members
Points: 8044 Visits: 7163
The integer value for the first day of the month is even easier:


SELECT BOM = @ThisYear * 10000 + @ThisMonth * 100 + 1,



but you must CAST it to char(8) before storing it in a date/datetime column.


DECLARE @BOM datetime
SELECT @BOM = CAST(@ThisYear * 10000 + @ThisMonth * 100 + 1 AS char(8))
SELECT @BOM



SQL DBA,SQL Server MVP(07, 08, 09)[size=2]Prosecutor James Blackburn, in closing argument in the Fatal Vision murders trial: If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them.[/size]
Michael Valentine Jones
Michael Valentine Jones
SSCertifiable
SSCertifiable (5.9K reputation)SSCertifiable (5.9K reputation)SSCertifiable (5.9K reputation)SSCertifiable (5.9K reputation)SSCertifiable (5.9K reputation)SSCertifiable (5.9K reputation)SSCertifiable (5.9K reputation)SSCertifiable (5.9K reputation)

Group: General Forum Members
Points: 5862 Visits: 11771
Jeff Moden (2/25/2013)
You can also cheat for performance with a little integer math. The 22800 is the year (1900*12). The "0" in the BOM forumula is 1900-01-01. The "-1" in the EOM formula is the day before that. Because of the integer math, it's very fast. I can't remember if it was Michael Valentine Jones or Peter Larsson that I first saw with this forumula.

DECLARE @ThisYear  INT,
@ThisMonth INT;
SELECT @ThisYear = 2013,
@ThisMonth = 2;

SELECT BOM = DATEADD(mm, @ThisYear*12-22800+@ThisMonth-1, 0),
EOM = DATEADD(mm, @ThisYear*12-22800+@ThisMonth ,-1)



Of course, the "-1" in the BOM formula can be distributed to the other constant to make the formula a bit shorter, still.

DECLARE @ThisYear  INT,
@ThisMonth INT;
SELECT @ThisYear = 2012, --Leap Year!
@ThisMonth = 2;

SELECT BOM = DATEADD(mm, @ThisYear*12-22801+@ThisMonth, 0),
EOM = DATEADD(mm, @ThisYear*12-22800+@ThisMonth,-1)



Both will also work correctly for dates before 1900 without modification and Leap Years are also figured correctly.


That formula was a bit of a joint effort that Peter Larsson and I developed on this thread:
Make Date function (like in VB)
http://www.sqlteam.com/forums/topic.asp?TOPIC_ID=22339
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