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


Computed Column Divide by Zero?


Computed Column Divide by Zero?

Author
Message
Tom Brown
Tom  Brown
Ten Centuries
Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)

Group: General Forum Members
Points: 1342 Visits: 1466
Comments posted to this topic are about the item Computed Column Divide by Zero?
Hardy21
Hardy21
Ten Centuries
Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)Ten Centuries (1.2K reputation)

Group: General Forum Members
Points: 1204 Visits: 1399
Good question.
If computed columns are persisted in nature (e.g. QTot AS QF1 + QF2 PERSISTED,) then you receive the error after "Insert Zeroes" print statement and "SELECT * FROM @Quantities" statement returns 2 rows - datasource Test1 & Test3.

Thanks
deepak.a
deepak.a
Mr or Mrs. 500
Mr or Mrs. 500 (562 reputation)Mr or Mrs. 500 (562 reputation)Mr or Mrs. 500 (562 reputation)Mr or Mrs. 500 (562 reputation)Mr or Mrs. 500 (562 reputation)Mr or Mrs. 500 (562 reputation)Mr or Mrs. 500 (562 reputation)Mr or Mrs. 500 (562 reputation)

Group: General Forum Members
Points: 562 Visits: 863
Thanks For the Good Question Tom Brown i learnt some thing new today and also i tried to create index on the computed columns it will not alllow to create index directly.

and i tried in this way


 

PRINT 'Define Table';
CREATE TABLE #Quantities (
ID INT IDENTITY,
DataSource varchar(30) NOT NULL,
QF1 Float,
QF2 Float,
QTot AS QF1 + QF2,
PF1 AS QF1 / (QF1 + QF2),
PF2 AS QF2 / (QF1 + QF2) );

CREATE NONCLUSTERED INDEX IXC1 on #Quantities(ID) INCLUDE(PF1,PF2)

PRINT 'Insert data';
INSERT INTO #Quantities (DataSource, QF1, QF2)
SELECT 'Test 1' , 66, 34;

Print 'Insert Zeroes';
INSERT INTO #Quantities (DataSource, QF1, QF2)
SELECT 'Test 2', 0, 0;

Print 'Insert Nulls';
INSERT INTO #Quantities (DataSource, QF1, QF2)
SELECT 'Test 3', null, null;

PRINT 'Show Table';
SELECT * FROM #Quantities;

DROP TABLE #Quantities





i got the error while inserting the value it self

thanks again for the Good question
malleswarareddy_m
malleswarareddy_m
SSCrazy
SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)

Group: General Forum Members
Points: 2015 Visits: 1189
Lost two points because of misunderstanding of set arthiabort on.I already worked divide by zero errors and handle these type of errors.but little bit confused.with arthabort you can handle this other wise using nullif also we can handle.Againg thanks for good question on basics.

Malleswarareddy
I.T.Analyst
MCITP(70-451)
tommyh
tommyh
SSCommitted
SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)SSCommitted (1.6K reputation)

Group: General Forum Members
Points: 1560 Visits: 2000
Great question.

However... why does SQL let something get stored (and im not talking about the computed column itself since that aint stored... unless its persisted) in the database in the first case, that it later cant read? Anyone know the reasoning behind that? (Besides performance that is)

/T
henrik staun poulsen
henrik staun poulsen
SSCommitted
SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)

Group: General Forum Members
Points: 1833 Visits: 1210
In order to get round the divide by zero error, I generally do this:

PF1 AS QF1 / nullif((QF1 + QF2),0),
instead of
PF1 AS QF1 / (QF1 + QF2),

I.e. set the divisor to null, if the divisor is zero.
I used to do complicated Case statements, but then I needed to retype the divisor.
This way, I just add "NULLIF(" at the front and ",0)" at the end.

I'we written about it at Stack overflow

Best regards,
Henrik Staun Poulsen
www.stovi.com



Nils Gustav Stråbø
Nils Gustav Stråbø
SSCrazy
SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)

Group: General Forum Members
Points: 2013 Visits: 3575
Stupid me, lost the points because I was thinking of persisted computed columns. Don't know why.
Hugo Kornelis
Hugo Kornelis
SSCrazy Eights
SSCrazy Eights (8.3K reputation)SSCrazy Eights (8.3K reputation)SSCrazy Eights (8.3K reputation)SSCrazy Eights (8.3K reputation)SSCrazy Eights (8.3K reputation)SSCrazy Eights (8.3K reputation)SSCrazy Eights (8.3K reputation)SSCrazy Eights (8.3K reputation)

Group: General Forum Members
Points: 8337 Visits: 11580
I totally agree with the other comments: good question. I wanted to add a comment about the effect of persisting the computed column (by adding the PERSISTED option or by including it in an index), but others have beaten me to it. ;-)

tommyh (10/13/2010)
why does SQL let something get stored (and im not talking about the computed column itself since that aint stored... unless its persisted) in the database in the first case, that it later cant read? Anyone know the reasoning behind that? (Besides performance that is)

The developer chose not to persist the computed column. That means that the developer required SQL Server not to evaluate the expression until referenced. The only way for SQL Server to "know" that the expression can't be evaluated is by trying to evaulate it, so there is no way to tell when the data is stored if there will be an error - except if SQL Server chooses to disregard the developer's wish.
Further, it might also be the case that the data stored is intermediate. The first stage of processing an order might involve copying the data from the order form; a later stage adds other data. A column that is only needed after the second stage could be a computed column that results in an error before the second stage is completed. Think about a computed column that lists the time between receipt of an order and shipping of the goods - while not producing an error, the computation would not result in a meaningful value if querie while the order is still being processed.

henrik staun poulsen (10/13/2010)
In order to get round the divide by zero error, I generally do this:

PF1 AS QF1 / nullif((QF1 + QF2),0),
instead of
PF1 AS QF1 / (QF1 + QF2),

I.e. set the divisor to null, if the divisor is zero.
I used to do complicated Case statements, but then I needed to retype the divisor.
This way, I just add "NULLIF(" at the front and ",0)" at the end.

That would be my suggestion as well. While the suggestion in the explanation works as well, it requires the person who queries the data to know that the column is computed, AND to know the exact expression. Writing the expression so that there can never be an error encapsulates this knowledge and reduces the risk of errors when new people start writing queries.
BTW, the NULLIF function is simply a shorthand for the complicated CASE expressions you used to do. The NULLIF reduces the amount of code to maintain, but does not offer any performance benefits.


Hugo Kornelis, SQL Server MVP
Visit my SQL Server blog: http://sqlblog.com/blogs/hugo_kornelis
Carlo Romagnano
Carlo Romagnano
Hall of Fame
Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)Hall of Fame (3.6K reputation)

Group: General Forum Members
Points: 3626 Visits: 3236
henrik staun poulsen (10/13/2010)
In order to get round the divide by zero error, I generally do this:

PF1 AS QF1 / nullif((QF1 + QF2),0),
instead of
PF1 AS QF1 / (QF1 + QF2),

Good. The computed column should be NULL, if expression is invalid.
Stewart "Arturius" Campbell
Stewart "Arturius" Campbell
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: 5802 Visits: 7137
good question.
thanks

____________________________________________
Space, the final frontier? not any more...
All limits henceforth are self-imposed.
“libera tute vulgaris ex”
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