Query XML which has multiple child and subchild

  • Hi ,

    We have a requirement in which we need to Query an XML which has child and sub child(structure mentioned below) and we want to insert the data into corresponding different tables. For eg,

    <ID>

    <NO>1</NO>

    <Code>C001</Code>

    <Program>

    </NO>

    </Detail>

    <Project>

    <ID>1</ID>

    <Name>ABC</Name>

    </Project>

    <Project>

    <ID>2</ID>

    <Name>ADG></Name>

    </Program>

    </ID>

    Number of Projects under program can be many(not only 2). The details need to be inserted into 2 tables ID and Project. Please suggest me how to do the same using stored procedure.

    Thanks

    Jim

  • The example XML wasn't well formed so I have had to tweak it to make it valid.. To shred this you would need to use the nodes() function. Here is an example script to get you started with shredding it:

    DECLARE @xml XML

    SET @xml = '

    <ID>

    <NO>1</NO>

    <Code>C001</Code>

    <Program>

    <Project>

    <ID>1</ID>

    <Name>ABC</Name>

    </Project>

    <Project>

    <ID>2</ID>

    <Name>ADG</Name>

    </Project>

    </Program>

    </ID>'

    SELECT t.c.value('(NO/text())[1]', 'int') AS 'NO'

    , t.c.value('(Code/text())[1]', 'varchar(100)') AS 'Code'

    , p.c.value('(ID/text())[1]', 'int') AS 'Project_ID'

    , p.c.value('(Name/text())[1]', 'varchar(100)') AS 'Project_Name'

    FROM @xml.nodes('/ID') AS T(C)

    CROSS APPLY T.C.nodes('Program/Project') AS P(C)

    returns

    NOCodeProject_IDProject_Name

    1C0011ABC

    1C0012ADG

  • Thanks arthurolcot!.

    There is a small change in the table structure in which the data needs to get inserted.

    CREATE TABLE ID(

    NO_PK INT IDENTITY(1,1) PRIMARY KEY,

    Id INT

    )

    CREATE TABLE PROJECT(

    NO_PK_Project INT IDENTITY(100,1) PRIMARY KEY,

    NO_FK_ID INT REFERENCES ID(NO_PK),

    PROJECTID INT,

    ID INT,

    PROJECTNAME VARCHAR(20)

    )

    Before inserting into project table I need to know the corresponding ID(NO_PK) and insert the respective rows. Then continue the same. Please suggest.

    Thanks

    Jim

  • Hi Jim, It's probably me not understanding the data structure or maybe the example XML is missing some elements, but I can't see where all the columns map to the XML nodes.

    In your ID table, you have a column id. does that map to the XML node /ID/NO ? If so then I don't see the point of this table.

    Also in your project table you have a column PROJECTID and a column ID, where do they map to? I can only see /ID/Program/Project/ID.

    Is the example XML missing any nodes?

  • Hi arthurolcot,

    Giving a sample xml and the table structure. Need to insert into the respective tables below. Please suggest

    DECLARE @xml xml

    = '<Master>

    <MasterNo>abc</MasterNo>

    <Id>def</Id>

    <FirstChild>

    <FirstChildNo>ghi</FirstChildNo>

    <ClaimNO>jkl</ClaimNO>

    </FirstChild>

    <SecondChild>

    <Code>098</Code>

    <Demo>765</Demo>

    </SecondChild>

    <ThirdChild>

    <ID>123</ID>

    <ChildNo>1</ChildNo>

    <FirstChild>

    <FirstChildNo/>

    <ClaimNo/>

    </FirstChild>

    <FourthChild>

    <Quantity>12</Quantity>

    <ID>1</ID>

    <FourthChildNo>

    <Number>125</Number>

    <Ref>ABC</Ref>

    </FourthChildNo>

    <FourthChildNo>

    <Number>125</Number>

    <Ref>ABC</Ref>

    </FourthChildNo>

    </FourthChild>

    </ThirdChild>

    <ThirdChild>

    <ID>123</ID>

    <ChildNo>1</ChildNo>

    <FirstChild>

    <FirstChildNo/>

    <ClaimNo/>

    </FirstChild>

    <FourthChild>

    <Quantity>2</Quantity>

    <ID>14</ID>

    <FourthChildNo>

    <Number>125</Number>

    <Ref>BC</Ref>

    </FourthChildNo>

    <FourthChildNo>

    <Number>25</Number>

    <Ref>BC</Ref>

    </FourthChildNo>

    </FourthChild>

    </ThirdChild>

    </Master>

    <Master>

    <MasterNo>bc</MasterNo>

    <Id>ef</Id>

    <FirstChild>

    <FirstChildNo>hi</FirstChildNo>

    <ClaimNO>kl</ClaimNO>

    </FirstChild>

    <SecondChild>

    <Code>98</Code>

    <Demo>65</Demo>

    </SecondChild>

    <ThirdChild>

    <ID>23</ID>

    <ChildNo>10</ChildNo>

    <FirstChild>

    <FirstChildNo/>

    <ClaimNo/>

    </FirstChild>

    <FourthChild>

    <Quantity>1</Quantity>

    <ID>1</ID>

    <FourthChildNo>

    <Number>15</Number>

    <Ref>ABC</Ref>

    </FourthChildNo>

    <FourthChildNo>

    <Number>15</Number>

    <Ref>AC</Ref>

    </FourthChildNo>

    </FourthChild>

    </ThirdChild>

    <ThirdChild>

    <ID>13</ID>

    <ChildNo>1</ChildNo>

    <FirstChild>

    <FirstChildNo/>

    <ClaimNo/>

    </FirstChild>

    <FourthChild>

    <Quantity>2</Quantity>

    <ID>104</ID>

    <FourthChildNo>

    <Number>15</Number>

    <Ref>C</Ref>

    </FourthChildNo>

    <FourthChildNo>

    <Number>5</Number>

    <Ref>BC</Ref>

    </FourthChildNo>

    </FourthChild>

    </ThirdChild>

    </Master>'

    CREATE TABLE m_Master(

    m_Seq_id int IDENTITY(1,1) PRIMARY KEY,

    MasterNo VARCHAR(20),

    Id VARCHAR(20)

    )

    CREATE TABLE m_FirstChild(

    m_FirstChild_Seq_Id int IDENTITY(100,1) PRIMARY KEY,

    m_Seq_id int REFERENCES m_Master(m_Seq_id),

    FirstChildNO VARCHAR(20),

    ClaimNO VARCHAR(20)

    )

    CREATE TABLE m_SecondChild(

    m_SecondChild_seq_id INT IDENTITY(100,1) PRIMARY KEY,

    m_Seq_id int REFERENCES m_Master(m_Seq_id),

    Code INT,

    Demo INT

    )

    CREATE TABLE m_ThirdChilds(

    m_ThirdChilds_seq_id INT IDENTITY(100,1) PRIMARY KEY,

    m_Seq_id int REFERENCES m_Master(m_Seq_id),

    ID INT,

    i_ChildNo INT,

    FirstChildNO VARCHAR(20),

    ClaimNO VARCHAR(20),

    Quantity INT,

    FourthChild_ID INT

    )

    CREATE TABLE m_FourthChilds(

    m_FourthChilds_seq_id INT IDENTITY(10,1) PRIMARY KEY,

    m_ThirdChilds_seq_id int REFERENCES m_ThirdChilds(m_ThirdChilds_seq_id),

    Number INT,

    Ref VARCHAR(20)

    )

  • Please share any hint/ideas to approach this xml

  • Personally if I was working with an xml structure like that and had to populate a number of tables, then I would consider shredding it to a single temp table first and then work with data from the temp table. Shredding xml is expensive so you should minimise how often you query the xml.

    Here is an example query that takes your example xml and then creates a single table from it. I haven't extracted all of the columns, but you should be fill in the gaps yourself by looking at the code. The main thing to remember is that for each repeating xml node i.e. <FirstChild> and <SecondChild> etc, you'll need a CROSS APPLY. You could adapt this to put the data into a temp table first and then insert/update your other tables from the temp table.

    hope it helps..

    SELECT mas.c.value('(MasterNo/text())[1]', 'varchar(20)') AS MasterNo

    , mas.c.value('(Id/text())[1]', 'varchar(20)') AS Id

    , fir.c.value('(FirstChildNo/text())[1]', 'varchar(20)') AS FirstChildNo

    , fir.c.value('(ClaimNO/text())[1]', 'varchar(20)') AS ClaimNO

    , sec.c.value('(Code/text())[1]', 'int') AS Code

    , sec.c.value('(Demo/text())[1]', 'int') AS Demo

    , thi.c.value('(ID/text())[1]', 'int') AS ThirdChild_ID

    , thi.c.value('(ChildNo/text())[1]', 'varchar(20)') AS ThirdChild_ChildNo

    , fort.c.value('(Quantity/text())[1]', 'int') AS FourthChild_Quantity

    , fort.c.value('(ID/text())[1]', 'int') AS FourthChild_ID

    , frtno.c.value('(Number/text())[1]', 'int') AS FourthChildNo_Number

    , frtno.c.value('(Ref/text())[1]', 'varchar(20)') AS FourthChildNo_Ref

    FROM @xml.nodes('/Master') mas(c)

    CROSS APPLY mas.c.nodes('FirstChild') fir(c)

    CROSS APPLY mas.c.nodes('SecondChild') sec(c)

    CROSS APPLY mas.c.nodes('ThirdChild') thi(c)

    CROSS APPLY thi.c.nodes('FourthChild') fort(c)

    CROSS APPLY fort.c.nodes('FourthChildNo') frtno(c)

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

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