- Start Microsoft SQL Server Management Studio (MSSMS).
- On the File menu, clickConnect Object Explorer. Fill out the Connect to Server dialog box:
- In the Server type list box, select Database Engine.
- In the Server name text box, type the name of the SQL cluster server.
- In the Authentication list box, choose your SQL Server Authentication method and specify your credentials. If you do not want to re-type the password every time you connect to the server, tick Remember password.
- Click Connect.
- Upon connection, click New Query and paste the following script into the query field:
SELECT
sys.databases.name as 'Database Name',
sys.databases.user_access_desc as "Restrict Access",
sys.databases.state_desc as 'State',
sys.databases.is_read_only as 'Read Only',
sys.databases.is_auto_shrink_on 'Auto Shrink Enabled',
sys.databases.is_encrypted as 'Encrypted',
bckup.last_backup as 'Last Database Backup',
files.data_file as 'Database File Path',
files.log_file as 'Log File Path',
files.db_size as 'Database Size MB',
files.log_size as 'Log File Size MB',
sys.databases.database_id as 'Database ID'
FROM sys.databases
LEFT JOIN (
SELECT msdb.dbo.backupset.database_name, MAX(msdb.dbo.backupset.backup_finish_date) AS last_backup
FROM msdb.dbo.backupmediafamily
INNER JOIN msdb.dbo.backupset ON msdb.dbo.backupmediafamily.media_set_id = msdb.dbo.backupset.media_set_id
WHERE msdb..backupset.type = 'D'
GROUP BY msdb.dbo.backupset.database_name
) bckup on bckup.database_name = sys.databases.name
LEFT JOIN (
SELECT
mdf.database_id,
mdf.name,
mdf.physical_name as data_file,
ldf.physical_name as log_file,
db_size = CAST((mdf.size * 8.0)/1024 AS DECIMAL(8,2)),
log_size = CAST((ldf.size * 8.0 / 1024) AS DECIMAL(8,2))
FROM (SELECT * FROM sys.master_files WHERE type_desc = 'ROWS' ) mdf
JOIN (SELECT * FROM sys.master_files WHERE type_desc = 'LOG' ) ldf
ON mdf.database_id = ldf.database_id
) files
ON files.database_id = sys.databases.database_id
ORDER BY 'Database Name'
- Click Execute (or hit the F5 key).
- Review the list of databases and their properties in the query results:
- Open Netwrix Auditor and navigate to Reports -> Predefined -> SQL Server — State-in-Time -> SQL Server Databases.
- Click View to see your report: