SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Initial size of the database file using T-SQL


Initial size of the database file using T-SQL

Author
Message
karthik.catchme
karthik.catchme
SSC-Enthusiastic
SSC-Enthusiastic (176 reputation)SSC-Enthusiastic (176 reputation)SSC-Enthusiastic (176 reputation)SSC-Enthusiastic (176 reputation)SSC-Enthusiastic (176 reputation)SSC-Enthusiastic (176 reputation)SSC-Enthusiastic (176 reputation)SSC-Enthusiastic (176 reputation)

Group: General Forum Members
Points: 176 Visits: 389
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
Jason-299789
Jason-299789
SSCarpal Tunnel
SSCarpal Tunnel (5K reputation)SSCarpal Tunnel (5K reputation)SSCarpal Tunnel (5K reputation)SSCarpal Tunnel (5K reputation)SSCarpal Tunnel (5K reputation)SSCarpal Tunnel (5K reputation)SSCarpal Tunnel (5K reputation)SSCarpal Tunnel (5K reputation)

Group: General Forum Members
Points: 4993 Visits: 3232
I don't believe that the original size is stored anywhere only the current size.

_________________________________________________________________________
SSC Guide to Posting and Best Practices
Cadavre
Cadavre
SSCrazy Eights
SSCrazy Eights (9.1K reputation)SSCrazy Eights (9.1K reputation)SSCrazy Eights (9.1K reputation)SSCrazy Eights (9.1K reputation)SSCrazy Eights (9.1K reputation)SSCrazy Eights (9.1K reputation)SSCrazy Eights (9.1K reputation)SSCrazy Eights (9.1K reputation)

Group: General Forum Members
Points: 9082 Visits: 8492
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
karthik.catchme
karthik.catchme
SSC-Enthusiastic
SSC-Enthusiastic (176 reputation)SSC-Enthusiastic (176 reputation)SSC-Enthusiastic (176 reputation)SSC-Enthusiastic (176 reputation)SSC-Enthusiastic (176 reputation)SSC-Enthusiastic (176 reputation)SSC-Enthusiastic (176 reputation)SSC-Enthusiastic (176 reputation)

Group: General Forum Members
Points: 176 Visits: 389
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.

Rob.Simpson
Rob.Simpson
Grasshopper
Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)Grasshopper (12 reputation)

Group: General Forum Members
Points: 12 Visits: 12
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;


Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search