XQuery: Get the value only, and not the child node values

  • Hi Guys,

    If I have the following XML

    <ROOT>

    <SPECIALNEEDS>

    INCLUDE

    <NEED>

    BLIND

    </NEED>

    <NEED>

    BRAILLE AUDIO

    </NEED>

    </SPECIALNEEDS>

    </ROOT>

    How do I get the value "INCLUDE" only.

    xmltext.value('(ROOT/SPECIALNEEDS)[1]', nvarchar(max)) is giving me all the value contents (Include Blind Braille Audio)

  • DECLARE @xml XML =

    '<ROOT>

    <SPECIALNEEDS>

    INCLUDE

    <NEED>

    BLIND

    </NEED>

    <NEED>

    BRAILLE AUDIO

    </NEED>

    </SPECIALNEEDS>

    </ROOT>'

    SELECT TD.D.value('./text()[1]','Varchar(400)')

    FROM @xml.nodes('/ROOT/SPECIALNEEDS') AS TD(D)

    Please note the whitespace preserved on the left of INCLUDE, as it's part of the node text.

    You can LTRIM it or make sure you XML formed appropriately eg:

    '<ROOT>

    <SPECIALNEEDS>INCLUDE

    <NEED>

    BLIND

    </NEED>

    <NEED>

    BRAILLE AUDIO

    </NEED>

    </SPECIALNEEDS>

    </ROOT>'

    _____________________________________________
    "The only true wisdom is in knowing you know nothing"
    "O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!":-D
    (So many miracle inventions provided by MS to us...)

    How to post your question to get the best and quick help[/url]

  • Thanks Eugene, That was really helpful.

    Just because I am anal about these things 😉

    How would you write the select statement if the data was in a #temptable with a column of type XML

  • Use CROSS APPLY

    DECLARE @xml XML =

    '<ROOT>

    <SPECIALNEEDS>

    INCLUDE

    <NEED>

    BLIND

    </NEED>

    <NEED>

    BRAILLE AUDIO

    </NEED>

    </SPECIALNEEDS>

    </ROOT>'

    SELECT @xml AS xmlCol

    INTO #temptable

    SELECT TD.D.value('./text()[1]','Varchar(400)')

    FROM #temptable

    CROSS APPLY xmlCol.nodes('/ROOT/SPECIALNEEDS') AS TD(D)

    ____________________________________________________

    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
  • LIVING AND LEARNING!!!!!!! 😀

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

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