sqlschool.gr logo

articles

Articles of SQLschool.gr Team

Databases Restore History Report

Antonios Chatzipavlis
Saturday 06 August 2016

Ένας DBA καθημερινά έχει πολλά πράγματα να κάνει και πολλές ερωτήσεις να απαντήσει. Πολλές φορές αυτό που θέλει να κάνει ή να απαντήσει δεν γίνεται με το πάτημα ενός κουμπιού.
Μια ερώτηση που μου τέθηκε χθες ήταν να δω το πότε έχει γίνει restore μια database σε ένα instance.

Η απάντηση εύκολα βγαίνει από το restorehistory table που υπάρχει στην msdb database αλλά πάντα θέλεις να έχεις περισσότερες πληροφορίες που αυτός δεν περιέχει. Έτσι έφτιαξα το παρακάτω query μπορεί να απαντήσει στις ερωτήσεις τους κάθε ένα σχετικά με το πότε έχουν γίνει restores και σε ποιες databases στο συγκεκριμένο instance.

select 
        h.destination_database_name as destination_database_name
,       h.restore_date as date_of_restore
,        b.database_name as source_database_name
,        b.server_name as source_server_name
,        case h.restore_type
            when 'D' then 'Database'
            when 'F' then 'File'
            when 'G' then 'Filegroup'
            when 'I' then 'Differential'
            when 'L' then 'Log'
            when 'V' then 'Verifyonly'
            when 'R' then 'Revert'
            else  h.restore_type
        end as restore_type
,       h.user_name as restored_by_user          
,       h.device_count 
,        b.name as backup_name    
,       b.description as backup_description
,        cast ((select    
                      m.family_sequence_number as device_seqnum
                    ,m.physical_device_name as device_name
                    ,case device_type
                        when 2 then 'DISK'
                        when 5 then 'TAPE'
                        when 7 then 'VIRTUAL'
                        when 105 then 'PERMANENT'
                        else cast (device_type as nvarchar)
                    end as device_type
                from msdb.dbo.backupmediafamily as m
                where m.media_set_id = b.backup_set_id
                for xml raw ('restoredevice'),root('restoredevices')) 
                as xml) as restored_device_info
,        cast ((select 
                     file_number
                    ,destination_phys_name
                    ,filegroup_name 
                from msdb.dbo.restorefile as rf
                    inner join msdb.dbo.restorefilegroup as rg on rf.restore_history_id = rg.restore_history_id
                where rf.restore_history_id=h.restore_history_id
                for xml raw ('restoredfile'),root('restorefiles')) 
                as xml) as restored_files
from msdb.dbo.restorehistory as h
    inner join msdb.dbo.backupset as b on h.backup_set_id = b.backup_set_id
order by restore_date desc

Antonios Chatzipavlis

Antonios Chatzipavlis

Antonios Chatzipavlis is a highly experienced Data Solutions Consultant and Trainer. He has been working in the IT industry since 1988, holding various roles such as senior developer, IT Manager, Data & AI Solutions Architect and Consultant.

Since 1995, Antonios has focused on modern technologies and software development tools, primarily by Microsoft. He has specialized in Data & AI since 2000, with expertise in Microsoft Data Platform (SQL Server, Azure SQL Databases, Azure Synapse Analytics, Microsoft Fabric, Power BI, AI) and Databricks.

Antonios is also a Microsoft Certified Trainer (MCT) for over 25 years, has been recognized as a Microsoft Most Valuable Professional (MVP) in Data Platform since 2010 and he is in the Data Expert 40 Powerlist 2024 by Boussias. He is the co-founder and visionary behind XLYTiCA, a company dedicated to Data & AI solutions.

Episode

Task Flows in Microsoft Fabric

image

More Episodes...

Tip

Get Certified: Become a Fabric Data Engineer

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-2025 All rights reserved

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