import and shred xml to sql table (openrowset)

  • Hello,

    I'm also trying to import certain fields of an xml-file into an existing sql table (neutc_import).

    Problem is: I get '0 rows affected' when I execute the query below.

    In the end I need to have mac-address and tcname for every machine in table neutc_import.

    I'm sure the query is wrong at least regarding the "Cross Apply" statement.

    As you can see I am not very experienced with this type of stuff - so your

    help is really appreciated - maybe just a small adjustment necessary (?)

    query:

    INSERT INTO neutc_import(macaddr,tcname)

    SELECT X.a.query('MACAddress').value('.', 'varchar(50)'),

    X.a.query('ComputerName').value('.', 'VARCHAR(50)')

    FROM (

    SELECT CAST(x AS XML)

    FROM OPENROWSET(

    BULK 'E:\scout_import\DSBU010995_Imdly_2_HwInfo.xml',

    SINGLE_BLOB) AS T(x)

    ) AS T(x)

    CROSS APPLY x.nodes('records/record') AS X(a);

    referenced xml:

    ....

    <?xml version="1.0" encoding="utf-8"?>

    <Systems Version="4.00" xsi:schemaLocation="urn:schemas-ts-fujitsu-com:software-preload HWInfo4.00.xsd" xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance" xmlns:xsd="http://www.w3.org/2001/XMLSchema" xmlns="urn:schemas-ts-fujitsu-com:software-preload">

    <System>

    <SystemIdentification>

    <SerialNumber>DSBU010995</SerialNumber>

    <IndividualSoftwareID />

    <SystemUUID>{B2E832CC-7484-11E1-8B14-5026909B9A32}</SystemUUID>

    <CustomerSerialNumber />

    <IMEINumber></IMEINumber>

    <MACAddresses>

    <MACAddress type="OnBoard">00:30:05:68:FF:BD</MACAddress>

    </MACAddresses>

    </SystemIdentification>

    <OrderReferenceData>

    <P82OrderNumber>xxxxxxx</P82OrderNumber>

    <P82CustomerOrderNumber>xxxxxxx</P82CustomerOrderNumber>

    <P84OrderNumber>xxxxxxx</P84OrderNumber>

    <P84OrderPosition>100</P84OrderPosition>

    <P84CustomerOrderNumber>xxxxxxx</P84CustomerOrderNumber>

    <EndCustomerOrderNumber>xxxxxxx</EndCustomerOrderNumber>

    </OrderReferenceData>

    <ProductDetails>

    <OrderCode>CUZ:KxxxVXXX-EMFxx</OrderCode>

    <Product>LB P771 BLACK /CUZ:KxxxVXXX-EMFxx</Product>

    </ProductDetails>

    <SoftwareModules />

    <OrderAttachements>

    <HeaderSpecificData />

    <PositionSpecificData>

    <ClientParameters SubClient="None" Client="Caritas">

    <ComputerName>CNxxxxx</ComputerName>

    <OldComputerName>ONxxxxx</OldComputerName>

    <PrimaryContact>Max Mustermann</PrimaryContact>

    </ClientParameters>

    </PositionSpecificData>

    </OrderAttachements>

    </System>

    <System>

    <SystemIdentification>

    <SerialNumber>DSBU010995</SerialNumber>

    <IndividualSoftwareID />

    <SystemUUID>{B2E832CC-7484-11E1-8B14-5026909B9A32}</SystemUUID>

    <CustomerSerialNumber />

    <IMEINumber></IMEINumber>

    <MACAddresses>

    <MACAddress type="OnBoard">00:30:05:68:FF:BD</MACAddress>

    </MACAddresses>

    </SystemIdentification>

    <OrderReferenceData>

    <P82OrderNumber>xxxxxxx</P82OrderNumber>

    <P82CustomerOrderNumber>xxxxxxx</P82CustomerOrderNumber>

    <P84OrderNumber>xxxxxxx</P84OrderNumber>

    <P84OrderPosition>200</P84OrderPosition>

    <P84CustomerOrderNumber>xxxxxxx</P84CustomerOrderNumber>

    <EndCustomerOrderNumber>xxxxxxx</EndCustomerOrderNumber>

    </OrderReferenceData>

    <ProductDetails>

    <OrderCode>CUZ:KxxxVXXX-EMFxx</OrderCode>

    <Product>LB P771 BLACK /CUZ:KxxxVXXX-EMFxx</Product>

    </ProductDetails>

    <SoftwareModules />

    <OrderAttachements>

    <HeaderSpecificData />

    <PositionSpecificData>

    <ClientParameters SubClient="None" Client="Caritas">

    <ComputerName>CNxxxxx</ComputerName>

    <OldComputerName>ONxxxxx</OldComputerName>

    <PrimaryContact>Max Mustermann</PrimaryContact>

    </ClientParameters>

    </PositionSpecificData>

    </OrderAttachements>

    </System>

    </Systems>

    ...

    greetings from nivce Munich - Michael.

  • in looking at this, the complex root node Systems of the XML seems to be confusing SQL Server. If I make the root node just <Systems> instead of <Systems Version="4.00" xsi:schemaLocation="urn:schemas-ts-fujitsu-com:software-preload HWInfo4.00.xsd" xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance" xmlns:xsd="http://www.w3.org/2001/XMLSchema" xmlns="urn:schemas-ts-fujitsu-com:software-preload">

    then this works for me:

    SELECT

    list.rows.query('SystemIdentification/MACAddresses/MACAddress').value('.', 'varchar(50)'),

    list.rows.query('OrderAttachements/PositionSpecificData/ClientParameters/ComputerName').value('.', 'varchar(50)')

    FROM (SELECT CAST(x AS XML) FROM OPENROWSET(BULK 'C:\Downloads\trying.xml', SINGLE_BLOB) AS T(x)) AS f(doc)

    CROSS APPLY f.doc.nodes('/Systems/System') AS list(rows)

Viewing 2 posts - 1 through 2 (of 2 total)

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