Manually Update Statistics on a SQL Server Database

Statistics allows SQL Server to tune its physical operations while creating an execution plan. This improves query processing and performance.

Once Statistics have been created, you can manually use the sp_updatestats procedure to refresh the statistics with the latest data. sp_updatedstats updates information about the distribution of key values for one or more statistics groups (collections) in the specified table or indexed view.

USE AdventureWorks
GO
EXEC
sp_updatestats

OUTPUT

image

Update: My colleague and SQL Server expert Govind Kanshi shared a script with me to run a few checks before Updating Statistics. Here’s the script for your reference


-- Find out which tables have auto-update off

SELECT o.name AS [Table], i.name AS [Index Name],
STATS_DATE(i.object_id, i.index_id) AS [Update Statistics date],
s.auto_created AS [Created by QueryProcessor], s.no_recompute
AS [Disabled Auto Update Statistics],
s.user_created AS [Created by user]
FROM sys.objects AS o WITH (NOLOCK)
INNER JOIN sys.indexes AS i WITH (NOLOCK) ON o.object_id = i.object_id
INNER JOIN sys.stats AS s WITH (NOLOCK) ON i.object_id = s.object_id
AND i.index_id = s.stats_id
WHERE o.[type] = 'U'
AND no_recompute = 1
ORDER BY STATS_DATE(i.object_id, i.index_id) ASC;

-- set that property on

ALTER INDEX INDEXA
ON dbo.TABLEX
SET (STATISTICS_NORECOMPUTE = OFF) ;

-- statistics update date – this should tell you which stats have not
-- been updated for long time minus info if no_recomputer is on/off

SELECT o.name AS [Table], i.name AS [Index Name],
STATS_DATE(i.object_id, i.index_id) AS [Update Statistics date],
s.auto_created AS [Created by QueryProcessor], s.no_recompute
AS [Disabled Auto Update Statistics],
s.user_created AS [Created by user]
FROM sys.objects AS o WITH (NOLOCK)
INNER JOIN sys.indexes AS i WITH (NOLOCK) ON o.object_id = i.object_id
INNER JOIN sys.stats AS s WITH (NOLOCK) ON i.object_id = s.object_id
AND i.index_id = s.stats_id
WHERE o.[type] = 'U'
ORDER BY STATS_DATE(i.object_id, i.index_id) ASC;

-- now update the stats

UPDATE STATISTICS TableX IndexA


If you want to generate and update statistics across all tables, use sp_createstats

No comments:

Post a Comment