YES!!!

OK, well, I guess I should be more specific because as in most things in SQL Server, the real answer is “it depends”. And for these two options, it depends mostly on your SQL Server version. Since SQL Server 7.0, the way that auto update works, has changed (much so for the better!!). So, if you’re in SQL Server 2005 or SQL Server 2008, I would say most definitely – leave these ON (or if you turned them off – turn them back on!!!)! If you still have problems with a specific index causing your grief, then turn off auto update at the index level NOT at the database level. To turn of auto update at the index level use STATISTICS_NORECOMPUTE in the index (or statistics) definition.

Now, as for why (and how!) this has changed over the versions… here we go:

SQL Server 7.0

  • Invalidation: Statistics were *invalidated* when a row modification counter (sysindexes.rowmodctr) was reached. This meant that they could not tell where the modifications were occuring and, if modifications were somewhat isolated to a specific column ALL of the statistics for the TABLE would be invalidated (so, statistics could be invalidated earlier than necessary)
  • Updating: Even worse, in SQL Server 7.0, when statistics were invalidated, they were immediately updated. This caused two problems – thrashing at the time of invalidation because all of the stats needed to be updated AND two, if the statistics were not used for awhile then extra work was involved to update them and by the time they were used, they might already be somewhat out of date already.

SQL Server 2000

  • Invalidation: Statistics were still invalidated based on a row modification counter.
  • Updating: SQL Server 2000 fixed the “updating-potentially-too-often” problem by only updating statistics when they were needed.

SQL Server 2005

  • Invalidation: The biggest changes were introduced in SQL Server 2005 where they decided to NO LONGER user the sysindexes.rowmodctr and instead use an internal (and undocumented) columns specific modification counter. Now, statistic invalidation is more isolated to only those columns which are heavily modified. This internal/undoc’ed column is sysrowsetcolumns.rcmodified and can only be seen when connecting to SQL Server using the DAC (Dedicated Admin Connection).
  • Updating: Updating didn’t really change but, SQL Server 2005 added “Aynch Auto Update” for statistics so that when the QO (query optimizer) encounters an out-of-date (i.e. invalidated) statistic, they can “trigger” the update but not wait for the update (meaning that they’ll optimize using the out-of-date statistic). This can be both positive (faster) and negative (might not be the best plan if the statistics have changed drastically). It is off by default and IMO, I’d leave it off in most cases but if you find that auto update events (which can be Profiled) are causing you grief, then you can turn this on at the database level.

SQL Server 2008

Nothing new except “Filtered Statistics” and these are interesting as the density vector is still relative to the table (not the predicate) but the histogram is just over the predicate (OK, I know I’ll have to blog a lot more about this one!). Anyway, I’m still playing/learning a lot more about these and they make the most sense with filtered indexes (as opposed to just a filtered statistic) but, just like statistics on secondary columns you will also potentially want statistics on the secondary columns of your indexes. The next question is should they have a filter or not. I’ve found that sp_createstats doesn’t seem to create statistics with filters and I’m going to need to do some testing here but I think statistics with filters (filters that match the non-clustered index) should help to make the stats better (and even allow better usage of filtered indexes) but, I’m really going to need a bunch of time with this – and another post :). As for auto create/auto update – no changes there!

Long story short, if you’re using SQL Server 2005 or SQL Server 2008, you should leave auto create/auto update ON.

Thanks for reading!

kt

PS – A few of you have mailed me about a bug in the sp_helpindex2 script(s). OK, that’s my next post!!! Possibly with an sp_helpstats2 script as well!