XML SQL Query

  • Hello all.

    I am new to SQL and even newer to XML files so please go easy on me, I am just learning this stuff.

    I have a sample of the XML file I am working with. I cannot change this file, it from a external supplier.

    <GAME>

    <TEAM>

    <TEAMID>1</TEAMID>

    <PLAYER>

    <PLAYERID>001</PLAYERID>

    <NAME>Brown</NAME>

    </PLAYER>

    <PLAYER>

    <PLAYERID>002</PLAYERID>

    <NAME>White</SURNAME>

    </PLAYER>

    </TEAM>

    <TEAM>

    <TEAMID>2</TEAMID>

    <PLAYER>

    <PLAYERID>003</PLAYERID>

    <NAME>Black</NAME>

    </PLAYER>

    <PLAYER>

    <PLAYERID>004</PLAYERID>

    <NAME>Graham</SURNAME>

    </PLAYER>

    </TEAM>

    </GAME>

    I can easily pull out all the player information with the below code

    SELECT

    pref3.value('(PLAYERID/text())[1]', 'varchar(50)') as PLAYER_ID,

    pref3.value('(NAME/text())[1]', 'varchar(50)') as PLAYERNAME

    FROM

    XMLwithOpenXML CROSS APPLY

    XMLData.nodes('/GAME/TEAM/PLAYER') AS TEST3(pref3)

    This will return

    PLAYERIDPLAYERNAME

    001 Brown

    002 White

    003 Black

    004 Graham

    However I want to be able to also associate the Player ID with his Team ID like below.

    TEAMID PLAYERID

    1 001

    1 002

    2 003

    2 004

    The below only pulls the first record for each team, but i need all records for each team selected.

    SELECT

    pref3.value('(TEAMID/text())[1]', 'varchar(50)') as TEAMID,

    pref3.value('(PLAYER/PLAYERID/text())[1]', 'varchar(50)') as PLAYERID

    FROM

    XMLwithOpenXML CROSS APPLY

    XMLData.nodes('/GAME/TEAM') AS TEST3(pref3)

    For Example

    TEAMID PLAYERID

    1 001

    2 003

    Can someone lend me a hand with this ????

  • This should do it...

    SELECT

    pref3.value('(../TEAMID/text())[1]','varchar(50)') as TEAM_ID,

    pref3.value('(PLAYERID/text())[1]', 'varchar(50)') as PLAYER_ID,

    pref3.value('(NAME/text())[1]', 'varchar(50)') as PLAYERNAME

    FROM

    XMLwithOpenXML CROSS APPLY

    XMLData.nodes('/GAME/TEAM/PLAYER') AS TEST3(pref3)

    MM



    select geometry::STGeomFromWKB(0x0106000000020000000103000000010000000B0000001000000000000840000000000000003DD8CCCCCCCCCC0840000000000000003DD8CCCCCCCCCC08408014AE47E17AFC3F040000000000104000CDCCCCCCCCEC3F9C999999999913408014AE47E17AFC3F9C99999999991340000000000000003D0000000000001440000000000000003D000000000000144000000000000000400400000000001040000000000000F03F100000000000084000000000000000401000000000000840000000000000003D0103000000010000000B000000000000000000143D000000000000003D009E99999999B93F000000000000003D009E99999999B93F8014AE47E17AFC3F400000000000F03F00CDCCCCCCCCEC3FA06666666666FE3F8014AE47E17AFC3FA06666666666FE3F000000000000003D1800000000000040000000000000003D18000000000000400000000000000040400000000000F03F000000000000F03F000000000000143D0000000000000040000000000000143D000000000000003D, 0);

  • Forum Etiquette: How to post Reporting Services problems
  • [/url]
  • Forum Etiquette: How to post data/code on a forum to get the best help - by Jeff Moden
  • [/url]
  • How to Post Performance Problems - by Gail Shaw
  • [/url]

  • mister.magoo (5/26/2014)


    This should do it...

    SELECT

    pref3.value('(../TEAMID/text())[1]','varchar(50)') as TEAM_ID,

    pref3.value('(PLAYERID/text())[1]', 'varchar(50)') as PLAYER_ID,

    pref3.value('(NAME/text())[1]', 'varchar(50)') as PLAYERNAME

    FROM

    XMLwithOpenXML CROSS APPLY

    XMLData.nodes('/GAME/TEAM/PLAYER') AS TEST3(pref3)

    BRILLIANT, thanks for your help.

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

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