Last active
March 29, 2017 10:35
-
-
Save bertwagner/0096952bb76f12e40dc1c85c683ac331 to your computer and use it in GitHub Desktop.
SQL to JSON datetime modifications
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
DECLARE @sqlDate datetime2 = '2017-03-28 12:45:00.1234567' | |
DECLARE @jsonData nvarchar(max) = N'{ "createDate" : "2017-03-28T12:45:00.000Z" }' | |
,@newDate datetime2(3) = '2017-03-28T12:48:00.123Z' | |
-- Let's start out modifying our data by replacing the value completely | |
SELECT JSON_VALUE(@jsonData, '$.createDate') | |
-- If we want to pass in a perfectly formatted JSON string, then it's pretty easy | |
SELECT JSON_MODIFY(@jsonData, '$.createDate', '2017-03-28T12:48:00.123Z') | |
-- Output: { "createDate" : "2017-03-28T12:48:00.123Z" } | |
-- If we want to pass in a SQL datetime2 value, say like what we have stored in @newDate, then things get a little messy. | |
-- The JSON_MODIFY function requires the third argument to be the nvarchar datatype. This means | |
-- we need to get our SQL datetime2 into a valid JSON string first. | |
-- If we use FOR JSON PATH to create the JSON date from the SQL datetime2, things get ugly because | |
-- FOR JSON PATH always creates a property : value combination | |
SELECT JSON_MODIFY(@jsonData, '$.createDate', (SELECT @newDate as newDate FOR JSON PATH)) | |
-- Output: { "createDate" : [{"newDate":"2017-03-28T12:48:00.123"}] } | |
-- In order to only pass the JSON datetime into the value for the "createDate" property, we need to | |
-- use the CONVERT style number 127 to convert our dateTime to a JSON format | |
SELECT JSON_MODIFY(@jsonData, '$.createDate', (SELECT CONVERT(nvarchar, @newDate, 127))) | |
-- Output: { "createDate" : "2017-03-28T12:48:00.123" } | |
-- But what happened to our "Z" indicating UTC? | |
-- We of course need to specify the AT TIME ZONE again: | |
SELECT JSON_MODIFY(@jsonData, '$.createDate', (SELECT CONVERT(nvarchar, @newDate AT TIME ZONE 'UTC', 127))) | |
--Output: { "createDate" : "2017-03-28T12:48:00.123Z" } |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment