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


Error handling


Error handling

Author
Message
mviggers
mviggers
SSC Rookie
SSC Rookie (44 reputation)SSC Rookie (44 reputation)SSC Rookie (44 reputation)SSC Rookie (44 reputation)SSC Rookie (44 reputation)SSC Rookie (44 reputation)SSC Rookie (44 reputation)SSC Rookie (44 reputation)

Group: General Forum Members
Points: 44 Visits: 47
I have created following table for testing purposes:

CREATE TABLE TESTTABLE
(
id int not null,
txt1 varchar(20) not null,
int2 int not null
)


Example 1. Insert first record

insert TESTTABLE
select 1, 'Text1', 1
if @@ERROR <> 0
print 'error occured'


Result: The record is succesfully inserted.

Example 2. Insert second record:

insert TESTTABLE
select 2, 'Text2xxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxx', 2
if @@ERROR <> 0
print 'error occured'


Result = 'error occured' (msg 8152 - string or binary data would be truncated). @@ERROR catches the error.

Example 3. Insert third record:

insert TESTTABLE
select 3, 'Text3', 'Text3'
if @@ERROR <> 0
print 'error occured'


This insertion results in a syntax error (msg 245 - Conversion failed when converting the varchar value 'Text4' to data type int. @@ERROR DOES NOT catch the error.

4. Example Insert fourth record:

insert TESTTABLE
select 4, 'Text4', 4, 'Text4'
if @@ERROR <> 0
print 'error occured'


This insertion results in a syntax error (msg 213 - column name or number of supplied values does not match table definition. @@ERROR DOES NOT catch the error.

QUESTION:
Does anyone know how to catch errors in example 3 and 4?

Thanks

/Mikkel
Sean Lange
Sean Lange
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16566 Visits: 17016
Generally speaking using try/catch is preferred to examining @@error.

Using try/catch will successfully trap the runtime errors encountered for items 1, 2 and 3.


begin try
insert TESTTABLE
select 1, 'Text1', 1
end try
begin catch
print 'error occured'
end catch

begin try
insert TESTTABLE
select 2, 'Text2xxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxxx', 2
end try
begin catch
print 'error occured'
end catch

begin try
insert TESTTABLE
select 3, 'Text3', 'Text3'
end try
begin catch
print 'error occured'
end catch



However, the error in #4 is going to throw a compile error. That means it will parse fine but the exception is thrown when the engine compiles your statement. That means it can't be caught because it actually happens prior to executing.

_______________________________________________________________

Need help? Help us help you.

Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

Need to split a string? Try Jeff Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
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