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 ««123»»

Monitor Database Growth Expand / Collapse
Author
Message
Posted Thursday, May 22, 2008 3:05 AM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Yesterday @ 10:49 PM
Points: 331, Visits: 1,209
I think the second part of part 2 is in error; I think it should be like this:

--Else
IF Exists (Select t.DBName, g.DBName from #TempDBSize2 t
left outer join DBGrowthRate g on T.dbname = g.DBName where g.dbname is null)
Begin
Insert into dbo.DBGrowthRate (DBName, DBID, NumPages, OrigSize, CurSize, GrowthAmt, MetricDate)
(Select tds.DBName, tds.database_ID, Sum(tds.Size) as NumPages,
Convert(decimal(10,2),(((Sum(Convert(decimal(10,2),tds.Size)) * 8000)/1024)/1024)) as OrigSize,
Convert(decimal(10,2),(((Sum(Convert(decimal(10,2),tds.Size)) * 8000)/1024)/1024)) as CurSize,
'0.00 MB' as GrowthAmt, GetDate() as MetricDate
from #TempDBSize2 tds
where tds.database_ID not in (Select Distinct DBID from DBGrowthRate
where DBName = tds.DBName)
Group by tds.database_ID, tds.DBName)
End

This will do the trick for a newly added database.
Post #505043
Posted Monday, June 30, 2008 12:12 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Monday, February 17, 2014 3:59 PM
Points: 5, Visits: 45
I modified the script to do what I want and it is working well for me. This is for SQL 2000; you can get it to work with SQL 2005 with a minor tweak of the sys tables.

--Part1

CREATE TABLE [DBGrowthRate] (
[DBGrowthID] [int] IDENTITY (1, 1) NOT NULL ,
[DBName] [varchar] (100) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[DBID] [int] NULL ,
[OrigSize] [decimal](10, 2) NULL ,
[CurSize] [decimal](10, 2) NULL ,
[GrowthAmt] [varchar] (100) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[InitialDate] [datetime] NULL ,
[ReportDate] [datetime] NULL CONSTRAINT [DF_ReportDate] DEFAULT (getdate())
) ON [PRIMARY]
GO




--PART 2
--Below is the code run weekly to check the growth.

create Proc usp_DBGrowthRate

AS

Select sd.name as DBName, af.dbid, Sum(af.Size) as NumPages, Convert(decimal(10,2),(Sum(Convert(decimal(10,2),af.Size)) * 8)/1024) as CurSize
into #TempDBSize
from master..sysdatabases sd
join master..sysaltfiles af
on sd.dbid = af.dbid
Group by af.dbid, sd.name
Order by sd.name, af.dbid


If Exists (Select Distinct DBName from #TempDBSize where DBName in (Select Distinct DBName from DBGrowthRate))
and Convert(varchar(10),GetDate(),101) > (Select Distinct Convert(varchar(10),Max(InitialDate),101) as InitialDate from DBGrowthRate)
Begin
update dgr
set dgr.CurSize = tds.Cursize
from DBGrowthRate dgr inner join #TempDBSize tds on tds.DBID = dgr.DBID

update dgr
set dgr.GrowthAmt = tds.CurSize - dgr.OrigSize
from DBGrowthRate dgr inner join #TempDBSize tds on tds.DBID = dgr.DBID

update DBGrowthRate
set ReportDate = GetDate()
End
Else
IF Exists (Select Distinct DBName from #TempDBSize where DBName not in (Select Distinct DBName from DBGrowthRate))
Begin
Insert into dbo.DBGrowthRate (DBName, DBID,OrigSize, CurSize, GrowthAmt, InitialDate)
(Select tds.DBName, tds.dbid,
tds.CurSize,
tds.CurSize,
'0.00 MB', GetDate()
from #TempDBSize tds
where tds.dbid not in (Select Distinct DBID from DBGrowthRate dgr where dgr.DBID = tds.DBID)
)
End


DROP TABLE #TempDBSize

GO





Post #526146
Posted Tuesday, July 29, 2008 2:43 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Wednesday, November 18, 2009 1:01 PM
Points: 1, Visits: 2
for SQL 2000 by changing sys.Master_Files to sysaltfiles and sys.databases to sysdatabases. Make sure to change your column names appropriately if you make this alteration!

What do you mean by Make sure to change your column names appropriately if you make this alteration!

Sorry new at this
Post #543057
Posted Wednesday, July 30, 2008 9:13 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Monday, December 30, 2013 5:15 AM
Points: 35, Visits: 77
The original script worked for me. I had to, of course, change the size of my database; so I delete a significant amount of history, did a full backup and ran the script again.

Everything worked fine from what I could tell.

"One shalt thou not count, neither count thou two, only then proceeding to three."
Post #543598
Posted Tuesday, November 11, 2008 8:17 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: 2 days ago @ 12:13 PM
Points: 9, Visits: 103
Worked great for me. Especially w/ the recommended changes for 2000/2005

Thanks a bunch....

JP
Post #601074
Posted Wednesday, March 18, 2009 12:46 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Monday, April 7, 2014 11:39 AM
Points: 3, Visits: 46
All SQL Folks...

The original script has MAJOR error....

--In PART2 --- where it runs to update the growth table...it tries to convert the DATE to CHAR...and then compares with GetDATE() -- which is not correct.

--- I have corrected the script...BELOW>..replace the script code with Following for your EXISTS condition....This works good for SQL 2000....Change your EXISTS condition accordingly for 2005 script too..


-PART 2 -- CORRECTED EXISTS Section below...Replace on original script.
...
...
If Exists (Select Distinct DBName from #TempDBSize2
where DBName in (Select Distinct DBName from DBGrowthRate))
and GetDate() > (Select Distinct Max(MetricDate) from DBGrowthRate)
Post #678809
Posted Tuesday, April 7, 2009 3:44 PM


Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Yesterday @ 11:07 AM
Points: 361, Visits: 1,168
How do you get it to insert rather than update? I want to keep track of the changes in size weekly...

¤ §unshine ¤
Post #692576
Posted Tuesday, August 25, 2009 12:37 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Monday, April 7, 2014 11:39 AM
Points: 3, Visits: 46
All...

I have corrected the code..As it has flaws dealing with date comparison...And hence you are not getting the GROWTH amount on weekly runs...

Here is the UPDATED code (works for 2005, 2008)....Also, I have converted the GrowthAMT to Numeric (instead of VARCHAR), --- Allowing you to export the results in EXCEL for further number crunching

Let me know if this works for your environments.


--PART 1 (UPDATED, Jignesh Rajgor 08/25/2009)
If exists (Select name from sys.objects where name = 'DBGrowthRate' and Type = 'U')
Drop Table dbo.DBGrowthRate

Create Table dbo.DBGrowthRate (DBGrowthID int identity(1,1), DBName varchar(100), DBID int,
NumPages int, OrigSize decimal(10,2), CurSize decimal(10,2), GrowthAmt decimal(10,2),
MetricDate datetime)

Select sd.name as DBName, mf.name as FileName, mf.database_id, file_id, size
into #TempDBSize
from sys.databases sd
join sys.master_files mf
on sd.database_ID = mf.database_ID
Order by mf.database_id, sd.name

Insert into dbo.DBGrowthRate (DBName, DBID, NumPages, OrigSize, CurSize, GrowthAmt, MetricDate)
(Select tds.DBName, tds.database_ID, Sum(tds.Size) as NumPages,
Convert(decimal(10,2),(((Sum(Convert(decimal(10,2),tds.Size)) * 8000)/1024)/1024)) as OrigSize,
Convert(decimal(10,2),(((Sum(Convert(decimal(10,2),tds.Size)) * 8000)/1024)/1024)) as CurSize,
0 as GrowthAmt, GetDate() as MetricDate
from #TempDBSize tds
where tds.database_ID not in (Select Distinct DBID from DBGrowthRate
where DBName = tds.database_ID)
Group by tds.database_ID, tds.DBName)

Drop table #TempDBSize

Select *
from DBGrowthRate
--Above creates initial table and checks initial data





--PART 2
--Below is the code run weekly to check the growth.
Select sd.name as DBName, mf.name as FileName, mf.database_id, file_id, size
into #TempDBSize2
from sys.databases sd
join sys.master_files mf
on sd.database_ID = mf.database_ID
Order by mf.database_id, sd.name

If Exists (Select Distinct DBName from #TempDBSize2
where DBName in (Select Distinct DBName from DBGrowthRate))
and GetDate() > (Select Distinct Max(MetricDate) as MetricDate from DBGrowthRate)
Begin
Insert into dbo.DBGrowthRate (DBName, DBID, NumPages, OrigSize, CurSize, GrowthAmt, MetricDate)
(Select tds.DBName, tds.database_ID, Sum(tds.Size) as NumPages,
dgr.CurSize as OrigSize,
Convert(decimal(10,2),(((Sum(Convert(decimal(10,2),tds.Size)) * 8000)/1024)/1024)) as CurSize,
((Convert(decimal(10,2),(((Sum(Convert(decimal(10,2),tds.Size)) * 8000)/1024)/1024))) - dgr.CurSize )as GrowthAmt, GetDate() as MetricDate
from #TempDBSize2 tds
join DBGrowthRate dgr
on tds.database_ID = dgr.DBID
Where DBGrowthID = (Select Distinct Max(DBGrowthID) from DBGrowthRate
where DBID = dgr.DBID)
Group by tds.database_ID, tds.DBName,dgr.CurSize, dgr.OrigSize)
End

--Select *
--from DBGrowthRate
----Verifies values were entered

Drop table #TempDBSize2
Post #776982
Posted Tuesday, August 25, 2009 12:51 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Monday, April 7, 2014 11:39 AM
Points: 3, Visits: 46
...Here is the 2000 Version..of the code....

--PART 1
If exists (Select name from sysobjects where name = 'DBGrowthRate' and Type = 'U')
Drop Table dbo.DBGrowthRate

Create Table dbo.DBGrowthRate (DBGrowthID int identity(1,1), DBName varchar(100), DBID int,
NumPages int, OrigSize decimal(10,2), CurSize decimal(10,2), GrowthAmt decimal(10,2),
MetricDate datetime)

Select sd.name as DBName, mf.name as FileName, mf.dbid, fileid, size
into #TempDBSize
from master.dbo.sysdatabases sd
join master.dbo.sysaltfiles mf
on sd.dbid = mf.dbid
Order by mf.dbid, sd.name

Insert into dbo.DBGrowthRate (DBName, DBID, NumPages, OrigSize, CurSize, GrowthAmt, MetricDate)
(Select tds.DBName, tds.dbid, Sum(tds.Size) as NumPages,
Convert(decimal(10,2),(((Sum(Convert(decimal(10,2),tds.Size)) * 8000)/1024)/1024)) as OrigSize,
Convert(decimal(10,2),(((Sum(Convert(decimal(10,2),tds.Size)) * 8000)/1024)/1024)) as CurSize,
0 as GrowthAmt, GetDate() as MetricDate
from #TempDBSize tds
where tds.dbid not in (Select Distinct DBID from DBGrowthRate
where DBName = tds.dbid)
Group by tds.dbid, tds.DBName)

Drop table #TempDBSize

Select *
from DBGrowthRate
--Above creates initial table and checks initial data





--PART 2
--Below is the code run weekly to check the growth.
Select sd.name as DBName, mf.name as FileName, mf.dbid, fileid, size
into #TempDBSize2
from master.dbo.sysdatabases sd
join master.dbo.sysaltfiles mf
on sd.dbid = mf.dbid
Order by mf.dbid, sd.name

If Exists (Select Distinct DBName from #TempDBSize2
where DBName in (Select Distinct DBName from DBGrowthRate))
and GetDate() > (Select Distinct Max(MetricDate) as MetricDate from DBGrowthRate)
Begin
Insert into dbo.DBGrowthRate (DBName, DBID, NumPages, OrigSize, CurSize, GrowthAmt, MetricDate)
(Select tds.DBName, tds.dbid, Sum(tds.Size) as NumPages,
dgr.CurSize as OrigSize,
Convert(decimal(10,2),(((Sum(Convert(decimal(10,2),tds.Size)) * 8000)/1024)/1024)) as CurSize,
((Convert(decimal(10,2),(((Sum(Convert(decimal(10,2),tds.Size)) * 8000)/1024)/1024))) - dgr.CurSize )as GrowthAmt, GetDate() as MetricDate
from #TempDBSize2 tds
join DBGrowthRate dgr
on tds.dbid = dgr.DBID
Where DBGrowthID = (Select Distinct Max(DBGrowthID) from DBGrowthRate
where DBID = dgr.DBID)
Group by tds.dbid, tds.DBName,dgr.CurSize, dgr.OrigSize)
End

--Select *
--from DBGrowthRate
----Verifies values were entered

Drop table #TempDBSize2
Post #776998
Posted Friday, September 11, 2009 4:38 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Wednesday, September 22, 2010 11:32 AM
Points: 1, Visits: 25
I will let you know... thanks...
Post #786764
« Prev Topic | Next Topic »

Add to briefcase ««123»»

Permissions Expand / Collapse