x

date problem

I am trying to subtract a month from a YearMonth format. YYYYMM YearMonth is is varchar format.

So I do :

 select yearmonth - 1 from tableA

The problem is when get to 200601 it returns 200600 instead of 200512

Any suggestion how to fix this?

more ▼

asked Oct 25, 2011 at 07:30 AM in Default

avatar image

sqlnewb
216 29 32 35

(comments are locked)
10|1200 characters needed characters left

1 answer: sort voted first

To do date arithmetic on the field, you need to turn it into a date

Follow this code

 declare @YYYYMM varchar(6)
 set @YYYYMM = '200601'
 
 select 
  convert(datetime, @YYYYMM+'01', 112),
  dateadd(mm, -1, convert(datetime, @YYYYMM+'01', 112)),
  convert(varchar, dateadd(mm, -1, convert(datetime, @YYYYMM+'01', 112)),112),
  left(convert(varchar, dateadd(mm, -1, convert(datetime, @YYYYMM+'01', 112)),112),6)

I first string concatenate a '01' to make a string that matches the date format of 112 (ISO standard). Then I can convert that to an actual date, then subtract one month using DATEADD, convert it back to a string from the 112 style date, and finally remove the last 2 characters to get your YYYYMM format back again.

The last one is the one you need, but I've shown the intermediary steps to help you understand the path....

more ▼

answered Oct 25, 2011 at 07:40 AM

avatar image

Kev Riley ♦♦
64.2k 48 62 81

Thanks that makes sense. Thank for the explanation as well

Oct 25, 2011 at 07:48 AM sqlnewb
(comments are locked)
10|1200 characters needed characters left
Your answer
toggle preview:

Up to 2 attachments (including images) can be used with a maximum of 524.3 kB each and 1.0 MB total.

Follow this question

By Email:

Once you sign in you will be able to subscribe for any updates here

By RSS:

Answers

Answers and Comments

SQL Server Central

Need long-form SQL discussion? SQLserverCentral.com is the place.

Topics:

x1069
x39

asked: Oct 25, 2011 at 07:30 AM

Seen: 1771 times

Last Updated: Oct 25, 2011 at 07:30 AM

Copyright 2016 Redgate Software. Privacy Policy