Initial size of the database file using T-SQL

  • 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

  • I don't believe that the original size is stored anywhere only the current size.

    _________________________________________________________________________
    SSC Guide to Posting and Best Practices

  • 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
    My blog - http://www.cadavre.co.uk/
    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/

  • 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.

  • 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;

  • @rob.Simpson, Thank you for your awesome script.

    A few thoughts for improvement:

    1. The [InitialSizeMB] field seems to be "KB", instead of MB.
    (e.g. the [master] database has a value of 4096. It should be ~4 Megabytes, not ~4 GB)

    2. I ran into errors being thrown by the "dbcc page" command on my database.
    So, to correct this, I added a "Begin Try" and "End Try" around the "insert statement".
    Followed by an immediate empty "Begin Catch" and "End Catch" block.

    3. To suppress the "DBCC completed" messages, just add: ", NO_INFOMSGS" to the "dbcc page" command.

    4. At the top of the query, add "SET NOCOUNT ON" otherwise it will produce a lot of row counts which could be misleading.

    Other than that, thank you for a wonderful script!

Viewing 6 posts - 1 through 5 (of 5 total)

You must be logged in to reply to this topic. Login to reply