Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Error handling


Error handling

Author
Message
brian.geregach
brian.geregach
SSC Rookie
SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)

Group: General Forum Members
Points: 30 Visits: 28
First off, my appologies, I am a newbie to programming and SQL.

Setup:
I have an SSIS package that inserts rows to a database. On occasion I get a constraint error on one of my reference tables. So far it is because of missing data.

What I want to do:
I want to redirect the row, grab the data and insert it into the reference table then reprocess the row.

Questions:
A) is this possible? I have looked at doing a lookup task prior to the row being inserted to the database. I have also looked at using a sql task in my error handling, but having issues with the code (see B).
B) I need help with the code. How do I pull the information from that single row then insert it into the database? Do I use a variable? Is this a select statement?

Any help would be greatly appreciated.

Thank you

Brian
Mansfield
Mansfield
Old Hand
Old Hand (370 reputation)Old Hand (370 reputation)Old Hand (370 reputation)Old Hand (370 reputation)Old Hand (370 reputation)Old Hand (370 reputation)Old Hand (370 reputation)Old Hand (370 reputation)

Group: General Forum Members
Points: 370 Visits: 394
I would set up the SSIS package to insert into a staging table first. Then use a SQL task to check for references in the staging table that does not yet exist, and insert the references. Use something like a left outer join check:


insert into reference_table (reference_id, reference_description)
select s.reference_id, 'some description'
from staging_table s
left join reference_table r on r.reference_id = s.reference_id
where r.reference_id is null



After the references are resolved, copy from the staging table to the actual table being loaded.
Phil Parkin
Phil Parkin
SSCrazy Eights
SSCrazy Eights (8.4K reputation)SSCrazy Eights (8.4K reputation)SSCrazy Eights (8.4K reputation)SSCrazy Eights (8.4K reputation)SSCrazy Eights (8.4K reputation)SSCrazy Eights (8.4K reputation)SSCrazy Eights (8.4K reputation)SSCrazy Eights (8.4K reputation)

Group: General Forum Members
Points: 8375 Visits: 19500
brian.geregach (4/16/2013)
First off, my appologies, I am a newbie to programming and SQL.

Setup:
I have an SSIS package that inserts rows to a database. On occasion I get a constraint error on one of my reference tables. So far it is because of missing data.

What I want to do:
I want to redirect the row, grab the data and insert it into the reference table then reprocess the row.

Questions:
A) is this possible? I have looked at doing a lookup task prior to the row being inserted to the database. I have also looked at using a sql task in my error handling, but having issues with the code (see B).
B) I need help with the code. How do I pull the information from that single row then insert it into the database? Do I use a variable? Is this a select statement?

Any help would be greatly appreciated.

Thank you

Brian


There is more than one way to solve this. Here are three:

1) (Pure SSIS)
Use a lookup task to check for existence. When matched then continue as currently. When not matched:
a) Insert a suitable row into the reference table using a OLEDB command
b) Insert to child table as usual.

2) (Hybrid)
Use a lookup as above. When matched, all OK. When not matched
a) Direct to a staging table
b) At the end of the dataflow, run a stored proc to process and insert the rows in the reference and staging tables as required.

3) (Use SSIS as little as possible)
Use the solution suggested by Mansfield.

I would expect (2) to be the fastest, (1) is the most elegant and (3) is probably easiest to set up, maintain and troubleshoot - for SQL folks anyway. In my opinion, of course.

One problem with (1) is that you cannot use a cached lookup - so performance is likely to be average at best.


Help us to help you. For better, quicker and more-focused answers to your questions, consider following the advice in this link.

If the answer to your question can be found with a brief Google search, please perform the search yourself, rather than expecting one of the SSC members to do it for you.

Please surround any code or links you post with the appropriate IFCode formatting tags. It helps readability a lot.
brian.geregach
brian.geregach
SSC Rookie
SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)

Group: General Forum Members
Points: 30 Visits: 28
My thanks to the two responders. Both suggestions look very helpful.

Brian
Sergiy
Sergiy
SSCertifiable
SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)SSCertifiable (5.8K reputation)

Group: General Forum Members
Points: 5846 Visits: 11406
Mansfield (4/28/2013)
I would set up the SSIS package to insert into a staging table first. Then use a SQL task to check for references in the staging table that does not yet exist, and insert the references. Use something like a left outer join check:


insert into reference_table (reference_id, reference_description)
select s.reference_id, 'some description'
from staging_table s
left join reference_table r on r.reference_id = s.reference_id
where r.reference_id is null



After the references are resolved, copy from the staging table to the actual table being loaded.


From my experience WHERE NOT EXISTS always perfoms better, at least not worse, than LEFT JOIN with IS NULL check:


insert into reference_table (reference_id, reference_description)
select s.reference_id, 'some description'
from staging_table s
WHERE NOT EXISTS (select * from reference_table r
where r.reference_id = s.reference_id)


Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search