Capturing XML output from a Stored Procedure

  • I am running MSSQL 2005 Enterprise and am wondering if it is possible to capture the XML output from a stored procedure into a table with an XML column or into an XML variable?

    For rowset output an Insert/Exec works just fine, but, for XML output this scenario does not work...

    Any ideas?



    PeteK
    I have CDO. It's like OCD but all the letters are in alphabetical order... as they should be.

  • Not sure what's not working for you.

    I just tried this, and it worked:

    create proc dbo.XMLTest

    as

    set nocount on;

    select *

    from dbo.Numbers

    for XML raw, type;

    go

    create table #T (

    ID int identity primary key,

    XMLVal XML);

    insert into #T (XMLVal)

    exec dbo.XMLTest;

    go

    drop proc dbo.XMLTest

    go

    select *

    from #T;

    drop table #T;

    Can you provide the code that's not working for you? Might be able to see what's wrong with it.

    - Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
    Property of The Thread

    "Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon

  • Thanks Crazy Eights, I too can make your example work in SSMS but when I replace your simple sproc with the one from my shop I get the following error message:

    Msg 6819, Level 16, State 5, Procedure BackroundCheck_Dev, Line 1093

    The FOR XML clause is not allowed in a INSERT statement.

    I'm not permitted to post the entire code of this sproc here, but I can post the SELECT statement that is generating the final XML output:

    Select

    (

    Select

    (

    Select

    LastName[last_name],

    FirstName[first_name],

    MiddleName[middle_name]

    from dbo.#ResultsWithRelatives with (nolock)

    where Id=Person.Id

    for XML path('result'),elements,type

    )

    from dbo.#ResultsWithRelatives [Person] with (nolock)

    for XML path('person'),elements,type,root('results')

    ),

    (

    Select

    @Parms[sproc_parms],

    Cast(@Rows as VarChar)[sproc_hits],

    (

    Select

    'seconds'[@units],

    Cast(DateDiff(ms,@tst,GetDate())/1000.0 as Decimal(9,4))

    for XML path('sproc_time'),type

    )

    from (Select Null[info]) info

    for XML Auto,elements,type

    )

    for XML Path('data'),Elements;



    PeteK
    I have CDO. It's like OCD but all the letters are in alphabetical order... as they should be.

  • Just figured this out to some degree. If you code:

    if object_id('tempdb.dbo.#tmp') is not null drop table dbo.#tmp;

    create table dbo.#tmp(x xml);

    insert dbo.#tmp

    select 1 [Number] for xml path('root')

    it will fail with Msg 6819, however, the following will work!?!

    if object_id('tempdb.dbo.#tmp') is not null drop table dbo.#tmp;

    create table dbo.#tmp(x xml);

    insert dbo.#tmp

    select (select 1 [Number] for xml path('root'))



    PeteK
    I have CDO. It's like OCD but all the letters are in alphabetical order... as they should be.

  • MICROSOFT @(*&#$%)(*@#$...

    I've recoded my original sproc with the above change to the XML output SELECT statement and am now able to insert it's output into a table with an XML column...



    PeteK
    I have CDO. It's like OCD but all the letters are in alphabetical order... as they should be.

  • MICROSOFT @#$(*&@#$(*%&@#$... the saga continues...

    One other thing... When you code:

    Select (Select 1[Number] for XML Path('root'))

    the output result type is character! I recoded, again, to the following:

    Select Cast((Select 1[Number] for XML Path('root')) as XML)

    and everything seems to work as expected with the Insert/Exec or just an Exec...



    PeteK
    I have CDO. It's like OCD but all the letters are in alphabetical order... as they should be.

  • You don't have to convert/cast the data. Use "type" in the For XML clause.

    select (select 1 as Val for xml raw, type);

    If you don't use "type", it comes out as varchar, instead of as XML. That's documented in Books Online.

    - Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
    Property of The Thread

    "Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon

  • Dude, you rock! I totally missed that in BOL... But I'm still not going to take back the MICROSOFT @)(@#$)(*@#$#@$...



    PeteK
    I have CDO. It's like OCD but all the letters are in alphabetical order... as they should be.

  • Peter E. Kierstead (12/16/2009)


    Dude, you rock! I totally missed that in BOL... But I'm still not going to take back the MICROSOFT @)(@#$)(*@#$#@$...

    Thank you.

    As for the comment about MS: Trust me, the XML-in-SQL documentation is horrible. The more you use it, the more you'll hate the documentation. The functionality rocks, the documentation is miserable. So, expect to feel that way quite often if you go down that road.

    And some of the functionality is quirky to the point of being neurotic. Like not being able to use For XML in an Insert Select, but being able to bypass that with a simple subquery. Why can't the parser and compiler just do the intuitive thing and turn it into a subquery behind the scenes for you? T-SQL is designed to do exactly that with so many things. But not this one.

    It gets weird. Lets you do some pretty cool stuff, but definitely gets weird at times.

    - Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
    Property of The Thread

    "Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon

Viewing 9 posts - 1 through 8 (of 8 total)

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