sqlschool.gr logo

articles

Articles of SQLschool.gr Team

Estimate backup size for each database in a SQL Server instance (sp_EstimateAllDBBackupSize)

Antonios Chatzipavlis
Saturday 19 September 2015

Ένας DBA πρέπει να είναι σε θέση να γνωρίζει και να προβλέπει πολλά πράγματα κάθε μέρα.
Ένα από αυτά είναι να γνωρίζει το μέγεθος που χρειάζεται το backup των databases που έχει στο SQL Server instance του, ιδιαίτερα όταν αυτό είναι disk backup.

Γνωρίζοντας αυτό κάνει την ζωή του ευκολότερη καθώς ξέρει αν και που έχει τους χώρους που απαιτούνται.

Μεγαλύτερος «βραχνάς» είναι το full backup που όπως είναι φυσικό χρειάζεται και το περισσότερο χώρο.

Σαν DBA που καθημερινά διαχειρίζομαι πάνω από 270 instances και 3500 databases η ανάγκη μου να γνωρίζω και αυτό είναι σημαντική.

Για το λόγο αυτό είχα φτιάξει μια stored procedure με την οποία έκανα την δουλειά μου.

Σήμερα την χρειάστηκα ξανά και τις έκανα μερικές αλλαγές και αποφάσισα να την δημοσιεύσω καθώς έχω διαπιστώσει ότι σας αρέσουν αυτά τα μικρά καλούδια.

Ο κώδικας της stored procedure είναι ο παρακάτω και το μόνο που χρειάζεται να κάνετε είναι copy και paste σε ένα query window στο SSMS και να το εκτελέσετε.

Δημιουργεί την stored procedure στην master database για την εκτέλεση της απλά γράφεται το όνομα της σε ένα query window
use master
go

if not exists (select * from information_schema.routines where routine_name = 'sp_EstimateAllDBBackupSize')
    exec ('create proc dbo.sp_EstimateAllDBBackupSize as select ''stub version, to be replaced''')
go



alter proc sp_EstimateAllDBBackupSize
as
/*********************************************************************************************
sp_EstimateAllDBBackupSize (c) 2015 SQLschool.gr - Antonios Chatzipavlis

Version History
1.00    Sep 19, 2015

Feedback: mailto:info@sqlschool.gr

License: 
    sp_EstimateAllDBBackupSize is free to download and use for personal, educational, 
    and internal corporate purposes, provided that this header is preserved. 
*********************************************************************************************/
begin
    set nocount on;

    declare @dbname sysname;
    declare @query nvarchar(1000);
    declare @stm nvarchar(1000);

    set @query = 'use [?]
    insert into #backupsize
    select      db_name() 
            , convert(decimal(15,2), sum(size) * 8192 / 1048576) 
            , convert(decimal(15,2), sum(fileproperty(name,''spaceused'')) * 8192 / 1048576) 
    from sys.database_files;'

    if ( object_id('tempdb..#backupsize') is not null )
    begin
        drop table #backupsize;
    end    

    create table  #backupsize
    (
        database_name sysname
    ,    total_db_size_mb decimal(15, 2)
    ,    estimated_backup_size_mb decimal(15, 2)
    );
    
    declare dblist cursor local fast_forward for 
            select name from sys.databases order by name;

    open dblist;

    fetch next from dblist into @dbname;
    while (@@fetch_status <> -1)
    begin
        if (@@fetch_status <> -2)
        begin
            set @stm =replace(@query,'?',@dbname);
            execute(@stm);
        end
        fetch next from dblist into @dbname;
    end

    close dblist;
    deallocate dblist;

    select * from #backupsize;
end
go
Enjoy
/*antonch*/

Antonios Chatzipavlis

Antonios Chatzipavlis

Antonios is a Data Solutions Consultant and Trainer. He has been working in IT since 1988. In his career, he has worked as senior developer, IT Manager, Solutions Architect and IT Consultant. Since 1995 he has been devoted on new technologies and software development tools, mainly by Microsoft, either by training company staff and colleagues or assisting them in design, development and implementation as a consultant or chief developer. He has focused in Databases and Data Science since 1995. He specialized in Microsoft SQL Server since version 6.0 in areas like SQL Server Internals, Database Design and Development, Business Intelligence and in 2010 he has started working with Azure Data Platform, NoSQL databases, Big Data Technologies and Machine Learning. He is an active member of many IT communities in Greece, answering colleagues' questions and writing articles in his web site. He is the owner of SQLschool.gr which is a community portal with a lot of information about Microsoft SQL Server. He has been a Microsoft Certified Trainer (MCT) since 2000. Microsoft honored him as MVP on Data Platform due to his activities in SQL Server since 2010. He holds a large number of Microsoft Certifications and Microsoft SQL Server Certifications since version 6.5.

Tip

What's New in SQL Server 2022 - Episodes

More Tips...

Become a member

If you want to receive updates from us become a member to our community.

Connect

Explore

Learn


sqlschool.gr © 2010-2024 All rights reserved

This site uses cookies for operational and analytics purposes only. By continuing to browse this site, you agree to their use.