Skip to main content

Find the last day of the month

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.
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

Popular posts from this blog

Registry manipulation from SQL

Registry Manupulation from SQL Server is pretty easy. There are 4 extended stored procedure in SQL Server 2000 for the purpose of manupulating the server registry. They are: 1) xp_regwrite 2) xp_regread 3) xp_regdeletekey 4) xp_regdeletevalue Let us see each one of them in detail! About xp_regwrite This extended stored procedure helps us to create data item in the (server’s) registry and we could also create a new key. Usage: We must specify the root key with the @rootkey parameter and an individual key with the @key parameter. Please note that if the key doesn’t exist (without any warnnig) it would be created in the registry. The @value_name parameter designates the data item and the @type the type of the data item. Valid data item types include REG_SZ and REG_DWORD . The last parameter is the @value parameter, which assigns a value to the data item. Let us now see an example which would add a new key called " TestKey ", and a new data item under it called TestKeyValue :

Screen scraping using XmlHttp and Vbscript ...

I wrote a small program for screen scraping any sites using XmlHttp object and VBScript. I know I haven't done any rocket science :) still I thought of sharing the code with you all. XmlHttp -- E x tensible M arkup L anguage H ypertext T ransfer P rotocol An advantage is that - the XmlHttp object queries the server and retrieve the latest information without reloading the page. Source code: < html > < head > < script language ="vbscript"> Dim objXmlHttp Set objXmlHttp = CreateObject("Msxml2.XMLHttp") Function ScreenScrapping() URL == "UR site URL comes here" objXmlHttp.Open "POST", url, False objXmlHttp.onreadystatechange = getref("HandleStateChange") objXmlHttp.Send End Function Function HandleStateChange() If (ObjXmlHttp.readyState = 4) Then msgbox "Screenscrapping completed .." divShowContent.innerHtml = objXmlHttp.responseText End If End Function </ script > < head > < body > &l

Script table as - ALTER TO is greyed out - SQL SERVER

One of my office colleague recently asked me why we are not able to generate ALTER Table script from SSMS. If we right click on the table and choose "Script Table As"  ALTER To option would be disabled or Greyed out. Is it a bug? No it isn't a bug. ALTER To is there to be used for generating modified script of Stored Procedure, Functions, Views, Triggers etc., and NOT for Tables. For generating ALTER Table script there is an work around. Right click on the table, choose "Modify" and enter into the design mode. Make what ever changes you want to make and WITHOUT saving it right click anywhere on the top half of the window (above Column properties) and choose "Generate Change Script". Please be advised that SQL Server would drop actually create a new table with modifications, move the data from the old table into it and then drop the old table. Sounds simple but assume you have a very large table for which you want to do this! Then it woul