Getting Output value from sp_executesql for XML issue

  • Hi,

    I am trying to get an xml blob into a var from dynamic sql. However, whenever I run this:

    DECLARE @tApplXML XML

    ,@SQL NVARCHAR(max)

    ,@ParmDefinition NVARCHAR(1024)

    ,@applnbr int

    set @applnbr = 24

    SET @SQL = N'SELECT * FROM [database].[dbo].

    WHERE [ApplNbr] = @pApplNbr

    FOR XML PATH(''database.table'')'

    SET @ParmDefinition = N'@pApplNbr INT,@ptApplXML xml OUTPUT'

    EXECUTE sp_executeSQL

    @SQL,

    @ParmDefinition,

    @pApplNbr = @ApplNbr,

    @ptApplXML= @tApplXML OUTPUT

    select @tApplXML

    Firstly I get the XML returned from the OUTPUT , then I get a NULL value. I need @tApplXML to retain the XML value. But whatever I try I cant seem to get it to work.... :pinch:

    Can anyone point me in the right direction?

    Many thanks, Phil

  • Try this:

    DECLARE @tApplXML XML

    ,@SQL NVARCHAR(max)

    ,@ParmDefinition NVARCHAR(1024)

    ,@applnbr int

    set @applnbr = 24

    SET @SQL = N'SELECT @ptApplXML = (SELECT * FROM [database].[dbo].

    WHERE [ApplNbr] = @pApplNbr

    FOR XML PATH(''database.table''))'

    SET @ParmDefinition = N'@pApplNbr INT,@ptApplXML xml OUTPUT'

    PRINT @SQL

    EXECUTE sp_executeSQL

    @SQL,

    @ParmDefinition,

    @pApplNbr = @ApplNbr,

    @ptApplXML= @tApplXML OUTPUT

    select @tApplXML


    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

  • Thanks so much. Its embarrassing, thats so simple. I couldn't see the wood for the trees :blush:

  • No need to be embarrassed and you're welcome.

    You'd be surprised how often the simplest issue is uncovered quickly by a second set of eyes. In this case, I happened to have done a lot of dynamic SQL of late so the answer kind of jumped out at me.

    And it helped a lot to have code that was easily modified to run on my SQL.


    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 4 posts - 1 through 3 (of 3 total)

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