Ver Mensaje Individual
  #2 (permalink)  
Antiguo 08/02/2012, 12:09
Avatar de iislas
iislas
Colaborador
 
Fecha de Ingreso: julio-2007
Ubicación: Mexico, D.F.
Mensajes: 6.482
Antigüedad: 17 años, 5 meses
Puntos: 180
Respuesta: Indices inutilizados sql server 2008

¿Que indices NO se usan?

Código SQL:
Ver original
  1. DECLARE @db VARCHAR(25)
  2. SET @db = '<database>'
  3. SELECT object_name(i.object_id), i.name
  4. FROM sys.indexes i, sys.objects o
  5. WHERE  i.index_id NOT IN (SELECT s.index_id
  6.        FROM sys.dm_db_index_usage_stats s
  7.     WHERE s.object_id=i.object_id AND
  8.     i.index_id=s.index_id AND
  9.    database_id = db_id(@db) )
  10. AND o.TYPE = 'U'
  11. AND o.object_id = i.object_id
  12. ORDER BY object_name(i.object_id) ASC
  13. GO

¿Que indices me hacen falta?

Código SQL:
Ver original
  1. SELECT
  2.   mig.index_group_handle, mid.index_handle,
  3.   CONVERT (DECIMAL (28,1),
  4.     migs.avg_total_user_cost * migs.avg_user_impact * (migs.user_seeks + migs.user_scans)
  5.   ) AS improvement_measure,
  6.   'CREATE INDEX IDX_' + REPLACE(REPLACE(mid.statement, '[', ''), ']', '')+ CONVERT (VARCHAR, mig.index_group_handle) + '_' + CONVERT (VARCHAR, mid.index_handle)
  7.   + ' ON ' + mid.statement
  8.   + ' (' + ISNULL (mid.equality_columns,'')
  9.     + CASE WHEN mid.equality_columns IS NOT NULL AND mid.inequality_columns IS NOT NULL THEN ',' ELSE '' END
  10.     + ISNULL (mid.inequality_columns, '')
  11.   + ')'
  12.   + ISNULL (' INCLUDE (' + mid.included_columns + ')', '') AS create_index_statement,
  13.   migs.*, mid.database_id, mid.[object_id]
  14. FROM sys.dm_db_missing_index_groups mig
  15. INNER JOIN sys.dm_db_missing_index_group_stats migs ON migs.group_handle = mig.index_group_handle
  16. INNER JOIN sys.dm_db_missing_index_details mid ON mig.index_handle = mid.index_handle
  17. WHERE CONVERT (DECIMAL (28,1), migs.avg_total_user_cost * migs.avg_user_impact * (migs.user_seeks + migs.user_scans)) > 10
  18. ORDER BY migs.avg_total_user_cost * migs.avg_user_impact * (migs.user_seeks + migs.user_scans) DESC

¿Consejos?

Crear un PLAN DE MANTENIMIENTO que se ejecute al menos 1 vez por semana que incluya la REGENERACION DE INDICES
__________________
MCTS Isaias Islas