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 1234»»»

get the first and last day of any Year/Month Expand / Collapse
Author
Message
Posted Monday, February 25, 2013 3:11 PM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Wednesday, July 9, 2014 7:16 AM
Points: 21, Visits: 234
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/month

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

thanx



--
candide
________Panta rhei
Post #1423790
Posted Monday, February 25, 2013 3:21 PM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Today @ 3:28 PM
Points: 13,138, Visits: 11,977
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/month

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 Moden's 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)
Post #1423794
Posted Monday, February 25, 2013 3:45 PM


SSC-Insane

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

Group: General Forum Members
Last Login: Today @ 3:56 PM
Points: 23,081, Visits: 31,616
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





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 #1423803
Posted Monday, February 25, 2013 10:38 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 3:00 PM
Points: 36,789, Visits: 31,247
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."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1423881
Posted Tuesday, February 26, 2013 4:43 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Wednesday, July 9, 2014 7:16 AM
Points: 21, Visits: 234
Hi,

Jeff's solution works great
exactly what I needed

thanx


--
candide
________Panta rhei
Post #1424003
Posted Tuesday, February 26, 2013 5:09 AM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Sunday, July 27, 2014 4:18 AM
Points: 246, Visits: 1,167
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
Post #1424012
Posted Tuesday, February 26, 2013 7:59 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 3:00 PM
Points: 36,789, Visits: 31,247
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."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1424094
Posted Tuesday, February 26, 2013 8:01 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 3:00 PM
Points: 36,789, Visits: 31,247
candide (2/26/2013)
Hi,

Jeff's solution works great
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."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1424096
Posted Tuesday, February 26, 2013 3:43 PM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Today @ 3:53 PM
Points: 1,975, Visits: 2,923
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)
"In America, every man is innocent until proven broke!" Brant Parker
Post #1424267
Posted Tuesday, February 26, 2013 5:29 PM
Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Today @ 3:55 PM
Points: 3,129, Visits: 11,422
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




Post #1424293
« Prev Topic | Next Topic »

Add to briefcase 1234»»»

Permissions Expand / Collapse