Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Index Usage - Deleted Expand / Collapse
Author
Message
Posted Tuesday, July 31, 2012 4:48 AM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Thursday, December 18, 2014 12:03 AM
Points: 1,380, Visits: 2,708
Hi All

I'm using the below script to track index usage on a particular table.

Why does the leaf_delete_count show zero? I deleted some records from the table but it still shows zero.

Am I missing something here?

SELECT SO.name,
SI.name IndexName
,SI.type_desc IndexType
,IPS.avg_fragmentation_in_percent
,IPS.index_level
,IOS.range_scan_count
,IUS.user_lookups
,IUS.user_scans
,IUS.user_seeks
,IUS.index_id
,IOS.leaf_delete_count
,IOS.leaf_insert_count
,IOS.leaf_update_count
FROM sys.indexes SI
INNER JOIN sys.objects SO
ON SO.object_id = SI.object_id
INNER JOIN sys.dm_db_index_physical_stats (DB_ID('dbname'), OBJECT_ID('tablename'), NULL , NULL, N'LIMITED')IPS
ON IPS.object_id = SI.object_id
AND IPS.index_id = SI.index_id
inner join sys.dm_db_index_operational_stats (DB_ID('dbname'), OBJECT_ID('tablename'), NULL , NULL) IOS
on IOS.object_id = SO.object_id
and IOS.index_id = SI.index_id
inner join sys.dm_db_index_usage_stats IUS
on IUS.object_id = SO.object_id
and IUS.index_id = SI.index_id
where SI.name is not null


Thanks
Post #1337777
Posted Tuesday, July 31, 2012 12:35 PM


SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Wednesday, December 10, 2014 4:28 PM
Points: 115, Visits: 402
To increase the performance of DELETE operation the records are not deleted immediately, instead they are marked as ghosted . A background process called ghost cleanup task later removes the deleted records physically from the index page.you should look for 'leaf_ghost_count' column in the 'sys.dm_db_index_operational_stats' for number of logically deleted records.

Cheers ,
Pooyan D
________________________________________________
Microsoft Certified Technology Specialist : SQL Server 2008
Post #1338096
Posted Tuesday, July 31, 2012 11:46 PM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Thursday, December 18, 2014 12:03 AM
Points: 1,380, Visits: 2,708
pooyan_pdm (7/31/2012)
To increase the performance of DELETE operation the records are not deleted immediately, instead they are marked as ghosted . A background process called ghost cleanup task later removes the deleted records physically from the index page.you should look for 'leaf_ghost_count' column in the 'sys.dm_db_index_operational_stats' for number of logically deleted records.


How long after the delete does the Ghost Cleanup happen?

Thanks
Post #1338303
Posted Wednesday, August 1, 2012 12:54 AM


SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Wednesday, December 10, 2014 4:28 PM
Points: 115, Visits: 402
When a record is marked as ghost in an index page , it is reflected in the header of this page you can check it by running dbcc page m_ghostreccount . During the next time the page is scanned the ghost clean up task removes the deleted record from the slot array of that page but the record is never actually deleted . It is not accessable anymore instead.

Cheers ,
Pooyan D
________________________________________________
Microsoft Certified Technology Specialist : SQL Server 2008
Post #1338328
Posted Wednesday, August 1, 2012 11:38 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: 2 days ago @ 1:25 AM
Points: 7,141, Visits: 12,767
SQLSACT (7/31/2012)
pooyan_pdm (7/31/2012)
To increase the performance of DELETE operation the records are not deleted immediately, instead they are marked as ghosted . A background process called ghost cleanup task later removes the deleted records physically from the index page.you should look for 'leaf_ghost_count' column in the 'sys.dm_db_index_operational_stats' for number of logically deleted records.


How long after the delete does the Ghost Cleanup happen?

Thanks

There is no way to predict when it will be physcially cleaned up. The ghost cleanup thread wakes up every 5 seconds looking for things to clean, but it will not be guaranteed to cleanup all ghosted records each time it wakes up. The algorithm is hidden from us and it will only do enough work to try and keep up while balancing overall system performance.

Deep dive: Inside the Storage Engine: Ghost cleanup in depth


__________________________________________________________________________________________________
There are no special teachers of virtue, because virtue is taught by the whole community. --Plato
Post #1338713
Posted Thursday, August 2, 2012 2:19 AM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Thursday, December 18, 2014 12:03 AM
Points: 1,380, Visits: 2,708
opc.three (8/1/2012)
SQLSACT (7/31/2012)
pooyan_pdm (7/31/2012)
To increase the performance of DELETE operation the records are not deleted immediately, instead they are marked as ghosted . A background process called ghost cleanup task later removes the deleted records physically from the index page.you should look for 'leaf_ghost_count' column in the 'sys.dm_db_index_operational_stats' for number of logically deleted records.


How long after the delete does the Ghost Cleanup happen?

Thanks

There is no way to predict when it will be physcially cleaned up. The ghost cleanup thread wakes up every 5 seconds looking for things to clean, but it will not be guaranteed to cleanup all ghosted records each time it wakes up. The algorithm is hidden from us and it will only do enough work to try and keep up while balancing overall system performance.

Deep dive: Inside the Storage Engine: Ghost cleanup in depth



Thanks for this

Post #1339003
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse