SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Primary Key and Clustered Index: how to set in this example?


Primary Key and Clustered Index: how to set in this example?

Author
Message
WolfgangE
WolfgangE
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: 1349 Visits: 798
hi there,

hope it's the right forum ;-)

I have an example where I am not sure about setting my primary key and my clustered index for best performance and used storage size.
I have a table containing a summary of parcels that were distributed for customers.
A customer can buy an additional service for a parcel.

Here's the (simplified!) table with some sample data.


create table #ShippingNote(
DeliveryDay date not null,
DebitorNumber char(5) not null,
DestinationPostalCode varchar(10) not null,
AdditionalService varchar(20) null,
ParcelCount int not null
);
go
insert into #ShippingNote values
( '20130801', '12345', '6200', 'PRIORITY', 5 )
,( '20130801', '12345', '6200', NULL, 7 )
,( '20130801', '12345', '6200', 'DANGEROUS_GOOD', 10 )
,( '20130801', '12345', '8020', 'PRIORITY', 3 )
,( '20130801', '12345', '8020', 'FRAGILE', 12 )

,( '20130801', '98765', '6200', 'PRIORITY', 9 )
,( '20130801', '98765', '6200', NULL, 3 )
,( '20130801', '98765', '6200', 'DANGEROUS_GOOD', 7 )
,( '20130801', '98765', '8020', 'PRIORITY', 11 )
,( '20130801', '98765', '8020', 'FRAGILE', 5 )

,( '20130802', '12345', '6200', 'PRIORITY', 3 )
,( '20130802', '12345', '6200', NULL, 1 )
,( '20130802', '12345', '6200', 'DANGEROUS_GOOD', 15 )
,( '20130802', '12345', '8020', 'PRIORITY', 3 )
,( '20130802', '12345', '8020', 'FRAGILE', 1 )

,( '20130802', '98765', '6200', 'PRIORITY', 5 )
,( '20130802', '98765', '6200', NULL, 20 )
,( '20130802', '98765', '6200', 'DANGEROUS_GOOD', 1 )
,( '20130802', '98765', '8020', 'PRIORITY', 9 )
,( '20130802', '98765', '8020', 'FRAGILE', 8 )




Now I want a report, how many parcels we distributed per customer, per DestionationPostalCode and per AdditionalService. The report can - within a stored procedure - be filtered on a date range, the DebitorNumber and the PostalCode.
Here's the query:

declare
@FromDeliveryDay date,
@ToDeliveryDay date,
@DebitorNumber char(5),
@DestinationPostalCode varchar(10);

set @FromDeliveryDay = '20130801';
set @ToDeliveryDay = '20130802';
set @DebitorNumber = '12345';
set @DestinationPostalCode = '6200'

select
s.DebitorNumber,
s.DestinationPostalCode,
s.AdditionalService,
SumParcels = sum( s.ParcelCount )
from #ShippingNote s
where s.DeliveryDay between @FromDeliveryDay and @ToDeliveryDay and
s.DebitorNumber = @DebitorNumber and
s.DestinationPostalCode = @DestinationPostalCode
group by
s.DebitorNumber,
s.DestinationPostalCode,
s.AdditionalService
order by
s.DebitorNumber,
s.DestinationPostalCode,
s.AdditionalService



This query is the only query on this table. Yes, the table and the query are made just for this one report because it is used that much often.

For my understanding the perfect clustered index for performance would be the following:


create UNIQUE clustered index #cix_ShippingNote
on #ShippingNote ( DeliveryDay, DebitorNumber, DestinationPostalCode, AdditionalService )



The query results in an index seek and all the ordering of the data for grouping is already done.

Now the question:
I need to replicate this table to another server. This means I have to define a primary key.

In theory the perfect primary key would be the clustered index, like this:


alter table #cix_ShippingNote add constraint ShippingNote_PK
primary key clustered( DeliveryDay, DebitorNumber, DestinationPostalCode, AdditionalService )



Unfortunately, the column AdditionalService is nullable. This way I can't create the PK.

For this I added an identity column to the table and used it as a primary key. I left the clustered index as shown above.
But now, as the primary key is nonclustered, it contains the full clustered key. This means I double the size of the whole table. I don't think that makes sense.

I thought about making the PK on the identity column, clustered, and add an additional unique nonclustered index on the rest of the columns. This way the query should still do fine. It's only the "overhead" of the PK column.

Is there a better way?


Thank's a lot, WolfgangE
GilaMonster
GilaMonster
SSC Guru
SSC Guru (233K reputation)SSC Guru (233K reputation)SSC Guru (233K reputation)SSC Guru (233K reputation)SSC Guru (233K reputation)SSC Guru (233K reputation)SSC Guru (233K reputation)SSC Guru (233K reputation)

Group: General Forum Members
Points: 233533 Visits: 46361
Primary key is not decided by a query. It's part of the design process of the table. It's a column or set of columns that uniquely (with no nulls) identifies the row.

Clustered index should organise the table primarily, be usable for queries as a secondary goal only (yes, there are people who hold to the opposite of that, some get very 'passionate' about their point of view)

Indexing basics
http://www.sqlservercentral.com/articles/Indexing/68439/
http://www.sqlservercentral.com/articles/Indexing/68563/
http://www.sqlservercentral.com/articles/Indexing/68636/

No, I haven't read through the query in detail, waaay too early for complex questions

Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


WolfgangE
WolfgangE
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: 1349 Visits: 798
I do have a natural PK. The only difficulty is: one of these columns is nullable. So I cannot create the PK constraint.
The question is: do I add a artificial PK, like an identity column, which is not used in any way, or are there better solutions, like replacing the NULL-values by an empty string or something?
GilaMonster
GilaMonster
SSC Guru
SSC Guru (233K reputation)SSC Guru (233K reputation)SSC Guru (233K reputation)SSC Guru (233K reputation)SSC Guru (233K reputation)SSC Guru (233K reputation)SSC Guru (233K reputation)SSC Guru (233K reputation)

Group: General Forum Members
Points: 233533 Visits: 46361
I'd add an artificial primary key and put a unique constraint on the unique set of columns.

Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


Bhuvnesh
Bhuvnesh
SSChampion
SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)

Group: General Forum Members
Points: 13818 Visits: 4077
WolfgangE (9/3/2013)
I thought about making the PK on the identity column, clustered, and add an additional unique nonclustered index on the rest of the columns.
In this case There is no use to make PK clustred index as you are not goung to use it for Query performance better. Keep the clusterd in index on your searchable column (as mentioend in your index ) and make the PK (int) non clustered index. because in any case your query will get benefit if clustered index is on searchable columns .

-------Bhuvnesh----------
I work only to learn Sql Server...though my company pays me for getting their stuff done;-)
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