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
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: 8323 Visits: 11573
deepak.a (10/15/2010)
Hi Hugo which is the best pratice for Computed columns having PERSISTED or without having PERSISTED option or having an index for the computed columns

It depends.

For non-indexed computed columns, if the data modifies often and is not queried often, you should not persist it.
If the data seldom modifies and the persisted column is often queried, you should persist it.
If the data seldom modifies, the persisted column is sometimes queried and the other columns are often modified, it's an edge case. You save on evaluatig the expression when reading the computed column, but the extra bytes in each row slow down all accesses to the table.

EDIT: Removed a line where I erroneously claimed that persisting is required to index a computeed column. See the post by Henrik that follows this one.


Hugo Kornelis, SQL Server MVP
Visit my SQL Server blog: http://sqlblog.com/blogs/hugo_kornelis
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
Hugo,

<<If you want to index a computed column, you must persist it.

Are you sure?
I've just added a computed column to one of our big tables (+4 billion rows).
I did not add "PERSISTED" to the alter table statement.

Then I created an index on the column.
Looks fine.
A simple query on the field returns data from the index according to the plan.

But one caveat:
I have a query that currently crashes after 8 hours, when it is using the new index.
We're using SQL Server 2008 sp1 and some cu's.

Best regards,
Henrik Staun Poulsen
www.stovi.com



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: 8323 Visits: 11573
henrik staun poulsen (10/15/2010)
Hugo,

<<If you want to index a computed column, you must persist it.

Are you sure?
I've just added a computed column to one of our big tables (+4 billion rows).
I did not add "PERSISTED" to the alter table statement.

Then I created an index on the column.
Looks fine.
A simple query on the field returns data from the index according to the plan.

But one caveat:
I have a query that currently crashes after 8 hours, when it is using the new index.
We're using SQL Server 2008 sp1 and some cu's.

You are completely right; I should have checked that statement before speaking. I'll edit my previous post.
(And on a simple test I just ran, I did not crash the query - so your problem might not be related to the indexed computed column)


Hugo Kornelis, SQL Server MVP
Visit my SQL Server blog: http://sqlblog.com/blogs/hugo_kornelis
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
Hugo Kornelis (10/15/2010)
henrik staun poulsen (10/15/2010)
Hugo,

<<If you want to index a computed column, you must persist it.

Are you sure?
I've just added a computed column to one of our big tables (+4 billion rows).
I did not add "PERSISTED" to the alter table statement.

Then I created an index on the column.
Looks fine.
A simple query on the field returns data from the index according to the plan.

But one caveat:
I have a query that currently crashes after 8 hours, when it is using the new index.
We're using SQL Server 2008 sp1 and some cu's.

You are completely right; I should have checked that statement before speaking. I'll edit my previous post.
(And on a simple test I just ran, I did not crash the query - so your problem might not be related to the indexed computed column)


hi one more doubt on creating the index on computed columns

 
-- Query 1 Creating the index for computed columns no Error
CREATE TABLE #tblTemp
(
Name1 varchar(10),
Col1 int,
PartitionKey as (Col1 % 10)
)
GO
CREATE CLUSTERED INDEX ix_Partitionkey on #tblTemp(PartitionKey)
GO
INSERT INTO #tblTemp(Name1,Col1) select 'Nam1',565
INSERT INTO #tblTemp(Name1,Col1) select 'Nam2',58
SELECT * FROM #tblTemp

DROP TABLE #tblTemp
GO



-- Query 2 Creating the index for computed columns Error Raised For Foat DataType
CREATE TABLE #Quantities (
ID INT IDENTITY,
DataSource varchar(30) NOT NULL,
QF1 FLOAT,
QF2 FLOAT,
QTot AS QF1 + QF2
)
GO
CREATE CLUSTERED INDEX IX_PF1 on #Quantities(QTot)
GO
drop table #Quantities


/*
-- Error
Msg 2799, Level 16, State 1, Line 1
Cannot create index or statistics 'IX_PF1' on table '#Quantities' because the computed column 'QTot' is imprecise and not persisted.
Consider removing column from index or statistics key or marking computed column persisted.

*/

-- Query 3 Creating the index for computed columns No Error for Decimal datattype
CREATE TABLE #Quantities2 (
ID INT IDENTITY,
DataSource varchar(30) NOT NULL,
QF1 DECIMAL(18,2),
QF2 DECIMAL(18,2),
QTot AS QF1 + QF2
)
GO
CREATE CLUSTERED INDEX IX_PF1 on #Quantities2(QTot)
GO
drop table #Quantities2



in the above Quesries second one (Query 2) thrown on error while creating the index on computed column but the Query 1 and Query 3 not thrown error i'm confused about this

Thanks & Regards
Deepak.A
tilew-948340
tilew-948340
SSChasing Mays
SSChasing Mays (629 reputation)SSChasing Mays (629 reputation)SSChasing Mays (629 reputation)SSChasing Mays (629 reputation)SSChasing Mays (629 reputation)SSChasing Mays (629 reputation)SSChasing Mays (629 reputation)SSChasing Mays (629 reputation)

Group: General Forum Members
Points: 629 Visits: 2437
Hugo Kornelis (10/15/2010)
tilew-948340 (10/14/2010)
[quote]Hardy21 (10/13/2010)
Good question.

I am a little confused here: ...


If you want to try it with PERSISTED, then just add PERSISTED at the end of the computed column declarations and change nothing else.
...


Hi Hugo.
The first time I tried the PERSISTED, I got the divide by zero error AFTER the "show table" wich does not seem to be, as I understand it, what it should be doing. So I tried many "set" option, wich brought me to the "declare" error...
So, if I put the PERSISTED word, should not the error happend after the "Insert null"?
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: 8323 Visits: 11573
deepak.a (10/15/2010)
one more doubt on creating the index on computed columns
(...)
in the above Quesries second one (Query 2) thrown on error while creating the index on computed column but the Query 1 and Query 3 not thrown error i'm confused about this

As implied by the text of the error message, a computed column that SQL Server considers imprecise can not be indexed without first pesisting it. But a computed column that is not imprecies can be persisted.
All results of calculations with floating point data is considered imprecise, that's the reason you get the error in query 2.


Hugo Kornelis, SQL Server MVP
Visit my SQL Server blog: http://sqlblog.com/blogs/hugo_kornelis
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: 8323 Visits: 11573
tilew-948340 (10/15/2010)
Hi Hugo.
The first time I tried the PERSISTED, I got the divide by zero error AFTER the "show table" wich does not seem to be, as I understand it, what it should be doing. So I tried many "set" option, wich brought me to the "declare" error...
So, if I put the PERSISTED word, should not the error happend after the "Insert null"?

Here is the code that I used - if you compare this to the QotD, you'll see that adding PERSISTED at one place is the only modification.
PRINT 'Define Table';
DECLARE @Quantities TABLE (
DataSource varchar(30) NOT NULL,
QF1 Float,
QF2 Float,
QTot AS QF1 + QF2,
PF1 AS QF1 / (QF1 + QF2),
PF2 AS QF2 / (QF1 + QF2) PERSISTED);

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;



If I run this (from SSMS, against SQL Server 2005), I get an error after "Insert Zeroes", and a result set with two rows (one with values; one with NULLs)


Hugo Kornelis, SQL Server MVP
Visit my SQL Server blog: http://sqlblog.com/blogs/hugo_kornelis
Koen Verbeeck
Koen Verbeeck
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: 16453 Visits: 13207
Good question, but I've seen more difficult ones for two points.



How to post forum questions.
Need an answer? No, you need a question.
What’s the deal with Excel & SSIS?

Member of LinkedIn. My blog at SQLKover.

MCSA SQL Server 2012 - MCSE Business Intelligence
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
Hugo Kornelis (10/15/2010)
deepak.a (10/15/2010)
one more doubt on creating the index on computed columns
(...)
in the above Quesries second one (Query 2) thrown on error while creating the index on computed column but the Query 1 and Query 3 not thrown error i'm confused about this

As implied by the text of the error message, a computed column that SQL Server considers imprecise can not be indexed without first pesisting it. But a computed column that is not imprecies can be persisted.
All results of calculations with floating point data is considered imprecise, that's the reason you get the error in query 2.


thanks for your reply hugo , but in query 3 i have used decimal (decimal(18,2))data type for that there s no error thrown
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: 8323 Visits: 11573
deepak.a (10/15/2010)
Hugo Kornelis (10/15/2010)
deepak.a (10/15/2010)
one more doubt on creating the index on computed columns
(...)
in the above Quesries second one (Query 2) thrown on error while creating the index on computed column but the Query 1 and Query 3 not thrown error i'm confused about this

As implied by the text of the error message, a computed column that SQL Server considers imprecise can not be indexed without first pesisting it. But a computed column that is not imprecies can be persisted.
All results of calculations with floating point data is considered imprecise, that's the reason you get the error in query 2.


thanks for your reply hugo , but in query 3 i have used decimal (decimal(18,2))data type for that there s no error thrown

That's because decimal(18,2) is NOT imprecise, whereas float is.


Hugo Kornelis, SQL Server MVP
Visit my SQL Server blog: http://sqlblog.com/blogs/hugo_kornelis
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