December 21, 2007 at 12:37 am
Hi,
1) How to find out the current month's first Date ?
2) How to find out the current month's Last Date ?
3) How to find out the Previous (or) Next month's Last Date ?
4) How to find out the Previous (or) Next month's First Date ?
My friend faced the above questions in his recent interview.
I have tried to find out the solution by using DateFunctions.But,I Can't.:doze:
Inputs are highly appreciable!
karthik
December 21, 2007 at 1:12 am
DECLARE
@FirstOfThisMonth DATETIME,
@LastOfThisMonth DATETIME,
@FirstOfLastMonth DATETIME,
@LastOfLastMonth DATETIME,
@FirstOfNextMonth DATETIME,
@LastOfNextMonth DATETIME
SELECT
@FirstOfThisMonth =
CAST (
CAST ( YEAR (GETDATE()) AS VARCHAR ) + '-' +
CAST ( MONTH (GETDATE()) AS VARCHAR ) + '-' +
'01' AS DATETIME
)
SELECT @LastOfThisMonth =
DATEADD( "m", 1, @FirstOfThisMonth)-1
SELECT @FirstOfLastMonth =
DATEADD( "m", -1, @FirstOfThisMonth)
SELECT @LastOfLastMonth = @FirstOfThisMonth -1
SELECT @FirstOfNextMonth =
DATEADD( "m", 1, @FirstOfThisMonth)
SELECT @LastOfNextMonth =
DATEADD( "m", 2, @FirstOfThisMonth)-1
SELECT
@FirstOfThisMonth AS FirstOfThisMonth,
@LastOfThisMonth AS LastOfThisMonth,
@FirstOfLastMonth AS FirstOfLastMonth,
@LastOfLastMonth AS LastOfLastMonth,
@FirstOfNextMonth AS FirstOfNextMonth,
@LastOfNextMonth AS LastOfNextMonth
.
December 21, 2007 at 1:25 am
Thanks.But,is it possible to get lastmonth's lastdate without using localvariables ?
I mean i want to find last month's last date only ? I don't required the current month's first,last month.Just using a single query, i want to find out the last month's last date.
karthik
December 21, 2007 at 1:28 am
Using Datefunctions.
select getdate()-day(getdate()) as LastDayLastMth, getdate()-(day(getdate())-1) as FirstDayThisMth,dateadd(m,1,getdate())-day(dateadd(m,1,getdate())) as LastDayThisMth,dateadd(m,1,getdate())-day(dateadd(m,1,getdate()))+1 as FirstDayNextMth
December 21, 2007 at 1:40 am
December 21, 2007 at 9:12 am
karthikeyan (12/21/2007)
Thanks.But,is it possible to get lastmonth's lastdate without using localvariables ?I mean i want to find last month's last date only ? I don't required the current month's first,last month.Just using a single query, i want to find out the last month's last date.
Karthik,
It's just an example... the important part is the formulas... just use the formulas in your code. Think outside the box a bit... analyze the code and figure it out. That's what makes a strong developer is being able to take an example and make simple changes to it to get it to do what you want.
--Jeff Moden
Change is inevitable... Change for the better is not.
December 23, 2007 at 9:32 pm
Hi Karthik,
Refer to Jeff's mail above. That is how majority of us learned. You have been provided 2 approaches. One using local variable and another without them.
Any way, if you still want the code, use the below one.
select getdate()-day(getdate()) as LastDayLastMth
December 24, 2007 at 10:44 am
This will do it.
select
FirstOfThisMonth =
dateadd(month,datediff(month,0,getdate()),0),
LastOfThisMonth =
dateadd(month,datediff(month,-1,getdate()),-1),
FirstOfLastMonth =
dateadd(month,datediff(month,0,getdate())-1,0),
LastOfLastMonth =
dateadd(month,datediff(month,-1,getdate())-1,-1),
FirstOfNextMonth =
dateadd(month,datediff(month,0,getdate())+1,0),
LastOfNextMonth =
dateadd(month,datediff(month,-1,getdate())+1,-1)
Start of Time Period Functions:
http://www.sqlteam.com/forums/topic.asp?TOPIC_ID=64755
Start of Week Function:
http://www.sqlteam.com/forums/topic.asp?TOPIC_ID=47307
End Date of Time Period Functions:
http://www.sqlteam.com/forums/topic.asp?TOPIC_ID=64759
End of Week Function:
December 25, 2007 at 3:56 am
December 31, 2007 at 12:12 am
Michael,
select FirstOfThisMonth =dateadd(month,datediff(month,0,getdate()),0),LastOfThisMonth =dateadd(month,datediff(month,-1,getdate()),-1),FirstOfLastMonth =dateadd(month,datediff(month,0,getdate())-1,0),LastOfLastMonth =dateadd(month,datediff(month,-1,getdate())-1,-1)
Thanks.only the first two was worked.
I have made some changes in the last 2 statements.
FirstOfLastMonth =dateadd(month,datediff(month,0,dateadd(mm,-1,getdate())),0),
LastOfLastMonth =dateadd(month,datediff(month,-1,dateadd(mm,-1,getdate()),-1)
It gave last month's firstdate & lastdate.
karthik
December 31, 2007 at 12:17 am
Also,Dateadd(month,0,0)
Here,
1st - Zero stands for Number to be added to the month part.
2nd -Zero Stands for 1900-01-01(Default Datetime).
It will show 1900-01-01.
Dateadd(month,0,-1)
Here,
1st - Zero stands for Number to be added to the month part.
2nd -Zero Stands for 1899-12-31.
It will show 1899-12-31
Am i correct ?
karthik
December 31, 2007 at 1:20 am
declare @Year int
declare @Month int
select @Year=datepart(year,getdate()),@Month=datepart(month,getdate())
declare @NextMonth int
if @Month<>12
set @NextMonth=@Month+1
else
set @NextMonth=1
select convert(datetime, convert(char(4),@Year)+right('0'+convert(varchar,@Month),2)+'01')FirstDay
,dateadd(d,-1,convert(datetime,convert(char(4),@Year)+right('0'+convert(varchar,@NextMonth),2)+'01'))LastDay
http://transactsql.blogspot.com/
December 31, 2007 at 1:51 am
[font="Courier New"]--1) How to find out the current month's first Date ?
SELECT CONVERT(DATETIME,'01 '+RIGHT(CONVERT(CHAR(11),GETDATE(),113),8))
--2) How to find out the current month's Last Date ?
SELECT DATEADD(DAY,-1,'01 '+RIGHT(CONVERT(CHAR(11),DATEADD(MONTH,1,GETDATE()),113),8))
--3) How to find out the Previous (or) Next month's Last Date ?
SELECT DATEADD(DAY,-1,'01 '+RIGHT(CONVERT(CHAR(11),GETDATE(),113),8))--previous
SELECT DATEADD(DAY,-1,'01 '+RIGHT(CONVERT(CHAR(11),DATEADD(MONTH,2,GETDATE()),113),8))--next
--4) How to find out the Previous (or) Next month's First Date ?
SELECT CONVERT(DATETIME,'01 '+RIGHT(CONVERT(CHAR(11),DATEADD(MONTH,-1,GETDATE()),113),8))--previous
SELECT CONVERT(DATETIME,'01 '+RIGHT(CONVERT(CHAR(11),DATEADD(MONTH,1,GETDATE()),113),8))--next
[/font]
Do I get the job?
Best wishes,
Phil Factor
December 31, 2007 at 10:05 am
karthikeyan (12/31/2007)
Michael,select FirstOfThisMonth =dateadd(month,datediff(month,0,getdate()),0),LastOfThisMonth =dateadd(month,datediff(month,-1,getdate()),-1),FirstOfLastMonth =dateadd(month,datediff(month,0,getdate())-1,0),LastOfLastMonth =dateadd(month,datediff(month,-1,getdate())-1,-1)
Thanks.only the first two was worked.
I have made some changes in the last 2 statements.
FirstOfLastMonth =dateadd(month,datediff(month,0,dateadd(mm,-1,getdate())),0),
LastOfLastMonth =dateadd(month,datediff(month,-1,dateadd(mm,-1,getdate()),-1)
It gave last month's firstdate & lastdate.
You must have made a mistake when you copied my code. I just tested it again and it is all correct.
I test the code you posted, and the code for LastOfLastMonth is not even correct syntax.
December 31, 2007 at 10:24 am
Phil Factor (12/31/2007)
[font="Courier New"]--1) How to find out the current month's first Date ?SELECT CONVERT(DATETIME,'01 '+RIGHT(CONVERT(CHAR(11),GETDATE(),113),8))--2) How to find out the current month's Last Date ?SELECT DATEADD(DAY,-1,'01 '+RIGHT(CONVERT(CHAR(11),DATEADD(MONTH,1,GETDATE()),113),8))--3) How to find out the Previous (or) Next month's Last Date ?SELECT DATEADD(DAY,-1,'01 '+RIGHT(CONVERT(CHAR(11),GETDATE(),113),8))--previousSELECT DATEADD(DAY,-1,'01 '+RIGHT(CONVERT(CHAR(11),DATEADD(MONTH,2,GETDATE()),113),8))--next--4) How to find out the Previous (or) Next month's First Date ?
SELECT CONVERT(DATETIME,'01 '+RIGHT(CONVERT(CHAR(11),DATEADD(MONTH,-1,GETDATE()),113),8))--previousSELECT CONVERT(DATETIME,'01 '+RIGHT(CONVERT(CHAR(11),DATEADD(MONTH,1,GETDATE()),113),8))--next[/font]Do I get the job?
Your code produces correct results, but I have found in testing that doing this by converting to strings and back to datetime is a much slower method that using the nested dateadd/datediff method that I posted. The dateadd/datediff code is also shorter to write. I reposted your code below and followed each with the equivalent using nested dateadd/datediff to show the difference in code length.
--1) How to find out the current month's first Date ?
SELECT CONVERT(DATETIME,'01 '+RIGHT(CONVERT(CHAR(11),GETDATE(),113),8))
select dateadd(month,datediff(month,0,getdate()),0)
--2) How to find out the current month's Last Date ?
SELECT DATEADD(DAY,-1,'01 '+RIGHT(CONVERT(CHAR(11),DATEADD(MONTH,1,GETDATE()),113),8))
select dateadd(month,datediff(month,-1,getdate()),-1)
--3) How to find out the Previous (or) Next month's Last Date ?
SELECT DATEADD(DAY,-1,'01 '+RIGHT(CONVERT(CHAR(11),GETDATE(),113),8))--previous
select dateadd(month,datediff(month,-1,getdate())-1,-1)
SELECT DATEADD(DAY,-1,'01 '+RIGHT(CONVERT(CHAR(11),DATEADD(MONTH,2,GETDATE()),113),8))--next
select dateadd(month,datediff(month,-1,getdate())+1,-1)
--4) How to find out the Previous (or) Next month's First Date ?
SELECT CONVERT(DATETIME,'01 '+RIGHT(CONVERT(CHAR(11),DATEADD(MONTH,-1,GETDATE()),113),8))--previous
select dateadd(month,datediff(month,0,getdate())-1,0)
SELECT CONVERT(DATETIME,'01 '+RIGHT(CONVERT(CHAR(11),DATEADD(MONTH,1,GETDATE()),113),8))--next
select dateadd(month,datediff(month,0,getdate())+1,0)
Viewing 15 posts - 1 through 15 (of 45 total)
You must be logged in to reply to this topic. Login to reply