Prior to SQL Server 2012 we can make use of DATEADD function to find the last day of a month for the provided date.
DECLARE @dtTempDate DATETIME
SELECT @dtTempDate = GETDATE()
In SQL Server 2005 or 2008 these are couple of ways by which we can get the desired
--Option1
SELECT DATEADD(DAY, -1, DATEADD (MONTH, MONTH (@dtTempDate) , DATEADD (YEAR, YEAR (@dtTempDate) - 1900, 0 )))
--Option2
SELECT DATEADD( DAY, -1, DATEADD(MONTH, 1, DATEADD(DAY, 1 - DAY(@dtTempDate), @dtTempDate)))
--Option3
SELECT DATEADD(DAY, -1, DATEADD(MONTH, DATEDIFF(MONTH, 0, @dtTempDate) +1, 0))
Now in SQL Server 2012 there is a new Date and Time function named EOMONTH.
Solution using EOMONTH which would work only in SQL Server 2012 and above:
SELECT EOMONTH (@dtTempDate) AS [Current Month Last Date]
--here the second parameter tells how many MONTHS to add to the given input
SELECT EOMONTH (@dtTempDate,1) AS [Next Month Last Date]
SELECT EOMONTH (@dtTempDate, -1) AS [Previous Month Last Date]
Beware EOMONTH might throw up wrong results when used in Date Range queries. Let me try to explain it using an example.
CREATE TABLE tblSales
(
SalesDate DATETIME,
Orders INT
)
GO
INSERT INTO tblSales VALUES ('2012-03-19 00:00:00.000',10)
INSERT INTO tblSales VALUES ('2012-03-20 07:13:54.420',1)
INSERT INTO tblSales VALUES ('2012-03-31 00:00:00.000',100)
INSERT INTO tblSales VALUES ('2012-03-31 00:00:01.001',200)
INSERT INTO tblSales VALUES ('2012-03-31 07:12:29.123',500)
GO
Assume current date is 19th March 2012. We need to list all records between 19th March to End of that Month. i.e., 19th March 2012 TO 31st March 2012
In prior versions of SQL Server: Using BETWEEN would show inaccurate results as it takes only till mid night of 31st March 2012. The below query would list only the first 3 records and it would ignore the Orders 200 and 500 which is obviously wrong.
SELECT SalesDate, Orders FROM tblSales
WHERE SalesDate BETWEEN '20120319' AND '20120331';
So to get proper result we need to make use of something like SalesDate > 19th March AND SalesDate is < April 1st.
SELECT SalesDate, Orders FROM tblSales
WHERE SalesDate >= '20120319' AND SalesDate < '20120401';
Using EOMONTH in SQL Server 2012:
--This would translate exactly to the query which we had written for prior version using BETWEEN
--So what does it mean? Its going to display wrong results!!
DECLARE @dtTempDate DATETIME
SELECT @dtTempDate = GETDATE()
In SQL Server 2005 or 2008 these are couple of ways by which we can get the desired
--Option1
SELECT DATEADD(DAY, -1, DATEADD (MONTH, MONTH (@dtTempDate) , DATEADD (YEAR, YEAR (@dtTempDate) - 1900, 0 )))
--Option2
SELECT DATEADD( DAY, -1, DATEADD(MONTH, 1, DATEADD(DAY, 1 - DAY(@dtTempDate), @dtTempDate)))
--Option3
SELECT DATEADD(DAY, -1, DATEADD(MONTH, DATEDIFF(MONTH, 0, @dtTempDate) +1, 0))
Now in SQL Server 2012 there is a new Date and Time function named EOMONTH.
EOMONTH ( start_date [, month_to_add ] )
Solution using EOMONTH which would work only in SQL Server 2012 and above:
SELECT EOMONTH (@dtTempDate) AS [Current Month Last Date]
--here the second parameter tells how many MONTHS to add to the given input
SELECT EOMONTH (@dtTempDate,1) AS [Next Month Last Date]
SELECT EOMONTH (@dtTempDate, -1) AS [Previous Month Last Date]
Beware EOMONTH might throw up wrong results when used in Date Range queries. Let me try to explain it using an example.
CREATE TABLE tblSales
(
SalesDate DATETIME,
Orders INT
)
GO
INSERT INTO tblSales VALUES ('2012-03-19 00:00:00.000',10)
INSERT INTO tblSales VALUES ('2012-03-20 07:13:54.420',1)
INSERT INTO tblSales VALUES ('2012-03-31 00:00:00.000',100)
INSERT INTO tblSales VALUES ('2012-03-31 00:00:01.001',200)
INSERT INTO tblSales VALUES ('2012-03-31 07:12:29.123',500)
GO
Assume current date is 19th March 2012. We need to list all records between 19th March to End of that Month. i.e., 19th March 2012 TO 31st March 2012
In prior versions of SQL Server: Using BETWEEN would show inaccurate results as it takes only till mid night of 31st March 2012. The below query would list only the first 3 records and it would ignore the Orders 200 and 500 which is obviously wrong.
SELECT SalesDate, Orders FROM tblSales
WHERE SalesDate BETWEEN '20120319' AND '20120331';
So to get proper result we need to make use of something like SalesDate > 19th March AND SalesDate is < April 1st.
SELECT SalesDate, Orders FROM tblSales
WHERE SalesDate >= '20120319' AND SalesDate < '20120401';
Using EOMONTH in SQL Server 2012:
--This would translate exactly to the query which we had written for prior version using BETWEEN
--So what does it mean? Its going to display wrong results!!
SELECT SalesDate, Orders FROM tblSales
WHERE SalesDate BETWEEN '20120319' AND EOMONTH('20120319');
--Add a day to the output of EOMONTH to fetch the accurate result
SELECT SalesDate, Orders FROM tblSales
WHERE SalesDate >= '20120319' AND SalesDate < DATEADD(DAY, 1, EOMONTH('20120319'))
Comments