Stored procedures and data flow task

  • Hello,

    I have a complex stored procedure which returns some results. I want to take this stored procedure and use it in a Data Flow task to move these results to a table. The data flow source task only gives me the option for using SQL commands not stored procedures. Even if I use 'exec proceduredname' it still doesn't work. anyone know how would I go about transfering stored procedure results to a table?

    Thanks,

    Strick

  • Hi,

    What error are you getting? the OLE DB datasource will work if you choose 'SQL command' as the Data access mode and in the SQL command text use

    exec spName with ? for each parameter (if any).

    Click parameters to map the stored procedure parameter name(s) (including @) to a variable(s).

  • To the OP (if still around) did you solve this easily?

    This is also the problem I am having.

    I want to execute a stored proc and output the results to an excel file. I can set up an exec sql task fine but when I try map it to an excel destination it won't recognise any columns and when I build the execl sql task is says the exec sql construct or statement not supported.

    When I try a script component it won't recognise any input columns.

    It feels like this should be easy but I think I missing something simple somewhere.

    Any help greatly appreciated.

  • andy.westgate (6/18/2013)


    To the OP (if still around) did you solve this easily?

    This is also the problem I am having.

    I want to execute a stored proc and output the results to an excel file. I can set up an exec sql task fine but when I try map it to an excel destination it won't recognise any columns and when I build the execl sql task is says the exec sql construct or statement not supported.

    When I try a script component it won't recognise any input columns.

    It feels like this should be easy but I think I missing something simple somewhere.

    Any help greatly appreciated.

    The ExecuteSQL task is not the one you want here.

    What you need is a DataFlow and inside that DataFlow you should should put an OLEDB source pointing to your stored proc.

    Then create your Excel destination and join the two - you should be able to do your column mapping from there.

    Note that if your stored proc selects from a temp table you may need additional guidance before SSIS 'recognises' the columns.

    The absence of evidence is not evidence of absence
    - Martin Rees
    The absence of consumable DDL, sample data and desired results is, however, evidence of the absence of my response
    - Phil Parkin

  • Thanks Phil

    Good to have that confirmed. It was the lack of mapping between the DFT and the Exceil destination that was throwing me but I have a couple of things to go on now.

  • andy.westgate (6/18/2013)


    Thanks Phil

    Good to have that confirmed. It was the lack of mapping between the DFT and the Exceil destination that was throwing me but I have a couple of things to go on now.

    No problems. Maybe my message was not totally clear though - the OLEDB source and Excel Destination should both be contained in the dataflow. It is the source and destination which should be linked, not the dataflow and the destination.

    The absence of evidence is not evidence of absence
    - Martin Rees
    The absence of consumable DDL, sample data and desired results is, however, evidence of the absence of my response
    - Phil Parkin

  • It was clear! I was just using the wrong terminilogy in reply.

    All sorted now. The whole reason I started going down the Execute SQL Task route is because I couldn't get the OLE DB source to produce any columns with exec sp as the sql command.

    I have since amended the sp to include set FMTONLY off (which I'm sure has othe consequences too particularly in Sql 2012) and this has meant it has brought back the columns which I can not map to an execl destination.

  • I also cannot get any columns out and the sp has no parameters so shouldn't be any setup I'm neglecting.

    I'm baffled.

  • Are you selecting from a temp table in your process? Does your process have set nocount on at the top?

    The absence of evidence is not evidence of absence
    - Martin Rees
    The absence of consumable DDL, sample data and desired results is, however, evidence of the absence of my response
    - Phil Parkin

  • ah, you got me, Phil - it IS selecting from a temp table. Well, shoot, makes perfect sense that SSIS cannot divine that from thin air.

    Do I HAVE to materialize the table? The stored procedure has been in use for a while to assess "freshness" of our warehouse data. An email comes out with tables past their SLA so we know where our problems are.

    It was recently decided that it would be convenient to dump All freshness data to a table, not just Past SLA, and continue the emails alerts for Past SLA.

    I hadn't wanted to change the sp but it seems like maybe I can kill two birds with one stone by sending ALL data to a table in the sp and then having Only the past-SLA collected into an email.

    I'm not seeing any hidden maintenance nightmares in this scenario. Am I missing something?

  • The SSIS temp table 'hack' is described here[/url]. A relatively straightforward publication of meta data does the job.

    In 2012, the hack changes, but given the forum, I'm assuming that you are running 2005.

    The absence of evidence is not evidence of absence
    - Martin Rees
    The absence of consumable DDL, sample data and desired results is, however, evidence of the absence of my response
    - Phil Parkin

  • Yes, 2005. Plenty of good stuff to try - thanks!!

  • I went with the FMTONLY ON to display "dummy select" high up in sp, set FMTONLY OFF and have SET NOCOUNT ON in the OLEDB source.

    Wow, lots of stumbling around for what feels like shouldn't be too hard, but, sp's are different animals.

    Thanks, Phil, the links were awesome reading.

Viewing 13 posts - 1 through 12 (of 12 total)

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