Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Initial size of the database file using T-SQL Expand / Collapse
Author
Message
Posted Tuesday, April 9, 2013 11:19 PM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Tuesday, January 5, 2016 1:05 PM
Points: 22, Visits: 384
Hi,

Please let me know how to get the initial size of the database file using T-SQL.

sys.master_files, sys.database_files, sysfiles, sysaltfiles --> gives only the current size and not the initial size.


Thanks,
Karthik R
Post #1440652
Posted Wednesday, April 10, 2013 2:05 AM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: Today @ 7:15 AM
Points: 1,075, Visits: 3,218
I don't believe that the original size is stored anywhere only the current size.

_________________________________________________________________________
SSC Guide to Posting and Best Practices
Post #1440690
Posted Wednesday, April 10, 2013 2:14 AM


SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: 2 days ago @ 4:14 AM
Points: 2,491, Visits: 8,362
karthik.catchme (4/9/2013)
Hi,

Please let me know how to get the initial size of the database file using T-SQL.

sys.master_files, sys.database_files, sysfiles, sysaltfiles --> gives only the current size and not the initial size.


Thanks,
Karthik R


IIRC, the size that you initially gave to the database file is not stored anywhere. I think that the "initial size" that you can see when you right click a database in the GUI then click properties and then click files is in fact the current size.

Execute the following: -
SELECT db.name AS [Logical Name],
CASE WHEN db.[type] = 0 THEN 'Rows Data'
ELSE 'Log' END AS [File Type],
(db.size*8)/1024 AS initialSize
FROM sys.database_files db

And I think that you'll see that the "initial size" reported by the query matches the "initial size" in the GUI.



Forever trying to learn

For better, quicker answers on T-SQL questions, click on the following...
http://www.sqlservercentral.com/articles/Best+Practices/61537/

For better, quicker answers on SQL Server performance related questions, click on the following...
http://www.sqlservercentral.com/articles/SQLServerCentral/66909/



If you litter your database queries with nolock query hints, are you aware of the side effects?
Try reading a few of these links...

(*) Missing rows with nolock
(*) Allocation order scans with nolock
(*) Consistency issues with nolock
(*) Transient Corruption Errors in SQL Server error log caused by nolock
(*) Dirty reads, read errors, reading rows twice and missing rows with nolock


Craig Wilkinson - Software Engineer
LinkedIn
Post #1440693
Posted Wednesday, April 10, 2013 8:26 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Tuesday, January 5, 2016 1:05 PM
Points: 22, Visits: 384
Books online states that shrinkdatabase cannot shrink smaller than its original size. So, how does SQL Server know the initial size / original size of the database without saving it in any of the system tables?

When using the DBCC SHRINKDATABASE statement, you cannot shrink a whole database to be smaller than its original size. Therefore, if a database was created with a size of 10 MB and grew to 100 MB, the smallest the database could be reduced to is 10 MB, even if all the data in the database has been deleted.
Post #1440840
Posted Tuesday, October 6, 2015 4:41 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Wednesday, October 7, 2015 8:22 AM
Points: 1, Visits: 3
karthik.catchme (4/9/2013)
Hi,
Please let me know how to get the initial size of the database file using T-SQL.
sys.master_files, sys.database_files, sysfiles, sysaltfiles --> gives only the current size and not the initial size.


2½ year old thread, but I couldn't find the answer anywhere. This is what I came up with:

declare @Page0Dump table ([ParentObject] [nvarchar](4000), [Object] [nvarchar](4000), [Field] [nvarchar](4000), [VALUE] [nvarchar](4000));
insert into @Page0Dump execute sp_executesql N'dbcc page (N''msdb'', 1, 0, 3) with tableresults;';
select pd.[VALUE] * 8 [Initial Size (MB)] from @Page0Dump pd where pd.[Field] = N'MinSize';

That returns the initial size of the "msdb" database data file. Change the first two parameters ("msdb" and "1" above) to the database name and a file_id of a file in that database, respectively. The file_ids for a database can be found with:

select db_name(mf.[database_id]) [DatabaseName], mf.[file_id], mf.[name]
from [sys].[master_files] mf where mf.[database_id] = db_id(N'msdb') order by mf.[name] asc;

Or use variables with those values:

declare @fs [int],
@databaseName [sysname],
@fileName [sysname],
@fileId [int],
@initialSize [int];
declare @Page0Dump table ([ParentObject] [nvarchar](4000), [Object] [nvarchar](4000), [Field] [nvarchar](4000), [VALUE] [nvarchar](4000));
declare @FileInitialSizes table ([DatabaseName] [sysname], [FileId] [int], [FileName] [sysname], [InitialSizeMB] [int]);
declare mfs cursor for
select db_name(mf.[database_id]), mf.[file_id], mf.[name]
from [sys].[master_files] mf
order by mf.[name] asc;
open mfs;
while 1 = 1 begin
fetch next from mfs into @databaseName, @fileId, @fileName;
set @fs = @@fetch_status;
if @@fetch_status != 0 break;
delete from @Page0Dump;
insert into @Page0Dump execute sp_executesql N'dbcc page (@databaseName, @fileId, 0, 3) with tableresults;', N'@databaseName [sysname], @fileId [int]', @databaseName = @databaseName, @fileId = @fileId;
select @initialSize = pd.[VALUE] * 8 from @Page0Dump pd where pd.[Field] = N'MinSize';
insert into @FileInitialSizes values(@databaseName, @fileId, @fileName, @initialSize);
end;
close mfs;
deallocate mfs;
select * from @FileInitialSizes fis order by fis.[DatabaseName] asc, fis.[FileId] asc;

Post #1726025
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse