March 18, 2016 at 9:11 am
Hello,
I started working in a company where we have 6 production servers with a lot of databases on each server.
Is there a way to figure out what databases have not being used for a year, so we could take them offline.
Thank you
March 18, 2016 at 9:17 am
you can infer the last accessed time of every database since the server was last rebooted base din the index stats; if you've got something regularly rebooting your server, you'll have to add some sort of audit yourself.
i use this query:
--based on the ideas from
--http://sqlblog.com/blogs/aaron_bertrand/archive/2008/05/06/when-was-my-database-table-last-accessed.aspx
;WITH AllDatabases
AS
(
SELECT database_id,name AS TheDatabase from master.sys.databases WHERE name NOT IN('master','tempdb','model','msdb')
),
myCTE
AS
(
SELECT
AllDatabases.TheDatabase,
statz.last_user_seek,
statz.last_user_scan,
statz.last_user_lookup,
statz.last_user_update
FROM AllDatabases
LEFT OUTER JOIN sys.dm_db_index_usage_stats statz
ON AllDatabases.database_id = statz.database_id
)
SELECT
ServerRestartedDate = (SELECT CREATE_DATE FROM sys.databases where name='tempdb'),
x.TheDatabase,
MAX(x.last_read) AS last_read,
MAX(x.last_write) AS last_write
FROM
(
SELECT TheDatabase,last_user_seek AS last_read, NULL AS last_write FROM myCTE
UNION ALL
SELECT TheDatabase,last_user_scan, NULL FROM myCTE
UNION ALL
SELECT TheDatabase,last_user_lookup, NULL FROM myCTE
UNION ALL
SELECT TheDatabase,NULL, last_user_update FROM myCTE
) AS x
GROUP BY TheDatabase
ORDER BY TheDatabase
END
Lowell
March 18, 2016 at 11:12 am
I haven't met a read-only database, so you could probably compare backups.
March 18, 2016 at 11:49 am
Once you've identified what you believe to be a list of databases no longer used, then set the database option 'Restrict Access' for each to RESTRICTED_USER mode (default is MULTI_USER), which will block access to any user except SYSADMIN. Another option is to take each of them OFFLINE. Keep them this way for at least 45 days before dropping, so they can be easily made available again if someone misses it. Also confirm you have a backups.
"Do not seek to follow in the footsteps of the wise. Instead, seek what they sought." - Matsuo Basho
March 18, 2016 at 11:54 am
Luis Cazares (3/18/2016)
I haven't met a read-only database, so you could probably compare backups.
Easy enough, if differential backups are consistently 0 in content and no connections are made to the database then drop the bugger:-D
On more serious note, using the index usage statistics doesn't really cut it as there are quite few holes to fall through such as heap tables, that is no index to use, no usage recorded, no one said that those databases are well structured/designed!
😎
March 18, 2016 at 12:57 pm
Eirikur Eiriksson (3/18/2016)
Luis Cazares (3/18/2016)
I haven't met a read-only database, so you could probably compare backups.Easy enough, if differential backups are consistently 0 in content and no connections are made to the database then drop the bugger:-D
On more serious note, using the index usage statistics doesn't really cut it as there are quite few holes to fall through such as heap tables, that is no index to use, no usage recorded, no one said that those databases are well structured/designed!
😎
Even if a database is read-only, it can still be used, even heavily used.
"Do not seek to follow in the footsteps of the wise. Instead, seek what they sought." - Matsuo Basho
March 18, 2016 at 1:24 pm
Eric M Russell (3/18/2016)
Eirikur Eiriksson (3/18/2016)
Luis Cazares (3/18/2016)
I haven't met a read-only database, so you could probably compare backups.Easy enough, if differential backups are consistently 0 in content and no connections are made to the database then drop the bugger:-D
On more serious note, using the index usage statistics doesn't really cut it as there are quite few holes to fall through such as heap tables, that is no index to use, no usage recorded, no one said that those databases are well structured/designed!
😎
Even if a database is read-only, it can still be used, even heavily used.
You are absolutely right, seen this happen more than once:Whistling:
😎
March 18, 2016 at 3:09 pm
Thank you, SSChampion.
But I cannot run the query because do not have permission on sys.dm_db_index_usage_stats .
This code below does not help
USE master;
GO
GRANT VIEW SERVER STATE TO [test1]
GO
March 18, 2016 at 4:06 pm
New DBA (3/18/2016)
Thank you, SSChampion.But I cannot run the query because do not have permission on sys.dm_db_index_usage_stats .
This code below does not help
USE master;
GO
GRANT VIEW SERVER STATE TO [test1]
GO
Is it because you are not user "test1" ? 🙂
March 20, 2016 at 11:07 pm
March 21, 2016 at 6:44 am
I am not user 'test1'. I put it just for example. Of cause I used the real user name 🙂
March 21, 2016 at 6:48 am
I am not user 'test1'. I put it just for example. Of cause I used the real user name 🙂
March 21, 2016 at 6:49 am
Thank you, great article, will review.
March 28, 2016 at 12:40 pm
Based on the article, I created table
Create Table dbo.DatabaseAudit
(
ServerNamevarchar(255) Not Null
,DBNamevarchar(255) Not Null
,LoginTimedatetime Not Null
,LastBatchdatetime Not Null
,[Status]varchar(55) Not Null
,HostNamevarchar(255) Not Null
,ProgramNamevarchar(255) Not Null
,NTUserNamevarchar(255) Not Null
,LogiNamevarchar(255) Not Null
,AuditDatedatetime Not Null
Constraint DatabaseAudit_DF_AuditDate Default (Getdate())
)
On [Primary]
Then created SP that populates this table
Create Procedure dbo.DatabaseAudit_Insert
As
Begin
Set Nocount On;
Insert Into dbo.DatabaseAudit
(
ServerName
,DBName
,LoginTime
,LastBatch
,[Status]
,HostName
,ProgramName
,NTUserName
,LogiName
)
Select
@@ServerName
,Name
,Login_Time
,Last_Batch
,[Status]
,Coalesce(HostName, '')
,Coalesce(Program_Name, '')
,Coalesce(NT_UserName, '')
,LogiName
From
sys.databases d
Left Join
master.dbo.sysprocesses sp On (d.database_id = sp.dbid)
Where
database_id Not Between 1 and 4 /* Exclude system databases */
And LogiName Is Not Null
End
Should SP be running in Master DB or in any DB? I have it now in Database1 (example). Also table is in Database1. I created job and it's running every 10 minutes. Why I have rows inserted by SP into my table only with DBName "Database1"? I am querying other databases in SSMS and expect to see those DB Names in my table. This SP using master.dbo.sysprocesses table, no matter in what database I am running it, I think it should return data about all databases that get queried. Why I get only info about Database1?
March 28, 2016 at 12:40 pm
Based on the article, I created table
Create Table dbo.DatabaseAudit
(
ServerNamevarchar(255) Not Null
,DBNamevarchar(255) Not Null
,LoginTimedatetime Not Null
,LastBatchdatetime Not Null
,[Status]varchar(55) Not Null
,HostNamevarchar(255) Not Null
,ProgramNamevarchar(255) Not Null
,NTUserNamevarchar(255) Not Null
,LogiNamevarchar(255) Not Null
,AuditDatedatetime Not Null
Constraint DatabaseAudit_DF_AuditDate Default (Getdate())
)
On [Primary]
Then created SP that populates this table
Create Procedure dbo.DatabaseAudit_Insert
As
Begin
Set Nocount On;
Insert Into dbo.DatabaseAudit
(
ServerName
,DBName
,LoginTime
,LastBatch
,[Status]
,HostName
,ProgramName
,NTUserName
,LogiName
)
Select
@@ServerName
,Name
,Login_Time
,Last_Batch
,[Status]
,Coalesce(HostName, '')
,Coalesce(Program_Name, '')
,Coalesce(NT_UserName, '')
,LogiName
From
sys.databases d
Left Join
master.dbo.sysprocesses sp On (d.database_id = sp.dbid)
Where
database_id Not Between 1 and 4 /* Exclude system databases */
And LogiName Is Not Null
End
Should SP be running in Master DB or in any DB? I have it now in Database1 (example). Also table is in Database1. I created job and it's running every 10 minutes. Why I have rows inserted by SP into my table only with DBName "Database1"? I am querying other databases in SSMS and expect to see those DB Names in my table. This SP using master.dbo.sysprocesses table, no matter in what database I am running it, I think it should return data about all databases that get queried. Why I get only info about Database1?
Viewing 15 posts - 1 through 15 (of 15 total)
You must be logged in to reply to this topic. Login to reply