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


Fill factors, index fragmentation and indexing strategy


Fill factors, index fragmentation and indexing strategy

Author
Message
Marios Philippopoulos
Marios Philippopoulos
SSCarpal Tunnel
SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)

Group: General Forum Members
Points: 4544 Visits: 3755
I need to confirm whether my understanding with regards to fill factors and index fragmentation is correct in the following scenario.

I have a table of about 300,000 rows that looks like this:

Column
---------
AID (INT - Identity column, monotonically increasing - also the PK)
FKID (INT - foreign-key column)
Dt (DATETIME)

The PK is clustered.

The table is truncated and re-populated from scratch according to a daily schedule.

I want to create non-clustered indexes on the FKID and DT columns.

My question is:
do I need to worry about specifying a fill factor for the non-clustered indexes? My feeling is that I don't need a fill factor, since the data is entered one row at a time in the table, so there should be no random inserts into the pages of the non-clustered indexes.

Can someone pls confirm?

__________________________________________________________________________________
SQL Server 2016 Columnstore Index Enhancements - System Views for Disk-Based Tables
Persisting SQL Server Index-Usage Statistics with MERGE
Turbocharge Your Database Maintenance With Service Broker: Part 2
Matt Miller (4)
Matt Miller (4)
SSChampion
SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)

Group: General Forum Members
Points: 12211 Visits: 18574
You might worry about it if the columns making up the key change a lot. in a similar way to why you worry about fill factor for clustered indexes, data movement in those columns would cause the index to fragment if there isn't enough room to accomodate the change.

Of course - it's not as "bad" as a page split in the clustered index, but still - might be worth considering some amount of slack.

Specify it exactly like you would on a clustered index.


create index ix_jr09 on job20080930(rowID) include (msg) WITH FILLFACTOR=80



----------------------------------------------------------------------------------
Your lack of planning does not constitute an emergency on my part...unless you're my manager...or a director and above...or a really loud-spoken end-user..All right - what was my emergency again?
Marios Philippopoulos
Marios Philippopoulos
SSCarpal Tunnel
SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)

Group: General Forum Members
Points: 4544 Visits: 3755
Matt Miller (10/15/2008)
You might worry about it if the columns making up the key change a lot. in a similar way to why you worry about fill factor for clustered indexes, data movement in those columns would cause the index to fragment if there isn't enough room to accomodate the change.

Of course - it's not as "bad" as a page split in the clustered index, but still - might be worth considering some amount of slack.

Specify it exactly like you would on a clustered index.


create index ix_jr09 on job20080930(rowID) include (msg) WITH FILLFACTOR=80



Thanks for responding.

In this case we are not doing any updates, just a straight TRUNCATE of the table and INSERT of new data. Also, the clustered index is set on the identity column, so there should be no random inserts.

__________________________________________________________________________________
SQL Server 2016 Columnstore Index Enhancements - System Views for Disk-Based Tables
Persisting SQL Server Index-Usage Statistics with MERGE
Turbocharge Your Database Maintenance With Service Broker: Part 2
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)

Group: General Forum Members
Points: 85933 Visits: 41091
In that case, I'd use a FILL Factor of 100 for that tiny bit more speed on any SELECTS you may do on the table.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Matt Miller (4)
Matt Miller (4)
SSChampion
SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)

Group: General Forum Members
Points: 12211 Visits: 18574
Jeff Moden (10/15/2008)
In that case, I'd use a FILL Factor of 100 for that tiny bit more speed on any SELECTS you may do on the table.


True - but that assumes a "single load" scenario, where the table is essentially recreated "from scratch" and then left alone afterwards. That also entails dropping the non-clustered's before the truncate and recreating the indexes once the insert has happened. That may well fit your scenario.

If you plan on leaving the indexes in place (or if the indexes happen over a prolonged stretch of time), you'd still need a fill factor <100.

----------------------------------------------------------------------------------
Your lack of planning does not constitute an emergency on my part...unless you're my manager...or a director and above...or a really loud-spoken end-user..All right - what was my emergency again?
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)

Group: General Forum Members
Points: 85933 Visits: 41091
Matt Miller (10/15/2008)
Jeff Moden (10/15/2008)
In that case, I'd use a FILL Factor of 100 for that tiny bit more speed on any SELECTS you may do on the table.


True - but that assumes a "single load" scenario, where the table is essentially recreated "from scratch" and then left alone afterwards. That also entails dropping the non-clustered's before the truncate and recreating the indexes once the insert has happened. That may well fit your scenario.

If you plan on leaving the indexes in place (or if the indexes happen over a prolonged stretch of time), you'd still need a fill factor <100.


No... Smile it assumes a clustered PK on the IDENTITY column (like the OP said) which will keep things just as tidy as a single load.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Matt Miller (4)
Matt Miller (4)
SSChampion
SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)

Group: General Forum Members
Points: 12211 Visits: 18574
Jeff Moden (10/15/2008)
Matt Miller (10/15/2008)
Jeff Moden (10/15/2008)
In that case, I'd use a FILL Factor of 100 for that tiny bit more speed on any SELECTS you may do on the table.


True - but that assumes a "single load" scenario, where the table is essentially recreated "from scratch" and then left alone afterwards. That also entails dropping the non-clustered's before the truncate and recreating the indexes once the insert has happened. That may well fit your scenario.

If you plan on leaving the indexes in place (or if the indexes happen over a prolonged stretch of time), you'd still need a fill factor <100.


No... it assumes a clustered PK on the IDENTITY column (like the OP said) which will keep things just as tidy as a single load.


I understand that keeps the CLUSTERED index tidy - but how does that help the NON-Clustered indexes (and their fill factors). OP was asking about the fill factor of the NCI's (which would fragment if present on load of the data)

----------------------------------------------------------------------------------
Your lack of planning does not constitute an emergency on my part...unless you're my manager...or a director and above...or a really loud-spoken end-user..All right - what was my emergency again?
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)SSC Guru (85K reputation)

Group: General Forum Members
Points: 85933 Visits: 41091
Sorry... the day's coffee is wearing off. Smile I didn't read all of your last...

You're correct. Since the rows are going to be added on a onesy basis, there could be some pretty nasty fragmentation at FILL FACTOR 100 on the non-clustered indexes. I don't believe even an 80 FILL FACTOR would help there. Might want to go as low as, say, 60 as a guess. Best thing to do would be to find out what an average day of inserts looks like and calculate a FILL FACTOR to support the inserts.

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Marios Philippopoulos
Marios Philippopoulos
SSCarpal Tunnel
SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)SSCarpal Tunnel (4.5K reputation)

Group: General Forum Members
Points: 4544 Visits: 3755
Thank you both for your replies.

I'm not sure I follow though. How would the non-clustered indexes get fragmented? The table population is done all at once, in a sequential fashion by the clustered PK. Wouldn't the non-clustered-index pages be also filled sequentially in a "from-top-to-bottom" fashion?

There should be no page splits in this scenario.

__________________________________________________________________________________
SQL Server 2016 Columnstore Index Enhancements - System Views for Disk-Based Tables
Persisting SQL Server Index-Usage Statistics with MERGE
Turbocharge Your Database Maintenance With Service Broker: Part 2
Matt Miller (4)
Matt Miller (4)
SSChampion
SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)

Group: General Forum Members
Points: 12211 Visits: 18574
Marios Philippopoulos (10/16/2008)
Thank you both for your replies.

I'm not sure I follow though. How would the non-clustered indexes get fragmented? The table population is done all at once, in a sequential fashion by the clustered PK. Wouldn't the non-clustered-index pages be also filled sequentially in a "from-top-to-bottom" fashion?

There should be no page splits in this scenario.


The page inserts are sequential for the clustered index only. Since you're using other columns in the non-clustered indexes, it would be a "random insert" scenario on those indexes, unless the key column in the non-clustered index also happen to follow EXACTLY the same ordering as the ID (which would be rather unusual).

Since you're doing a single load, your best bet is to actually then drop all non-clustered indexes before the load, and rebuild them from scratch when the load is done. In which case - load them as Jeff was recommending (100% fill factor, since there will be NO fragmentation).

----------------------------------------------------------------------------------
Your lack of planning does not constitute an emergency on my part...unless you're my manager...or a director and above...or a really loud-spoken end-user..All right - what was my emergency again?
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