February 26, 2015 at 5:07 am
Hi there - How would I find the last read/write dates for all the tables within a database. Thanks!
--------------------------------------------
Laughing in the face of contention...
February 26, 2015 at 6:12 am
It's not a perfect solution because if you have heaps it won't work, but you can look to the sys.dm_index_usage_stats for everything else.
"The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood"
- Theodore Roosevelt
Author of:
SQL Server Execution Plans
SQL Server Query Performance Tuning
February 26, 2015 at 6:19 am
Grant Fritchey (2/26/2015)
It's not a perfect solution because if you have heaps it won't work, but you can look to the sys.dm_index_usage_stats for everything else.
Something like this:
SELECT DB_NAME(database_id) AS database_name,
OBJECT_NAME(object_id, database_id) AS object_name,
MAX(reads.last_read) AS last_read,
MAX(last_user_update) AS last_write
FROM sys.dm_db_index_usage_stats
CROSS APPLY (
VALUES(last_user_seek),(last_user_scan),(last_user_lookup)
) AS reads(last_read)
GROUP BY DB_NAME(database_id),
OBJECT_NAME(object_id, database_id)
-- Gianluca Sartori
February 26, 2015 at 6:51 am
Perfect! Thanks.
The results don't include objects which have not been written/read to/from i.e. nulls. Is there a way of returning these stats? Thanks again.
--------------------------------------------
Laughing in the face of contention...
February 26, 2015 at 6:57 am
arrjay (2/26/2015)
Perfect! Thanks.The results don't include objects which have not been written/read to/from i.e. nulls. Is there a way of returning these stats? Thanks again.
pretty sure you have to join against sys.tables first,and left join to the index stats in order to get all tables. index stats is server wide, so if you need it for anything other than one specific database, it's not going to work, or require a boatload of additional logic.
Lowell
February 26, 2015 at 7:00 am
Lowell (2/26/2015)
arrjay (2/26/2015)
Perfect! Thanks.The results don't include objects which have not been written/read to/from i.e. nulls. Is there a way of returning these stats? Thanks again.
pretty sure you have to join against sys.tables first,and left join to the index stats in order to get all tables. index stats is server wide, so if you need it for anything other than one specific database, it's not going to work, or require a boatload of additional logic.
Completely agree.
-- Gianluca Sartori
February 26, 2015 at 7:51 am
spaghettidba (2/26/2015)
Lowell (2/26/2015)
arrjay (2/26/2015)
Perfect! Thanks.The results don't include objects which have not been written/read to/from i.e. nulls. Is there a way of returning these stats? Thanks again.
pretty sure you have to join against sys.tables first,and left join to the index stats in order to get all tables. index stats is server wide, so if you need it for anything other than one specific database, it's not going to work, or require a boatload of additional logic.
Completely agree.
+1
"The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood"
- Theodore Roosevelt
Author of:
SQL Server Execution Plans
SQL Server Query Performance Tuning
Viewing 7 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply