Hierarchical XML data to JSON

  • I'm trying to create JSON output using hierarchical data below. I'm able to get the XML data but seeing special characters in the output (text with '&'). Can someone please suggest me on how handle special characters and format the output in JSON? Below is the sample data (test tables, insert statements, queries and expected output). I'm working on Win 7 and SQL 2012.

    Thanks

    CREATE TABLE lubr_req (enty_key bigint,mi_check_pt_rout_key_n bigint,mi_check_pt_pred_key_n bigint,MI_MEAS_LOC_SEQ_N FLOAT);

    CREATE TABLE meas_loc (enty_key bigint,mi_check_pt_rout_key_n bigint,mi_check_pt_pred_key_n bigint,MI_MEAS_LOC_SEQ_N FLOAT);

    CREATE TABLE chkp_cond (enty_key bigint,mi_chkpcond_rout_key_n bigint,mi_chkpcond_pred_key_n bigint,MI_CHKPCOND_SEQ_NUM_N FLOAT) ;

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64251803159,64251705940,64251705940,1);

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64251802979,64251705940,64251705940,2);

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64251802983,64251705940,64251705940,3);

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64251802987,64251705940,64251705940,4);

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64251803136,64251705940,64251705940,5);

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64251803145,64251705940,64251705940,6);

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64251803140,64251705940,64251705940,7);

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64252166561,64251705940,64252166559,1);

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64252166572,64251705940,64252166559,1.5);

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64251803150,64251705940,64251705940,8);

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64251803155,64251705940,64251705940,9);

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64251807715,64251705940,64251705940,10);

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64252166567,64251705940,64252166564,1);

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64252166575,64251705940,64252166574,1);

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64252166571,64251705940,64252166570,1);

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64252166577,64251705940,64252166576,1);

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64251802222,64251705940,64252161111,1);

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64252166573,64251705940,64252161111,2);

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64252166580,64251705940,64252161111,2);

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64252166581,64251705940,64252161111,1.5);

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64252166582,64251705940,64252161111,1.25);

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64252166583,64251705940,64252161111,2);

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64252166585,64251705940,64252166584,1);

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64252166586,64251705940,64252166584,2);

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64252166588,64251705940,64252166587,1);

    INSERT INTO lubr_req (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64252166579,64251705940,64252166578,1);

    INSERT INTO chkp_cond (enty_key,mi_chkpcond_rout_key_n,mi_chkpcond_pred_key_n,MI_CHKPCOND_SEQ_NUM_N) VALUES (64252166564,64251705940,64251803140,2);

    INSERT INTO chkp_cond (enty_key,mi_chkpcond_rout_key_n,mi_chkpcond_pred_key_n,MI_CHKPCOND_SEQ_NUM_N) VALUES (64252161111,64251705940,64252166561,1);

    INSERT INTO chkp_cond (enty_key,mi_chkpcond_rout_key_n,mi_chkpcond_pred_key_n,MI_CHKPCOND_SEQ_NUM_N) VALUES (64252166574,64251705940,64252166561,2.5);

    INSERT INTO chkp_cond (enty_key,mi_chkpcond_rout_key_n,mi_chkpcond_pred_key_n,MI_CHKPCOND_SEQ_NUM_N) VALUES (64252166570,64251705940,64251803140,3);

    INSERT INTO chkp_cond (enty_key,mi_chkpcond_rout_key_n,mi_chkpcond_pred_key_n,MI_CHKPCOND_SEQ_NUM_N) VALUES (64252166576,64251705940,64252166572,1);

    INSERT INTO chkp_cond (enty_key,mi_chkpcond_rout_key_n,mi_chkpcond_pred_key_n,MI_CHKPCOND_SEQ_NUM_N) VALUES (64252166578,64251705940,64251803140,4);

    INSERT INTO chkp_cond (enty_key,mi_chkpcond_rout_key_n,mi_chkpcond_pred_key_n,MI_CHKPCOND_SEQ_NUM_N) VALUES (64252166559,64251705940,64251803140,1);

    INSERT INTO chkp_cond (enty_key,mi_chkpcond_rout_key_n,mi_chkpcond_pred_key_n,MI_CHKPCOND_SEQ_NUM_N) VALUES (64252166584,64251705940,64251802983,1);

    INSERT INTO chkp_cond (enty_key,mi_chkpcond_rout_key_n,mi_chkpcond_pred_key_n,MI_CHKPCOND_SEQ_NUM_N) VALUES (64252166587,64251705940,64251802983,2);

    create table lubr_chkp (enty_key bigint, rounte_key bigint, parent_key bigint, enty_seq float, chkp_cond nvarchar(6))

    ;with t as (

    select enty_key,mi_check_pt_rout_key_n rounte_key,mi_check_pt_pred_key_n parent_key,MI_MEAS_LOC_SEQ_N enty_seq, 'true' chkp_cond

    from meas_loc

    union all

    select enty_key,mi_check_pt_rout_key_n rounte_key,mi_check_pt_pred_key_n parent_key,MI_MEAS_LOC_SEQ_N enty_seq, 'true' chkp_cond

    from lubr_req

    union all

    select enty_key,mi_chkpcond_rout_key_n rounte_key,mi_chkpcond_pred_key_n parent_key,MI_CHKPCOND_SEQ_NUM_N enty_seq, 'false' chkp_cond

    from chkp_cond

    )

    insert into lubr_chkp (enty_key , rounte_key , parent_key , enty_seq, chkp_cond )

    select enty_key , rounte_key , parent_key , enty_seq, chkp_cond from t

    drop function SelectChild

    go

    CREATE function SelectChild(@key as bigint)

    returns xml

    begin

    return (

    select

    CONVERT(varchar(100), CAST(enty_seq AS float)) as "@SeqNum",

    enty_key as "@EntityKey",

    chkp_cond as "@IsCheckpoint",

    isnull(CONVERT(varchar(max), cast(dbo.SelectChild(enty_key) as xml)),'null') as "@ListDirectChildren"

    from lubr_chkp

    where parent_key = @key

    order by enty_seq

    for xml path('entity'), type

    )

    end

    go

    select cast(

    (SELECT

    CONVERT(varchar(100), CAST(enty_seq AS float)) as "@SeqNum"

    ,enty_key AS "@EntityKey"

    ,chkp_cond as "@IsCheckpoint"

    ,isnull(CONVERT(varchar(max), cast(dbo.SelectChild(enty_key) as xml)),'null') as "@ListDirectChildren"

    FROM lubr_chkp

    WHERE parent_key = 64251705940

    order by enty_seq

    FOR XML PATH ('entity'), type) as varchar(max))

    --Expected output

    [{"SeqNum":1,"EntityKey":64251803159,"IsCheckpoint":true,"ListDirectChildren":null},

    {"SeqNum":2,"EntityKey":64251802979,"IsCheckpoint":true,"ListDirectChildren":null},

    {"SeqNum":3,"EntityKey":64251802983,"IsCheckpoint":true,"ListDirectChildren":

    [{"SeqNum":1,"EntityKey":64252166584,"IsCheckpoint":false,"ListDirectChildren":

    [{"SeqNum":1,"EntityKey":64252166585,"IsCheckpoint":true,"ListDirectChildren":null},

    {"SeqNum":2,"EntityKey":64252166586,"IsCheckpoint":true,"ListDirectChildren":null}]},

    {"SeqNum":2,"EntityKey":64252166587,"IsCheckpoint":false,"ListDirectChildren":

    [{"SeqNum":1,"EntityKey":64252166588,"IsCheckpoint":true,"ListDirectChildren":null}]}]},

    {"SeqNum":4,"EntityKey":64251802987,"IsCheckpoint":true,"ListDirectChildren":null},

    {"SeqNum":5,"EntityKey":64251803136,"IsCheckpoint":true,"ListDirectChildren":null},

    {"SeqNum":6,"EntityKey":64251803145,"IsCheckpoint":true,"ListDirectChildren":null},

    {"SeqNum":7,"EntityKey":64251803140,"IsCheckpoint":true,"ListDirectChildren":

    [{"SeqNum":1,"EntityKey":64252166559,"IsCheckpoint":false,"ListDirectChildren":

    [{"SeqNum":1,"EntityKey":64252166561,"IsCheckpoint":true,"ListDirectChildren":

    [{"SeqNum":1,"EntityKey":64252161111,"IsCheckpoint":false,"ListDirectChildren":

    [{"SeqNum":1,"EntityKey":64251802222,"IsCheckpoint":true,"ListDirectChildren":null},

    {"SeqNum":1.25,"EntityKey":64252166582,"IsCheckpoint":true,"ListDirectChildren":null},

    {"SeqNum":1.5,"EntityKey":64252166581,"IsCheckpoint":true,"ListDirectChildren":null},

    {"SeqNum":2,"EntityKey":64252166573,"IsCheckpoint":true,"ListDirectChildren":null},

    {"SeqNum":2,"EntityKey":64252166580,"IsCheckpoint":true,"ListDirectChildren":null},

    {"SeqNum":2,"EntityKey":64252166583,"IsCheckpoint":true,"ListDirectChildren":null}]},

    {"SeqNum":2.5,"EntityKey":64252166574,"IsCheckpoint":false,"ListDirectChildren":

    [{"SeqNum":1,"EntityKey":64252166575,"IsCheckpoint":true,"ListDirectChildren":null}]}]},

    {"SeqNum":1.5,"EntityKey":64252166572,"IsCheckpoint":true,"ListDirectChildren":

    [{"SeqNum":1,"EntityKey":64252166576,"IsCheckpoint":false,"ListDirectChildren":

    [{"SeqNum":1,"EntityKey":64252166577,"IsCheckpoint":true,"ListDirectChildren":null}]}]}]},

    {"SeqNum":2,"EntityKey":64252166564,"IsCheckpoint":false,"ListDirectChildren":

    [{"SeqNum":1,"EntityKey":64252166567,"IsCheckpoint":true,"ListDirectChildren":null}]},

    {"SeqNum":3,"EntityKey":64252166570,"IsCheckpoint":false,"ListDirectChildren":

    [{"SeqNum":1,"EntityKey":64252166571,"IsCheckpoint":true,"ListDirectChildren":null}]},

    {"SeqNum":4,"EntityKey":64252166578,"IsCheckpoint":false,"ListDirectChildren":

    [{"SeqNum":1,"EntityKey":64252166579,"IsCheckpoint":true,"ListDirectChildren":null}]}]},

    {"SeqNum":8,"EntityKey":64251803150,"IsCheckpoint":true,"ListDirectChildren":null},

    {"SeqNum":9,"EntityKey":64251803155,"IsCheckpoint":true,"ListDirectChildren":null},

    {"SeqNum":10,"EntityKey":64251807715,"IsCheckpoint":true,"ListDirectChildren":null}]

  • Why I understand the intent - is there a requirement to have SQL Server do the JSON serialization? There is a LOT of shareware and/or open source applications that translate XML into JSON. Rebuilding a JSON converter in SQL Server smells like using the wrong tool to do the job.

    ----------------------------------------------------------------------------------
    Your lack of planning does not constitute an emergency on my part...unless you're my manager...or a director and above...or a really loud-spoken end-user..All right - what was my emergency again?

  • Our customers are in Oracle and SQL Server 2012. I was asked to create a script to transform data from the tables (which have parent-child relation) to JSON format. I'm bit new to JSON formatting. I was able to transform the data to JSON format in Oracle. But in SQL it's been bit challenging. Could you please suggest any Microsoft tools that would format the data to JSON and load the formatted data back in SQL Server (to a different table).

  • Well neither are technically "Microsoft tools", but I've used two different options:

    http://json.codeplex.com/[/url] had a built up C# library to (open source) you can invoke from .NET code to reserialize XML as JSON.

    I've also had occasion to use the ALTOVA serializer. It's very nice in interactive session, but does require licensing one or more components from ALTOVA, so this wouldn't be free, but it did yield performance enhancements to the plain code widget when we ramped up on the transform tool.

    ----------------------------------------------------------------------------------
    Your lack of planning does not constitute an emergency on my part...unless you're my manager...or a director and above...or a really loud-spoken end-user..All right - what was my emergency again?

  • I've used Json.NET from Newtonsoft in an SSIS process which deserialised JSON & it worked very well. I imagine it would work just as well while serialising.

    The absence of evidence is not evidence of absence.
    Martin Rees

    You can lead a horse to water, but a pencil must be lead.
    Stan Laurel

  • Thanks Matt. Can I request one small help? Below test code has all create table/insert/function and select statement. When I run the select statement, I'm getting escape characters in the output and unable to get complete xml format output. Could you please help me correct the function or select query to produce the output in the right xml format?

    I noticed a procedure in this link which transforms data to JSON. I'd like to try it.

    https://nyquist212.wordpress.com/2014/02/11/tsql-to-json-2/

    CREATE TABLE meas_loc (enty_key bigint,mi_check_pt_rout_key_n bigint,mi_check_pt_pred_key_n bigint,MI_MEAS_LOC_SEQ_N FLOAT);

    CREATE TABLE chkp_cond (enty_key bigint,mi_chkpcond_rout_key_n bigint,mi_chkpcond_pred_key_n bigint,MI_CHKPCOND_SEQ_NUM_N FLOAT) ;

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64251803159,64251705940,64251705940,1);

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64251802979,64251705940,64251705940,2);

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64251802983,64251705940,64251705940,3);

    INSERT INTO chkp_cond (enty_key,mi_chkpcond_rout_key_n,mi_chkpcond_pred_key_n,MI_CHKPCOND_SEQ_NUM_N) VALUES (64252166584,64251705940,64251802983,1);

    INSERT INTO meas_loc (enty_key,mi_check_pt_rout_key_n,mi_check_pt_pred_key_n,MI_MEAS_LOC_SEQ_N) VALUES (64252166585,64251705940,64252166584,1);

    create table lubr_chkp (enty_key bigint, rounte_key bigint, parent_key bigint, enty_seq float, chkp_cond nvarchar(6))

    ;with t as (

    select enty_key,mi_check_pt_rout_key_n rounte_key,mi_check_pt_pred_key_n parent_key,MI_MEAS_LOC_SEQ_N enty_seq, 'true' chkp_cond

    from meas_loc

    union all

    select enty_key,mi_chkpcond_rout_key_n rounte_key,mi_chkpcond_pred_key_n parent_key,MI_CHKPCOND_SEQ_NUM_N enty_seq, 'false' chkp_cond

    from chkp_cond

    )

    insert into lubr_chkp (enty_key , rounte_key , parent_key , enty_seq, chkp_cond )

    select enty_key , rounte_key , parent_key , enty_seq, chkp_cond from t

    go

    drop function SelectChild

    go

    CREATE function SelectChild(@key as bigint)

    returns xml

    begin

    return (

    select

    CONVERT(varchar(100), CAST(enty_seq AS float)) as "@SeqNum",

    enty_key as "@EntityKey",

    chkp_cond as "@IsCheckpoint",

    isnull(CONVERT(varchar(max), cast(dbo.SelectChild(enty_key) as xml)),'null')as "@ListDirectChildren"

    from lubr_chkp

    where parent_key = @key

    order by enty_seq

    for xml path('entity'), type

    )

    end

    go

    WITH PrepareTable (XMLString)AS(SELECT

    CONVERT(varchar(100), CAST(enty_seq AS float)) as SeqNum

    ,enty_key AS EntityKey

    ,chkp_cond as IsCheckpoint

    ,isnull(CONVERT(varchar(max), cast(dbo.SelectChild(enty_key) as xml)),'null')as ListDirectChildren

    FROM lubr_chkp

    WHERE parent_key = 64251705940

    order by enty_seq FOR XML RAW,TYPE,ELEMENTS)SELECT [XMLString]FROM[PrepareTable]

  • Follow the advice you were given in the OTHER thread, as in, stop using cast to varchar.

    These changes worked for me.

    drop function dbo.SelectChild

    go

    CREATE function dbo.SelectChild(@key as bigint)

    returns xml

    begin

    return (

    select

    CONVERT(varchar(100), CAST(enty_seq AS float)) as "@SeqNum",

    enty_key as "@EntityKey",

    chkp_cond as "@IsCheckpoint",

    (Select dbo.SelectChild(enty_key) for XML path(''),type) as "ListDirectChildren"

    from lubr_chkp

    where parent_key = @key

    order by enty_seq

    for xml path('entity'), type

    )

    end

    go

    WITH PrepareTable (XMLString)AS(SELECT

    CONVERT(varchar(100), CAST(enty_seq AS float)) as SeqNum

    ,enty_key AS EntityKey

    ,chkp_cond as IsCheckpoint

    ,(Select dbo.SelectChild(enty_key) for XML path(''),type) as ListDirectChildren

    FROM lubr_chkp

    WHERE parent_key = 64251705940

    order by enty_seq FOR XML PATH,TYPE,ELEMENTS)

    SELECT [XMLString]FROM[PrepareTable]

    ----------------------------------------------------------------------------------
    Your lack of planning does not constitute an emergency on my part...unless you're my manager...or a director and above...or a really loud-spoken end-user..All right - what was my emergency again?

Viewing 7 posts - 1 through 6 (of 6 total)

You must be logged in to reply to this topic. Login to reply