227 lines
No EOL
8.9 KiB
Transact-SQL
227 lines
No EOL
8.9 KiB
Transact-SQL
IF OBJECT_ID('[fnConvertJSONToTable]') IS NOT NULL BEGIN
|
|
DROP FUNCTION [fnConvertJSONToTable]
|
|
END
|
|
GO
|
|
|
|
CREATE FUNCTION fnConvertJSONToTable (@JSON NVARCHAR(MAX))
|
|
RETURNS @hierarchy TABLE
|
|
(
|
|
element_id INT IDENTITY(1, 1) NOT NULL,
|
|
sequenceNo [int] NULL,
|
|
parent_ID INT,
|
|
Object_ID INT,
|
|
NAME NVARCHAR(2000),
|
|
StringValue NVARCHAR(MAX) NOT NULL,
|
|
ValueType VARCHAR(10) NOT NULL
|
|
)
|
|
AS
|
|
BEGIN
|
|
DECLARE
|
|
@FirstObject INT,
|
|
@OpenDelimiter INT,
|
|
@NextOpenDelimiter INT,
|
|
@NextCloseDelimiter INT,
|
|
@Type NVARCHAR(10),
|
|
@NextCloseDelimiterChar CHAR(1),
|
|
@Contents NVARCHAR(MAX),
|
|
@Start INT,
|
|
@end INT,
|
|
@param INT,
|
|
@EndOfName INT,
|
|
@token NVARCHAR(200),
|
|
@value NVARCHAR(MAX),
|
|
@SequenceNo int,
|
|
@name NVARCHAR(200),
|
|
@parent_ID INT,
|
|
@lenJSON INT,
|
|
@characters NCHAR(36),
|
|
@result BIGINT,
|
|
@index SMALLINT,
|
|
@Escape INT
|
|
|
|
DECLARE @Strings TABLE
|
|
(
|
|
String_ID INT IDENTITY(1, 1),
|
|
StringValue NVARCHAR(MAX)
|
|
)
|
|
|
|
SELECT
|
|
@characters='0123456789abcdefghijklmnopqrstuvwxyz',
|
|
@SequenceNo=0,
|
|
@parent_ID=0;
|
|
WHILE 1 = 1
|
|
BEGIN
|
|
SELECT
|
|
@start=PATINDEX('%[^a-zA-Z]["]%', @json collate SQL_Latin1_General_CP850_Bin);
|
|
|
|
IF @start=0 BREAK
|
|
IF SUBSTRING(@json, @start+1, 1)='"'
|
|
BEGIN --Delimited Name
|
|
SET @start=@Start+1;
|
|
SET @end=PATINDEX('%[^\]["]%', RIGHT(@json, LEN(@json+'|')-@start) collate SQL_Latin1_General_CP850_Bin);
|
|
END
|
|
IF @end=0 --no end delimiter to last string
|
|
BREAK --no more
|
|
SELECT @token=SUBSTRING(@json, @start+1, @end-1)
|
|
--now put in the escaped control characters
|
|
SELECT @token=REPLACE(@token, FROMString, TOString)
|
|
FROM
|
|
(SELECT
|
|
'\"' AS FromString, '"' AS ToString
|
|
UNION ALL SELECT '\\', '\'
|
|
UNION ALL SELECT '\/', '/'
|
|
UNION ALL SELECT '\b', CHAR(08)
|
|
UNION ALL SELECT '\f', CHAR(12)
|
|
UNION ALL SELECT '\n', CHAR(10)
|
|
UNION ALL SELECT '\r', CHAR(13)
|
|
UNION ALL SELECT '\t', CHAR(09)
|
|
) substitutions
|
|
SELECT @result=0, @escape=1
|
|
--Begin to take out any hex escape codes
|
|
WHILE @escape>0
|
|
BEGIN
|
|
SELECT @index=0,
|
|
--find the next hex escape sequence
|
|
@escape=PATINDEX('%\x[0-9a-f][0-9a-f][0-9a-f][0-9a-f]%', @token collate SQL_Latin1_General_CP850_Bin)
|
|
IF @escape>0 --if there is one
|
|
BEGIN
|
|
WHILE @index<4 --there are always four digits to a \x sequence
|
|
BEGIN
|
|
SELECT --determine its value
|
|
@result=@result+POWER(16, @index)
|
|
*(CHARINDEX(SUBSTRING(@token, @escape+2+3-@index, 1),
|
|
@characters)-1), @index=@index+1 ;
|
|
|
|
END
|
|
-- and replace the hex sequence by its unicode value
|
|
SELECT @token=STUFF(@token, @escape, 6, NCHAR(@result))
|
|
END
|
|
END
|
|
--now store the string away
|
|
INSERT INTO @Strings (StringValue) SELECT @token
|
|
-- and replace the string with a token
|
|
SELECT @JSON=STUFF(@json, @start, @end+1,
|
|
'@string'+CONVERT(NVARCHAR(5), @@identity))
|
|
END
|
|
-- all strings are now removed. Now we find the first leaf.
|
|
WHILE 1=1 --forever until there is nothing more to do
|
|
BEGIN
|
|
|
|
SELECT @parent_ID=@parent_ID+1
|
|
--find the first object or list by looking for the open bracket
|
|
SELECT @FirstObject=PATINDEX('%[{[[]%', @json collate SQL_Latin1_General_CP850_Bin)--object or array
|
|
IF @FirstObject = 0 BREAK
|
|
IF (SUBSTRING(@json, @FirstObject, 1)='{')
|
|
SELECT @NextCloseDelimiterChar='}', @type='object'
|
|
ELSE
|
|
SELECT @NextCloseDelimiterChar=']', @type='array'
|
|
SELECT @OpenDelimiter=@firstObject
|
|
WHILE 1=1 --find the innermost object or list...
|
|
BEGIN
|
|
SELECT
|
|
@lenJSON=LEN(@JSON+'|')-1
|
|
--find the matching close-delimiter proceeding after the open-delimiter
|
|
SELECT
|
|
@NextCloseDelimiter=CHARINDEX(@NextCloseDelimiterChar, @json,
|
|
@OpenDelimiter+1)
|
|
--is there an intervening open-delimiter of either type
|
|
SELECT @NextOpenDelimiter=PATINDEX('%[{[[]%',
|
|
RIGHT(@json, @lenJSON-@OpenDelimiter)collate SQL_Latin1_General_CP850_Bin)--object
|
|
IF @NextOpenDelimiter=0
|
|
BREAK
|
|
SELECT @NextOpenDelimiter=@NextOpenDelimiter+@OpenDelimiter
|
|
IF @NextCloseDelimiter<@NextOpenDelimiter
|
|
BREAK
|
|
IF SUBSTRING(@json, @NextOpenDelimiter, 1)='{'
|
|
SELECT @NextCloseDelimiterChar='}', @type='object'
|
|
ELSE
|
|
SELECT @NextCloseDelimiterChar=']', @type='array'
|
|
SELECT @OpenDelimiter=@NextOpenDelimiter
|
|
END
|
|
---and parse out the list or name/value pairs
|
|
SELECT
|
|
@contents=SUBSTRING(@json, @OpenDelimiter+1,
|
|
@NextCloseDelimiter-@OpenDelimiter-1)
|
|
SELECT
|
|
@JSON=STUFF(@json, @OpenDelimiter,
|
|
@NextCloseDelimiter-@OpenDelimiter+1,
|
|
'@'+@type+CONVERT(NVARCHAR(5), @parent_ID))
|
|
WHILE (PATINDEX('%[A-Za-z0-9@+.e]%', @contents collate SQL_Latin1_General_CP850_Bin))<>0
|
|
BEGIN
|
|
IF @Type='Object' --it will be a 0-n list containing a string followed by a string, number,boolean, or null
|
|
BEGIN
|
|
SELECT
|
|
@SequenceNo=0,@end=CHARINDEX(':', ' '+@contents)--if there is anything, it will be a string-based name.
|
|
SELECT @start=PATINDEX('%[^A-Za-z@][@]%', ' '+@contents collate SQL_Latin1_General_CP850_Bin)--AAAAAAAA
|
|
SELECT @token=SUBSTRING(' '+@contents, @start+1, @End-@Start-1),
|
|
@endofname=PATINDEX('%[0-9]%', @token collate SQL_Latin1_General_CP850_Bin),
|
|
@param=RIGHT(@token, LEN(@token)-@endofname+1)
|
|
SELECT
|
|
@token=LEFT(@token, @endofname-1),
|
|
@Contents=RIGHT(' '+@contents, LEN(' '+@contents+'|')-@end-1)
|
|
SELECT @name=stringvalue FROM @strings
|
|
WHERE string_id=@param --fetch the name
|
|
END
|
|
ELSE
|
|
SELECT @Name=null,@SequenceNo=@SequenceNo+1
|
|
SELECT
|
|
@end=CHARINDEX(',', @contents)-- a string-token, object-token, list-token, number,boolean, or null
|
|
IF @end=0
|
|
--HR Engineering notation bugfix start
|
|
IF ISNUMERIC(@contents) = 1
|
|
SELECT @end = LEN(@contents)
|
|
Else
|
|
--HR Engineering notation bugfix end
|
|
SELECT @end=PATINDEX('%[A-Za-z0-9@+.e][^A-Za-z0-9@+.e]%', @contents+' ' collate SQL_Latin1_General_CP850_Bin) + 1
|
|
SELECT
|
|
@start=PATINDEX('%[^A-Za-z0-9@+.e][A-Za-z0-9@+.e]%', ' '+@contents collate SQL_Latin1_General_CP850_Bin)
|
|
--select @start,@end, LEN(@contents+'|'), @contents
|
|
SELECT
|
|
@Value=RTRIM(SUBSTRING(@contents, @start, @End-@Start)),
|
|
@Contents=RIGHT(@contents+' ', LEN(@contents+'|')-@end)
|
|
IF SUBSTRING(@value, 1, 7)='@object'
|
|
INSERT INTO @hierarchy
|
|
(NAME, SequenceNo, parent_ID, StringValue, Object_ID, ValueType)
|
|
SELECT @name, @SequenceNo, @parent_ID, SUBSTRING(@value, 8, 5),
|
|
SUBSTRING(@value, 8, 5), 'object'
|
|
ELSE
|
|
IF SUBSTRING(@value, 1, 6)='@array'
|
|
INSERT INTO @hierarchy
|
|
(NAME, SequenceNo, parent_ID, StringValue, Object_ID, ValueType)
|
|
SELECT @name, @SequenceNo, @parent_ID, SUBSTRING(@value, 7, 5),
|
|
SUBSTRING(@value, 7, 5), 'array'
|
|
ELSE
|
|
IF SUBSTRING(@value, 1, 7)='@string'
|
|
INSERT INTO @hierarchy
|
|
(NAME, SequenceNo, parent_ID, StringValue, ValueType)
|
|
SELECT @name, @SequenceNo, @parent_ID, stringvalue, 'string'
|
|
FROM @strings
|
|
WHERE string_id=SUBSTRING(@value, 8, 5)
|
|
ELSE
|
|
IF @value IN ('true', 'false')
|
|
INSERT INTO @hierarchy
|
|
(NAME, SequenceNo, parent_ID, StringValue, ValueType)
|
|
SELECT @name, @SequenceNo, @parent_ID, @value, 'boolean'
|
|
ELSE
|
|
IF @value='null'
|
|
INSERT INTO @hierarchy
|
|
(NAME, SequenceNo, parent_ID, StringValue, ValueType)
|
|
SELECT @name, @SequenceNo, @parent_ID, @value, 'null'
|
|
ELSE
|
|
IF PATINDEX('%[^0-9]%', @value collate SQL_Latin1_General_CP850_Bin)>0
|
|
INSERT INTO @hierarchy
|
|
(NAME, SequenceNo, parent_ID, StringValue, ValueType)
|
|
SELECT @name, @SequenceNo, @parent_ID, @value, 'real'
|
|
ELSE
|
|
INSERT INTO @hierarchy
|
|
(NAME, SequenceNo, parent_ID, StringValue, ValueType)
|
|
SELECT @name, @SequenceNo, @parent_ID, @value, 'int'
|
|
if @Contents=' ' Select @SequenceNo=0
|
|
END
|
|
END
|
|
INSERT INTO @hierarchy (NAME, SequenceNo, parent_ID, StringValue, Object_ID, ValueType)
|
|
SELECT '-',1, NULL, '', @parent_id-1, @type
|
|
--
|
|
RETURN
|
|
END
|
|
GO |