XML query

  • I have the following basic XML document:

    <MatchKeys>

    <fuzzyKeys>

    <key key1="MatchKey_PostOut" key2="MatchKey_Name1" />

    <key key1="MatchKey_Name1" key2="MatchKey_PhoneticStreet" key3="MatchKey_PhoneticCompanyName"/>

    <key key1="MatchKey_PostOut" key2="MatchKey_PostIn" />

    </fuzzyKeys>

    </MatchKeys>

    The data is stored in an XML SQL variable but now I would like to put it into a table so the data looks like this:

    with cteMatchKeys (MatchKey_Group, MatchKey_ID, KeyColumn)

    as

    (

    select 1, 1, 'MatchKey_PostOut' union all

    select 1, 2, 'MatchKey_Name1' union all

    select 2, 1, 'MatchKey_Name1' union all

    select 2, 2, 'MatchKey_PhoneticStreet' union all

    select 2, 3, 'MatchKey_PhoneticCompanyName' union all

    select 3, 1, 'MatchKey_PostOut' union all

    select 3, 2, 'MatchKey_PostIn'

    )

    select * from cteMatchKeys

    Any ideas?

    ---------------------------------------------------------

    It takes a minimal capacity for rational thought to see that the corporate 'free press' is a structurally irrational and biased, and extremely violent, system of elite propaganda.
    David Edwards - Media lens[/url]

    Society has varying and conflicting interests; what is called objectivity is the disguise of one of these interests - that of neutrality. But neutrality is a fiction in an unneutral world. There are victims, there are executioners, and there are bystanders... and the 'objectivity' of the bystander calls for inaction while other heads fall.
    Howard Zinn

  • DECLARE @x XML ='<MatchKeys>

    <fuzzyKeys>

    <key key1="MatchKey_PostOut" key2="MatchKey_Name1" />

    <key key1="MatchKey_Name1" key2="MatchKey_PhoneticStreet" key3="MatchKey_PhoneticCompanyName"/>

    <key key1="MatchKey_PostOut" key2="MatchKey_PostIn" />

    </fuzzyKeys>

    </MatchKeys>';

    SELECT DENSE_RANK() OVER(ORDER BY x1.r1) AS MatchKey_Group,

    ROW_NUMBER() OVER(PARTITION BY x1.r1 ORDER BY x2.r2) AS MatchKey_ID,

    x2.r2.value('.','VARCHAR(30)') AS KeyColumn

    FROM @x.nodes('/MatchKeys/fuzzyKeys/key') AS x1(r1)

    CROSS APPLY x1.r1.nodes('@*') AS x2(r2);

    ____________________________________________________

    Deja View - The strange feeling that somewhere, sometime you've optimised this query before

    How to get the best help on a forum

    http://www.sqlservercentral.com/articles/Best+Practices/61537
  • Well, looks like Mark beat me to it. Anyhow, this is kind of (I think) the same thing.

    DECLARE @xmlData XML

    SET @xmlData = ('

    <MatchKeys>

    <fuzzyKeys>

    <key key1="1" key2="1" key3="MatchKey_PostOut" />

    </fuzzyKeys>

    <fuzzyKeys>

    <key key1="1" key2="2" key3="MatchKey_Name1" />

    </fuzzyKeys>

    <fuzzyKeys>

    <key key1="2" key2="1" key3="MatchKey_Name1" />

    </fuzzyKeys>

    <fuzzyKeys>

    <key key1="2" key2="2" key3="MatchKey_PhoneticStreet" />

    </fuzzyKeys>

    <fuzzyKeys>

    <key key1="2" key2="3" key3="MatchKey_PhoneticCompanyName" />

    </fuzzyKeys>

    <fuzzyKeys>

    <key key1="3" key2="1" key3="MatchKey_PostOut" />

    </fuzzyKeys>

    <fuzzyKeys>

    <key key1="3" key2="2" key3="MatchKey_PostIn" />

    </fuzzyKeys>

    </MatchKeys>

    ')

    SELECT

    x.ref.value('@key1[1]', 'int') AS MatchKey_Group,

    x.ref.value('@key2[1]', 'int') AS MatchKey_ID,

    x.ref.value('@key3[1]', 'varchar(50)') AS KeyColumn

    FROM @xmlData.nodes('/MatchKeys/fuzzyKeys/key') AS x( ref )

    Mark, what is the purpose of the DENSE_RANK(), ROW_NUMBER(), and the CROSS APPLY? This is the fist time I've messed with XML, so it may be something simple.

    Greg
    _________________________________________________________________________________________________
    The glass is at one half capacity: nothing more, nothing less.

  • Greg Snidow

    Mark, what is the purpose of the DENSE_RANK(), ROW_NUMBER(), and the CROSS APPLY? This is the fist time I've messed with XML, so it may be something simple.

    Okay, I see now. Abu does not have the ID columns in the XML, so you are creating them?

    Abu, I think you can ignore my previous post.

    Greg
    _________________________________________________________________________________________________
    The glass is at one half capacity: nothing more, nothing less.

  • Thanks guys. Much appreciated!

    Although I find Greg's solution easier to understand which makes me wonder, should I re-format my XML?!

    BTW, I've no idea how Mark's solution works lol, I'm going to have spend some time to work it out.

    Once again, thanks for your help!

    ---------------------------------------------------------

    It takes a minimal capacity for rational thought to see that the corporate 'free press' is a structurally irrational and biased, and extremely violent, system of elite propaganda.
    David Edwards - Media lens[/url]

    Society has varying and conflicting interests; what is called objectivity is the disguise of one of these interests - that of neutrality. But neutrality is a fiction in an unneutral world. There are victims, there are executioners, and there are bystanders... and the 'objectivity' of the bystander calls for inaction while other heads fall.
    Howard Zinn

  • Maybe there's a middlin' easy alternative:

    DECLARE @xmlData XML ='<MatchKeys>

    <fuzzyKeys>

    <key key1="MatchKey_PostOut" key2="MatchKey_Name1" />

    <key key1="MatchKey_Name1" key2="MatchKey_PhoneticStreet" key3="MatchKey_PhoneticCompanyName"/>

    <key key1="MatchKey_PostOut" key2="MatchKey_PostIn" />

    </fuzzyKeys>

    </MatchKeys>';

    ;WITH XML_Unveiled AS (

    SELECT MatchKey_Group=ROW_NUMBER() OVER (ORDER BY (SELECT NULL)),

    x.ref.value('@key1[1]', 'varchar(50)') AS Key1,

    x.ref.value('@key2[1]', 'varchar(50)') AS Key2,

    x.ref.value('@key3[1]', 'varchar(50)') AS Key3

    FROM @xmlData.nodes('/MatchKeys/fuzzyKeys/key') AS x( ref ))

    SELECT MatchKey_Group, MatchKey_ID, KeyColumn

    FROM XML_Unveiled

    CROSS APPLY (

    VALUES (1, Key1),(2,Key2),(3,Key3)) a (MatchKey_ID, KeyColumn)

    WHERE KeyColumn IS NOT NULL

    ORDER BY MatchKey_Group, MatchKey_ID

    See the first link in my signature if you haven't seen the CROSS APPLY VALUES approach to UNPIVOT before.


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.

    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

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

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