SSIS - Input Excel file - updating Table - conditional split?

  • Hi - I am SUPER new to SSIS , kind of thrown into it with no training or help other that what I can dig up on Google - so I am hoping one of you can walk me thru this.

    I have a multi-tabbed Excel file as input - where tab 1 has

    action ---- reasonID ---- description

    New ---- 1 ---- add new record

    Update ---- 2 ---- chg descr of record 2

    Delete ---- 3 ---- remove record 3 entirely

    I figured out how to create a Conditional split based on the action. and to create a Recordset of the result ( I think)

    my problem is - I now have 3 output record sets in my data flow tab.

    When I am back in the Control flow -- how do I update the ExceptionReason table with the data from each reason set? besides each one having different recordset names, they will need to perform a different set of SQL ( Insert, Update or Delete)

  • Using the conditional split is a good start.

    Route the insert rows to an OLE DB Destination and write them directly into the destination talbe (make sure to use the fast load option).

    Write the deletes and updates to a staging table or a temporary table (if you want to use a temp table, let me know, it requires additional explanation).

    In the control flow, use an Execute SQL Task to update/delete your destination table using the following SQL:

    -- deletes

    DELETE FROM MyTable

    FROM MyTable m

    INNER JOIN MyStagingTable s ON m.ID = s.ID

    WHERE s.ReasonID = 3;

    -- updates

    UPDATE m

    SET col1 = s.col1

    ,col2 = s.col2

    ...

    ,coln = s.coln

    FROM MyTable m

    INNER JOIN MyStagingTable s ON m.ID = s.ID

    WHERE s.ReasonID = 2;

    Need an answer? No, you need a question
    My blog at https://sqlkover.com.
    MCSE Business Intelligence - Microsoft Data Platform MVP

  • thanks for the response.

    Yes I am going to have to use a temp table as our DBA area frowns upon lots of "staging" tables in the database.

  • debbiekitzke (9/13/2013)


    thanks for the response.

    Yes I am going to have to use a temp table as our DBA area frowns upon lots of "staging" tables in the database.

    If you have to choose between staging tables or excessive locking and logging by the SSIS OLE DB command, I'd choose staging tables any day.

    (tell that to your DBA 🙂

    Temp tables are a viable alternative, but they can put an extra burden on tempdb, so I hope your DBA has put it on a fast disk.

    If you want to use them, you need to make sure they are created before they are used in the data flow. You also need to put the data flow to DelayValidation equals true.

    Finally, to make sure the temp table still exists before the data flow actually uses it, you need to put the property RetainSameConnection to true on the connection manager.

    Need an answer? No, you need a question
    My blog at https://sqlkover.com.
    MCSE Business Intelligence - Microsoft Data Platform MVP

  • Tell your DBA to consider putting the staging tables into their own schema. I call mine "Temp", but "Staging" or "Landing" would be good names. This might remove his objections. There is no good reason to object to this in principle. If he's trying to prevent have hundreds of seldom used tables, that might be a practical objection. But he's making things harder for you, probably unnecessarily so.

  • Koen Verbeeck (9/15/2013)


    Finally, to make sure the temp table still exists before the data flow actually uses it, you need to put the property RetainSameConnection to true on the connection manager.

    And remember to use "Global Temp" tables (the ones that begin with ##).

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

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