As a DBA, you are responsible for monitoring the growth of the databases on multiple servers in different environments. There are many ways we can achieve this, my requirement was to use linked servers to get the databases size of all the linked servers and email the report to DBA group.
Here is the script i have written to get the database sizes of all the linked servers.
CREATE PROCEDURE [dbo].[SumofDBsize]
AS
BEGIN
--This procedure is used to sum all the databases sizes in all the Linked servers.</pre>
IF OBJECT_ID('tempdb.dbo.#sum_volum') IS NOT NULL
BEGIN
DROP TABLE tempdb.dbo.#sum_volum;
END
ELSE
BEGIN
CREATE TABLE #sum_volum (
Server_name varchar(50),
DATABASE_NAME varchar(500),
DATABASE_SIZE bigint
)
END
DECLARE @tmp_key varchar(50)
DECLARE @db CURSOR
DECLARE @sql nvarchar(max)
SET @db = CURSOR FOR
SELECT
name 'server_name'
FROM sys.servers
ORDER BY server_id
OPEN @db
FETCH NEXT FROM @db INTO @tmp_key
WHILE (@@FETCH_STATUS = 0)
BEGIN
--select @tmp_key
SET @sql = N'insert into #sum_volum(DATABASE_NAME,DATABASE_SIZE)
select
db.name ,
DATABASE_SIZE = convert(bigint, convert(bigint, sum(s_mf.size))*8)
--REMARKS = convert(varchar(500),null)
from ' + QUOTENAME(@tmp_key) + '.master.sys.master_files s_mf right outer join ' + QUOTENAME(@tmp_key) + '.master. sys.databases db on s_mf.database_id = db.database_id
where
s_mf.state = 0
group by db.name
order by 1 ';
EXEC sp_sqlexec @sql
SELECT
@tmp_key
UPDATE #sum_volum
SET Server_name = @tmp_key
WHERE Server_name IS NULL
OR Server_name = ''
FETCH NEXT FROM @db INTO @tmp_key
END;
CLOSE @db
DEALLOCATE @db
EXEC msdb.dbo.sp_send_dbmail @profile_name = 'SUM_DB_Volumes',
@recipients = 'youremail@gmail.com',
@subject = 'SQL servers Database Volume Reports',
@body = 'Please Find the attachment for the Volume reports',
@execute_query_database = 'YourDBName',
@query = '
select server_name,DATABASE_NAME,sum(DATABASE_SIZE) ''DATABASE_SIZE''
from #sum_volum
group by server_name,DATABASE_NAME,DATABASE_SIZE
union all
select '''',''Total Size In KB'',sum(DATABASE_SIZE)
from #sum_volum
union all
select '''',''Total Size In GB'',((sum( DATABASE_SIZE )/1024)/1024)
from #sum_volum
union all
select '''',''Total Size In TB'',(((sum( DATABASE_SIZE )/1024)/1024)/1024)
from #sum_volum',
@attach_query_result_as_file = 1,
@query_result_separator = ' ',
@exclude_query_output = 1,
@query_result_no_padding = 1,
@query_result_header = 1,
@query_attachment_filename = 'SQL server volume report.csv'
END
GO
Hope you enjoyed the post!
Cheers
Ramasankar Molleti
LinkedIn: LinkedIn Profile
Twitter: Twitter
