• muhammadrazzaqpk-1032285 (12/8/2011)


    Thanks - I have given it every try - As you know I am not good at all with powershell scripting but it will be helpful for me if a working script where I have to just change name of my server and query.

    Perhaps if you take my script and I am sure you will be able to reproduce the error.

    I really do appreciate your time.

    Hi

    Run this script. It should create a SQL Agent job that when run will run your query across all SQL Servers that are registered in your CMS. The results will be saved to a text file on your E drive which you can load into a database using SSIS or some other method.

    USE [msdb]

    GO

    /****** Object: Job [Last Successful Backup] Script Date: 12/8/2011 1:02:48 PM ******/

    BEGIN TRANSACTION

    DECLARE @ReturnCode INT

    SELECT @ReturnCode = 0

    /****** Object: JobCategory [[Uncategorized (Local)]]] Script Date: 12/8/2011 1:02:48 PM ******/

    IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'[Uncategorized (Local)]' AND category_class=1)

    BEGIN

    EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'[Uncategorized (Local)]'

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

    END

    DECLARE @jobId BINARY(16)

    EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'Last Successful Backup',

    @enabled=1,

    @notify_level_eventlog=0,

    @notify_level_email=0,

    @notify_level_netsend=0,

    @notify_level_page=0,

    @delete_level=0,

    @description=N'No description available.',

    @category_name=N'[Uncategorized (Local)]',

    @owner_login_name=N'sa', @job_id = @jobId OUTPUT

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

    /****** Object: Step [PowerShell] Script Date: 12/8/2011 1:02:48 PM ******/

    EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'PowerShell',

    @step_id=1,

    @cmdexec_success_code=0,

    @on_success_action=1,

    @on_success_step_id=0,

    @on_fail_action=2,

    @on_fail_step_id=0,

    @retry_attempts=0,

    @retry_interval=0,

    @os_run_priority=0, @subsystem=N'PowerShell',

    @command=N'$instanceNameList = invoke-Sqlcmd -query "

    SELECT [server_name] as Name

    FROM [msdb].[dbo].[sysmanagement_shared_registered_servers_internal] SSRSI

    join [msdb].[dbo].[sysmanagement_shared_server_groups_internal] SSSGI

    on SSRSI.server_group_id = SSSGI.server_group_id

    " -serverinstance "myserver\dba"

    $results = @()

    foreach($instanceName in $instanceNameList)

    {$results += Invoke-Sqlcmd -Query "

    SELECT a.name, b.type, MAX(b.backup_finish_date) LastSuccessfulBackup,

    CAST((GETDATE() - MAX(b.backup_finish_date)) AS NUMERIC(5, 2)) IntervalInDays

    FROM master..sysdatabases a

    LEFT OUTER JOIN msdb..backupset b ON a.name = b.database_name

    where b.type=''D''

    GROUP BY a.name, b.type

    ORDER BY a.name, b.type

    " -ServerInstance $instanceName.Name}

    $results| Where-Object {$_} | Export-Csv E:\Backup_log -NoTypeInformation',

    @database_name=N'master',

    @flags=0

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

    EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1

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

    EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)'

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

    COMMIT TRANSACTION

    GOTO EndSave

    QuitWithRollback:

    IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION

    EndSave:

    GO