Technical Article

NEW and DELETED Database REPORT

,

A Procedure build Report about NEW and Deleted DB.
First time you must to run p_build_check_db.
This procedure build table  master..t_databases same as
master..sysdatabases .
Procedure  p_check_db compare t_databases and sysdatabases and send a report to your@E-MailAddress.

Best regards. Vadim.  

/******************************************************************************************** 
**Name: p_build_check_db.
**Desc: NEW and DELETED Database Report per Server (Part 1). 
** 
**      Location : MSDB
**Called by: 
**            execute p_build_check_db 
**              
**Input:          Output: table master..t_databases
**      -----------------------------------------------------
**Author : Mushkatin Vadim.Israel. E-Mail: Vadimm@bezeq.com  
**Created: 25/2/2002. 
********************************************************************************************/set quoted_identifier off
go

Create  proc  p_build_check_db as 
 
If object_id('master..t_databases') is not null 
     DROP  TABLE master..t_databases
CREATE TABLE master..t_databases
        (
 
        dbname             varchar(50)     not null 
                   CONSTRAINT dbname PRIMARY KEY ,
create_date        varchar(25)     not null,
filenames          varchar(200)    not null, 
last_updated       varchar(25)     not null,  

  )

set nocount on 
declare    @dbname   varchar(50),
            @filename varchar(200),
            @crdate   varchar(25) 
declare c cursor for 
select name,crdate,filename 
        from master..sysdatabases 
--where  name  not in ('Northwind','pubs','tempdb','master','model','msdb')

open c 
fetch next from c 
      into @dbname,@crdate,@filename 
while @@fetch_status = 0 
begin 
       insert master..t_databases (dbname,create_date,filenames,last_updated)
              values (@dbname,@crdate,@filename,getdate())

        fetch next from c 
              into @dbname,@crdate,@filename 
end 
close c 
deallocate c
GO

Exec p_build_check_db     --Must be run first time before running a job.
Go
 
/******************************************************************************************** 
**Name: p_check_db.
**Desc: NEW and DELETED Database report per Server (Part 2). 
**
**      Location : MSDB 
**Called by: 
**            execute p_check_db 
**              
**Input:          Output: E-Mail
**      -----------------------------------------------------
**Author : Mushkatin Vadim.Israel. E-Mail: Vadimm@bezeq.com
**Created: 25/2/2002. 
********************************************************************************************/set quoted_identifier off
go

Create  proc  p_check_db as 
 
declare    @newdb_count   int,
            @deldb_count   int,
            @newdb_subject varchar(50),
            @deldb_subject varchar(50)    

set @newdb_subject = @@servername + ' NEW DB '
set @deldb_subject = @@servername + ' DELETED DB '

select @newdb_count = count(*) 
from master..sysdatabases 
where  name  not in 
   (select dbname 
    from master..t_databases) 

if @newdb_count > 0
begin
   set quoted_identifier   off
   SET ANSI_NULLS    ON
   SET ANSI_WARNINGS    ON

   Exec master..xp_sendmail  @recipients ='Your@E-MailAddress',
--       @query = 'select substring(name,1,25) as dbname,crdate,filename 
         @query = 'select substring(name,1,25) as dbname,crdate   
                  from master..sysdatabases 
                  where name  not in 
                    (select dbname 
                     from master..t_databases)', 
        @subject = @newdb_subject ,
        @message = 'The output of p_check_db:',
        @attach_results = 'TRUE', @width = 250
end

select @deldb_count = count(*) 
from master..t_databases 
where  dbname  not in 
   (select name 
    from master..sysdatabases) 

if @deldb_count > 0
begin
   set quoted_identifier   off
   SET ANSI_NULLS    ON
   SET ANSI_WARNINGS    ON

   Exec master..xp_sendmail   @recipients ='Your@E-MailAddress',
        @query = 'select dbname,create_date,filenames  
                  from master..t_databases 
                  where dbname  not in 
                    (select name 
                     from master..sysdatabases)', 
        @subject = @deldb_subject ,
        @message = 'The output of p_check_db:',
        @attach_results = 'TRUE', @width = 250
end
Go

--*** J O B ***---

BEGIN TRANSACTION            
  DECLARE @JobID BINARY(16)  
  DECLARE @ReturnCode INT    
  SELECT @ReturnCode = 0     
IF (SELECT COUNT(*) FROM msdb.dbo.syscategories WHERE name = N'[Uncategorized (Local)]') < 1 
  EXECUTE msdb.dbo.sp_add_category @name = N'[Uncategorized (Local)]'

  -- Delete the job with the same name (if it exists)
  SELECT @JobID = job_id     
  FROM   msdb.dbo.sysjobs    
  WHERE (name = N'send_newdb_report')       
  IF (@JobID IS NOT NULL)    
  BEGIN  
  -- Check if the job is a multi-server job  
  IF (EXISTS (SELECT  * 
              FROM    msdb.dbo.sysjobservers 
              WHERE   (job_id = @JobID) AND (server_id <> 0))) 
  BEGIN 
    -- There is, so abort the script 
    RAISERROR (N'Unable to import job ''send_newdb_report'' since there is already a multi-server job with this name.', 16, 1) 
    GOTO QuitWithRollback  
  END 
  ELSE 
    -- Delete the [local] job 
    EXECUTE msdb.dbo.sp_delete_job @job_name = N'send_newdb_report' 
    SELECT @JobID = NULL
  END 

BEGIN 

  -- Add the job
  EXECUTE @ReturnCode = msdb.dbo.sp_add_job @job_id = @JobID OUTPUT , @job_name = N'send_newdb_report', @owner_login_name = N'sa', @description = N'No description available.', @category_name = N'[Uncategorized (Local)]', @enabled = 1, @notify_level_email = 0, @notify_level_page = 0, @notify_level_netsend = 2, @notify_level_eventlog = 2, @delete_level= 0
  IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback 

  -- Add the job steps
  EXECUTE @ReturnCode = msdb.dbo.sp_add_jobstep @job_id = @JobID, @step_id = 1, @step_name = N'Report', @command = N'exec p_check_db', @database_name = N'msdb', @server = N'', @database_user_name = N'', @subsystem = N'TSQL', @cmdexec_success_code = 0, @flags = 0, @retry_attempts = 0, @retry_interval = 1, @output_file_name = N'', @on_success_step_id = 0, @on_success_action = 3, @on_fail_step_id = 0, @on_fail_action = 2
  IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback 
  EXECUTE @ReturnCode = msdb.dbo.sp_add_jobstep @job_id = @JobID, @step_id = 2, @step_name = N'Build', @command = N'exec p_build_check_db', @database_name = N'msdb', @server = N'', @database_user_name = N'', @subsystem = N'TSQL', @cmdexec_success_code = 0, @flags = 0, @retry_attempts = 0, @retry_interval = 1, @output_file_name = N'', @on_success_step_id = 0, @on_success_action = 1, @on_fail_step_id = 0, @on_fail_action = 2
  IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback 
  EXECUTE @ReturnCode = msdb.dbo.sp_update_job @job_id = @JobID, @start_step_id = 1 

  IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback 

  -- Add the job schedules
  EXECUTE @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id = @JobID, @name = N'ReportDB_schedule', @enabled = 1, @freq_type = 4, @active_start_date = 20020116, @active_start_time = 0, @freq_interval = 1, @freq_subday_type = 1, @freq_subday_interval = 0, @freq_relative_interval = 0, @freq_recurrence_factor = 0, @active_end_date = 99991231, @active_end_time = 235959
  IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback 

  -- Add the Target Servers
  EXECUTE @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @JobID, @server_name = N'(local)' 
  IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback 

END
COMMIT TRANSACTION          
GOTO   EndSave              
QuitWithRollback:
  IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION 
EndSave:

Rate

You rated this post out of 5. Change rating

Share

Share

Rate

You rated this post out of 5. Change rating