SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Update the first and last 2 charactors with year and month


Update the first and last 2 charactors with year and month

Author
Message
cfm
cfm
SSC-Enthusiastic
SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)

Group: General Forum Members
Points: 167 Visits: 36
I have a value that I need to change the first characters with the year and the last 2 characters with the month. The AttributeValue field value is 17WEBD01. I need to update the 17 with the current years last two digits and I need to update the 01 with the current month 2 digits.

I tried this statement and others but I keep getting errors
   
UPDATE [EC_StoreAttributes]
    SET Left(AttributeValue, 2) = SELECT RIGHT(CONVERT(VARCHAR(8), @Today, 1), 2)
where AttributeType = 'ECSRCCODE' and StoreRecordId = '1' 
sathwik.em91
sathwik.em91
Valued Member
Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)Valued Member (64 reputation)

Group: General Forum Members
Points: 64 Visits: 468
I have tried with getdate please change it to the date you need and I have convereted into a string..
UPDATE [EC_StoreAttributes]

   SET Left(AttributeValue, 2) = SELECT RIGHT(CONVERT(VARCHAR(10),GETDATE(),101),2)

, Right(AttributeValue, 2) = SELECT LEFT(CONVERT(VARCHAR(10),GETDATE(),101),2)

WHERE
AttributeType = 'ECSRCCODE' and StoreRecordId = '1' 

Hope this should work!!
Happy coding
cfm
cfm
SSC-Enthusiastic
SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)

Group: General Forum Members
Points: 167 Visits: 36
I'm getting an error message Incorrect syntax near the keyword 'Left'.
Jacob Wilkins
Jacob Wilkins
SSC-Insane
SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)

Group: General Forum Members
Points: 23494 Visits: 12942
LEFT and RIGHT are just functions that return a string; you can't SET the LEFT/RIGHT characters of a string like this (it would be like trying to do SET GETDATE()=...).

There are a variety of combinations of string functions you could use to satisfy this; I'll just show one possibility:


DECLARE @test TABLE (some_string VARCHAR(MAX));

INSERT INTO @test VALUES ('17test01'),('17something05'),('16morerandomstuff11');

SELECT modified_string=STUFF(LEFT(CONVERT(VARCHAR,GETDATE(),12),4),3,0,SUBSTRING(some_string,3,LEN(some_string)-4))
FROM @test;

cfm
cfm
SSC-Enthusiastic
SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)

Group: General Forum Members
Points: 167 Visits: 36
Can you help explain the script?

Can you help explain this part of the script.

SELECT modified_string=STUFF(LEFT(CONVERT(VARCHAR,GETDATE(),12),4),3,0,

This is the length that starts at position 3 then you subtract 4 characters to remove the first and last 2 characters of the value
SUBSTRING(some_string,3,LEN(some_string)-4))
Jacob Wilkins
Jacob Wilkins
SSC-Insane
SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)SSC-Insane (23K reputation)

Group: General Forum Members
Points: 23494 Visits: 12942
Sure!

The SUBSTRING part of the expression just returns the original string without the first and last 2 characters, as you noted.

Then the CONVERT turns the current datetime into a string using style 12, which is YYMMDD, as documented at https://docs.microsoft.com/en-us/sql/t-sql/functions/cast-and-convert-transact-sql#date-and-time-styles

Then the LEFT takes the leftmost 4 characters of that YYMMDD string, giving us a string that is today's date in YYMM format.

That is the string passed as the first parameter STUFF, which starts at position 3 (the second parameter, which means the insertion is after YY), replaces 0 characters (the third STUFF parameter, and with no replacement means it's pure insertion), and then inserts the result of the SUBSTRING (that is the 4th parameter to the STUFF).

In summary, the expression strips off the first 2 and last 2 characters of the original string, and then inserts that between the YY and MM in a YYMM version of today's date.

Hopefully that helps!
ScottPletcher
ScottPletcher
SSC Guru
SSC Guru (75K reputation)SSC Guru (75K reputation)SSC Guru (75K reputation)SSC Guru (75K reputation)SSC Guru (75K reputation)SSC Guru (75K reputation)SSC Guru (75K reputation)SSC Guru (75K reputation)

Group: General Forum Members
Points: 75965 Visits: 8900

UPDATE [EC_StoreAttributes]

SET AttributeValue = CONVERT(varchar(2), GETDATE(), 112) +
SUBSTRING(AttributeValue, 3, LEN(AttributeValue) - 4) +
CONVERT(varchar(2), GETDATE(), 3)

WHERE
AttributeType = 'ECSRCCODE' and StoreRecordId = '1'



SQL DBA,SQL Server MVP(07, 08, 09) Prosecutor James Blackburn, in closing argument in the Fatal Vision murders trial:
If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them.
cfm
cfm
SSC-Enthusiastic
SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)

Group: General Forum Members
Points: 167 Visits: 36
If I want the year and month I would need to add the right and left. correct

UPDATE [EC_StoreAttributes]

SET AttributeValue = RIGHT(CONVERT(VARCHAR(10), GETDATE(), 101), 2) +
SUBSTRING(AttributeValue, 3, LEN(AttributeValue) - 4) +
left(CONVERT(VARCHAR(10), GETDATE(), 101), 2)

WHERE
AttributeType = 'ECSRCCODE' and StoreRecordId = '1'
drew.allen
drew.allen
SSC Guru
SSC Guru (57K reputation)SSC Guru (57K reputation)SSC Guru (57K reputation)SSC Guru (57K reputation)SSC Guru (57K reputation)SSC Guru (57K reputation)SSC Guru (57K reputation)SSC Guru (57K reputation)

Group: General Forum Members
Points: 57180 Visits: 14834
cfm - Monday, February 26, 2018 9:28 AM
If I want the year and month I would need to add the right and left. correct

UPDATE [EC_StoreAttributes]

SET AttributeValue = RIGHT(CONVERT(VARCHAR(10), GETDATE(), 101), 2) +
SUBSTRING(AttributeValue, 3, LEN(AttributeValue) - 4) +
left(CONVERT(VARCHAR(10), GETDATE(), 101), 2)

WHERE
AttributeType = 'ECSRCCODE' and StoreRecordId = '1'

There are actually two different approaches that could be used. You could start with the attribute and then add the year at the beginning and the month at the end or you could start with the year and month and insert the attribute in the middle.

This second approach may not be as obvious to native English speakers, because English doesn't regularly use infixes (which is essentially what this approach mirrors). The one case is called expletive insertion or f*ing insertion and is used to show emphasis. Examples include abso-<expletive>-lutely and in-<expletive>-credible where an expletive is inserted in the words "absolutely" and "incredible" respectively.

Drew


J. Drew Allen
Business Intelligence Analyst
Philadelphia, PA
How to post data/code on a forum to get the best help.
How to Post Performance Problems
Make sure that you include code in the appropriate IFCode tags, e.g. [code=sql]<your code here>[/code]. You can find the IFCode tags under the INSERT options when you are writing a post.
ScottPletcher
ScottPletcher
SSC Guru
SSC Guru (75K reputation)SSC Guru (75K reputation)SSC Guru (75K reputation)SSC Guru (75K reputation)SSC Guru (75K reputation)SSC Guru (75K reputation)SSC Guru (75K reputation)SSC Guru (75K reputation)

Group: General Forum Members
Points: 75965 Visits: 8900
Oops, correction:


UPDATE [EC_StoreAttributes]

SET AttributeValue = CONVERT(varchar(2), GETDATE(), 12) -- 112)112) + /* 12 rather than 112 */
SUBSTRING(AttributeValue, 3, LEN(AttributeValue) - 4) +
CONVERT(varchar(2), GETDATE(), 3)

WHERE
AttributeType = 'ECSRCCODE' and StoreRecordId = '1'



SQL DBA,SQL Server MVP(07, 08, 09) Prosecutor James Blackburn, in closing argument in the Fatal Vision murders trial:
If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them.
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum








































































































































































SQLServerCentral


Search