-- Copyright 2008 Maurice Pelchat -- YourSQLDba : Auto-maintenance tools for SQL Server Databases -- Author : Maurice Pelchat -- GitHub Website Readme : https://github.com/pelsql/YourSqlDba/blob/master/README.md -- Online Documentation : https://tinyurl.com/YourSqlDba -- Latest release of YourSqlDba : https://github.com/pelsql/YourSqlDba/blob/master/YourSQLDba_InstallOrUpdateScript.sql?raw=true -- First install? Easy setup to make YourSqlDba run with SQL Agent and Database Mail https://tinyurl.com/YSDInitSetup Drop Table if Exists #version create table #Version (version nvarchar(40), VersionDate datetime) set nocount on insert into #Version Values ('6.8.0.2', convert(datetime, '2022-05-01', 120)) --Alter database yoursqldba set single_user with rollback immediate --go --Alter database yoursqldba set multi_user --go --use tempdb --go --RESTORE DATABASE [YourSQLDba] FROM DISK = N'C:\Users\pelchat\Desktop\YourSQLDba_[2012-09-13_01h44m26_Jeu]_database.Bak' WITH FILE = 1, MOVE N'YourSQLDba' TO N'C:\isql2008r2\DBData\YourSQLDba.MDF', MOVE N'YourSQLDbaDb_Log' TO N'C:\isql2008r2\DBLogs\YourSQLDba_Log.LDF', NOUNLOAD, STATS = 10 --GO declare @sql nvarchar(max); set @sql = ' ------------------------------------------------------------------------------------ YourSQLDba : Auto-maintenance tools for SQL Server Databases Author : Maurice Pelchat Contributors : Danielle Paquette-Harvey, Pierre-Luc Denommé, Dominic Perreault Licence : LGPL http://www.opensource.org/licenses/lgpl-2.1.php See point 15. of the licence described to the link above about warranty. ------------------------------------------------------------------------------------ YourSQLDba : Outils de maintenance de bases de données pour SQL Server Auteur : Maurice Pelchat Contributeurs : Danielle Paquette-Harvey, Pierre-Luc Denommé, Dominic Perreault License : LGPL http://www.opensource.org/licenses/lgpl-2.1.php Voir point 15. de la licence décrite au lien ci-dessus concernant la garantie. ------------------------------------------------------------------------------------ ' set @sql = replace(@sql, '"', '''') print @sql -- If YourSqlDba.Do_Maint is actually running wait until it ends, and prevent it -- to run until this script is done. We don't want to break running code -- when replacing SQL Modules with new versions Use tempdb If DB_ID('YourSqlDba') IS NOT NULL Begin set nocount on Set @Sql = N' Use YourSqlDba declare @cnt int =1 While (1=1) Begin If APPLOCK_TEST ("public", "YourSqlDba.Do_Maint", "Exclusive", "Session")=1 Break Raiserror ("Waiting for YourSqlDba.Do_maint to terminate...", 0, 1) with nowait Select "Check messages for more info: Waiting for YourSqlDba.Do_maint to terminate..., " Waitfor Delay "00:00:01" -- wait a sec, some msg are out End ' Set @Sql=replace(@sql collate database_default,'"','''') Exec (@Sql) End Use tempdb -- -- Installation procedure -- -- Step 1 : Simply launch this script, it install YourSQLDba database and objects requiered for maintenance -- Step 2 : ON FIRST INSTALL ONLY, run YourSQLDba_SetupOf_SqlAgent_MaintenanceJobs_DatabaseMail. -- This script setup SQLAgent Tasks, Database Mail -- using supplied parameters. -- Example for it is supplied at the end of this script. -- First two parameters are backups directories for log and for complete database backups -- Thrid parameter is email of the database admin or other operator -- Forth parameter is the address or name of a mail server that will -- accept anonymous smtp from your sql server (from database mail). -- -- Upgrades : Just rerun the new version of the script as described in Step 1 only -- -- Customizations are possible int the SQL Agent Job generated by the setup. -- Maintenance parameters are customizable at the job step level. -- Once defined, more steps can be added to the job with different parameters for different databases sets -- More steps can be added for operating systems commands especially to move backups files -- -- ===================================================================================================== -- ***************************************************************************************************** -- FOR CONTRIBUTORS -- -- You can send your comments and/or source code to pelsql@hotmail.com -- -- Any upgrades must take into account that the script must finds itself the state of the current -- installed version and bring it to the latest version (the actual script). -- -- Samples of this process are kept from previous version as if it ever existed -- but because of translation to identifiers in english, this version never really existed. -- -- However the method proove to be 100% successful with the previous french version. -- Many users of the original version upgraded their solution without problem and from any previous version -- -- It helped very much in making the project easy to upgrade, as it is always the same : -- re-run the latest script to upgrade to the last version. -- -- ***************************************************************************************************** -- For users of previous version set new solution to 'YourSQLDba' database declare @msg nvarchar(max) = NULL ;With Coll(name) as (select convert(sysname, SERVERPROPERTY('Collation'))) select @Msg = 'YourSqlDba doesn''t supported servers with case sensitive or binary collations ' From Coll Where name Like '%[_]CS[_]%' Or name Like '%[_]BIN' if @msg IS NOT NULL Raiserror (@Msg, 25,1) WITH LOG GO If not exists ( select * from sys.configurations Where name = 'show advanced options' And value_in_use = 1 ) Begin EXEC sp_configure 'show advanced options', 1 Reconfigure End GO If not exists ( select * from sys.configurations Where name = 'allow updates' And value_in_use = 0 ) Begin EXEC sp_configure 'allow updates', 0 Reconfigure End GO If not exists ( select * from sys.configurations Where name = 'clr enabled' And value_in_use = 1 ) Begin Exec sp_configure 'clr enabled', 1 End GO If not exists ( select * from sys.configurations Where name = 'Agent XPs' And value_in_use = 1 ) Begin EXEC sp_configure 'Agent XPs', 1 Reconfigure with override End GO -- Adjust SQL Server error logs archive to maximum of 30 Set nocount On EXEC xp_instance_regwrite N'HKEY_LOCAL_MACHINE', N'Software\Microsoft\MSSQLServer\MSSQLServer', N'NumErrorLogs', REG_DWORD, 30 GO -- If Sql Service Broker in not enabled on MSDB, enable it if exists(select name, is_broker_enabled from sys.databases where name = 'msdb' and is_broker_enabled = 0) begin print 'Sql Service broker activation in MSDB' exec('alter database msdb set enable_broker with ROLLBACK IMMEDIATE') end -- else -- print 'Broker already enabled on MSDB' GO If Db_name() <> 'TempDb' Use TempDb; GO -- **************************************************************************************************** -- Save actual copy of YourSqlDba, in case a rollback is needed or past yoursqldba logs would be useful -- **************************************************************************************************** If databasepropertyEx('YourSQLDba','status') IS NOT NULL -- db is there Begin -- save data about some YourSqlDba tables Drop table if Exists ##JobHistory; Drop table if Exists ##JobHistoryDetails; Drop Table if Exists ##JobHistoryLineDetails; -- instead of presenting event info in XML, it is presented in readable form Drop table if Exists ##JobLastBkpLocations; Drop table if Exists ##TargetServer; Drop table if Exists ##JobSeqUpdStat; Drop table if Exists ##NetworkDrivesToSetOnStartup; -- If table exists in previous version save its content If Object_id('YourSqlDba.Maint.JobHistory') IS NOT NULL Begin Declare @JsonPrms Int, @colId Int Exec sp_executeSql N'Use YourSqlDba; Set @colId=Columnproperty(Object_id(''YourSqlDba.Maint.JobHistory''), ''JSonPrms'', ''ColumnId'')' , N'@colId Int Output' , @ColId Output If @Colid IS NOT NULL Exec('Select * Into ##JobHistory From YourSqlDba.Maint.JobHistory') Else Begin Exec( -- JsonPrms column is missing, brew the new version of the table with just JobNo, JsonPrm ' Select JobNo , JobStart , JobEnd , Spid , JsonPrms= ( Select , JobName , DoInteg, DoUpdStats, DoReorg, DoFullBkp, DoDiffBkp, DoLogBkp, JobName, JobStart, JobEnd , IncDb, ExcDb, ExcDbFromPolicy_CheckFullRecoveryModel , TimeStampNamingForBackups, FullBkpRetDays, LogBkpRetDays , NotifyMandatoryFullDbBkpBeforeLogBkp , SpreadUpdStatRun, SpreadCheckDb , FullBackupPath, LogBackupPath, , FullBkExt, LogBkExt, , ConsecutiveDaysOfFailedBackupsToPutDbOffline , MirrorServer , MigrationTestMode , ReplaceSrcBkpPathToMatchingMirrorPath , ReplacePathsInDbFilenames , JobId, StepId , BkpLogsOnSameFile , EncryptionAlgorithm, EncryptionCertificate From YourSqlDba.Maint.JobHistory For JSON PATH, WITHOUT_ARRAY_WRAPPER ) Into ##JobHistory From YourSqlDba.Maint.JobHistory ' ) End End If Object_id('YourSqlDba.Maint.JobHistoryDetails') IS NOT NULL Select * Into ##JobHistoryDetails From YourSqlDba.Maint.JobHistoryDetails If Object_id('YourSqlDba.Maint.JobHistoryLineDetails') IS NOT NULL Select * Into ##JobHistoryLineDetails From YourSqlDba.Maint.JobHistoryLineDetails If Object_id('YourSqlDba.Maint.JobLastBkpLocations') IS NOT NULL Select * Into ##JobLastBkpLocations From YourSqlDba.Maint.JobLastBkpLocations If Object_id('YourSqlDba.Mirroring.TargetServer') IS NOT NULL Select * Into ##TargetServer From YourSqlDba.Mirroring.TargetServer If Object_id('YourSqlDba.Maint.JobSeqUpdStat') IS NOT NULL Select top 1 * Into ##JobSeqUpdStat From YourSqlDba.Maint.JobSeqUpdStat If Object_id('YourSqlDba.Maint.NetworkDrivesToSetOnStartup') Is NOT NULL Select * Into ##NetworkDrivesToSetOnStartup From YourSqlDba.Maint.NetworkDrivesToSetOnStartup -- if database is not upgraded yet do a save, but avoid if it is to the same version If Not Exists(Select * from YourSqlDba.Install.VersionInfo () Actual join #Version NextVersion On Actual.VersionNumber = NextVersion.Version Collate database_default) Begin Declare @pathBkp Nvarchar(512); Exec master.dbo.xp_instance_regread N'HKEY_LOCAL_MACHINE' , N'Software\Microsoft\MSSQLServer\MSSQLServer' , N'BackupDirectory' , @pathBkp OUTPUT , 'no_output' -- SAVING A BACKUP COPY OF YOURSQLDBA, BEFORE WIPING IT AND RECRATING IT -- Don't use SaveDbOnNewFileSet but use "lighter" code to reduce code dependencies Declare @Language nvarchar(512) Exec YourSqlDba.yInstall.InstallationLanguage @language Output If RIGHT(@pathBkp, 1) <> '\' Set @pathBkp = @pathBkp + '\' Declare @bkpFile nvarchar(512) Select @bkpFile = @pathBkp+'YourSqlDba_'+REPLACE(CONVERT(nvarchar, Getdate(), 120), ':', '_')+'.bak'; Declare @version nvarchar(10) Select @version = VersionNumber From YourSqlDba.Install.VersionInfo () print '******************************************************************************************************************************' print 'Saving a copy of version '+@version+' of YourSqlDba to ' + @bkpFile print '******************************************************************************************************************************' Declare @bkpName nvarchar(512) Set @bkpName = 'Backup version '+@version+' of ' + @bkpFile -- bkpName must be <= 128 otherwise it complains about data truncation in msdb backup history details If len(@bkpName) > 128 Set @bkpName = Left(@bkpName, 125)+ '...' Backup Database YourSqlDba To Disk = @bkpFile With Init, name = @bkpname End Exec ('Alter database YourSqlDba Set single_user with rollback immediate') Exec ('WaitFor Delay ''00:00:05''; ') Exec ('Drop database YourSqlDba') End Go -- ------------------------------------------------------------------------------ -- Recreate a new YourSqlDba -- ------------------------------------------------------------------------------ Declare @sql nvarchar(max) Declare @pathData nvarchar(512) Declare @pathLog nvarchar(512) -- Read actual file locationof YourSqlDba if it exists and is available ;With PathOfFileLocations as ( select reverse(Stuff(Reverse(Physical_Name), 1, charindex('\', Reverse(Physical_Name)), '')) collate database_default as path , Case when Charindex(Name collate database_default, 'master, model, tempdb, msdb') > 0 Or Name like 'ReportServer%' Then 0 Else 1 End as SystemDb , type , database_id , Case When database_Id = db_id('YourSqlDba') Then 1 Else 0 End as IsYourSqlDba -- to identify YourSqlDba files if its there from sys.master_files Where DatabasePropertyex(Db_name(Database_id), 'Status') = 'Online' ) -- Select * From PathOfFileLocations , EvalFileLocation as ( Select path, IsYourSqlDba, Systemdb, type, Count (distinct database_id) Nb -- count by business cases, YourSqlDba first, then non system Db, then systemDb From PathOfFileLocations Group by path, IsYourSqlDba, SystemDb, type ) --Select * From EvalFileLocation , RankBestFileLocations as ( Select * -- Rank best choice by : It is YourSqlDba actual location, non systemDb (0 before 1), and number of files , Row_Number() Over (partition By type Order by IsYourSqlDba, systemDb, nb desc) as best From EvalFileLocation ) -- Select * From RankBestFileLocations Select -- trick to select good values that comes from different rows, on a single result row @pathData = max(case when type = 0 Then path else '' End) , @pathLog = max(case when type = 1 Then path else '' End) From RankBestFileLocations Where best = 1 Set @sql = ' Create Database YourSQLDba ON PRIMARY ( Name = "YourSQLDba", FILENAME = "\YourSQLDba.MDF", SIZE = 60MB, FILEGROWTH = 20MB ) LOG ON ( Name = "YourSQLDba_Log", FILENAME = "\YourSQLDba_Log.LDF", SIZE = 5MB, FILEGROWTH = 5MB ) COLLATE LATIN1_GENERAL_CI_AI ALTER Database YourSQLDba Set RECOVERY SIMPLE ' Set @sql = Replace (@sql, '"', '''') Set @sql = Replace (@sql, '', @pathData) Set @sql = Replace (@sql, '', @pathLog) Exec (@sql) GO -- Create YourSqlDba login, with unknown password. If required DBA can change it. If not exists (select * from sys.sql_logins where name='YourSQLDba') Begin declare @unknownPwd nvarchar(100) = convert(nvarchar(400), HASHBYTES('SHA1', convert(nvarchar(100),newid())), 2) Exec ( ' create login Yoursqldba With Password = '''+@unknownPwd+''' , DEFAULT_DATABASE = YourSqlDba , CHECK_EXPIRATION = OFF , CHECK_POLICY = OFF , DEFAULT_LANGUAGE=US_ENGLISH ' ) END GO Exec sp_addsrvrolemember @loginame= 'YourSqlDba' , @rolename = 'sysadmin' GO ALTER AUTHORIZATION ON Database::[YourSQLDba] To [YourSqlDba] ALTER Database YourSqlDba Set TRUSTWORTHY ON GO --use tempdb --GO --alter database YourSQLDba set single_user with rollback immediate --GO --RESTORE DATABASE [YourSQLDba] FROM DISK = N'G:\SQL2005Backups\YourSQLDba_database[2][Mardi].Bak' WITH FILE = 1, NOUNLOAD, STATS = 5 --GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO -- create schemas to identify fonctions Exec('Create schema Audit authorization dbo;') Exec('Create schema yAudit authorization dbo;') Exec('Create schema Export authorization dbo;') Exec('Create schema yExport authorization dbo;') Exec('CREATE SCHEMA yExecNLog AUTHORIZATION dbo') Exec('Create schema Install authorization dbo;') Exec('Create schema yInstall authorization dbo;') Exec('Create schema Maint authorization dbo;') Exec('Create schema yMaint authorization dbo;') Exec('Create schema Mirroring authorization dbo;') Exec('Create schema yMirroring authorization dbo;') Exec('Create schema PerfMon authorization dbo;') Exec('Create schema yPerfMon authorization dbo;') Exec('CREATE SCHEMA Upgrade AUTHORIZATION dbo') Exec('CREATE SCHEMA yUpgrade AUTHORIZATION dbo') Exec('Create schema Tools authorization dbo;') Exec('Create schema yUtl authorization dbo;') GO If object_id('yUtl.DropObj ') is not null drop proc yUtl.DropObj GO create Proc yUtl.DropObj @name sysname , @showDrop int = 0 as Begin declare @db sysname; set @db = isnull(PARSENAME (@name, 3),db_name()) declare @sh sysname; set @sh = isnull(PARSENAME (@name, 2), 'dbo') declare @n sysname; set @n = isnull(PARSENAME (@name, 1), '') If OBJECT_ID(@db+'.'+@sh+'.'+@n) Is NULL Return declare @sql nvarchar(max) Set @sql = ' If Db_name() <> "" use [] Declare @ObjType sysname declare @name sysname; set @name = @sh+"."+@n Set @objType = Case When objectpropertyEx(OBJECT_ID(@name), "IsProcedure")=1 Then "Procedure" When objectpropertyEx(OBJECT_ID(@name), "IsTrigger")=1 Then "Trigger" When objectpropertyEx(OBJECT_ID(@name), "IsInlineFunction")=1 Then "Function" When objectpropertyEx(OBJECT_ID(@name), "IsScalarFunction")=1 Then "Function" When objectpropertyEx(OBJECT_ID(@name), "IsTableFunction")=1 Then "Function" When objectpropertyEx(OBJECT_ID(@name), "IsUserTable")=1 Then "Table" When objectpropertyEx(OBJECT_ID(@name), "IsView")=1 Then "View" -- With SQL2008R2 SP1 objectpropertyEx fails to detect CLR FUNCTION with the is???Function above When exists(Select * from sys.objects where object_id = OBJECT_ID(@name) And type_desc Like "%FUNCTION") Then "Function" Else "" End If @objType = "" collate database_default Raiserror (N"Unsupported object type by yUtl.DropObj %s.%s.%s", 11, 1, @db, @sh, @n) Else Begin if @showdrop = 1 Print "use []; Drop "+@objtype+" ["+@sh+"].["+@n+"]" Exec ("If Db_name() <> """" Use []; Drop "+@objtype+" ["+@sh+"].["+@n+"]") End ' Set @sql = REPLACE(@sql, '', @db) Set @sql = REPLACE(@sql, '"', '''') Exec sp_executeSql @sql, N'@db sysname, @sh sysname, @n sysname, @showdrop int', @db, @sh, @n, @showDrop End -- yUtl.DropObj GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO ----------------------------------------------------------------------------------------------- -- Get text between start /*Delim and Delim*/ where Delim is a parameter -- from source text which can be the current batch is @moduleRef is NULL -- or the definition of the moduleRef if the parameter is varchar -- or the definition of the module whom object_id passed as a parameter ----------------------------------------------------------------------------------------------- Create Function Dbo.GetCmtBetweenDelim (@delim sysname, @ModuleRef Sql_Variant) Returns table as Return ( Select * From (Select Delim=@delim, ModuleRef=@ModuleRef) as ModuleRef CROSS APPLY (Select Typ=IIF(ModuleRef IS NULL, NULL, sql_variant_property(ModuleRef, 'BaseType'))) as Typ OUTER APPLY (Select PrmIsName=Convert(sysName,moduleRef) Where Typ = 'varchar') as PrmIsName OUTER APPLY (Select ObjId=Convert(int, moduleRef) Where Typ = 'int') as ObjId OUTER APPLY ( Select moduleName=Object_Schema_name(ObjId)+'.'+Object_name(ObjId) Where ObjId IS NOT NULL UNION ALL Select ModuleName=PrmIsName Where PrmIsName Is NOT NULL ) as ModuleName OUTER APPLY ( -- The module text like a view or a inline function Select SrcTxt=OBJECT_DEFINITION(Object_Id(ModuleName)) collate database_default Where Typ Is NOT NULL And ModuleName IS Not NULL And ModuleName <> '' UNION ALL -- The top call stack of calling SQL Select SrcTxt=event_info Collate Database_default From sys.dm_exec_input_buffer(@@spid, null) Where Typ Is NOT NULL And ModuleName = '' And event_type = 'Language Event' UNION ALL -- the current batch, or the stored proc inside which is shown as the current bacth Select SrcTxt=qt.text Collate Database_default From sys.dm_exec_requests er Cross Apply sys.dm_exec_sql_text(er.sql_handle) as qt Where Typ IS Null And er.session_id = @@SPID ) as SrcTxt CROSS APPLY (Select LgCt=LEN(Delim) ) as LgCt CROSS APPLY (Select StartP=charindex('/*'+Delim, SrcTxt)+LgCt+2 ) As StartP CROSS APPLY (Select EndP=charindex(Delim+'*/', SrcTxt)-1 ) as EndP OUTER APPLY (Select DelimTxtInCmtFound=Cast(Substring(SrcTxt, StartP, EndP-StartP+1) as nvarchar(max)) Where startP > 0 And EndP > StartP And LgCt>0) as TxtInCmt OUTER APPLY (Select Found=IIF(DelimTxtInCmtFound IS NULL,0,1)) as Found -- in case input is invalid as when start and/or end comment ar missing OUTER APPLY (Select InvalidDelimMsg='!Dbo.GetCmtBetweenDelim: Comment Delim is null!' Where Found=0 And Delim is NULL) as InvalidDelimMsg OUTER APPLY ( Select InvalidModuleMsg='!Dbo.GetCmtBetweenDelim: No text to search because inexisting module'+moduleName+'!' Where found=0 And PrmIsName IS NOT NULL And SrcTxt IS NULL UNION ALL Select InvalidModuleMsg='!Dbo.GetCmtBetweenDelim: No text to search because inexisting module id '+CONVERT(nvarchar, ObjId)+'!' Where found=0 And Typ = 'Int' And SrcTxt is NULL ) as InvalidModuleMsg CROSS APPLY (Select MsgTemplateForInvalidInput='!Dbo.GetCmtBetweenDelim: No comment text between start Delim /*#Delim# and end Delim #Delim#*/!') as MsgTemplateForInvalidInput OUTER APPLY (Select DelimNotFoundMsg=Replace(MsgTemplateForInvalidInput, '#Delim#', Delim) Where found=0) as Msg3 CROSS APPLY (Select TxtInCmt=Coalesce(InvalidDelimMsg, InvalidModuleMsg, DelimNotFoundMsg, DelimTxtInCmtFound)) as TextBetweenCmtDelims /* -- !!!!! KEEP THIS COMMENT, THIS IS A TEST ASSERTION FOR THIS FUNCTION -- !!!!! Test fail When this bunch of select + union all are selected and returns something Select Test=1, * from Dbo.GetCmtBetweenDelim (NULL, 'Dbo.GetCmtBetweenDelim') Where isnull(TxtInCmt,'') <> '!Dbo.GetCmtBetweenDelim: Comment Delim is null!' union all Select Test=2,* from Dbo.GetCmtBetweenDelim ('Haha', NULL) /*HeheTextBetweenHehe*/ -- not like with ____ to avoid finding itself in condition Where isnull(TxtInCmt,'') not like '!Dbo.GetCmtBetweenDelim: No comment text between start Delim /*____ and end Delim ____*/!' union all Select Test=3,* from Dbo.GetCmtBetweenDelim ('Haha', 'Dbo.GetCmtBetweenDelim') /*HeheTextBetweenHehe*/ -- not like with ____ to avoid finding itself in condition Where isnull(TxtInCmt,'') not like '!Dbo.GetCmtBetweenDelim: No comment text between start Delim /*____ and end Delim ____*/!' union all Select Test=4,* from Dbo.GetCmtBetweenDelim ('Hehe', NULL) /*HeheTextBetweenHehe*/ Where isnull(TxtInCmt,'') <> 'TextBetween' union all Select Test=5,* from Dbo.GetCmtBetweenDelim ('Hehe', 'Dbo.GetCmtBetweenDelim') Where isnull(TxtInCmt,'') <> 'TextBetween' */ /*===Purpose=== This function is to get some SQL Code wrapped in a multiline comment that must starts and ends by a Delim of your choice /*"Delim" and end by "Delim"*/ It simplifies coding of code definition or code template instead of using litteral strings by having not to care about quotes. The comment may be extracted depending @Moduleref Sql_Variant parameter from: ■ The running batch or directly in a stored procedure. ■ @@ProcId (id of the running SP) ■ Any SQL module name including itself (like a stored proc, function, Trigger Or View) ■ The topmost calling SQL (ex: a comment in the batch starting before the called stored proc) This function have a very extensive use in this library! ===Purpose===*/ /*===Samples=== -- Get the code in some current running batch or stored procedure, here the commented code is in the select itself Select Sql From ( Select FctName=ParseName(Object_schema_name(Object_id))+'.'+ParseName(Object_name(Object_id)), type_desc, type From Sys.Objects Where type_desc like '%Function%' And Type_Desc Not like 'Clr%' ) As FctName Cross Apply Dbo.GetCmtBetweenDelim('===DropAllFct===', NULL) As C /*===DropAllFct=== Drop Function '#FctName#' ===DropAllFct===*/ CROSS Apply (Select Sql=Replace(C.TxtInCmt, '#FctName#', FctName)) as Sql --GO Create Function dbo.FunctionDropper () returns table as return Select Sql From ( Select FctName=ParseName(Object_schema_name(Object_id))+'.'+ParseName(Object_name(Object_id)), type_desc, type From Sys.Objects Where type_desc like '%Function%' And Type_Desc Not like 'Clr%' And Object_id <> Object_Id('dbo.FunctionDropper') -- dont drop myself ) As FctName -- instead of null for @moduleRef, use self function name. Cross Apply Dbo.GetCmtBetweenDelim('===DropAllFct===', 'dbo.FunctionDropper') As C cross apply (Select sch=Object_schema_name(Object_id)) as Sch Cross apply (select name=Object_name(Object_id)) as Name Cross apply (Select FctName=QuoteName(Sch)+'.'+Quotename(name)) as FctName /*===DropAllFct=== Drop Function if exists #FctName# ===DropAllFct===*/ CROSS Apply (Select Sql=Replace(C.TxtInCmt, '#FctName#', FctName)) as Sql --GO Create Function dbo.ScriptFunctionDrops () returns table as return Select Sql From ( Select FctName=Object_schema_name(Object_id)+'.'+Object_name(Object_id), type_desc, type From Sys.Objects Where type_desc like '%Function%' And Type_Desc Not like 'Clr%' And Object_id <> Object_Id('dbo.ScriptFunctionDrops') -- dont drop myself ) As FctName -- instead of null for @moduleRef, use self function name. Cross Apply Dbo.GetCmtBetweenDelim('===DropAllFct===', 'dbo.ScriptFunctionDrops') As C /*===DropAllFct=== Drop Function '#FctName#' ===DropAllFct===*/ CROSS Apply (Select Sql=Replace(C.TxtInCmt, '#FctName#', FctName)) as Sql --GO Create Proc dbo.DropsFunctions as Begin Declare @Sql Nvarchar(max) = '' Select @sql=@sql+Sql From ( Select FctName=Object_schema_name(Object_id)+'.'+Object_name(Object_id), type_desc, type From Sys.Objects Where type_desc like '%Function%' And Type_Desc Not like 'Clr%' And Object_id <> Object_Id('dbo.ScriptFunctionDrops') -- dont drop myself ) As FctName -- instead of null for @moduleRef, use system variable that give current procedure id Cross Apply Dbo.GetCmtBetweenDelim('===DropAllFct===', @@ProcId) As C /*===DropAllFct=== Drop Function '#FctName#' ===DropAllFct===*/ CROSS Apply (Select Sql=Replace(C.TxtInCmt, '#FctName#', FctName)) as Sql Exec (@Sql) End ===Samples===*/ /*===KeyWords=== Scripting,comments,scripting ===KeyWords===*/ ) -- Dbo.GetCmtBetweenDelim GO Drop function if exists Dbo.ConcatFromJson GO Create Function Dbo.ConcatFromJson(@InitSeparator nvarchar(10), @Separator nvarchar(10), @json nvarchar(max)) -- makes concat easier to do Returns Table As Return ----------------------------------------------------------------------------------------------------- -- this fonction accept muti-row of a single column values put in a Json Auto with optional order -- expression to concat extract them with openjson and concat them using an XML expression. -- some escaped char have to be removed because they are created by the XML concat expression -- -- There is 3 parameters, Initial separator which replace separator on the first row value -- If initial separator is NULL, separator is used everywhere, initial separator is the same as separator -- if initial separator is non-null, it replace first separator by its value ----------------------------------------------------------------------------------------------------- ( Select result From (Select Separator=ISNULL(@Separator,''), J=@json) as Prm0 -- no initSeparator, take same value as separator CROSS APPLY (Select InitSeparator=ISNULL(@InitSeparator, Prm0.Separator), Prm0.J) as Prm -- SQL do not mesure trailings spaces in LEN function, so add an extra non space char, mesure this len minus one. CROSS APPLY (Select LenInitSeparator=LEN(InitSeparator+'|')-1) as LenInitSeparator CROSS APPLY (Select lenSeparator=LEN(Separator+'|')-1) LenSeparator -- concat everything with separator, so initSeparator is not there yet, separator is at its place CROSS APPLY ( Select allConcat= ( Select isnull(Separator,'') +Conc.Col as [text()] From (Select * From openJson(Prm0.j) with (Col nvarchar(max))) as Conc For XML Path(''),TYPE).value -- ,TYPE).value('.','NVARCHAR(MAX)') allow to make no escapes for ' " < > & in result ('.','NVARCHAR(MAX)') ) As allConcat -- cases to deal with -- separator is empty string if @separator is null, and initSeparator is the same as separator, if InitSeparator is null -- InitSeparator isn't null, remove start of string of the len of Separator, and put InitSeparator instead as first separator -- Shortcut job work, if there is no sep, job done Outer Apply (Select ConcatAllNoSep=allConcat Where InitSeparator = '' And Separator = '') as ConcatAllNoSep -- otherwise Handle initialSeparator OUTER Apply (Select ConcatAllButFirst=STUFF(allConcat, 1, LenSeparator, InitSeparator) Where ConcatAllNoSep Is NULL) as ConcatAllButFirst CROSS APPLY (Select Result=COALESCE(ConcatAllNoSep, ConcatAllButFirst)) as Result /*-- some test Select J1.result, ExpectedRes, ok, Test=IIf(ok=1, 'Success', 'Fail')+' for '+TestName, ColsTbInJson, InitSep, Sep, Expected From (Values ('Set1')) as S(SetN) cross join (Select Nl=char(13)+CHAR(10)) as Nl cross apply ( Select ColsTbInJson= ( Select Col=item+NL From (Values ('Set1', 'Select item1&', 1), ('Set1', 'Select [item2]<', 2), ('Set1', 'Select {item3}"', 3)) as t(setN, item, ord) Where t.setN=S.setN order by ord FOR Json auto ) ) as x CROSS APPLY -- parameter for cases to test, and expected result ( Select * From ( Values (NULL , NULL , 'Select item1&\nSelect [item2]<\nSelect {item3}"\n' , 'Null separators, so no sep between them') , (NULL , ', ' , ', Select item1&\n, Select [item2]<\n, Select {item3}"\n' , 'NULL Initial separator, separator initial separator = separator') , (' ' , 'Union all ' , ' Select item1&\nUnion all Select [item2]<\nUnion all Select {item3}"\n' , 'some initial separator to substitute to first occurence of separator' ) ) as t(initSep, Sep , Expected , TestName) CROSS APPLY (Select expectedRes=REPLACE(expected, '\n', NL)) as ExpectedRes ) TestData Cross apply Dbo.ConcatFromJson(initSep, Sep, colsTbInJson) as J1 Outer apply (select Ok=1 Where result=ExpectedRes) as Ok -- end of test cases */ /*===KeyWords=== Scripting ===KeyWords===*/ ) -- Dbo.ConcatFromJson GO Drop function if exists Dbo.MultipleReplaces GO -- -------------------------------------------------------------------------- -- very useful function for turning templates into real code -- json tags are expressed as #JsonTagName# and replaced by their json values -- -------------------------------------------------------------------------- Create Function Dbo.MultipleReplaces (@Template nvarchar(max), @JsonDataSource Nvarchar(max)) Returns Table as Return --- --- JSON support makes Dbo.ReplaceTagsMatchingXMLAttributesNamesByTheirValue obsolete. --- This version does the same thing faster. --- -- keep this commented code below to test inner working of the query -- --declare @JsonDataSource as nvarchar(max) = --' --[ -- { -- "TbName": "[S#].[RealRestoreFileListOnly]", -- "Cols": " [spid] int NULL Default (@@spid)\n, [LogicalName] nvarchar(128) NULL\n, [PhysicalName] nvarchar(260) NULL\n, [Type] nchar(1) NULL\n, [FileGroupName] nvarchar(128) NULL\n, [Size] numeric(20, 0) NULL\n, [MaxSize] numeric(20, 0) NULL\n, [FileID] bigint NULL\n, [CreateLSN] numeric(25, 0) NULL\n, [DropLSN] numeric(25, 0) NULL\n, [UniqueID] uniqueidentifier NULL\n, [ReadOnlyLSN] numeric(25, 0) NULL\n, [ReadWriteLSN] numeric(25, 0) NULL\n, [BackupSizeInBytes] bigint NULL\n, [SourceBlockSize] int NULL\n, [FileGroupID] int NULL\n, [LogGroupGUID] uniqueidentifier NULL\n, [DifferentialBaseLSN] numeric(25, 0) NULL\n, [DifferentialBaseGUID] uniqueidentifier NULL\n, [IsReadOnly] bit NULL\n, [IsPresent] bit NULL\n, [TDEThumbprint] varbinary(32) NULL\n, [SnapshotURL] nvarchar(36) NULL\n" -- }, -- { -- "TbName": "[S#].[RealRestoreHeaderOnly]", -- "Cols": " [spid] int NULL Default (@@spid)\n, [BackupName] nvarchar(128) NULL\n, [BackupDescription] nvarchar(255) NULL\n, [BackupType] smallint NULL\n, [ExpirationDate] datetime NULL\n, [Compressed] tinyint NULL\n, [Position] smallint NULL\n, [DeviceType] tinyint NULL\n, [UserName] nvarchar(128) NULL\n, [ServerName] nvarchar(128) NULL\n, [DatabaseName] nvarchar(128) NULL\n, [DatabaseVersion] int NULL\n, [DatabaseCreationDate] datetime NULL\n, [BackupSize] numeric(20, 0) NULL\n, [FirstLSN] numeric(25, 0) NULL\n, [LastLSN] numeric(25, 0) NULL\n, [CheckpointLSN] numeric(25, 0) NULL\n, [DatabaseBackupLSN] numeric(25, 0) NULL\n, [BackupStartDate] datetime NULL\n, [BackupFinishDate] datetime NULL\n, [SortOrder] smallint NULL\n, [CodePage] smallint NULL\n, [UnicodeLocaleId] int NULL\n, [UnicodeComparisonStyle] int NULL\n, [CompatibilityLevel] tinyint NULL\n, [SoftwareVendorId] int NULL\n, [SoftwareVersionMajor] int NULL\n, [SoftwareVersionMinor] int NULL\n, [SoftwareVersionBuild] int NULL\n, [MachineName] nvarchar(128) NULL\n, [Flags] int NULL\n, [BindingID] uniqueidentifier NULL\n, [RecoveryForkID] uniqueidentifier NULL\n, [Collation] nvarchar(128) NULL\n, [FamilyGUID] uniqueidentifier NULL\n, [HasBulkLoggedData] bit NULL\n, [IsSnapshot] bit NULL\n, [IsReadOnly] bit NULL\n, [IsSingleUser] bit NULL\n, [HasBackupChecksums] bit NULL\n, [IsDamaged] bit NULL\n, [BeginsLogChain] bit NULL\n, [HasIncompleteMetaData] bit NULL\n, [IsForceOffline] bit NULL\n, [IsCopyOnly] bit NULL\n, [FirstRecoveryForkID] uniqueidentifier NULL\n, [ForkPointLSN] numeric(25, 0) NULL\n, [RecoveryModel] nvarchar(60) NULL\n, [DifferentialBaseLSN] numeric(25, 0) NULL\n, [DifferentialBaseGUID] uniqueidentifier NULL\n, [BackupTypeDescription] nvarchar(60) NULL\n, [BackupSetGUID] uniqueidentifier NULL\n, [CompressedBackupSize] bigint NULL\n, [Containment] tinyint NULL\n, [KeyAlgorithm] nvarchar(32) NULL\n, [EncryptorThumbprint] varbinary(20) NULL\n, [EncryptorType] nvarchar(32) NULL\n" -- }, -- { -- "TbName": "[S#].[InstallYourSqlDba]", -- "Cols": " [Version] varchar(7) Not NULL\n, [RevisionDate] date NULL\n" -- }, -- { -- "TbName": "[S#].[RealScriptToRun]", -- "Cols": " [spid] int Not NULL Default (@@spid)\n, [nestLevel] int Not NULL Default (@@nestlevel)\n, [seq] int Not NULL\n, [eventTime] datetime2(7) NULL Default (sysdatetime())\n, [Sql] nvarchar(Max) NULL\n, [label] nvarchar(Max) NULL\n, [db] sysname NULL\n" -- }, -- { -- "TbName": "[S#].[ProcessMaintenancePrm]", -- "Cols": " [JsonDoMaintPrm] nvarchar(Max) NULL\n, [JsonJobStates] nvarchar(Max) NULL\n" -- } --] --' --Declare @template nvarchar(max)= --' --Create Table #TbName# --( --#Cols#) --TEXTIMAGE_ON --' --; With TagSrc as ( Select RowKey -- AttributeRowSeq is useful as it allows to specify a replace order from JsonDataSource attribute by relative position -- example If tagSrc='This is #F#', and JsonDataSource contains '[{"F":"contains #b#","B":"b contains #c#,"C":"last"}]' -- replace seq will be: 'This is #F#' -> 'This is contains #b#' -> 'This is contains last' , AttributeRowSeq = Row_number() Over (Partition by Rowkey Order By Pos) , AttributeNbOfRow = COUNT(*) Over (Partition by RowKey) , AttributeTag = '#'+[Key]+'#' collate database_default , AttributeValue = isnull(Value,'') collate database_default -- tags with no values are replaced by empty string , rowvalue From (Select JsonDataSource=@JsonDataSource) as JsonDataSource CROSS APPLY (select Rowkey=[key], RowValue=Value, Pos=CharIndex('"'+[Key]+'":', JsonDataSource) From openjson (JsonDataSource)) as Rows cross apply openJson (RowValue) ) , TagReplacements As ( Select RowKey, AttributeRowSeq, AttributeNbOfRow, AttributeTag, AttributeValue, LastReplace=Cast (REPLACE (@template, AttributeTag, AttributeValue) as nvarchar(max)) From tagSrc Where AttributeRowSeq = 1 UNION ALL Select T.Rowkey, T.AttributeRowSeq, T.AttributeNbOfRow, T.AttributeTag, T.AttributeValue, LastReplace=Cast (REPLACE (LastReplace, T.AttributeTag, T.AttributeValue) as nvarchar(max)) From (Select Rowkey, LastReplace, LastAttributeRowSeq=AttributeRowSeq From TagReplacements) as Prev JOIN TagSrc AS T On T.RowKey = Prev.RowKey And T.AttributeRowSeq = Prev.LastAttributeRowSeq+1 ) Select replacedTxt=LastReplace from TagReplacements Where AttributeNbOfRow = AttributeRowSeq /*======= some test example by calling the function itself =============== Select replacedTxt From ( Select jMain = ( Select --- ********** if complex expressions are used it is important to put all columns --- ********** at the same select level otherwise json will not be properly formatted by Auto option TbName , Cols From ( -- choose table Select TbName = Dbo.FullObjName (object_id) From sys.tables --Where Dbo.FullObjName (object_id) like '%realRestore%' ) as TbName cross apply ( Select ColsTbInJson= ( -- get cols list and express it in json Select Col=CI.ColDef+nchar(10) From Dbo.ColInfo(TbName, NULL) as CI order by Ci.ColOrd FOR Json auto ) ) as x -- concat cols content from Json expression, and make put comma in front of each except the first one --cross apply (Select top 1 cols=j.CAT From Dbo.ConcatColFromJson('', ', ', colsTbInJson) as J) as cols cross apply (Select Cols=convert(nvarchar(max),result) From Dbo.ConcatFromJson('', ', ', colsTbInJson)) as cols For json Auto ) ) as V cross apply ( SELECT MainSyntaxTb.replacedTxt From (Select CreateTbTemplate=TxtInCmt From Dbo.GetCmtBetweenDelim ('===temp===', null)) as CreateTbTemplate /*===temp=== Create Table #TbName# ( #Cols#) TEXTIMAGE_ON ===temp===*/ Cross Apply Dbo.MultipleReplaces(CreateTbTemplate, jMain) as MainSyntaxTb ) MainSyntaxTb =================== end sample test =================================*/ /*===KeyWords=== Scripting ===KeyWords===*/ GO ------------------------------------------------------------------------------------- -- combine two useful functions for code template processing ------------------------------------------------------------------------------------- Drop function If exists Dbo.GetTemplateFromCmtAndReplaceTags GO Create Function Dbo.GetTemplateFromCmtAndReplaceTags (@delim sysname, @CmtSource Sql_Variant, @JSonDataSource Nvarchar(max)) Returns table As Return Select Code=Code.replacedTxt From Dbo.GetCmtBetweenDelim (@delim, @CmtSource) as Template CROSS APPLY Dbo.MultipleReplaces (Template.TxtInCmt, @JsonDataSource) as Code GO Drop function If exists dbo.ScriptMakeProcessMaintenancePrmGlobal GO Create Function dbo.ScriptMakeProcessMaintenancePrmGlobal (@JsonDoMaintPrm as Nvarchar(max)) returns table as return Select * From (Select ThisFunction='dbo.ScriptMakeProcessMaintenancePrmGlobal', JsonDoMaintPrm=@JsonDoMaintPrm) as Prm CROSS APPLY (Select templ=TxtInCmt From Dbo.GetCmtBetweenDelim ('===SetCtx===', ThisFunction)) as templ CROSS APPLY (Select Sql=replace(templ, '#JsonDoMaintPrm#', JsonDoMaintPrm)) as Sql /*===SetCtx=== -- ---------------------------------------------------------------- -- Set global states that can be retrieved in the call stack of -- sub procedure and fonction of the maintenance -- and in a permanent manner for databases across maintenance -- ---------------------------------------------------------------- -- A Session context allow to be able to retreive maintenance param in json format through session_context with JsonDoMaintPrm key -- A table of processed databases keep some cycle info across maintenance for each database Declare @JsonDoMaintPrm Nvarchar(4000) Select @JsonDoMaintPrm=TxtInCmt from dbo.GetCmtBetweenDelim ('===JsonDoMaintPrm===', NULL) /*===JsonDoMaintPrm=== #JsonDoMaintPrm# ===JsonDoMaintPrm===*/ Exec SP_Set_Session_context @key='JsonDoMaintPrm' , @value=@JsonDoMaintPrm , @read_only=0 ===SetCtx===*/ GO Drop View If exists dbo.WhoCalledWhat GO Create View dbo.WhoCalledWhat As -- --------------------------------------------------------------------------------------------- -- this View returns how the whole thing was called and at topmost level -- plus From Where, what and Who -- --------------------------------------------------------------------------------------------- Select Host , Prog , MainCall=Srctxt , Who , JobId , Stepid , SqlAgentJobName=SJ.NAme , PrefixStep , PosJobId , PosFinJobId , StartStepId from dbo.GetCmtBetweenDelim (null, '') CROSS APPLY (Select Who=Quotename(ORIGINAL_LOGIN())+ IIF(SUSER_SNAME() <> ORIGINAL_LOGIN(), ' Executing as: '+Quotename(SUSER_SNAME()), '')) as Who -- If calling program is SQLAgent, parse it to get JobId and StepId CROSS APPLY (Select Prog=PROGRAM_NAME(), Host=HOST_NAME (), SqlAgentSignature='SQLAgent%0x% : Step %)', PrefixStep=' : Step ') as SearchDom OUTER APPLY (Select PosJobId=Charindex('0x', Prog) Where Prog like SqlAgentSignature) as PosJobId OUTER APPLY (Select PosFinJobId=CharIndex(PrefixStep, Prog)) as PosFinJobId OUTER APPLY (Select JobIdStr=Substring(Prog, PosJobId, PosFinJobId-PosJobId) Where PosJobId >0 And PosFinJobId >0) as JobIdStr OUTER APPLY (Select JobId=convert (uniqueIdentifier, convert(varbinary(200),JobIdStr,1))) as JobId OUTER APPLY (Select StartStepId=PosFinJobId+Len(PrefixStep)+1 Where PosJobId >0 And PosFinJobId >0) as StartStepId OUTER APPLY (Select StepId=Substring(Prog, StartStepId, LEN(Prog)-StartStepId) Where StartStepId > 0) as StepId Left JOIN Msdb.dbo.sysjobs as SJ ON SJ.job_id = JobId /* drop proc if exists a go create proc A as Exec('B') go drop proc if exists B go create proc B as Select * from dbo.WhoCalledWhat go Exec A */ GO -- ------------------------------------------------------------------------------------------------------------- -- Function that infer many ways to name objects, choose the one that match your in resulting columns -- from partial of full object names OR object_id + optional dabatase Id -- The function accepts an SQL_VARIANT and depending of its type walks different ways to get the names parts -- and from then, returns many naming combinations, quoted or unquoted, partially qualified of schema qualified -- or database+schema+name -- ------------------------------------------------------------------------------------------------------------- Drop Function If Exists Dbo.InferObjectNamings GO Create Function Dbo.InferObjectNamings(@objRef SQL_Variant, @DbId Int) Returns Table as Return ( Select Db, Sch, name, SN, DSN, QDb, QSch, QSN, QDSN, hasDbInName, hasSchInName, MinimalQDSN, MinimalDSN , FromHereDebugInfo='Debug inf in next columns' , ObjRef, PrmDbId, Typ, ObjNameFromPrm, ObjIdFromPrm, DbInNameToCheck, DbInName , DbNameFromDbId, DbIdFromNameOrDbId, ObjIdFromPrmObjRefOrPrmId From (Select ObjRef=Convert(Sql_variant, @Objref), PrmDbId=@Dbid) as ObjRef --( -- Test for the function : Must be done from MSDB -- Select ObjRef=Convert(Sql_Variant, 'backupset'), PrmDbId = NULL --union all Select ObjRef=Convert(Sql_Variant, 'MSDB..[backupset]'), PrmDbId = NULL --union all Select ObjRef=Convert(Sql_Variant, '[dbo].[backupset]'), PrmDbId = NULL --union all Select ObjRef=Convert(Sql_Variant, '[managed_backup].[fn_get_parameter]'), PrmDbId = NULL --union all Select ObjRef=Convert(Sql_Variant, '[MSDB].[managed_backup].[fn_get_parameter]'), PrmDbId = NULL --union all Select ObjRef=Convert(Sql_Variant, '[MSDB].[managed_backup].[fn_get_parameter]'), PrmDbId = Db_id('msdb') -- dbid ignored --union all Select ObjRef=Convert(Sql_Variant, object_id('[MSDB].[managed_backup].[fn_get_parameter]')), PrmDbId = Db_id('msdb') -- dbid ok --union all Select ObjRef=Convert(Sql_Variant, object_id('[MSDB].[managed_backup].[fn_get_parameter]')), PrmDbId = NULL -- depend on current db context --) as PrmTst CROSS APPLY (Select Typ=sql_variant_property(ObjRef, 'BaseType')) as Typ OUTER APPLY (Select ObjNameFromPrm=Convert(sysName,ObjRef) Where Typ = 'varchar') as ObjNameFromPrm OUTER APPLY (Select ObjIdFromPrm=Convert(int, ObjRef) Where Typ = 'int') as ObjIdFromPrm CROSS APPLY (Select hasDbInName=IIF(PARSENAME (ObjNameFromPrm, 3) IS NOT NULL,1,0)) as hasDbInName CROSS APPLY (Select hasSchInName=IIF(PARSENAME (ObjNameFromPrm, 2) IS NOT NULL,1,0)) as hasSchInName OUTER APPLY (Select DbInNameToCheck=PARSENAME (ObjNameFromPrm, 3) Where ObjNameFromPrm IS NOT NULL) as DbInNameToCheck OUTER APPLY (Select DbInName=ISNULL(DbInNameToCheck, Db_Name()) Where ObjNameFromPrm IS NOT NULL) as DbInName OUTER APPLY (Select DbNameFromDbId=ISNULL(Db_name(prmDbId), Db_name()) Where ObjIdFromPrm IS Not NULL) as DbNameFromDbId CROSS APPLY (Select Db=CAST(COALESCE(DbInName, DbNameFromDbId) as sysname)) as Db CROSS APPLY (Select DbIdFromNameOrDbId=DB_ID(Db)) as DbIdFromNameOrDbId CROSS APPLY (Select ObjIdFromPrmObjRefOrPrmId=COALESCE(ObjIdFromPrm, OBJECT_ID(ObjNameFromPrm))) as ObjIdFromPrmObjRefOrPrmId CROSS APPLY (Select Sch=OBJECT_SCHEMA_NAME (ObjIdFromPrmObjRefOrPrmId, DbIdFromNameOrDbId)) as Sch CROSS APPLY (Select name=OBJECT_NAME (ObjIdFromPrmObjRefOrPrmId, DbIdFromNameOrDbId)) as Name Cross Apply (Select Dot='.') as Dot CROSS APPLY (Select QSch=QUOTENAME(Sch), QName=QUOTENAME(name), QDb=QUOTENAME(Db)) As QParts CROSS APPLY (Select QSN=Qsch+Dot+Qname) as QSN CROSS APPLY (Select QDSN=QDb+Dot+QSN) as QDSN CROSS APPLY (Select MinimalQDSN=IIF(hasDbInName=1, QDb+Dot,'')+IIF(hasSchInName=1,Qsch+Dot,IIF(hasDbInName=1,Dot,''))+QName) as MinimalQDSN CROSS APPLY (Select SN=Sch+Dot+Name) as Sn CROSS APPLY (Select DSN=Db+Dot+SN) as Dsn CROSS APPLY (Select MinimalDSN=IIF(hasDbInName=1, Db+Dot,'')+IIF(hasSchInName=1,sch+Dot,IIF(hasDbInName=1,Dot,''))+Name) as MinimalDSN /*===KeyWords=== Scripting,Object Management ===KeyWords===*/ ) GO Drop Function If EXISTS Dbo.DbsFileSizes GO Create Function Dbo.DbsFileSizes (@DbNameLike Sysname) -- ---------------------------------------------------------------------------------------------------------- -- This function get database(s) name, logical filename, type of file, physical filename, and size in mb -- ---------------------------------------------------------------------------------------------------------- Returns TABLE as Return SELECT DbName.DbName , Mf.type_desc , FileName.FileName , Mf.physical_name , fSizeInMb FROM sys.databases as Db JOIN sys.master_files as MF WITH(NOWAIT) ON MF.database_id = Db_id(Db.name) CROSS APPLY (Select DbFileSizeInMb = Cast(size * 8. / 1024 AS DECIMAL(8,2))) as DbFileSizeInMb CROSS APPLY (Select DbName=Db.name) as DbName CROSS APPLY (Select FileName=Mf.name) as FileName CROSS APPLY (Select fSizeInMb=CAST(size * 8. / 1024 AS DECIMAL(8,2))) as fSIzeinMb Where Db.name Like @DbNameLike Or @DbNameLike IS NULL /* Select * From Dbo.DbsFileSizes(NULL) -- all file db sizes Select * From Dbo.DbsFileSizes('%GPI%') -- all file db sizes of Db that match the filter */ GO --Drop objects that belongs to the assembly below -- they must be dropped from the assembly before dropping the assembly declare @sql nvarchar(max) ;With InfoModuleAssemblies as ( select OBJECT_SCHEMA_NAME(m.object_id) as NomSchema , OBJECT_NAME(m.object_id) as nomObj , A.name as NomModule from sys.assembly_modules M join sys.assemblies A On A.assembly_id = M.assembly_id ) Select @sql = ( Select convert(nvarchar(max), '') +'Exec yUtl.DropObj "'+I.NomSchema+'.'+I.nomObj+'";'+NCHAR(10) as [text()] from InfoModuleAssemblies I Where NomModule IN ('YourSqlDba_ClrExec', 'YourSqlDba_ClrFileOp') For XML PATH('') ) Set @sql = REPLACE(@sql, '"', '''') --print @sql exec (@sql) go If Db_name() <> 'YourSqlDba' Use YourSqlDba GO ALTER DATABASE YourSQLDba SET ENABLE_BROKER WITH ROLLBACK IMMEDIATE; GO ALTER DATABASE YourSQLDba SET NEW_BROKER WITH ROLLBACK IMMEDIATE; GO IF EXISTS (SELECT * FROM sys.assemblies asms WHERE asms.name = N'YourSqlDba_ClrExec') DROP ASSEMBLY [YourSqlDba_ClrExec] GO /****** Object: SqlAssembly [YourSqlDba_ClrExec] Script Date: 08/28/2012 16:04:35 ******/ CREATE ASSEMBLY [YourSqlDba_ClrExec] AUTHORIZATION [dbo] FROM 0x4D5A90000300000004000000FFFF0000B800000000000000400000000000000000000000000000000000000000000000000000000000000000000000800000000E1FBA0E00B409CD21B8014CCD21546869732070726F6772616D2063616E6E6F742062652072756E20696E20444F53206D6F64652E0D0D0A2400000000000000504500004C010300DC98D5520000000000000000E00002210B010B000018000000060000000000000E360000002000000040000000000010002000000002000004000000000000000400000000000000008000000002000000000000030040850000100000100000000010000010000000000000100000000000000000000000B43500005700000000400000D003000000000000000000000000000000000000006000000C0000007C3400001C0000000000000000000000000000000000000000000000000000000000000000000000000000000000000000200000080000000000000000000000082000004800000000000000000000002E7465787400000014160000002000000018000000020000000000000000000000000000200000602E72737263000000D00300000040000000040000001A0000000000000000000000000000400000402E72656C6F6300000C0000000060000000020000001E00000000000000000000000000004000004200000000000000000000000000000000F035000000000000480000000200050068240000141000000100000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000133002006F00000001000011000F00281100000A0A0614FE0116FE01130511052D0A14281200000A13042B4C731300000A0B160D2B240006096F1400000A0C08281500000A130511052D0A0007086F1600000A2600000917580D09066F1700000AFE04130511052DCD076F1800000A281200000A13042B0011042A001B300200610000000200001100731900000A0A06026F1A00000A6F1B00000A00731300000A0B07731C00000A0C0008731D00000A0D09176F1E00000A0006096F1F00000A0000DE120814FE01130511052D07086F2000000A00DC00076F1800000A281200000A13042B0011042A00000001100000020021001B3C0012000000001E02282200000A2A1B300500A9010000030000110002167D020000047201000070732300000A0B00046F2400000A6F2500000A1304384601000011046F2600000A74270000010C00086F2700000A14FE01130511053A2501000000086F2700000A0A086F2800000A16FE0116FE01130511052D0F0007066F2900000A260038FB00000000086F2800000A1F0AFE0216FE01130511053A9200000000086F2A00000A16FE0216FE01130511052D20007203000070086F2A00000A8C28000001086F2B00000A282C00000A0D002B080072010000700D000772370000701B8D010000011306110616086F2D00000A8C28000001A2110617086F2800000A8C29000001A2110618086F2E00000A8C29000001A211061906A211061A09A211066F2F00000A26076F3000000A26002B2C0007728F000070086F2800000A8C29000001086F2E00000A8C29000001066F3100000A26076F3000000A2600086F2800000A027B02000004FE0216FE01130511052D0E0002086F2800000A7D020000040000000011046F3200000A130511053AAAFEFFFFDE1D110475220000011307110714FE01130511052D0811076F2000000A00DC0002076F1800000A7D010000042A000000411C000002000000210000005D0100007E0100001D000000000000001B3003000201000004000011141304730500000613050072DB000070733300000A0B0000076F3400000A0007176F3500000A000711042D111105FE0606000006733600000A13042B0011046F3700000A00720D01007007733800000A250A130600110572010000707D010000041105167D02000004026F3900000A733A00000A0C061A6F3B00000A00066F3C00000A722901007002733D00000A6F3E00000A26066F3F00000A260411057B010000046F4000000A734100000A510311057B02000004284200000A810500000100DE14110614FE01130711072D0811066F2000000A00DC0000DE0E0D00096F4300000A734400000A7A0000DE120714FE01130711072D07076F2000000A00DC00002A000001280000020054006FC300140000000000001700C4DB000E3400000102001600D7ED0012000000001E02282200000A2A42534A4201000100000000000C00000076322E302E35303732370000000005006C000000C0040000237E00002C0500001407000023537472696E677300000000400C00004001000023555300800D0000100000002347554944000000900D00008402000023426C6F620000000000000002000001571502000902000000FA25330016000001000000350000000300000002000000060000000900000045000000130000000400000001000000030000000100000000000A00010000000000060051004A000A00790064000A00950064000A00AF0064000A00B80064000A00F800DD0006004D012E01060071015F01060088015F010600A5015F010600C4015F010600DD015F010600F6015F01060011025F0106002C025F01060045022E01060059025F010600850272024B00990200000600C802A8020600E802A8020A001903DD0006005003440306005E034A0006006F034A000E00A40399030E00B00399030600D603CC030E00E30399030600F103CC030E00FC0399030E00160499030E001E049903060030044A000A004404DD000A009E0488040A00DE04880406000F05FC040A003505880406006E054A00060094054A000A00B90588040A00DA05C7050A00110688040A003C0688040A005206C7050A005C0658000A00780688040A009E0688040600CB064A000600D5064A000A00EA0688040600F706A80200000000010000000000010001000100100021000000050001000100030110005A04000005000100050006006D044A01060077044D01502000000000960083000A000100CC200000000096009C00110003002823000000009600C100180005006024000000008618D700240008004C21000000008618D700240008005421000000008600B60450010800000000000000000001000A01000000000000000001001701000001001B01020002002201020003005A0100000100D20400000200D9043100D70024003900D70024004100D7003B004900D7003B005100D7003B005900D7003B006100D7003B006900D7003B007100D7003B007900D7003B008100D70040008900D7003B009100D7004500A100D7004B00A900D7002400B100D700240011002E038E00110038039200B900D7002400C10065039800C90074039D00B9007E03A200C1008503A800090090038E00D100D70024001900BA03F600D100C703FB00E100D7000101E900D7000701E90007040D0101012804130111013C0424001901D70024000900D7002400B900D7003B002101F104580129011B055E0131012905640139013E058E0039014A056801B90054056C0139015F05A800390174058E00C1008205720139018905A800390199056801B900A3057901B90054058101B900A30586013101B0058F015101D7003B005901E70524005101EC0540006101D700A60151012C06AC016901D700B30121004706BB01C100D700C00171016806C60169018F06CD018901D700D3018101AB06D9017101AF06A800C100BF06BB012100D700C00129003803E20191013E058E009901D7003B00A901D700240020008300500024000B0028002E0023001B022E002B001B022E00330021022E007B0064022E001B0003022E004B001B022E0073005B022E00430030022E003B0003022E005B001B022E006B00520240008300B70044000B00280060000B01280163002B02FE0164000B00280084000B002800AC001A019301E80104800000010000000714466A00000000000006030000020000000000000000000000010041000000000002000000000000000000000001005800000000000200000000000000000000000100990300000000030002000000003C4D6F64756C653E00596F757253716C4462615F436C72457865632E646C6C0045786563757465596F757253716C446261436D64735468726F756768434C52006D73636F726C69620053797374656D004F626A6563740053797374656D2E446174610053797374656D2E446174612E53716C54797065730053716C537472696E6700436C725F52656D6F766543746C436861720053716C586D6C00436C725F586D6C5072657474795072696E740053716C43686172730053716C496E74333200436C725F45786563416E644C6F67416C6C4D736773002E63746F72004D6963726F736F66742E53716C5365727665722E5365727665720053716C4661636574417474726962757465006265666F726545736361706500586D6C0053716C436D64004D617853657665726974790053797374656D2E52756E74696D652E496E7465726F705365727669636573004F7574417474726962757465004D7367730053797374656D2E5265666C656374696F6E00417373656D626C795469746C6541747472696275746500417373656D626C794465736372697074696F6E41747472696275746500417373656D626C79436F6E66696775726174696F6E41747472696275746500417373656D626C79436F6D70616E7941747472696275746500417373656D626C7950726F6475637441747472696275746500417373656D626C79436F7079726967687441747472696275746500417373656D626C7954726164656D61726B41747472696275746500417373656D626C7943756C7475726541747472696275746500436F6D56697369626C6541747472696275746500417373656D626C7956657273696F6E4174747269627574650053797374656D2E446961676E6F73746963730044656275676761626C6541747472696275746500446562756767696E674D6F6465730053797374656D2E52756E74696D652E436F6D70696C6572536572766963657300436F6D70696C6174696F6E52656C61786174696F6E734174747269627574650052756E74696D65436F6D7061746962696C69747941747472696275746500596F757253716C4462615F436C72457865630053716C46756E6374696F6E417474726962757465006765745F56616C7565006F705F496D706C696369740053797374656D2E5465787400537472696E674275696C64657200537472696E67006765745F43686172730043686172004973436F6E74726F6C00417070656E64006765745F4C656E67746800546F537472696E670053797374656D2E586D6C00586D6C446F63756D656E7400586D6C52656164657200437265617465526561646572004C6F61640053797374656D2E494F00537472696E6757726974657200586D6C54657874577269746572005465787457726974657200466F726D617474696E67007365745F466F726D617474696E6700586D6C4E6F646500586D6C577269746572005772697465546F0049446973706F7361626C6500446973706F73650053716C50726F636564757265417474726962757465003C3E635F5F446973706C6179436C61737332004C6F63616C4D736773004C6F63616C4D617853657665726974790053797374656D2E446174612E53716C436C69656E740053716C496E666F4D6573736167654576656E7441726773003C436C725F45786563416E644C6F67416C6C4D7367733E625F5F300073656E64657200617267730053716C4572726F72436F6C6C656374696F6E006765745F4572726F72730053797374656D2E436F6C6C656374696F6E730049456E756D657261746F7200476574456E756D657261746F72006765745F43757272656E740053716C4572726F72006765745F4D657373616765006765745F436C61737300417070656E644C696E65006765745F4C696E654E756D62657200496E743332006765745F50726F63656475726500466F726D6174006765745F4E756D6265720042797465006765745F537461746500417070656E64466F726D6174004D6F76654E6578740053716C436F6E6E656374696F6E0053797374656D2E446174612E436F6D6D6F6E004462436F6E6E656374696F6E004F70656E007365745F46697265496E666F4D6573736167654576656E744F6E557365724572726F72730053716C496E666F4D6573736167654576656E7448616E646C6572006164645F496E666F4D6573736167650053716C436F6D6D616E64006765745F427566666572004462436F6D6D616E6400436F6D6D616E6454797065007365745F436F6D6D616E64547970650053716C506172616D65746572436F6C6C656374696F6E006765745F506172616D65746572730053716C506172616D657465720041646400457865637574654E6F6E517565727900546F43686172417272617900457863657074696F6E004170706C69636174696F6E457863657074696F6E0053716C457863657074696F6E00436F6D70696C657247656E6572617465644174747269627574650000000001003320006100740020006C0069006E00650020007B0030007D00200069006E002000700072006F00630020007B0031007D00200000574500720072006F00720020007B0030007D002C0020005300650076006500720069007400790020007B0031007D002C0020006C006500760065006C0020007B0032007D0020003A0020007B0033007D007B0034007D00004B5700610072006E0069006E00670020005300650076006500720069007400790020007B0030007D002C0020006C006500760065006C0020007B0031007D0020003A0020007B0032007D00003163006F006E007400650078007400200063006F006E006E0065006300740069006F006E003D0074007200750065003B00001B730070005F006500780065006300750074006500530071006C0000154000730074006100740065006D0065006E0074000000AA6CEFD529B9F442B1324A9955514A3C0008B77A5C561934E089060001110911090600011109120D0B00030112111011151012110320000112010001005408074D617853697A65FFFFFFFF042001010E042001010205200101114D04200101083D01000300540E044E616D6511436C725F52656D6F766543746C4368617254020F497344657465726D696E697374696301540209497350726563697365010320000E05000111090E04200103080400010203052001125D03032000080A07060E125D03081109023E01000300540E044E616D6512436C725F586D6C5072657474795072696E7454020F497344657465726D696E69737469630154020949735072656369736501042000126D05200101126D05200101125D05200101127905200101117D062001011280850D07061269125D127112751109022101000100540E044E616D6515436C725F45786563416E644C6F67416C6C4D73677302060E020608072002011C1280910520001280950520001280990320001C03200005052001125D0E0600030E0E1C1C072002125D0E1D1C042000125D082004125D0E1C1C1C032000021207080E125D12809D0E128099021D1C128089052002011C18062001011280B1072002010E1280A90420001D03052001011D03062001011180BD0520001280C1052002010E1C0820011280C51280C50500011115081507081280B51280A90E1280D11280B1120C1280B502040100000017010012596F757253716C4462615F436C724578656300000501000000000E0100094D6963726F736F667400002101001C436F7079726967687420C2A920536F6369C3A974C3A920475249435300000801000701000000000801000800000000001E01000100540216577261704E6F6E457863657074696F6E5468726F7773010000000000DC98D55200000000020000001C01000098340000981600005253445327609F2559CCC94D924DFC882D58C7C001000000633A5C45717569706553716C5C596F757253716C4462615C596F757253716C4462615F436C72457865635C6F626A5C44656275675C596F757253716C4462615F436C72457865632E7064620000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000DC3500000000000000000000FE350000002000000000000000000000000000000000000000000000F03500000000000000000000000000000000000000005F436F72446C6C4D61696E006D73636F7265652E646C6C0000000000FF250020001000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000100100000001800008000000000000000000000000000000100010000003000008000000000000000000000000000000100000000004800000058400000740300000000000000000000740334000000560053005F00560045005200530049004F004E005F0049004E0046004F0000000000BD04EFFE0000010000000100466A071400000100466A07143F000000000000000400000002000000000000000000000000000000440000000100560061007200460069006C00650049006E0066006F00000000002400040000005400720061006E0073006C006100740069006F006E00000000000000B004D4020000010053007400720069006E006700460069006C00650049006E0066006F000000B0020000010030003000300030003000340062003000000034000A00010043006F006D00700061006E0079004E0061006D006500000000004D006900630072006F0073006F00660074000000500013000100460069006C0065004400650073006300720069007000740069006F006E000000000059006F0075007200530071006C004400620061005F0043006C00720045007800650063000000000040000F000100460069006C006500560065007200730069006F006E000000000031002E0030002E0035003100320037002E00320037003200300036000000000050001700010049006E007400650072006E0061006C004E0061006D006500000059006F0075007200530071006C004400620061005F0043006C00720045007800650063002E0064006C006C000000000058001A0001004C006500670061006C0043006F007000790072006900670068007400000043006F0070007900720069006700680074002000A900200053006F0063006900E9007400E90020004700520049004300530000005800170001004F0072006900670069006E0061006C00460069006C0065006E0061006D006500000059006F0075007200530071006C004400620061005F0043006C00720045007800650063002E0064006C006C0000000000480013000100500072006F0064007500630074004E0061006D0065000000000059006F0075007200530071006C004400620061005F0043006C00720045007800650063000000000044000F000100500072006F006400750063007400560065007200730069006F006E00000031002E0030002E0035003100320037002E00320037003200300036000000000048000F00010041007300730065006D0062006C0079002000560065007200730069006F006E00000031002E0030002E0035003100320037002E00320037003200300036000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000003000000C000000103600000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000 WITH PERMISSION_SET = SAFE GO EXEC sys.sp_addextendedproperty @name=N'SqlAssemblyProjectRoot', @value=N'C:\EquipeSql\YourSqlDba\YourSqlDba_ClrExec' , @level0type=N'ASSEMBLY',@level0name=N'YourSqlDba_ClrExec' GO CREATE PROCEDURE yExecNLog.Clr_ExecAndLogAllMsgs @SqlCmd nvarchar(max), @MaxSeverity Int Output, @Msgs nvarchar(max) OUTPUT AS EXTERNAL NAME [YourSqlDba_ClrExec].[ExecuteYourSqlDbaCmdsThroughCLR].[Clr_ExecAndLogAllMsgs] GO Create Function yExecNLog.Clr_RemoveCtlChar (@beforeEscape nvarchar(max)) returns nvarchar(max) as EXTERNAL NAME [YourSqlDba_ClrExec].[ExecuteYourSqlDbaCmdsThroughCLR].[Clr_RemoveCtlChar] GO -- no more in use Create Function yExecNLog.Clr_XmlPrettyPrint (@Xml Xml) returns nvarchar(max) as EXTERNAL NAME [YourSqlDba_ClrExec].[ExecuteYourSqlDbaCmdsThroughCLR].Clr_XmlPrettyPrint GO -- Create assemblies and procedure and function that points to them IF EXISTS (SELECT * FROM sys.assemblies asms WHERE asms.name = N'YourSqlDba_ClrFileOp') DROP ASSEMBLY [YourSqlDba_ClrFileOp] GO /****** Object: SqlAssembly [YourSqlDba_ClrFileOp] Script Date: 03/15/2012 16:25:38 ******/ CREATE ASSEMBLY [YourSqlDba_ClrFileOp] AUTHORIZATION [dbo] FROM 0x4D5A90000300000004000000FFFF0000B800000000000000400000000000000000000000000000000000000000000000000000000000000000000000800000000E1FBA0E00B409CD21B8014CCD21546869732070726F6772616D2063616E6E6F742062652072756E20696E20444F53206D6F64652E0D0D0A2400000000000000504500004C0103000894D5520000000000000000E00002210B010B000020000000060000000000001E3F0000002000000040000000000010002000000002000004000000000000000400000000000000008000000002000000000000030040850000100000100000000010000010000000000000100000000000000000000000D03E00004B00000000400000E803000000000000000000000000000000000000006000000C000000983D00001C0000000000000000000000000000000000000000000000000000000000000000000000000000000000000000200000080000000000000000000000082000004800000000000000000000002E74657874000000241F0000002000000020000000020000000000000000000000000000200000602E72737263000000E8030000004000000004000000220000000000000000000000000000400000402E72656C6F6300000C0000000060000000020000002600000000000000000000000000004000004200000000000000000000000000000000003F0000000000004800000002000500C8290000D013000001000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000001B3003004B0000000100001100178D1A0000010C08161F5C9D080A0272010000706F1100000A16FE010D092D0902066F1200000A10000002281300000A260372050000705100DE0D0B0003076F1400000A5100DE00002A000110000000002A00123C000D1E0000011B3003004B0000000100001100178D1A0000010C08161F5C9D080A0272010000706F1100000A16FE010D092D0902066F1200000A10000002281500000A000372050000705100DE0D0B0003076F1400000A5100DE00002A000110000000002A00123C000D1E0000011B3004005C0000000100001100178D1A0000010C08161F5C9D080A0272010000706F1100000A16FE010D092D0902066F1200000A1000000202281600000A720100007003281700000A281800000A000472050000705100DE0D0B0004076F1400000A5100DE00002A0110000000002A00234D000D1E0000011B300300A10000000200001100731A00000A0B178D1A00000113061106161F5C9D11060C0272010000706F1100000A16FE01130711072D0902086F1200000A1000000203281B00000A0A000613081613092B19110811099A0D0709281C00000A6F1D00000A26110917581309110911088E69FE04130711072DD900DE27130400076F1E00000A000772070000706F1D00000A260711046F1400000A6F1D00000A2600DE00000713052B0011052A00000001100000000035003C7100271E0000011330020016000000030000110002281F00000A0A0306282000000A732100000A512A00001B300300400100000400001100731A00000A0B178D1A00000113081108161F5C9D110813040272010000706F1100000A16FE01130911092D0A0211046F1200000A1000000203281B00000A0A0006130A16130B2B65110A110B9A1305001105732200000A0D1202096F2300000A7D010000041202096F2400000A7D020000041202096F2500000A7D030000041202096F2600000A7D040000041202096F2700000A7D0500000407088C020000026F1D00000A2600110B1758130B110B110A8E69FE04130911092D8D00DE78130600076F1E00000A00120272070000707D01000004120272170000707D020000041202166A7D030000041202721F000070282800000A7D040000041202721F000070282800000A7D0500000407088C020000026F1D00000A26120211066F1400000A7D0100000407088C020000026F1D00000A2600DE00000713072B0011072A011000000000370088BF00781E0000011330020067000000050000110002A5020000020A0312007B01000004282000000A732100000A510412007B02000004282000000A732100000A510512007B03000004732900000A81060000010E0412007B04000004732A00000A81070000010E0512007B05000004732A00000A81070000012A001B300200260000000600001100000302282B00000A520472050000705100DE100A0003165204066F1400000A5100DE00002A00000110000000000100131400101E0000011B3002002200000006000011000002282C00000A000372050000705100DE0D0A0003066F1400000A5100DE00002A000001100000000001001213000D1E0000011B3003007B0000000700001100178D1A00000113041104161F5C9D11040B0272010000706F1100000A16FE01130511052D0902076F1200000A1000000203281B00000A0A000613061613072B13110611079A0C08282C00000A00110717581307110711068E69FE04130511052DDF0472050000705100DE0D0D0004096F1400000A5100DE00002A000110000000002F003D6C000D1E0000011B300400BA0000000800001100178D1A00000113041104161F5C9D11040B0272010000706F1100000A16FE01130511052D0902076F1200000A10000002723500007003282D00000A281B00000A0A000613061613072B48110611079A0C081B8D1B000001130811081602A21108177201000070A211081808282E00000AA2110819723B000070A211081A04A21108282F00000A283000000A00110717581307110711068E69FE04130511052DAA0572050000705100DE0D0D0005096F1400000A5100DE00002A00000110000000002F007CAB000D1E0000011B3004002F000000060000110000020202281C00000A036F3100000A283000000A000472050000705100DE0D0A0004066F1400000A5100DE00002A0001100000000001001F20000D1E0000011B300300310000000900001100178D1A0000010C08161F5C9D080A000203283200000A000472050000705100DE0D0B0004076F1400000A5100DE00002A0000000110000000000F001322000D1E0000011B3004005C0000000100001100178D1A0000010C08161F5C9D080A0372010000706F1100000A16FE010D092D0903066F1200000A1001000203720100007002281C00000A281700000A283000000A000472050000705100DE0D0B0004076F1400000A5100DE00002A0110000000002A00234D000D1E0000011B300400A90000000700001100178D1A00000113041104161F5C9D11040B0272010000706F1100000A16FE01130511052D0902076F1200000A10000472010000706F1100000A16FE01130511052D0904076F1200000A1002000203281B00000A0A000613061613072B24110611079A0C0804720100007008281C00000A281700000A283000000A00110717581307110711068E69FE04130511052DCE0572050000705100DE0D0D0005096F1400000A5100DE00002A0000000110000000004C004E9A000D1E0000011B3002002E0000000A000011000002732200000A0A03066F2500000A550472050000705100DE110B0003166A5504076F1400000A5100DE00002A000001100000000001001A1B00111E0000011B3002004D0000000B0000110003721F000070282800000A8103000001047205000070510002282B00000A16FE010B072D0E0302283300000A81030000012B0704723F0000705100DE0D0A0004066F1400000A5100DE00002A0000000110000000001800263E000D1E0000011B3002004D0000000B0000110003721F000070282800000A8103000001047205000070510002282B00000A16FE010B072D0E0302283400000A81030000012B0704723F0000705100DE0D0A0004066F1400000A5100DE00002A0000000110000000001800263E000D1E0000011B30020023000000060000110004720500007051000203283500000A0000DE0D0A0004066F1400000A5100DE00002A0001100000000008000C14000D1E0000011B30020023000000060000110004720500007051000203283600000A0000DE0D0A0004066F1400000A5100DE00002A0001100000000008000C14000D1E0000011E02283700000A2A42534A4201000100000000000C00000076322E302E35303732370000000005006C00000050060000237E0000BC0600006007000023537472696E6773000000001C0E000060000000235553007C0E00001000000023475549440000008C0E00004405000023426C6F620000000000000002000001571502000900000000FA25330016000001000000260000000300000005000000150000003B000000370000001D0000000B000000010000000200000000000A0001000000000006005B0054000600650054000600900054000600F800E5000A00370122010A00730122010A007C0122010600D402B5020600970385030600AE0385030600CB0385030600EA03850306000304850306001C04850306003704850306005204850306006B04B50206007F0485030600AB0498044F00BF0400000600EE04CE0406000E05CE0406004105B50206005705B5020A007D0562050600930554000600980554000600BA05B0050600C405B0050600E20554000600FF05B0050A002106620506003606E50006005F0654000A007006220106008606B00506008F06B0050600EE06B00500000000010000000000010001000801100023000000050001000100010010002F00380009000600010006006C000A00060075000A00060083000D000600990010000600A60010005020000000009600B20014000100B820000000009600C300140003002021000000009600D4001B0005009821000000009600040123000800582200000000960040012A000A007C22000000009600590123000C00D823000000009600880132000E004C24000000009600A901460014009024000000009600B80114001700D024000000009600C7011B0019006825000000009600D7014F001C004026000000009600F0011B0020008C26000000009600FF011B002300DC260000000096000C021B002600542700000000960019024F0029001C28000000009600270258002D0068280000000096003B0261003000D42800000000960053026100330040290000000096006A021B003600802900000000960081021B003900C02900000000861897026B003C00000001009D0202000200A802000001009D0202000200A802000001009D0200000200E10202000300A802000001009D0200000200EF0200000100FD02020002006C00000001009D0200000200EF0200000100FD02020002006C0002000300750002000400830002000500990002000600A600000001000103020002000A0302000300A80200000100010302000200A802000001009D0200000200EF0202000300A802000001009D0200000200190300000300260302000400A80200000100010300000200330302000300A802000001003F03000002004E0302000300A802000001003F0300000200620302000300A802000001009D0200000200EF0200000300620302000400A80200000100010302000200830002000300A80200000100010302000200990002000300A80200000100010302000200A60002000300A80200000100010300000200780302000300A80200000100010300000200780302000300A802410097026B00490097026F00510097026F00590097026F00610097026F00690097026F00710097026F00790097026F00810097026F00890097027400910097026F00990097027900A90097027F00B10097026B00B90097028400C90097026B00D9009F05A700D900A805AC00E100D205B200F100EC05B800E100F805E300F90004060501D90015060A01E1001C061101010197026B00090197026B00E10040068B01F90049060501090155069201090159066B0011016706AC0119017A06B10129009702B801210197026F0029019E06B8002901A706B8002101B506A7022901C006AB022901D206AB021101E306B00231009702D00239009702D5023101F306FB023101F805E300D90015067103F900FA060501D9001506770331011C061101D9001607AA0331011E07110131012307B00231013407B002310144071101310152071101110097026B00200083008A002E005300D9042E006B001C052E004300D9042E00630013052E00730025052E002300D9042E003B00EE042E001B00D9042E001300BF042E002B00DF042E003300BF0440008300C60060008300E8008000CB001701C000CB00C30100018300E002200183000503400183002003600183004C03800183008F03A0018300B003C0018300D203E0018300EB03000283000504200283002D04400283005704600283007A04800283009D04BC009701BF01B602DB0200033C037D03C9032504510404800000010000000714DC670000000000002C05000002000000000000000000000001004B000000000002000000000000000000000001001601000000000000003C4D6F64756C653E00596F757253716C4462615F436C7246696C654F702E646C6C0046696C6544657461696C730046696C654F70437300436C725F46696C654F7065726174696F6E73006D73636F726C69620053797374656D0056616C756554797065004F626A6563740046696C654E616D650046696C65457874656E73696F6E0046696C6553697A6542797465004461746554696D65004D6F6469666965644461746500437265617465644461746500436C725F437265617465466F6C64657200436C725F44656C657465466F6C64657200436C725F52656E616D65466F6C6465720053797374656D2E436F6C6C656374696F6E730049456E756D657261626C6500436C725F476574466F6C6465724C6973740053797374656D2E446174610053797374656D2E446174612E53716C54797065730053716C436861727300436C725F476574466F6C6465724C69737446696C6C526F7700436C725F476574466F6C6465724C69737444657461696C65640053716C496E7436340053716C4461746554696D6500436C725F476574466F6C6465724C69737444657461696C656446696C6C526F7700436C725F46696C6545786973747300436C725F44656C65746546696C6500436C725F44656C65746546696C657300436C725F4368616E676546696C65457874656E73696F6E7300436C725F52656E616D6546696C6500436C725F436F707946696C6500436C725F4D6F766546696C6500436C725F4D6F766546696C657300436C725F47657446696C6553697A654279746500436C725F47657446696C65446174654D6F64696669656400436C725F47657446696C65446174654372656174656400436C725F417070656E64537472696E67546F46696C6500436C725F5772697465537472696E67546F46696C65002E63746F7200466F6C64657250617468004572726F724D6573736167650053797374656D2E52756E74696D652E496E7465726F705365727669636573004F7574417474726962757465004E6577466F6C6465724E616D65005365617263685061747465726E006F626A0046696C65506174680046696C65457869737473466C6167004F6C64457874656E73696F6E004E6577457874656E73696F6E004E657746696C654E616D6500536F7572636546696C65506174680044657374696E6174696F6E46696C65506174680044657374696E6174696F6E466F6C646572506174680046696C65436F6E74656E74730053797374656D2E5265666C656374696F6E00417373656D626C795469746C6541747472696275746500417373656D626C794465736372697074696F6E41747472696275746500417373656D626C79436F6E66696775726174696F6E41747472696275746500417373656D626C79436F6D70616E7941747472696275746500417373656D626C7950726F6475637441747472696275746500417373656D626C79436F7079726967687441747472696275746500417373656D626C7954726164656D61726B41747472696275746500417373656D626C7943756C7475726541747472696275746500436F6D56697369626C6541747472696275746500417373656D626C7956657273696F6E4174747269627574650053797374656D2E446961676E6F73746963730044656275676761626C6541747472696275746500446562756767696E674D6F6465730053797374656D2E52756E74696D652E436F6D70696C6572536572766963657300436F6D70696C6174696F6E52656C61786174696F6E734174747269627574650052756E74696D65436F6D7061746962696C69747941747472696275746500596F757253716C4462615F436C7246696C654F70005374727563744C61796F7574417474726962757465004C61796F75744B696E64004D6963726F736F66742E53716C5365727665722E5365727665720053716C50726F636564757265417474726962757465004368617200537472696E6700456E647357697468005472696D456E640053797374656D2E494F004469726563746F7279004469726563746F7279496E666F004372656174654469726563746F727900457863657074696F6E006765745F4D6573736167650044656C6574650050617468004765744469726563746F72794E616D6500436F6E636174004D6F76650053716C46756E6374696F6E4174747269627574650041727261794C6973740047657446696C65730047657446696C654E616D650041646400436C65617200436F6E7665727400546F537472696E670053716C537472696E67006F705F496D706C696369740046696C65496E666F0046696C6553797374656D496E666F006765745F4E616D65006765745F457874656E73696F6E006765745F4C656E677468006765745F4C617374577269746554696D65006765745F4372656174696F6E54696D6500546F4461746554696D650046696C65004578697374730047657446696C654E616D65576974686F7574457874656E73696F6E005265706C61636500436F7079004765744C617374577269746554696D65004765744372656174696F6E54696D6500417070656E64416C6C54657874005772697465416C6C54657874000000035C000001000F3C004500520052004F0052003E000007450052005200001531003900300030002D00300031002D003000310001052A002E0000032E00001F500061007400680020006E006F007400200066006F0075006E0064002E00000069F35BF5DADA714CB3CAEB2028898EE90008B77A5C561934E08902060E02060A0306110D060002010E100E070003010E0E100E06000212110E0E070002011C101215130006011C10121510121510111910111D10111D080003010E1002100E080004010E0E0E100E080003010E100A100E090003010E10110D100E03200001042001010E042001010205200101115104200101080520010111611C01000100540E044E616D6510436C725F437265617465466F6C646572042001020E0520010E1D0305000112750E0320000E0907041D0312791D03021C01000100540E044E616D6510436C725F44656C657465466F6C646572040001010E1C01000100540E044E616D6510436C725F52656E616D65466F6C6465720400010E0E0600030E0E0E0E050002010E0E7301000300540E044E616D6511436C725F476574466F6C6465724C697374540E0F5461626C65446566696E6974696F6E1646696C654E616D65206E766172636861722832353529540E1146696C6C526F774D6574686F644E616D6518436C725F476574466F6C6465724C69737446696C6C526F770600021D0E0E0E042001081C14070A1D0E1280851D030E127912111D03021D0E080400010E1C06000111808D0E0620010111808D0307010E80E201000300540E044E616D6519436C725F476574466F6C6465724C69737444657461696C6564540E0F5461626C65446566696E6974696F6E7546696C654E616D65206E7661726368617228323535292C2046696C65457874656E73696F6E206E7661726368617228323535292C2046696C6553697A654279746520626967696E742C204D6F64696669656444617465206461746574696D652C204372656174656444617465206461746574696D65540E1146696C6C526F774D6574686F644E616D6520436C725F476574466F6C6465724C69737444657461696C656446696C6C526F770320000A042000110D050001110D0E19070C1D0E12808511081280911D030E127912111D03021D0E08042001010A05200101110D04070111081A01000100540E044E616D650E436C725F46696C65457869737473040001020E04070112791A01000100540E044E616D650E436C725F44656C65746546696C651B01000100540E044E616D650F436C725F44656C65746546696C65730F07081D0E1D030E12791D03021D0E082401000100540E044E616D6518436C725F4368616E676546696C65457874656E73696F6E730500020E0E0E0500010E1D0E1107091D0E1D030E12791D03021D0E081D0E1A01000100540E044E616D650E436C725F52656E616D6546696C650520020E0E0E1801000100540E044E616D650C436C725F436F707946696C650807031D0312791D031801000100540E044E616D650C436C725F4D6F766546696C651901000100540E044E616D650D436C725F4D6F766546696C65731F01000100540E044E616D6513436C725F47657446696C6553697A654279746507070212809112792301000100540E044E616D6517436C725F47657446696C65446174654D6F6469666965640507021279022201000100540E044E616D6516436C725F47657446696C6544617465437265617465642201000100540E044E616D6516436C725F417070656E64537472696E67546F46696C652101000100540E044E616D6515436C725F5772697465537472696E67546F46696C6519010014596F757253716C4462615F436C7246696C654F7000000501000000000E0100094D6963726F736F667400002401001F436F7079726967687420C2A920536F6369657465204752494353203230313100000801000701000000000801000800000000001E01000100540216577261704E6F6E457863657074696F6E5468726F777301000000000894D55200000000020000001C010000B43D0000B41F0000525344535294223278304D449CFDBA5847D2D19101000000633A5C45717569706553716C5C596F757253716C4462615C596F757253716C4462615F436C7246696C654F705C6F626A5C44656275675C596F757253716C4462615F436C7246696C654F702E70646200000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000F83E000000000000000000000E3F0000002000000000000000000000000000000000000000000000003F00000000000000005F436F72446C6C4D61696E006D73636F7265652E646C6C0000000000FF25002000100000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000100100000001800008000000000000000000000000000000100010000003000008000000000000000000000000000000100000000004800000058400000900300000000000000000000900334000000560053005F00560045005200530049004F004E005F0049004E0046004F0000000000BD04EFFE0000010000000100DC67071400000100DC6707143F000000000000000400000002000000000000000000000000000000440000000100560061007200460069006C00650049006E0066006F00000000002400040000005400720061006E0073006C006100740069006F006E00000000000000B004F0020000010053007400720069006E006700460069006C00650049006E0066006F000000CC020000010030003000300030003000340062003000000034000A00010043006F006D00700061006E0079004E0061006D006500000000004D006900630072006F0073006F00660074000000540015000100460069006C0065004400650073006300720069007000740069006F006E000000000059006F0075007200530071006C004400620061005F0043006C007200460069006C0065004F0070000000000040000F000100460069006C006500560065007200730069006F006E000000000031002E0030002E0035003100320037002E00320036003500380038000000000054001900010049006E007400650072006E0061006C004E0061006D006500000059006F0075007200530071006C004400620061005F0043006C007200460069006C0065004F0070002E0064006C006C000000000064001F0001004C006500670061006C0043006F007000790072006900670068007400000043006F0070007900720069006700680074002000A900200053006F006300690065007400650020004700520049004300530020003200300031003100000000005C00190001004F0072006900670069006E0061006C00460069006C0065006E0061006D006500000059006F0075007200530071006C004400620061005F0043006C007200460069006C0065004F0070002E0064006C006C00000000004C0015000100500072006F0064007500630074004E0061006D0065000000000059006F0075007200530071006C004400620061005F0043006C007200460069006C0065004F0070000000000044000F000100500072006F006400750063007400560065007200730069006F006E00000031002E0030002E0035003100320037002E00320036003500380038000000000048000F00010041007300730065006D0062006C0079002000560065007200730069006F006E00000031002E0030002E0035003100320037002E003200360035003800380000000000000000000000000000000000000000000000000000000000003000000C000000203F00000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000 WITH PERMISSION_SET = EXTERNAL_ACCESS GO CREATE PROC yUtl.clr_CreateFolder (@FolderPath nvarchar(4000), @ErrorMessage nvarchar(4000) OUTPUT) AS EXTERNAL NAME [YourSqlDba_ClrFileOp].[Clr_FileOperations.FileOpCs].[Clr_CreateFolder]; GO CREATE PROC yUtl.clr_DeleteFolder (@FolderPath nvarchar(4000), @ErrorMessage nvarchar(4000) OUTPUT) AS EXTERNAL NAME [YourSqlDba_ClrFileOp].[Clr_FileOperations.FileOpCs].[Clr_DeleteFolder]; GO CREATE PROC yUtl.clr_RenameFolder (@FolderPath nvarchar(4000), @NewFolderName nvarchar(4000), @ErrorMessage nvarchar(4000) OUTPUT) AS EXTERNAL NAME [YourSqlDba_ClrFileOp].[Clr_FileOperations.FileOpCs].[Clr_RenameFolder]; GO CREATE FUNCTION yUtl.clr_GetFolderList (@FolderPath nvarchar(4000), @SearchPattern nvarchar(4000)) RETURNS TABLE ([FileName] nvarchar(255)) AS EXTERNAL NAME [YourSqlDba_ClrFileOp].[Clr_FileOperations.FileOpCs].[Clr_GetFolderList]; GO CREATE FUNCTION yUtl.clr_GetFolderListDetailed (@FolderPath nvarchar(4000), @SearchPattern nvarchar(4000)) RETURNS TABLE ([FileName] nvarchar(255), [FileExtension] nvarchar(255), [Size] bigint, [ModifiedDate] datetime, [CreatedDate] datetime) AS EXTERNAL NAME [YourSqlDba_ClrFileOp].[Clr_FileOperations.FileOpCs].[Clr_GetFolderListDetailed]; GO CREATE PROC yUtl.clr_FileExists (@FilePath nvarchar(4000), @FileExistsFlag bit OUTPUT, @ErrorMessage nvarchar(4000) OUTPUT) AS EXTERNAL NAME [YourSqlDba_ClrFileOp].[Clr_FileOperations.FileOpCs].[Clr_FileExists]; GO CREATE PROC yUtl.clr_DeleteFile (@FolderPath nvarchar(4000), @ErrorMessage nvarchar(4000) OUTPUT) AS EXTERNAL NAME [YourSqlDba_ClrFileOp].[Clr_FileOperations.FileOpCs].[Clr_DeleteFile]; GO CREATE PROC yUtl.clr_DeleteFiles (@FolderPath nvarchar(4000), @SearchPattern nvarchar(4000), @ErrorMessage nvarchar(4000) OUTPUT) AS EXTERNAL NAME [YourSqlDba_ClrFileOp].[Clr_FileOperations.FileOpCs].[Clr_DeleteFiles]; GO CREATE PROC yUtl.clr_ChangeFileExtensions (@FolderPath nvarchar(4000), @OldExtension nvarchar(4000), @NewExtension nvarchar(4000), @ErrorMessage nvarchar(4000) OUTPUT) AS EXTERNAL NAME [YourSqlDba_ClrFileOp].[Clr_FileOperations.FileOpCs].[Clr_ChangeFileExtensions]; GO CREATE PROC yUtl.clr_RenameFile (@FilePath nvarchar(4000), @NewFileName nvarchar(4000), @ErrorMessage nvarchar(4000) OUTPUT) AS EXTERNAL NAME [YourSqlDba_ClrFileOp].[Clr_FileOperations.FileOpCs].[Clr_RenameFile]; GO CREATE PROC yUtl.clr_CopyFile (@SourceFilePath nvarchar(4000), @DestinationFilePath nvarchar(4000), @ErrorMessage nvarchar(4000) OUTPUT) AS EXTERNAL NAME [YourSqlDba_ClrFileOp].[Clr_FileOperations.FileOpCs].[Clr_CopyFile]; GO CREATE PROC yUtl.clr_MoveFile (@SourceFilePath nvarchar(4000), @DestinationFolderPath nvarchar(4000), @ErrorMessage nvarchar(4000) OUTPUT) AS EXTERNAL NAME [YourSqlDba_ClrFileOp].[Clr_FileOperations.FileOpCs].[Clr_MoveFile]; GO CREATE PROC yUtl.clr_MoveFiles (@FolderPath nvarchar(4000), @SearchPattern nvarchar(4000), @DestinationFolderPath nvarchar(4000), @ErrorMessage nvarchar(4000) OUTPUT) AS EXTERNAL NAME [YourSqlDba_ClrFileOp].[Clr_FileOperations.FileOpCs].[Clr_MoveFiles]; GO CREATE PROC yUtl.clr_GetFileSizeByte (@FilePath nvarchar(4000), @FileSizeByte bigint OUTPUT, @ErrorMessage nvarchar(4000) OUTPUT) AS EXTERNAL NAME [YourSqlDba_ClrFileOp].[Clr_FileOperations.FileOpCs].[Clr_GetFileSizeByte]; GO CREATE PROC yUtl.clr_GetFileDateModified (@FilePath nvarchar(4000), @ModifiedDate datetime OUTPUT, @ErrorMessage nvarchar(4000) OUTPUT) AS EXTERNAL NAME [YourSqlDba_ClrFileOp].[Clr_FileOperations.FileOpCs].[Clr_GetFileDateModified]; GO CREATE PROC yUtl.clr_GetFileDateCreated (@FilePath nvarchar(4000), @CreatedDate datetime OUTPUT, @ErrorMessage nvarchar(4000) OUTPUT) AS EXTERNAL NAME [YourSqlDba_ClrFileOp].[Clr_FileOperations.FileOpCs].[Clr_GetFileDateCreated]; go CREATE PROC yUtl.clr_AppendStringToFile (@FilePath nvarchar(4000), @FileContents nvarchar(MAX), @ErrorMessage nvarchar(4000) OUTPUT) AS EXTERNAL NAME [YourSqlDba_ClrFileOp].[Clr_FileOperations.FileOpCs].[Clr_AppendStringToFile]; GO CREATE PROC yUtl.clr_WriteStringToFile (@FilePath nvarchar(4000), @FileContents nvarchar(MAX), @ErrorMessage nvarchar(4000) OUTPUT) AS EXTERNAL NAME [YourSqlDba_ClrFileOp].[Clr_FileOperations.FileOpCs].[Clr_WriteStringToFile]; GO If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yInstall.SqlVersionNumber' go Create Function yInstall.SqlVersionNumber () Returns Int as Begin Declare @i int; With VersionBrute (ver) as (Select convert(nvarchar, serverproperty('ProductVersion'))) Select @i = convert (int, Left(ver, charindex('.', ver)-1)) From VersionBrute return @i*10 -- match compatibility level End go If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yUtl.ReduceRepeatingSpaceToOne' GO -- this function reduce repeating spaces to a single one in one quick replace create function yUtl.ReduceRepeatingSpaceToOne(@s nvarchar(max) ) returns nvarchar(max) as Begin return (replace(replace(replace(@s, ' ', ' !'), '! ', ''), '!', '')) End go -- this procedure reports bestPractices to follow If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'PerfMon.GetBestPracticesMsgs' GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO Create Function PerfMon.GetBestPracticesMsgs () returns Table as Return ( With MemSqlmax (MemIngb) as ( Select top 1 -- for some reason this top 1 clause makes the optimizer choose an access plan that works fine with the loop below. (found at sql2012 sp3) Convert(int, Round((total_physical_memory_kb/(1024.0)) / 1024.0, 0)) From sys.dm_os_sys_memory ) -- rows builder for a loop , L0 AS (select 1 as c union all Select 1 as c ) --2 , L1 as (select 1 as C From L0 as A Cross JOIN L0 as B ) --4 , L2 as (select 1 as C From L1 as A Cross JOIN L1 as B ) -- 16 , L3 as (select 1 as C From L2 as A Cross JOIN L2 as B ) -- 256 , L4 as (select 1 as C From L3 as A Cross JOIN L3 as B ) -- 65536 -- row_number() limits the number of row built , nums as (Select ROW_NUMBER() OVER (Order by c) as i from L4) -- condition goes over previous row_number() indirectly which limits it , Loop as (Select * From MemSqlMax Join Nums ON i <= MemInGb) , FreeSpaceByGb as ( Select memInGb , Loop.i , Case When Loop.i <= 4 then 0 -- below 4Gb, there is already 1Gb that will be added later When Loop.i > 4.1 and Loop.i <= 16 Then 0.25 -- between 4Gb et 16Gb add 0.25Gb of free space by Gb for the OS When Loop.i > 16.1 Then 0.125 -- Above 16gb add 0.125 Gb of free space by Gb for the OS End as FreeMem From Loop ) --Select * from FreeSpaceByGb Order by i , TbMinFreeSpaceInMb as ( Select MemInGb, 1+SUM(FreeMem) as ToFree, Convert(Int, ((MemInGb - (1+SUM(FreeMem))) * 1024)) as MaxSpaceToUseInMb From FreeSpaceByGb Group By MemInGb ) --Select * from TbMinFreeSpaceInMb , optionVal (opt, val) as ( Select 'Max server memory (MB)', convert(int, MaxSpaceToUseInMb) From sys.configurations CROSS JOIN TbMinFreeSpaceInMb Where (1=0) And name = 'max server memory (MB)' And (value_in_use = 0 Or value_in_use > CONVERT(Int, MaxSpaceToUseInMb)) UNION ALL Select 'max degree of parallelism', 3 From sys.configurations Where name = 'max degree of parallelism' And value = 0 UNION ALL Select 'cost threshold for parallelism', 50 From sys.configurations C1 JOIN sys.configurations C2 ON C2.name = 'max degree of parallelism' And C2.Value <> 1 JOIN sys.dm_os_sys_info DMOS ON DMOS.cpu_count > 1 And DMOS.affinity_type_desc = 'AUTO' Where C1.name = 'cost threshold for parallelism' And C1.value < 50 UNION ALL Select 'backup compression default', 1 From sys.configurations Where name = 'backup compression default' And value <> 1 UNION ALL Select 'nested triggers', 1 From sys.configurations Where name = 'nested triggers' And value <> 1 ) Select Case When @@LANGUAGE <> 'français' Then 'Adjust following server settings by executing following commands:' Else 'Ajuster les propriétés suivantes du serveur en exécutant les commandes suivantes' End + '
' + r3.s + '
Reconfigure
GO
' as MsgLines From ( Select (Select CONVERT(nvarchar(max), '
exec Sp_Configure '''+opt+''', '+convert(nvarchar, val) + '
GO') From optionVal for Xml path('')) as Msgs ) as r0 CROSS APPLY (Select REPLACE (r0.Msgs, '>', '>') ) as r1(s) CROSS APPLY (Select REPLACE (r1.s, '≪', '<') ) as r2(s) CROSS APPLY (Select REPLACE (r2.s, ' ', '
')) as r3(s) ) GO Exec yUtl.DropObj 'PerfMon.ReportIgnoredBestPractices' GO Create Proc PerfMon.ReportIgnoredBestPractices @email_Address sysname As Begin Declare @Msg Nvarchar(max) Select @Msg = GM.MsgLines From PerfMon.GetBestPracticesMsgs() GM If @Msg IS NOT NULL EXEC Msdb.dbo.sp_send_dbmail @profile_name = 'YourSQLDba_EmailProfile' , @recipients = @email_Address , @importance = 'High' , @subject = 'YourSqlDba : Apply following good practices to your SQL Server configuration' , @body = @Msg , @body_format = 'HTML' -- Exec PerfMon.ReportIgnoredBestPractices 'pelchatm@grics.ca' End GO If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yExecNLog.QryReplace' GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO create procedure yExecNLog.QryReplace -- do multiple replace on dynamic SQL generation @sql nvarchar(max) Output , @srch1 nvarchar(1000) , @by1 nvarchar(1000) , @srch2 nvarchar(1000) = '' , @by2 nvarchar(1000) = '' , @srch3 nvarchar(1000) = '' , @by3 nvarchar(1000) = '' , @srch4 nvarchar(1000) = '' , @by4 nvarchar(1000) = '' , @srch5 nvarchar(1000) = '' , @by5 nvarchar(1000) = '' , @srch6 nvarchar(1000) = '' , @by6 nvarchar(1000) = '' as Begin set @sql = replace (@sql, @srch1, @by1) If isnull(@srch2,'') <> '' Set @sql = replace (@sql, @srch2, @by2) If isnull(@srch3,'') <> '' Set @sql = replace (@sql, @srch3, @by3) If isnull(@srch4,'') <> '' Set @sql = replace (@sql, @srch4, @by4) If isnull(@srch5,'') <> '' Set @sql = replace (@sql, @srch5, @by5) If isnull(@srch6,'') <> '' Set @sql = replace (@sql, @srch6, @by6) End -- yExecNLog.QryReplace GO Exec yUtl.DropObj 'yUtl.ColumnInfo' go Create function yUtl.ColumnInfo (@tbName sysname, @colName sysname, @typeName sysname = NULL) returns table as return ( Select OBJECT_SCHEMA_NAME (c.object_id) as schName, object_name(object_id) as TbName, TYPE_NAME (c.user_type_id) as TypeName, c.* From Sys.columns C Where c.object_id = object_id(@tbName) And c.name = @colName And (@typeName is NULL Or @typeName = TYPE_NAME (c.user_type_id) ) ) GO -- yUtl.ColumnInfo If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yExecNLog.FormatBasicBeginCatchErrMsg' GO create function yExecNLog.FormatBasicBeginCatchErrMsg () returns nvarchar(max) as Begin Return ( 'err :' + convert(nvarchar(10), ISNULL(error_number(),0)) + ' ' + ISNULL(ERROR_MESSAGE (),'No err Msg') + ' ' + case when error_procedure() is not null Then ' In procedure ' + error_procedure() + ':' End + case when error_line() is not null Then ' at line ' + CONVERT(nvarchar, ERROR_LINE()) End ) End go If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yExecNLog.Unindent_TSQL' -- newer shema GO -- ------------------------------------------------------------------------------ -- This function unindent TSQL code so that the leftmost code is in column one -- It helps log log dynamic T-SQL that is originally generated indented relative -- to it the code where it is defined. It is to ease nice dynamic code formatting -- at code level, and avoid extra indentation of gnererated code in logs -- ------------------------------------------------------------------------------ If Db_name() <> 'YourSqlDba' Use YourSqlDba GO create function yExecNLog.Unindent_TSQL ( @sql nvarchar(max) ) returns nvarchar(max) as Begin Declare @NbOfLn Int Declare @NextSql nvarchar(max) -- Unindent T-SQL to have leftmost code to start in column on Set @NbOfLn = len(@sql) - len(replace(@sql, nchar(10)+' ', nchar(10)+'')) If @NbOfLn = 0 Return (@sql) -- otherwise endless loop (happen with empty @sql string or @sql string without CRLF While (1 = 1) Begin set @NextSql = replace (@sql, nchar(10)+' ', nchar(10)+'') If len(@sql) - len(@NextSql) = @NbOfLn Set @sql = @NextSql Else Break End -- while Return (@sql) End -- yExecNLog.Unindent_TSQL GO If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yExecNLog.ReplaceByXmlEscapeChar' GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO -- this function purpose is to replace all chars -- that needs to be escpaed in XML before converting old table content Create Function yExecNLog.ReplaceByXmlEscapeChar (@txt varchar(max)) returns nvarchar(max) as Begin With t0 (t) as (select @txt) , t1 (t) as (select REPLACE(t, '&', '&') from t0) , t2 (t) as (select REPLACE(t, '<', '<') from t1) , t3 (t) as (select REPLACE(t, '>', '>') from t2) Select @txt = t from t3 Return (@txt) End go If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yInstall.DoubleLastSpaceInFirst78Colums' GO create function yInstall.DoubleLastSpaceInFirst78Colums ( @msg nvarchar(max) ) returns nvarchar(max) as Begin If len(@msg) > 78 -- Note that a bug exist in sp_send_dbmail. -- The @subject parameter is wrap from the 78 th column. -- Then the previous space is replaced by a line feed which is then ignore by sp_send_dbmail. -- A solution is to replace the last space in the first 78 columns of the "@msg" variable -- by two spaces. Begin Declare @First78 nvarchar(max) Declare @reverse78 nvarchar(max) Declare @spacePos int Set @First78 = left(@msg, 78) Set @reverse78 = REVERSE(@First78) Set @spacePos = PATINDEX('% %', @reverse78) -- position of the first space Set @spacePos = 79 - @spacePos -- position of the last space in the first 78 characters Set @msg = STUFF(@msg, @spacePos, 1, ' ') -- Replace the space by 2 spaces End Return @msg End -- yInstall.DoubleLastSpaceInFirst78Colums GO If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yInstall.DoubleLastSpaceInFirst150Colums' GO create function yInstall.DoubleLastSpaceInFirst150Colums ( @msg nvarchar(max) ) returns nvarchar(max) as Begin If len(@msg) > 150 -- Note that a bug exist in sp_send_dbmail. -- The @subject parameter is wrap from the 78 th column and the 150 th. -- Then the previous space is replaced by a line feed which is then ignore by sp_send_dbmail. -- A solution is to replace the last space in the first 78 colomns of the "@msg" variable -- by two spaces. And also the 150 th column. Begin Declare @First150 nvarchar(max) Declare @reverse150 nvarchar(max) Declare @spacePos int Set @First150 = left(@msg, 150) Set @reverse150 = REVERSE(@First150) Set @spacePos = PATINDEX('% %', @reverse150) -- position of the first space Set @spacePos = 151 - @spacePos -- position of the last space in the first 150 characters Set @msg = STUFF(@msg, @spacePos, 1, ' ') -- Replace the space by 2 spaces End Return @msg End -- yInstall.DoubleLastSpaceInFirst150Colums GO If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'PerfMon.LockChainView' GO CREATE view PerfMon.LockChainView as With LockChainCTE as ( select A.program_name as BlockingApp , A.hostname as BlockingHost , A.cmd as BlockingCmd , A.spid as BlockindSpid , DB_NAME(A.dbid) as BlockingDbSite , A.blocked as BlockedSPid from master.sys.sysprocesses As A where A.spid >= 51 And A.blocked > 0 UNION ALL Select B.program_name , B.hostname , B.cmd , b.spid , DB_NAME(B.dbid) , B.blocked From LockChainCTE as A join master.sys.sysprocesses as B ON B.spid = A.BlockindSpid ) select A.* , B.program_name as BlockedApp , B.hostname as BlockedHost , B.cmd as BlockedCmd , DB_NAME(b.dbid) as BlockedDbSite from LockChainCte A join master.sys.sysprocesses as B On B.spid = A.BlockedSPid -- End of view PerfMon.LockChainView GO ------------------------------------------------------------------------------------------------------------ If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'PerfMon.ResetAnalyzeWaitStats' GO -- This procedure is derived from code obtained from Paul Randal blog's site Create Procedure PerfMon.ResetAnalyzeWaitStats as DBCC SQLPERF ('sys.dm_os_wait_stats', CLEAR); go If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'PerfMon.AnalyzeWaitStats' GO -- This function is derived from code obtained from Paul Randal blog's site Create Function PerfMon.AnalyzeWaitStats () returns table as return ( -- reset wait stats with this : DBCC SQLPERF ('sys.dm_os_wait_stats', CLEAR); with unwanted_wait_types (wait_type) as ( --select --'select '''+wait_type+''' union all ' --from sys.dm_os_wait_stats order by wait_type select 'BROKER_EVENTHANDLER' union all select 'BROKER_RECEIVE_WAITFOR' union all select 'BROKER_TASK_STOP' union all select 'BROKER_TO_FLUSH' union all select 'BROKER_TRANSMITTER' union all select 'CHECKPOINT_QUEUE' union all select 'CHKPT' union all select 'CLR_AUTO_EVENT' union all select 'CLR_MANUAL_EVENT' union all select 'CLR_SEMAPHORE' union all select 'DBMIRROR_DBM_MUTEX' union all select 'DBMIRROR_EVENTS_QUEUE' union all select 'DBMIRRORING_CMD' union all select 'DIRTY_PAGE_POLL' union all -- sql2012 select 'DISPATCHER_QUEUE_SEMAPHORE' union all select 'FFT_RECOVERY' union all select 'FT_IFTS_SCHEDULER_IDLE_WAIT' union all select 'FT_IFTSHC_MUTEX' union all select 'HADR_FILESTREAM_IOMGR_IOCOMPLETION' union all select 'LOGMGR_QUEUE' union all select 'LAZYWRITER_SLEEP' union all select 'ONDEMAND_TASK_QUEUE' union all select 'PWAIT_ALL_COMPONENTS_INITIALIZED' union all Select 'QDS_CLEANUP_STALE_QUERIES_TASK_MAIN_LOOP_SLEEP' union all Select 'QDS_PERSIST_TASK_MAIN_LOOP_SLEEP' union all select 'REQUEST_FOR_DEADLOCK_SEARCH' union all select 'RESOURCE_QUEUE' union all select 'SERVER_IDLE_CHECK' union all select 'SLEEP' union all select 'SLEEP_BPOOL_FLUSH' union all select 'SLEEP_DBSTARTUP' union all select 'SLEEP_DCOMSTARTUP' union all select 'SLEEP_MASTERDBREADY' union all select 'SLEEP_MSDBSTARTUP' union all select 'SLEEP_SYSTEMTASK' union all select 'SLEEP_TASK' union all select 'SLEEP_TEMPDBSTARTUP' union all select 'SNI_HTTP_ACCEPT' union all select 'SP_SERVER_DIAGNOSTICS_SLEEP' union all select 'SQLTRACE_FILE_BUFFER_FLUSH' union all select 'SQLTRACE_INCREMENTAL_FLUSH_SLEEP' union all select 'Total' union all select 'TRACEWRITE' union all select 'WAITFOR' union all select 'WAITFOR_TASKSHUTDOWN' union all select 'XE_DISPATCHER_JOIN' union all select 'XE_DISPATCHER_WAIT' union all select 'XE_TIMER_EVENT' union all select '' where 1=2 ) , Waits_Sum_Wait_time_ms AS ( SELECT wait_type, signal_wait_time_ms, wait_time_ms / 1000.0 AS WaitS, (wait_time_ms - signal_wait_time_ms) / 1000.0 AS ResourceS, signal_wait_time_ms / 1000.0 AS SignalS, waiting_tasks_count AS WaitCount, wait_time_ms, Sum(wait_time_ms) OVER() AS TotalTimeMs, ROW_NUMBER() OVER(ORDER BY wait_time_ms DESC) AS RowNum FROM sys.dm_os_wait_stats WHERE wait_type NOT IN (Select wait_type from unwanted_wait_types) And wait_type not like 'PREEMPTIVE[_]%' ) , Waits AS ( SELECT wait_type, wait_time_ms / 1000.0 AS WaitS, (wait_time_ms - signal_wait_time_ms) / 1000.0 AS ResourceS, signal_wait_time_ms / 1000.0 AS SignalS, Waitcount, 100.0 * wait_time_ms / (case when TotalTimeMs > 0.0 Then TotalTimeMs Else 1 End) AS Percentage, RowNum FROM Waits_Sum_Wait_time_ms Where WaitCount > 0 ) SELECT W1.wait_type AS WaitType, CAST (W1.WaitS AS DECIMAL(14, 2)) AS Wait_S, CAST (W1.ResourceS AS DECIMAL(14, 2)) AS Resource_S, CAST (W1.SignalS AS DECIMAL(14, 2)) AS Signal_S, W1.WaitCount AS WaitCount, CAST (W1.Percentage AS DECIMAL(5, 2)) AS Percentage, CAST ((W1.WaitS / W1.WaitCount) AS DECIMAL (14, 4)) AS AvgWait_S, CAST ((W1.ResourceS / W1.WaitCount) AS DECIMAL (14, 4)) AS AvgRes_S, CAST ((W1.SignalS / W1.WaitCount) AS DECIMAL (14, 4)) AS AvgSig_S FROM Waits AS W1 INNER JOIN Waits AS W2 ON W2.RowNum <= W1.RowNum GROUP BY W1.RowNum, W1.wait_type, W1.WaitS, W1.ResourceS, W1.SignalS, W1.WaitCount, W1.Percentage HAVING SUM (W2.Percentage) - W1.Percentage < 95 -- percentage threshold ) go exec yUtl.DropObj 'yPerfMon.ActiveQueryInBatch' go create function yPerfMon.ActiveQueryInBatch(@batch nvarchar(max), @start int, @end int) returns table return ( With CalcStartEnd as (Select (@start/2)+1 as start, (CASE @end When -1 Then DATALENGTH(@batch) Else @End End)/2+1 as Stringlen) Select SUBSTRING (@batch, start, Stringlen) as RunningQuery from CalcStartEnd ); go exec yUtl.DropObj 'perfmon.SessionInfo' go create view perfmon.SessionInfo as select q.RunningQuery , T.Text as QueryBatch , db_name(r.database_id) as dbName , r.blocking_session_id as BlockedBy , S.host_name , S.program_name , S.status , S.cpu_time , S.memory_usage , S.row_count , S.total_scheduled_time , S.total_elapsed_time , S.reads , S.writes , S.logical_reads , r.start_time , r.percent_complete , s.last_request_start_time , S.last_request_end_time , S.login_name , S.client_interface_name , S.client_version , S.nt_domain , S.nt_user_name , S.context_info , S.endpoint_id , S.is_user_process , S.language , S.date_format , S.date_first , S.quoted_identifier , S.arithabort , S.ansi_null_dflt_on , S.ansi_defaults , S.ansi_warnings , S.ansi_padding , S.ansi_nulls , S.concat_null_yields_null , S.transaction_isolation_level , S.lock_timeout , S.deadlock_priority , S.prev_error , S.original_security_id , S.original_login_name , S.last_successful_logon , S.last_unsuccessful_logon , S.unsuccessful_logons , S.login_time , S.host_process_id , C.protocol_version , C.net_transport , p.query_plan from sys.dm_exec_sessions S left join sys.dm_exec_connections C On C.session_id = S.session_id left join sys.dm_exec_requests R on R.session_id = S.session_id outer apply sys.dm_exec_sql_text (r.sql_handle) as T outer apply yPerfMon.ActiveQueryInBatch(T.Text, r.statement_start_offset, r.statement_end_offset) as q outer apply sys.dm_exec_query_plan(r.plan_handle) p where s.program_name is not null go exec yUtl.DropObj 'PerfMon.DetailQueriesStats' go /*===CreatePerfMon.DetailQueriesStats=== Create Function PerfMon.DetailQueriesStats() Returns Table as Return ( With QueryStats as ( SELECT P.type_desc , DB_NAME(database_id) as DbName , object_name(object_id, database_id) as ObjName , CONVERT(nvarchar(max), '') as RunningQryInBatch , T.query_plan , cached_time , last_execution_time , execution_count , total_worker_time , last_worker_time , min_worker_time , max_worker_time , total_physical_reads , last_physical_reads , min_physical_reads , max_physical_reads , total_logical_writes , last_logical_writes , min_logical_writes , max_logical_writes , total_logical_reads , last_logical_reads , min_logical_reads , max_logical_reads , total_elapsed_time , last_elapsed_time , min_elapsed_time , max_elapsed_time FROM master.sys.dm_exec_procedure_stats as P cross apply sys.dm_exec_query_plan(plan_handle) as T UNION ALL SELECT P.type_desc , DB_NAME(database_id) , object_name(object_id, database_id) , CONVERT(nvarchar(max), '') as RunningQryInBatch , T.query_plan , cached_time , last_execution_time , execution_count , total_worker_time , last_worker_time , min_worker_time , max_worker_time , total_physical_reads , last_physical_reads , min_physical_reads , max_physical_reads , total_logical_writes , last_logical_writes , min_logical_writes , max_logical_writes , total_logical_reads , last_logical_reads , min_logical_reads , max_logical_reads , total_elapsed_time , last_elapsed_time , min_elapsed_time , max_elapsed_time FROM master.sys.dm_exec_Trigger_stats as P cross apply sys.dm_exec_query_plan(plan_handle) as T UNION ALL SELECT P.type_desc , DB_NAME(database_id) , object_name(object_id, database_id) , CONVERT(nvarchar(max), '') as RunningQryInBatch , T.query_plan , cached_time , last_execution_time , execution_count , total_worker_time , last_worker_time , min_worker_time , max_worker_time , total_physical_reads , last_physical_reads , min_physical_reads , max_physical_reads , total_logical_writes , last_logical_writes , min_logical_writes , max_logical_writes , total_logical_reads , last_logical_reads , min_logical_reads , max_logical_reads , total_elapsed_time , last_elapsed_time , min_elapsed_time , max_elapsed_time FROM master.sys.dm_exec_Function_stats as P cross apply sys.dm_exec_query_plan(plan_handle) as T UNION ALL SELECT 'Query' , '' , '' , RunningQryInBatch , query_plan , NULL , last_execution_time , execution_count , total_worker_time , last_worker_time , min_worker_time , max_worker_time , total_physical_reads , last_physical_reads , min_physical_reads , max_physical_reads , total_logical_writes , last_logical_writes , min_logical_writes , max_logical_writes , total_logical_reads , last_logical_reads , min_logical_reads , max_logical_reads , total_elapsed_time , last_elapsed_time , min_elapsed_time , max_elapsed_time FROM master.sys.dm_exec_query_stats as Q cross apply sys.dm_exec_query_plan(Q.plan_handle) as P cross apply sys.dm_exec_sql_text(Q.Sql_handle) as T cross apply (Select StartOfQryInBatch = 1+(Q.statement_start_offset/2)) as vStartOfQryInBatch cross apply (Select BatchLen = DATALENGTH(T.text)) as vBatchLen cross apply (Select QryStrLen = 1+(Case When Q.statement_end_offset=-1 Then BatchLen Else Q.statement_end_offset End)/2) as vQueryLen Cross Apply (Select RunningQryInBatch = Substring(T.text, StartOfQryInBatch, QryStrLen)) as vRunningQryInBatch ) Select * From QueryStats Where total_logical_reads/execution_count > 100 ) ===CreatePerfMon.DetailQueriesStats===*/ declare @Sql nvarchar(max) Select @Sql = CreateStmt From (Select FullVersion=cast(ServerProperty('Productversion') as nvarchar(20))) as vFullVersion CROSS APPLY (Select MajorVersion=Left(FullVersion, charindex('.', FullVersion)-1) ) as Majorversion CROSS APPLY (Select MyOwnSqlHandle=sql_handle From sys.dm_exec_requests Where session_id = @@SPID) as vMyOwnSqlHandle -- Select SQL text from this running batch (work in or out of this procedure, and makes easy to select and run Cross Apply (Select batchTxt=Text From sys.dm_exec_sql_text(MyOwnSqlHandle)) as vSelfSpText -- locate and extract code between /*===DynamicCodeTemplateToBuildDropStatement=== and ===DynamicCodeTemplateToBuildDropStatement===*/ above CROSS APPLY (Select CreateStmtDelim='===CreatePerfMon.DetailQueriesStats===') as vCreateStmt CROSS APPLY (Select AfterCmtStart=charindex('/*'+CreateStmtDelim, BatchTxt)+LEN(CreateStmtDelim)+2 ) As vAfterCmtStart CROSS APPLY (Select PosStartCmtEnd=charindex(CreateStmtDelim+'*/', BatchTxt) ) as vPosStartCmtEnd CROSS APPLY (Select CreateStmt=Substring(BatchTxt, AfterCmtStart, PosStartCmtEnd-AfterCmtStart) ) as vCommentContent Where Majorversion >= 13 Exec (@Sql) GO -- ------------------------------------------------------------------------------ -- Création des tables d'historique -- ------------------------------------------------------------------------------ If Db_name() <> 'YourSqlDba' Use YourSqlDba GO -- under construction If object_id('Maint.DbMaintPolicies') is not null And Not Exists (select * from yUtl.ColumnInfo ('Maint.DbMaintPolicies', 'FullBkExt', NULL)) Drop Table Maint.DbMaintPolicies go If Db_name() <> 'YourSqlDba' Use YourSqlDba GO Exec yUtl.DropObj 'Maint.XpCmdShellSavedState' go CREATE TABLE Maint.XpCmdShellSavedState ( EnforceSingleRowTable int default 1 primary key , value_In_Use int ) go -- create the latest version by keep most recent data from previous version -- that match by columns names Declare @sql nvarchar(max) Set @sql = ' Create table Maint.JobHistory ( JobNo int identity(1,1) , JobStart DateTime Default (getdate()) , JobEnd DateTime Default (getdate()) , spid Int Default @@spid , JSonPrms Nvarchar(max) , constraint Pk_HistMaintTrav primary key clustered (JobNo) ) ' Exec yExecNLog.QryReplace @sql output, '"', '''' Exec (@sql) If object_id('tempdb..##JobHistory') is not null -- successfully created Begin Select @Sql = Sql From ( Select * From ( -- comma separated list of matching column name between previous version of the table and this one Select MatchingColsList= ( Select convert(nvarchar(max), ','+name) as [text()] -- concat matching cols From YourSqlDba.Sys.Columns Y Where object_id=Object_id('YourSqlDba.Maint.JobHistory') And Exists -- a matching col of original table in TempDb..##JobHistory ( Select * FROM tempdb.Sys.Columns Tmp Where object_id=Object_id('TempDb..##JobHistory') And Y.Name = Tmp.Name Collate Database_default ) Order by column_id For xml path('') ) ) as MatchingColsBeforeAndAfter -- remove first comma in the cols list CROSS APPLY (Select MatchingCols=Stuff(MatchingColsList, 1, 1, '')) as MatchingCols ) As MatchingCols CROSS JOIN ( Select Template = ' Set Identity_insert YourSqlDba.Maint.JobHistory ON Delete YourSqlDba.Maint.JobHistory Insert into YourSqlDba.Maint.JobHistory («Cols») Select «Cols» From ##JobHistory Drop Table ##JobHistory Set Identity_insert YourSqlDba.Maint.JobHistory OFF ' ) as Template CROSS APPLY (Select Sql=REPLACE(template, '«Cols»', MatchingCols)) as Sql Exec (@sql) End GO GO Drop Function If Exists dbo.MainContextInfo GO Create Function dbo.MainContextInfo (@JobNo Int) returns table as return -- --------------------------------------------------------------------------------------------- -- This is a mecanism that allows to have access to parameters related to a maintenance -- job without having to pass them around from proc to proc across parameters. -- -- They are stored as a Json value, and set into the session context. -- Job Entry in Maint.JobHistory is persisted into JsonPrms column, when Job entry is created. -- Each Job entry has JobNo. -- -- When a job entry is created this Json value is stored into Maint.JobHistory -- If @JobNo isn't NULL parameters are extracted from JsonPrms stored into Maint.JobHistory. -- If @JobNo is NULL parameters are extracted from JsonPrms stored into session_context. -- -- --------------------------------------------------------------------------------------------- Select JobNo , JobStart , JobEnd , Oper=JSON_VALUE(JsonPrms, '$.oper') , MaintJobName = JSON_VALUE(JsonPrms, '$.MaintJobName') , SqlAgentJobName = JSON_VALUE(JsonPrms, '$.SqlAgentJobName') , IncDb=JSON_VALUE(JsonPrms, '$.IncDb') , ExcDb=JSON_VALUE(JsonPrms, '$.ExcDb') , command = JSON_VALUE(JsonPrms, '$.command') , DoInteg = JSON_VALUE(JsonPrms, '$.DoInteg') , DoUpdStats = JSON_VALUE(JsonPrms, '$.DoUpdStats') , DoReorg = JSON_VALUE(JsonPrms, '$.DoReorg') , DoBackup = JSON_VALUE(JsonPrms, '$.DoBackup') , DoFullBkp = JSON_VALUE(JsonPrms, '$.DoFullBkp') , DoDiffBkp = JSON_VALUE(JsonPrms, '$.DoDiffBkp') , DoLogBkp = JSON_VALUE(JsonPrms, '$.DoLogBkp') , MigrationTestMode = JSON_VALUE(JsonPrms, '$.MigrationTestMode') , FullBackupPath = JSON_VALUE(JsonPrms, '$.FullBackupPath') , LogBackupPath = JSON_VALUE(JsonPrms, '$.LogBackupPath') , TimeStampNamingForBackups = JSON_VALUE(JsonPrms, '$.TimeStampNamingForBackups') , FullBkExt = JSON_VALUE(JsonPrms, '$.FullBkExt') , LogBkExt = JSON_VALUE(JsonPrms, '$.LogBkExt') , FullBkpRetDays = Cast(JSON_VALUE(JsonPrms, '$.FullBkpRetDays') as int) , LogBkpRetDays = Cast(JSON_VALUE(JsonPrms, '$.LogBkpRetDays') as int) , NotifyMandatoryFullDbBkpBeforeLogBkp = JSON_VALUE(JsonPrms, '$.NotifyMandatoryFullDbBkpBeforeLogBkp') , BkpLogsOnSameFile = JSON_VALUE(JsonPrms, '$.BkpLogsOnSameFile') , SpreadUpdStatRun = Cast(JSON_VALUE(JsonPrms, '$.SpreadUpdStatRun') as int) , SpreadCheckDb = Cast(JSON_VALUE(JsonPrms, '$.SpreadCheckDb') as int) , ConsecutiveDaysOfFailedBackupsToPutDbOffline = Cast(JSON_VALUE(JsonPrms, '$.ConsecutiveDaysOfFailedBackupsToPutDbOffline') as int) , MirrorServer = JSON_VALUE(JsonPrms, '$.MirrorServer') , ReplaceSrcBkpPathToMatchingMirrorPath = JSON_VALUE(JsonPrms, '$.ReplaceSrcBkpPathToMatchingMirrorPath') , ReplacePathsInDbFilenames = JSON_VALUE(JsonPrms, '$.ReplacePathsInDbFilenames') , ExcDbFromPolicy_CheckFullRecoveryModel = JSON_VALUE(JsonPrms, '$.ExcDbFromPolicy_CheckFullRecoveryModel') , EncryptionAlgorithm = JSON_VALUE(JsonPrms, '$.EncryptionAlgorithm') , EncryptionCertificate = JSON_VALUE(JsonPrms, '$.EncryptionCertificate') , Host = JSON_VALUE(JsonPrms, '$.Host') , Prog = JSON_VALUE(JsonPrms, '$.Prog') , Who = JSON_VALUE(JsonPrms, '$.Who') , MainCall = JSON_VALUE(JsonPrms, '$.MainCall') , JobId = JSON_VALUE(JsonPrms, '$.JobId') , StepId = JSON_VALUE(JsonPrms, '$.StepId') , JSonPrms From ( Select JSonPrms, JobNo, JobStart, JobEnd From Maint.JobHistory Where jobNo = @JobNo UNION ALL Select JSonPrms= Cast(SESSION_CONTEXT (N'JsonDoMaintPrm') as nvarchar(max)) , JobNo=@JobNo, JobStart=NULL, JobEnd=NULL Where @JobNo Is NULL ) as JsonPrms GO -- create the latest version by keep most recent data -- this IF is just useful when testing some parts of the code oterwise it is always true when running the whole script If object_id('Maint.JobSeqCheckDb') is null Begin Declare @sql nvarchar(max) Set @sql = ' Create table Maint.JobSeqUpdStat ( seq int ) Insert into Maint.JobSeqUpdStat values(0) ' Exec (@sql) If Object_Id('tempdb..##JobSeqUpdStat') IS NOT NULL -- try keep previous value Exec ( ' If Exists(Select * from Maint.JobSeqUpdStat) Truncate Table Maint.JobSeqUpdStat Insert Into Maint.JobSeqUpdStat (seq) Select Seq From ##JobSeqUpdStat If @@rowcount = 0 Insert into Maint.JobSeqUpdStat values(0) Drop table ##JobSeqUpdStat ' ) End GO -- this IF is just useful when testing some parts of the code oterwise it is always true when running the whole script If object_id('Maint.JobSeqCheckDb') is null Begin Declare @sql nvarchar(max) Set @sql = ' Create table Maint.JobSeqCheckDb ( seq int ) -- values are updated at start Insert into Maint.JobSeqCheckDb values(0) ' Exec (@sql) End GO -- Dbcc ShrinkLog state -- no need to upgrade If object_id('Maint.DbccShrinkLogState') is null Begin Declare @sql nvarchar(max) Set @sql = ' Create table Maint.DbccShrinkLogState ( dbName Sysname , FailedShrinkTime Datetime NULL , constraint Pk_DbccShrinkLogState primary key (dbName) ) ' Exec (@sql) End GO -- this IF is just useful when testing some parts of the code oterwise it is always true when running the whole script If object_id('Maint.JobLastBkpLocations') is null Begin Declare @sql nvarchar(max) Set @sql = ' Create table Maint.JobLastBkpLocations ( dbName Sysname , lastLogBkpFile nvarchar(512) NULL , FailedBkpCnt Int Default 0 , lastFullBkpFile nvarchar(512) NULL , lastDiffBkpFile nvarchar(512) NULL , keepTrace bit default 0 NOT NULL , MirrorServer Sysname NULL , MigrationTestMode Int Default 0 , lastFullBkpDate Datetime , ReplaceSrcBkpPathToMatchingMirrorPath nvarchar(max) NULL , ReplacePathsInDbFilenames nvarchar(max) NULL , EncryptionAlgorithm nvarchar(10) NULL , EncryptionCertificate nvarchar(100) NULL , constraint Pk_HistMaintDernBkpPart primary key clustered (dbName) ) ' Exec (@sql) If Object_Id('tempdb..##JobLastBkpLocations') IS NOT NULL Begin ;With MatchingColsBeforeAndAfter as ( Select ( Select convert(nvarchar(max), ','+name) as [text()] From YourSqlDba.Sys.Columns Y Where object_id=Object_id('YourSqlDba.Maint.JobLastBkpLocations') And Exists ( Select * FROM tempdb.Sys.Columns Tmp Where object_id=Object_id('TempDb..##JobLastBkpLocations') And Y.Name = Tmp.Name Collate Database_default ) Order by column_id For xml path('') ) as Cols -- comma separated list of matching column name between previous version of the table and this one ) , Template as ( Select ' Insert into YourSqlDba.Maint.JobLastBkpLocations («Cols») Select «Cols» From ##JobLastBkpLocations Drop Table ##JobLastBkpLocations ' as Sql , Stuff(Cols, 1, 1, '') as Cols -- remove first comma in the cols list From MatchingColsBeforeAndAfter ) Select @Sql = r0.s From Template CROSS APPLY (Select REPLACE(Sql, '«Cols»', Cols)) as r0(s) Exec(@Sql) --select @sql End End GO -- this IF is just useful when testing some parts of the code oterwise it is always true when running the whole script If object_id('Mirroring.TargetServer') is null Begin Declare @sql nvarchar(max) Set @sql = ' create table Mirroring.TargetServer ( MirrorServerName sysname Not Null default "" , constraint PK_TargetServer Primary Key (MirrorServerName) ) ' Set @Sql = Replace(@Sql, '"', '''') Exec (@sql) If Object_Id('tempdb..##TargetServer') IS NOT NULL Begin Set @sql = ' Insert Into Mirroring.TargetServer (MirrorServerName) Select ISNULL(T.MirrorServerName, "") From ##TargetServer T Where Exists(Select * From Sys.Servers as S Where S.name = T.MirrorServerName Collate Database_Default And S.is_linked = 1) -- cleanup missing mirrorServer if no matching linked server exists Drop table ##TargetServer ' Set @Sql = Replace(@Sql, '"', '''') Exec (@sql) End End GO -- this IF is just useful when testing some parts of the code oterwise it is always true when running the whole script If object_id('Maint.JobHistoryDetails') is NULL Begin Declare @sql nvarchar(max) Set @sql = ' Create table Maint.JobHistoryDetails ( JobNo Int Not NULL , seq Int identity(1,1) , cmdStartTime datetime default getdate() , Secs Int , ForDiagOnly Bit NULL , constraint PK_HistMaintSql primary key clustered (JobNo, seq) , constraint FK_JobMaintHistoryDetails_TO_JobMaintHistory foreign key (JobNo) references Maint.JobHistory (JobNo) On delete cascade ) Create Index iCmdStartTime On Maint.JobHistoryDetails(CmdStartTime) ' Exec yExecNLog.QryReplace @sql output, '"', '''' Exec (@sql) End GO -- this IF is just useful when testing some parts of the code oterwise it is always true when running the whole script If object_id('Maint.JobHistoryLineDetails') is NULL Begin Declare @sql nvarchar(max) Set @sql = ' Create table Maint.JobHistoryLineDetails ( JobNo Int Not NULL , seq Int Not NULL , TypSeq Int Not NULL , Typ nvarchar(6) Not NULL , line int Not NULL , Txt Nvarchar(max) NULL , constraint PK_JobHistoryLineDetails primary key clustered (JobNo, seq, TypSeq, line) , constraint FK_JobMaintHistoryLineDetails_TO_JobMaintHistoryDetails foreign key (JobNo, seq) references Maint.JobHistoryDetails (JobNo, seq) On delete cascade ) ' Exec yExecNLog.QryReplace @sql output, '"', '''' Exec (@sql) End GO -- -------------------------------------------------------------------------------------------- -- Return SQL code or XML text string in multi-rows, 1 row per code line -- Workround of the 8000 char limit when printing SQL code. -- -------------------------------------------------------------------------------------------- drop FUNCTION if exists yExecNLog.SqlCodeLinesInResultSet GO create FUNCTION yExecNLog.SqlCodeLinesInResultSet ( @sql nvarchar(max) ) RETURNS @TxtSql TABLE (i int identity (1, 1), txt nvarchar(max)) AS Begin declare @i int, @d Datetime If @i > 0 Insert into @txtSql (txt) values ('-- Seq:'+ltrim(str(@i))+ ' Time:'+convert(nvarchar(20), @d, 120) + ' ' + replicate('-', 10) ) If @sql is null Or @sql = '' Begin Insert into @txtSql (txt) values ('') return End declare @Start int, @End Int, @line nvarchar(max), @EOLChars int Set @Start = 1 Set @End=0 -- Normalize end-of-line -- Sql server interpret first #13#10 as a valid end-of-line otherwise #10 -- If #10#13 is found it is shown a two end-of-line Set @sql = REPLACE(@sql, nchar(13)+nchar(10), nchar(10)) -- normalize #13#10 -> #10 Set @sql = REPLACE(@sql, nchar(13), nchar(10)) -- normalize #10#13 -> #10#10 -- shown like this in normal SSMS output If charindex(Nchar(10), @Sql)=0 Set @sql=@sql+nchar(10) While(1=1) Begin Set @end = charindex(nchar(10), @Sql, @Start) If @End = 0 Begin Set @line = Substring(@sql, @Start, len(@sql)-@Start+1) Break End Else Set @line = Substring(@sql, @Start, @End-@Start+1) Set @Start = @End+1 Insert into @txtSql (txt) values (replace (replace (@line, nchar(10), ''), nchar(13), '')) End RETURN End -- yExecNLog.SqlCodeLinesInResultSet GO -- -- If object_id('tempdb..##JobHistoryLineDetails') IS NULL -- mock up an empty table for conversion so the query below will work Begin Exec( ' Select top 0 JobNo=1, seq=1, TypSeq=1, typ=convert(nvarchar(6),null), Line=1, Action=convert(nvarchar(max),null) Into ##JobHistoryLineDetails ') End -- this IF is just useful when testing some parts of the code oterwise it is always true when running the whole script If object_id('tempdb..##JobHistoryDetails') IS NOT NULL Begin Set Identity_insert YourSqlDba.Maint.JobHistoryDetails ON Exec (' -- With version 6.8.0.0 a complete overhaul of YourSqlDba logging system is done -- Everything meaningful (and a lot more readable) is directly inserted from yExecNLog.LogAndOrExec -- JobHistoryDetails only keeps track of entry sequence in the job Insert into YourSqlDba.Maint.JobHistoryDetails (JobNo, Seq, cmdStartTime, Secs, ForDiagOnly) Select JobNo, Seq, cmdStartTime, Secs, ForDiagOnly From ##JobHistoryDetails ') Set Identity_insert YourSqlDba.Maint.JobHistoryDetails OFF End GO If object_id('tempdb..##JobHistoryLineDetails') IS NOT NULL Begin Exec (' Insert into YourSqlDba.Maint.JobHistoryLineDetails (JobNo, Seq, TypSeq, Typ, line, Txt) Select * From ##JobHistoryLineDetails ') End GO -- this IF is just useful when testing some parts of the code oterwise it is always true when running the whole script If object_id('Maint.TemporaryBackupHeaderInfo') is NULL Begin Declare @sql nvarchar(max) Set @sql = ' Create table Maint.TemporaryBackupHeaderInfo ( spid int default @@spid -- columns needed by YourSqlDba , BackupType smallint , Position smallint , DeviceType tinyint , DatabaseName nvarchar(128) , LastLSN numeric(25,0) , constraint PK_TemporaryBackupHeaderInfo primary key (spid, backupType, position, deviceType, DatabaseName) ) ' Exec (@sql) End go -- this IF is just useful when testing some parts of the code oterwise it is always true when running the whole script If object_id('Maint.TemporaryBackupFileListInfo') is NULL Begin Declare @sql nvarchar(max) Set @sql = ' Create table Maint.TemporaryBackupFileListInfo ( spid int default @@spid -- columns needed by YourSqlDba , LogicalName nvarchar(128) -- Logical name of the file. , PhysicalName nvarchar(260) -- Physical or operating-system name of the file. , Type NCHAR(1) -- The type of file, one of: L = Microsoft SQL Server log file D = SQL Server data file F = Full Text Catalog , FileID bigint -- File identifier, unique within the database. , constraint PK_TemporaryBackupFileListInfo primary key (spid, FileId, Type) ) ' Exec (@sql) End go If Db_name() <> 'YourSqlDba' Use YourSqlDba declare @sql nvarchar(max) Set @sql = ' Exec yUtl.DropObj "Install.VersionInfo" Exec sp_ExecuteSql @SqlCreateFunction ' Set @sql = REPLACE(@sql, '"', '''') declare @createFct nvarchar(max) Set @createFct = ' CREATE function Install.VersionInfo () returns table as return ( Select "" As VersionNumber , "" as VersionDate , "" as UpdateReminderDate , Replicate ("=", 40) + nchar(10)+ "YourSQLDba version: " + nchar(10)+ Replicate ("=", 40) as Msg ) -- Install.VersionInfo ' Set @createFct = REPLACE(@createFct, '', (select version from #Version)) Set @createFct = REPLACE(@createFct, '', (select convert(nvarchar(10), versionDate, 120) from #Version)) Set @createFct = REPLACE(@createFct, '', (select convert(nvarchar(10), getdate()+365, 120))) Set @createFct = REPLACE(@createFct, '"', '''') Exec Sp_ExecuteSql @sql, N'@SqlCreateFunction nvarchar(max)', @SqlCreateFunction=@createFct go If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'Install.PrintVersionInfo' GO Create Proc Install.PrintVersionInfo as Begin declare @versionInfo as nvarchar(500) Select @versionInfo = msg from Install.VersionInfo () Print @versionInfo End go If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yInstall.NextUpdateTime' GO create function yInstall.NextUpdateTime ( ) returns datetime as Begin return(Select max(convert(datetime, UpdateReminderDate, 120)) from Install.VersionInfo() as f) End -- yInstall.NextUpdateTime GO If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yUtl.UnicodeCrLf' GO Create Function yUtl.UnicodeCrLf ( ) RETURNS nchar(2) AS BEGIN Return (N' ') END -- yUtl.UnicodeCrLf GO If Db_name() <> 'YourSqlDba' Use YourSqlDba go -- ----------------- fonction yUtl.SplitList ------------------------------------------------------------ -- Function that split a string into a set of rows based on a @sep list -- ----------------------------------------------------------------------------------------------------------- If OBJECT_ID('yUtl.SplitList') is not null drop function yUtl.SplitList go CREATE function yUtl.SplitList (@Sep nvarchar(max), @list nvarchar(max)) returns @items table (item nvarchar(max), seq int) as Begin declare @start as Int, @Next as Int, @seq as int, @item as nvarchar(max) select @start = 1, @seq = 0, @Next = 1 While (@next > 0) Begin Select @seq = @seq + 1, @Next = CHARINDEX (@Sep, @list, @start) If @Next > 0 Set @item = ltrim(SUBSTRING (@list, @start, @next-@start)) Else Set @item = ltrim(SUBSTRING (@list, @start, len(@list)+1-@start)) Insert into @items values (nullif (@item, ''), @seq) Set @start = @next+1 End return End go If Db_name() <> 'YourSqlDba' Use YourSqlDba GO Exec yUtl.DropObj 'yUtl.NormalizeLineEnds' GO create function yUtl.NormalizeLineEnds -- line ends can be expressed as a pipe char or a regular line end except if it ends by \ ( @prm VARCHAR(max) = '' ) returns VARCHAR(max) as Begin -- remove tabs and finish string by '|', turn line ends chars into '|' and replace multiple consecutives '|' by a single one. -- |||| (|) by (.|) done twice because the last one in done on the first time --> '|.|.|.| --> (.|) by () --> '|' Return ( Select Case When @prm = '' Then '' Else replace(replace(replace(replace(replace (replace(replace(@prm, char(9), '')+'|', nchar(10), '|'), nchar(13), '|'), '||', '|.|'), '||', '|.|'), '.|', ''), '.|', '') End ) End -- yUtl.NormalizeLineEnds --Select yUtl.NormalizeLineEnds(' --one --two --') --Select '!'+yUtl.NormalizeLineEnds('')+'!' GO -- ------------------------------------------------------------------------------ -- Function to select database from @incDb and @excDb parameters -- or replace pairs from @replace... parameters -- ------------------------------------------------------------------------------ If Db_name() <> 'YourSqlDba' Use YourSqlDba GO Exec yUtl.DropObj 'yUtl.SplitParamInRows' GO create function yUtl.SplitParamInRows ( @prm VARCHAR(max) = '' ) returns @rows table ( No int identity , line nvarchar(max) ) as Begin Declare @line nvarchar(max) -- remove tabs from selection patterns and -- add separator at the end of the parameter list, -- so no exception is required in the processing of the list Set @prm = yUtl.NormalizeLineEnds(rtrim(@prm)) -- Extract rows and add it to @rows table While charindex('|', @Prm) > 0 -- While there is a separator Begin Set @line = ltrim(rtrim(Left (@Prm, charindex('|', @Prm)-1))) -- If it reveals some contents add it If @line <> '' Insert into @rows (line) values (@line) -- remove all up to and including '|' Set @Prm = Stuff(@Prm, 1, charindex('|', @Prm), '') End Return; End -- yUtl.SplitParamInRows GO If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yUtl.YourSQLDba_ApplyFilterDb' GO create function yUtl.YourSQLDba_ApplyFilterDb ( @IncDb VARCHAR(max) = '' -- @IncDb : See following comments for explanation , @ExcDb VARCHAR(max) = '' -- @ExcDb : See following comments for explanation ) returns @Db table ( DbName sysname , dbOwner sysname NULL -- because actual owner may be invalid after a restore , FullRecoveryMode int , cmptLevel tinyint ) as Begin -- Create table of inclusion and exclusion patterns that apply to database names declare @DbName sysname declare @Pat table ( rech sysname, -- search pattern action char(1) -- 'I' = include if pattern match 'E' = exclude if pattern match ) Insert into @pat Select line, 'I' from yUtl.SplitParamInRows (@IncDb) Insert into @pat Select line, 'E' from yUtl.SplitParamInRows (@ExcDb) -- ===================================================================================== -- Build database list to process -- ===================================================================================== -- Build Db list into temporary table and retain its recovery mode (for possible log backup processing) Insert into @Db (DbName, dbOwner, FullRecoveryMode, cmptLevel) Select name , SUSER_SNAME(owner_sid) , Case When DATABASEPROPERTYEX(name, 'Recovery') = 'Simple' Then 0 -- simple recovery mode, no log backup possible Else 1 -- full recovery mode, log backup possible End as FullRecoveryMode, compatibility_level from master.sys.databases Where name <> 'tempdb' -- If there is at least one inclusion pattern, remove from database list those that -- doesn't match this pattern. Remove from the rest of the list those that match -- with the exclusion pattern -- Yes it can be done in one single query ;) Delete D From @Db D Where ( -- only if there is any inclusion pattern Exists (Select * From @Pat Where Action = 'I') -- delete databases that don't match, otherwise nothing is deleted And Not Exists (Select * From @Pat P Where P.action = 'I' And D.DbName like P.Rech) ) -- Suppress any database from the list that match exclusion pattern Or Exists (Select * From @Pat P Where P.action = 'E' And D.DbName like P.Rech) return End; -- yUtl.YourSQLDba_ApplyFilterDb GO If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yUtl.NormalizePath' GO -- ------------------------------------------------------------------------------ -- Function that normalize path (ensure that a '\' is at the end of the path -- ------------------------------------------------------------------------------ If Db_name() <> 'YourSqlDba' Use YourSqlDba GO create function yUtl.NormalizePath ( @path nvarchar(512) ) returns nvarchar(512) as Begin If right(@path, 1) <> '\' Set @path = @path + '\' Set @path = left(@path, 2) + replace(substring(@path, 3, 512), '\\', '\') return (@path) -- Some tests -- Select yUtl.NormalizePath('c:\isql2005Backups') -- Select yUtl.NormalizePath('c:\isql2005Backups\\') -- Select yUtl.NormalizePath('c:\isql2005Backups\') -- Select yUtl.NormalizePath('\\aserver\aShare') -- Select yUtl.NormalizePath('\\aserver\\aShare') End -- yUtl.NormalizePath GO ----------------------------- Exec yUtl.DropObj 'yUtl.SearchWord' GO -- Alter Create function yUtl.SearchWord ( @mot sysname , @str nvarchar(max) , @deb int ) returns int as Begin -- procédure spécifique à la recherche des mot clés SQL suivants -- char, varchar, text, image, declare, datalength, convert, create table -- on ne permet pas que quand on trouve ces chaînes dans le texte -- qu'elles soient précédés ou suivies des caractères suivants -- qui manifestent qu'ils ne s'agit pas de ces mots clés -- les crochets [] on été acceptés de justesse car il y a une colonne -- de Edugroupe qui s'appelle Text et pour ne pas convertir la -- table on a mis le nom de colonne entre crochet dans le code. -- On peut donc distinguer dans une procédure s'il s'agit en fait -- du type en enlevant les crochets s'il y a lieu, sinon on en met. -- .a-z0-9\#/@[]_ Declare @dir Int Declare @c Char(1) If @deb is NULL Set @deb = 0 -- évite l'initalisation nécessaire de la variable passée en paramètre Set @dir = @deb If @dir < 0 -- reverse la chaîne pour simuler rechercher à reculons Begin Set @str = reverse(@str) Set @mot = reverse(@mot) Set @deb = Abs(@deb) -- Si chaine se termine par blancs, les blancs de fin sont pas comptés ! If @deb > len(@str+'.') Set @deb = len(@str+'.') -1 Set @deb = len(@str+'.')-@deb End --print '"'+@mot+'" --> "'+@str+'"' Set @deb = @deb-1 -- pour permettre expression commode @deb+1 en partant While(1=1) Begin set @deb = charindex(@mot, @str, @deb+1) --print @deb If @deb = 0 Break --print substring(@str, @deb-1, 1) If @deb > 1 Begin Set @c = substring(@str, @deb-1, 1) -- parce que like boggue quand on a '[' dedans If @c like '[.a-z0-9\#/]' Or @c in ('@','[', '_') Continue End If @deb + len(@mot) > len(@str) Break --print substring(@str, @deb + len(@mot), 1) set @c = substring(@str, @deb + len(@mot), 1) -- parce que like boggue quand on a ']' dedans If @c like '[.a-z0-9/#\]' Or @c in ('@','[', '_') Continue Break -- si ici on a toutes les conditions ok, donc trouvé End If @dir < 0 And @deb > 0 Set @deb = len(@str+'.')-(@deb+len(@mot)-1) return (@deb) End -- yUtl.SearchWord GO if objectpropertyEx(object_id('yUtl.SearchWords'), 'isTableFunction') = 1 Drop Function yUtl.SearchWords GO -- Alter Create function yUtl.SearchWords ( @mot sysname , @str nvarchar(max) ) returns @Tags table ( posMotCle int -- pos repere ) as Begin Declare @pos int While (1=1) Begin Set @pos = yUtl.SearchWord(@mot, @str, @pos) If @pos = 0 break insert into @Tags (posMotCle) values(@pos) Set @pos = @pos + 1 End return End -- yUtl.SearchWords GO -- ------------------------------------ yExecNLog.PrintSqlCode ---------------------------------- -- Use yExecNLog.SqlCodeLinesInResultSet for sql code printing purposes -- ---------------------------------------------------------------------------------------------------------- CREATE Procedure yExecNLog.PrintSqlCode @sql nvarchar(max) , @numberingRequired int = 0 AS Begin Set nocount on If @Sql IS NULL Begin Print 'Bug : Query text parameter is null !!' return End declare @codeLines table (i int primary key, txt nvarchar(max)) insert into @codeLines (i, txt) Select i, txt From yExecNLog.SqlCodeLinesInResultSet (@sql) Declare @Seq Int Declare @Line nvarchar(max) Set @seq = -1 While (1=1) Begin Select top 1 @Seq = i, @line = txt from @codeLines Where i > @seq Order by i If @@ROWCOUNT = 0 break If @numberingRequired = 0 Print @line Else Print Str(@seq,5)+' '+@line End --Set @Line = Str(@seq,5)+' line(s) printed' raiserror (@line,10,1) with nowait -- force print output End -- yExecNLog.PrintSqlCode GO -- ------------------------------------------------------------------------------ -- Procedure that create-manage new jobs entries -- ------------------------------------------------------------------------------ If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yExecNLog.AddJobEntry' GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO create proc yExecNLog.AddJobEntry @jobName nvarchar(512) , @jobNo int output as Begin -- This procedure is called once in maintenance job to get the jobNo. -- When a jobNo is known it is no more called in the job. -- For ad-hoc queries it ia always called since job no is not carried around -- so we try to reuse last job entry for ah-hoc queries -- it there is no more recent job which are not ah-hoc. -- When creating a new job entree get data from the main context set by YourSqlDba_DoMaint Insert into Maint.JobHistory (JSonPrms) Select jSonPrms From Dbo.MainContextInfo(null) -- the function also supplies an output of all parameters as individual columns, instead of a json blob. Select @jobNo = SCOPE_IDENTITY() End -- yExecNLog.AddJobEntry go If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yExecNLog.ExecWithProfilerTrace' GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO -- ------------------------------------------------------------------------------ -- This procedure wraps the call to the clr_exec Create Procedure yExecNLog.ExecWithProfilerTrace @sql nvarchar(max), @maxSeverity int output, @Msgs nvarchar(max) = '' output as Begin Set @MaxSeverity = 0 Exec yExecNLog.Clr_ExecAndLogAllMsgs @sqlcmd=@sql, @maxSeverity=@maxSeverity output, @msgs=@msgs output If @sql is null Set @sql = '' If @msgs is null Set @msgs = '' -- produce something that profiler can display of the dynamic query launched, and error messages and warnings if any Exec( 'declare @i int; set @i = 1 /* YourSqlDba profiler trace as a dummy instruction to Show Clr_ExecAndLogAllMsgs @sql param and @msgs output =============================================================================================== '+@sql+' ----------------------------------------------------------------------------------------------- '+@msgs+' =============================================================================================== */' ) End Go If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yExecNLog.LogAndOrExec' GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO -- ------------------------------------------------------------------------------ -- When @err is already specified ignore @sql parameter. -- The intent is to log high level error messages -- When @err is missing, @Info or @context specified but @sql = '' by parameter omission, -- intent is to log pure informational messages -- When @sql parameter is not empty, it must be run dynamically and any error messages -- would be loggued. By precaution, a message is written in case the command should -- not return because of a high severity error. -- @Sql should never be null, this is a programming error that happens when -- a part that is used to build the dynamic query is unexpectedly left null. -- this is loggued as an important debugging aid, because dynamic execution of -- a null Sql command leave otherwise no error message -- ------------------------------------------------------------------------------ Create proc yExecNLog.LogAndOrExec @YourSqlDbaNo nvarchar(max) = NULL , @context nvarchar(4000) = NULL , @sql nvarchar(max) = '' -- this is a convenient way to know if LogAndOrExec was called without SQL command , @Info nvarchar(max) = NULL , @err nvarchar(max) = NULL Output -- input : err msg to be written to log; output: error generated by an sql execution , @JobNo Int Output -- Git from previous call to yExecNLog.AddJobEntry , @errorN Int = 0 Output , @raiseError int = 0 , @forDiagOnly int = 0 as Begin Set nocount on Declare @seq Int Declare @NbOfLn Int Declare @Msgs varchar(max) -- spcified as varchar(max) to auto convert unicode character to convertable char to xml Declare @maxSeverity Int Declare @newJobName nvarchar(128) Declare @xml xml Set @errorN = 0 Begin TRY -- special entries are logged for job start that describe the job and it parameters -- the not exists clause ensure that it is done only once. Insert into Maint.JobHistoryDetails (JobNo, forDiagOnly) Values (@JobNo, @forDiagOnly) Set @Seq=SCOPE_IDENTITY() -- memorize parameters, which make queries easier to maintain with intellisence Declare @prm Table ( YourSqlDbaNo nvarchar(max) NULL , jobNo INT null , context nvarchar(4000) NULL , sql nvarchar(max) NULL , Info nvarchar(max) NULL , err nvarchar(max) NULL , errorN Int NULL , [raiseError] int NULL , forDiagOnly int NULL , Seq Int NULL ) Insert into @prm Values (@YourSqlDbaNo, @JobNo, @Context, @sql, @Info, @err, @errorN, @raiseError, @forDiagOnly, @Seq) -- create #trc model from Maint.JobHistoryLineDetails Select top 0 * Into #trc From Maint.JobHistoryLineDetails -- useful to trace, but select output can be returned when launched from -- Broker_AutoActivated_LaunchRestoreToMirrorCmd activated by -- [dbo].[YourSQLDbaTargetQueueMirrorRestore] queue insert into #trc Select I.JobNo , I.Seq , ToLog.TypSeq , ToLog.typ , ToLog.Line , ToLog.Txt From -- only happens once at job start (Select * From @prm as I) as I CROSS APPLY Dbo.MainContextInfo (I.JobNo) as J -- shred JSonPrms of JobHistory into columns JOIN Maint.JobHistory JH ON JH.JobNo = I.jobNo CROSS APPLY ( -- add job header if it isn't there yet -- conditionnaly add a descriptive of the newly starting job -- easily found if it the actual JobNo is not yet in the table Maint.JobHistoryLineDetails Select TypSeq=0, Typ='Job', Line=LineOrd, Txt=Line From ( Select LineOrd=1, Line=Replicate('=', 128) UNION ALL Select LineOrd=2, Line='JobNo: '+Convert(nvarchar, JH.JobNo)+' JobStart: '+convert(nvarchar, J.JobStart, 120)+' JobName= '+J.MaintJobName UNION ALL Select LineOrd=3, Line=Replicate('=', 128) UNION ALL Select LineOrd=4, Line='Job first start seq is '+convert(nvarchar,I.Seq) UNION ALL Select LineOrd=5, Line='Task requested: DBCC Checkdb' Where J.DoInteg = 1 Or J.DoInteg IS NULL UNION ALL Select LineOrd=6, Line='Task requested: Update Statistics' Where J.DoUpdStats = 1 Or J.DoUpdStats IS NULL UNION ALL Select LineOrd=7, Line='Task requested: Reorganize fragmented indexes' Where J.DoReorg = 1 Or J.DoReorg IS NULL UNION ALL Select LineOrd=8, Line='Task requested: Backup Databases' Where J.DoFullBkp = 1 Or J.DoFullBkp is null UNION ALL Select LineOrd=9, Line='Task requested: Backup Transaction Logs' Where J.DoLogBkp = 1 Or J.DoLogBkp is null Union All Select LineOrd=10, Line='Databases to match: ' + replace(J.IncDb, nchar(10), '') Where ltrim(replace(J.IncDb, nchar(10), ''))<> '' Union All Select LineOrd=11, Line='Databases to exclude: ' + replace(J.ExcDb, nchar(10), '') Where ltrim(replace(J.ExcDb, nchar(10), ''))<> '' ) as Det Where Not Exists (Select * From Maint.JobHistoryLineDetails As D Where D.JobNo = I.JobNo) -- printout query or informational info UNION ALL Select TypSeq, Typ, Line=LineOrd, Txt=Line From ( Select TypSeq=1, typ='Time', lineOrd=1, Line='=== '+ convert(nvarchar, Getdate(), 121) + ' ' +Replicate('=', 110) Union all Select TypSeq=2, typ='ctx', lineOrd=1, line=I.Context Where I.context is not null union all Select TypSeq=3, typ='inf', lineOrd=1, line=I.info Where I.info is not null union all Select TypSeq=5, typ='Sql', lineOrd=X.i, line=X.txt From -- Unindent T-SQL to have leftmost code to start in column one (Select SqlU=yExecNLog.Unindent_TSQL(sql) Where Sql <> '') as SqlU CROSS APPLY yExecNLog.SqlCodeLinesInResultSet( yExecNLog.Unindent_TSQL(sqlu)) as x Union all Select TypSeq=6, typ='errY', lineOrd=X.i, line=X.txt From -- Only one SELECT of conditions below must return a result otherwise it will make a duplicate error into JobHistoryLineDetails ( -- an error text where specified by caller Select Err Where I.Err <>'?' UNION ALL Select Err = 'YourSqlDba error notification '+convert(nvarchar,I.YourSqlDbaNo)+'. Please check ctx, inf, or msgs types' Where charindex(I.YourSqlDbaNo, '005 006 007 008 009 012 013 015 021')>0 And I.Err IS NULL -- YourSqlDba tried to build a dynamic query but either concatenated a null in the process or failed to generate SQL UNION ALL Select Err='Unexpected YourSqlDba error : Dynamically generated SQL IS NULL' Where Sql IS NULL And I.Err IS NULL UNION ALL -- When caller catch an unexpected error it can let the task to ExecAndLog -- to get current error state and format it. This request is expressed by Err parameter being '?' Select Err=yExecNLog.FormatBasicBeginCatchErrMsg () Where I.Err = '?' ) as S -- Split over many rows, lines of the error message if is multi-line Cross Apply yExecNLog.SqlCodeLinesInResultSet(s.err) as x Where s.err IS NOT NULL OR SQL IS NULL union all -- a return code was specified for a message given by YourSqlDba, it can be an error but is handled somewhere else, at end of job Select TypSeq=7, typ='YSDNo', lineOrd=1, line=YourSqlDbaNo Where YourSqlDbaNo is not null ) as linearView ) as ToLog -- if a real @sql command has to be run, try run it otherwise exit the proc -- Select * from #trc Insert into Maint.JobHistoryLineDetails (jobNo, Seq, TypSeq, Typ, Line, Txt) Select * from #trc Truncate table #trc -- because table is going to be reused for logging run-time execution error -- always update even for log message only Update Maint.JobHistory Set JobEnd = Getdate() Where JobNo = @JobNo If isnull(@sql, '') = '' Return -- nothing left to do -- execute query and ensure its logging in trace, because of the previous return statement -- there is some SQL to run Exec yExecNLog.ExecWithProfilerTrace @sql, @maxSeverity output, @Msgs Output -- @ErrorN is a boolean, 1 = error Select @errorN = IIF(@maxSeverity>10,1,0) -- always update in case of DBCC messages with error but not trapped error Update Maint.JobHistory Set JobEnd = Getdate() Where JobNo = @JobNo -- report execution result Insert into #trc Select I.JobNo , I.Seq , ToLog.TypSeq , ToLog.typ , Line=ToLog.LineOrd , ToLog.Txt From (Select * From @prm as I) as I CROSS APPLY ( -- this code is segmented about log to generate depending on @maxSeverity -- which indicates no error condition when 10 or below and error condition above -- For example prints, or dbcc checkdb output of tables checked without error -- leave no message of above to. @maxSeverity is a compute value produced by -- ExecWithProfilerTrace when processing multiple messages issued of a single query Select * From ( Select I.JobNo, I.Seq, TypSeq=8, typ='msgs', lineOrd=X.i, X.txt From ( -- log messages under typ msgs, but messages lines are generated in reversed order -- by the clr proc that traps them, so the need to be reordered in reverse order Select S.txt, I=Row_number() Over (Order by S.i desc) -- get new reversed sequence From yExecNLog.SqlCodeLinesInResultSet(@msgs) as S ) as X Where isnull(@msgs,'') <> '' And @maxSeverity <= 10 UNION ALL -- log messages under typ err Select I.JobNo, I.Seq, TypSeq=9, typ='errR', lineOrd=X.i, line=X.txt From yExecNLog.SqlCodeLinesInResultSet(@msgs) as x Where isnull(@msgs,'') <> '' And @maxSeverity > 10 UNION ALL -- Add success or failure status to query output Select I.JobNo, I.Seq, TypSeq=10, typ='Status', lineOrd=1, line=Status From @Prm as I CROSS APPLY(Select Status=IIF(@maxSeverity <= 10, 'Success', 'Fail maintenance context')) as Status Where @maxSeverity <= 10 ) as Ok ) as ToLog -- copy #trc if it has run-time execution error logged into it into Maint.JobHistoryLineDetails Insert into Maint.JobHistoryLineDetails (jobNo, Seq, TypSeq, Typ, Line, Txt) Select * from #trc -- for any type of error not related to Integrity testing 1 is returned -- if integrity testing have only error 5128, return this value, otherwise 1. -- This difference is taken in account in yMaint.IntegrityTesting. Select *, ErrorN=COALESCE(OnlyError5128InDbcc, FlagErrFromSeverity) From (Select FlagErrFromSeverity=1 Where @MaxSeverity>10) as ErrorNFromSeverity OUTER APPLY -- if integrity testing count error of type 5128 and the other types ( Select NbError5128=count(Error5128), NbErrorNot5128=count(NotError5128) From -- shortcut the whole evaluation as 0 rows return if @context isn't 'yMaint.IntegrityTesting' (Select * From #Trc Where @context = 'yMaint.IntegrityTesting') as IntegrityTest -- flag error 5128 found OUTER APPLY (Select Error5128=1 Where txt like '%Error 5128, Severity [0-9][0-9], level [0-9]%') Error5128 -- flag other error is 5128 is found but there is still the pattern for an error OUTER APPLY ( Select NotError5128=1 Where Error5128 IS NULL And txt like '%Error [0-9][0-9][0-9]%, Severity [0-9][0-9], level [0-9]%' ) NotError5128 ) as CountErrType -- flag if no other error than 5128 is found OUTER APPLY (Select OnlyError5128InDbcc=IIF(NbError5128>0 And NbErrorNot5128=0, 5128, NULL)) as OnlyError5128InDbcc -- Update Maint.JobHistoryDetails for query duration -- otherwise secs remains null as it was when the row was created Update Maint.JobHistoryDetails Set secs = Datediff(ss, cmdStartTime, getdate()) , forDiagOnly = Case When @maxSeverity > 10 Then 0 Else @forDiagOnly End From @Prm as P JOIN Maint.JobHistoryDetails JD ON JD.JobNo = P.JobNo And JD.seq = P.Seq -- @raiserror = 1 is never used in maintenance related tasks -- For example, it is used in ExportDatabase, which is a large script -- that we want to stop when an error is found. If @maxSeverity > 10 And @raiseError = 1 Raiserror ('Stop on error by request of calling procedure for : %s : %s ',11,1, @YourSqlDbaNo, @context) End TRY Begin CATCH -- Errors caught here are very rare, cause yExecNLog.ExecWithProfilerTrace catch then -- for all dynamic queries -- the must be related with some runtime even in this proc as an duplicate on insert to log -- or string truncation on insert to log or deadlock on updates to Maint.JobHistoryDetails -- Maint.JobHistory which are not very likely since they are properly indexed and done by JobNo Set @errorN = 1; -- describe the error to write it in YourSqlDba Job log declare @msg nvarchar(4000) Select @Msg=E.Err From @Prm as P CROSS APPLY (Select Err=yExecNLog.FormatBasicBeginCatchErrMsg () ) as E -- write it into Maint.JobHistoryLineDetails Insert Into Maint.JobHistoryLineDetails (jobNo, Seq, TypSeq, Typ, Line, Txt) Select I.JobNo, I.Seq, TypSeq=99, typ='ErrLog', lineOrd=1, line=@Msg From @Prm as I Update Maint.JobHistory Set JobEnd = Getdate() Where JobNo = @JobNo; End CATCH End -- yExecNLog.LogAndOrExec GO Exec yUtl.DropObj 'yMaint.CollectBackupHeaderInfoFromBackupFile' go Create Procedure yMaint.CollectBackupHeaderInfoFromBackupFile @bkpFile nvarchar(512) as Begin Declare @sql nvarchar(max) Create Table #Header ( BackupName nvarchar(128), BackupDescription nvarchar(255), BackupType smallint, ExpirationDate datetime, Compressed tinyint, Position smallint, DeviceType tinyint, UserName nvarchar(128), ServerName nvarchar(128), DatabaseName nvarchar(128), DatabaseVersion int, DatabaseCreationDate datetime, BackupSize numeric(20,0), FirstLSN numeric(25,0), LastLSN numeric(25,0), CheckpointLSN numeric(25,0), DatabaseBackupLSN numeric(25,0), BackupStartDate datetime, BackupFinishDate datetime, SortOrder smallint, CodePage smallint, UnicodeLocaleId int, UnicodeComparisonStyle int, CompatibilityLevel tinyint, SoftwareVendorId int, SoftwareVersionMajor int, SoftwareVersionMinor int, SoftwareVersionBuild int, MachineName nvarchar(128), Flags int, BindingID uniqueidentifier, RecoveryForkID uniqueidentifier, Collation nvarchar(128), FamilyGUID uniqueidentifier, HasBulkLoggedData bit, IsSnapshot bit, IsReadOnly bit, IsSingleUser bit, HasBackupChecksums bit, IsDamaged bit, BeginsLogChain bit, HasIncompleteMetaData bit, IsForceOffline bit, IsCopyOnly bit, FirstRecoveryForkID uniqueidentifier, ForkPointLSN numeric(25,0), RecoveryModel nvarchar(60), DifferentialBaseLSN numeric(25,0), DifferentialBaseGUID uniqueidentifier, BackupTypeDescription nvarchar(60), BackupSetGUID uniqueidentifier ) -- adjust table column depending on version -- sql2008 need CompressedBackupSize column If yInstall.SqlVersionNumber () >= 100 -- sql 2008 and above Alter table #Header Add CompressedBackupSize BigInt -- sql2012 need containement column If yInstall.SqlVersionNumber () >= 110 -- sql 2012 and above Alter table #Header Add containment tinyint -- sql2014 need theses If yInstall.SqlVersionNumber () >= 120 -- sql 2014 and above Begin Alter table #Header Add KeyAlgorithm nvarchar(32) Alter table #Header Add EncryptorThumbprint varbinary(20) Alter table #Header Add EncryptorType nvarchar(32) End Set @sql = 'Restore HeaderOnly from Disk=""' Set @sql = replace(@sql, '', @bkpFile) Set @Sql = ' insert into #Header exec ("'+replace(@sql, '"', '""')+'") ' Set @Sql = replace (@sql, '"', '''') Set @sql = yExecNLog.Unindent_TSQL(@sql) Declare @maxSeverity int Declare @msgs Nvarchar(max) Exec yExecNLog.ExecWithProfilerTrace @sql, @MaxSeverity output, @Msgs output Delete From Maint.TemporaryBackupHeaderInfo Where spid = @@spid If @maxSeverity > 10 Begin Raiserror (N'CollectBackupHeaderInfoFromBackupFile error %s: %s %s', 11, 1, @@SERVERNAME, @Sql, @Msgs) Return (1) End Insert into Maint.TemporaryBackupHeaderInfo (BackupType, position, deviceType, DatabaseName, lastLsn) Select BackupType, position, deviceType, DatabaseName, lastLsn From #Header Return(0) End Go Exec yUtl.DropObj 'yMaint.CollectBackupFileListFromBackupFile' go Create Procedure yMaint.CollectBackupFileListFromBackupFile @bkpFile nvarchar(512) as Begin Declare @sql nvarchar(max) create table #Files -- Database file list obtained from restore filelistonly ( LogicalName nvarchar(128) -- Logical name of the file. ,PhysicalName nvarchar(260) -- Physical or operating-system name of the file. ,Type NCHAR(1) -- The type of file, one of: L = Microsoft SQL Server log file D = SQL Server data file F = Full Text Catalog ,FileGroupName nvarchar(128) -- Name of the filegroup that contains the file. ,Size numeric(20,0) -- Current size in bytes. ,MaxSize numeric(20,0) -- Maximum allowed size in bytes. ,FileID bigint -- File identifier, unique within the database. ,CreateLSN numeric(25,0) -- Log sequence number at which the file was created. ,DropLSN numeric(25,0) NULL -- The log sequence number at which the file was dropped. -- If the file has not been dropped, this value is NULL. ,UniqueID uniqueidentifier -- Globally unique identifier of the file. ,ReadOnlyLSN numeric(25,0) NULL -- Log sequence number at which the filegroup containing the file changed -- from read-write to read-only (the most recent change). ,ReadWriteLSN numeric(25,0) NULL -- Log sequence number at which the filegroup containing the file changed -- from read-only to read-write (the most recent change). ,BackupSizeInBytes bigint -- Size of the backup for this file in bytes. ,SourceBlockSize int -- Block size of the physical device containing the file in bytes (not the backup device). ,FileGroupID int -- ID of the filegroup. ,LogGroupGUID uniqueidentifier NULL -- NULL. ,DifferentialBaseLSN numeric(25,0) NULL -- For differential backups, changes with log sequence numbers greater than or equal -- to DifferentialBaseLSN are included in the differential. ,DifferentialBaseGUID uniqueidentifier -- For differential backups, the unique identifier of the differential base. ,IsReadOnly bit -- 1 = The file is read-only. ,IsPresent bit -- 1 = The file is present in the backup. ) -- sql2008 need TDEThumbprint column If yInstall.SqlVersionNumber () >= 100 -- sql 2008 and above Alter table #Files Add TDEThumbprint varbinary(32) If yInstall.SqlVersionNumber () >= 130 -- Sql2016 and above Alter Table #Files Add SnapshotURL Nvarchar(36) Set @sql = 'Restore filelistonly from Disk=""' Set @sql = replace(@sql, '', @bkpFile ) Set @Sql = ' insert into #Files exec ("'+replace(@sql, '"', '""')+'") ' Set @Sql = replace (@sql, '"', '''') Set @sql = yExecNLog.Unindent_TSQL(@sql) Declare @maxSeverity int Declare @msgs Nvarchar(max) Exec yExecNLog.ExecWithProfilerTrace @sql, @MaxSeverity output, @Msgs output Delete From Maint.TemporaryBackupFileListInfo Where spid = @@spid If @maxSeverity > 10 Begin Raiserror (N'CollectBackupFileListFromBackupFile error %s: %s %s', 11, 1, @@SERVERNAME, @Sql, @Msgs) Return (1) End Insert into Maint.TemporaryBackupFileListInfo (FileId, Type, LogicalName, physicalName) Select FileId, Type, LogicalName, physicalName From #Files Return (0) End Go Exec yUtl.DropObj 'yMaint.SaveXpCmdShellStateAndAllowItTemporary' GO Create Proc yMaint.SaveXpCmdShellStateAndAllowItTemporary as Begin If Exists(Select * from Maint.XpCmdShellSavedState) Begin Exec ( ' With XpCmdShellState as ( Select convert(int,value_In_Use) as Value_in_use from Sys.configurations Where name = ''xp_cmdshell'' ) Update Maint.XpCmdShellSavedState Set value_In_Use = S.Value_in_use From XpCmdShellState S ' ) End Else Exec ( ' With XpCmdShellState as ( Select convert(int,value_In_Use) as Value_in_use from Sys.configurations Where name = ''xp_cmdshell'' ) Insert Into Maint.XpCmdShellSavedState (value_In_Use) Select * from XpCmdShellState ' ) EXEC sp_configure 'xp_cmdshell', 1 Reconfigure End GO Exec yUtl.DropObj 'yMaint.RestoreXpCmdShellState' GO Create Proc yMaint.RestoreXpCmdShellState as Begin If OBJECT_ID('Maint.XpCmdShellSavedState') IS Not NULL Begin Exec ( ' Declare @state int Select @state=convert(int, value_In_Use) From Maint.XpCmdShellSavedState EXEC sp_configure ''xp_cmdshell'', @state Reconfigure Delete Maint.XpCmdShellSavedState ' ) End End GO If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yMaint.PutDbOffline' GO Create proc yMaint.PutDbOffline @DbToLockOut nvarchar(128) = '' , @JobNo Int as Begin Declare @AlterDb nvarchar(512) Declare @Info nvarchar(512) If DatabasepropertyEx(@DbToLockOut, 'Status') <> 'EMERGENCY' And @DbToLockOut Not In ('master', 'model', 'msdb') Begin If DatabasepropertyEx(@DbToLockOut, 'Status') <> N'ONLINE' Return -- version 1.1 don't attempt to put offline a database that is already not online Set @AlterDb = ' Alter database [] Set offline With ROLLBACK immediate ' Set @Info = 'Database []is put offline because the previous error' Set @AlterDb = Replace(@AlterDb, '', @DbToLockOut) Set @Info = Replace(@Info, '', @DbToLockOut) Set @AlterDb = Replace(@AlterDb, '"', '''') Begin try Exec (@alterDb) Exec yExecNLog.LogAndOrExec @context = @Info , @YourSqlDbaNo = '005' , @JobNo = @JobNo End try begin catch Exec yExecNLog.LogAndOrExec @context = 'yMaint.PutDbOffline error' , @err='?' , @YourSqlDbaNo = '005' , @JobNo = @JobNo end catch End End -- yMaint.PutDbOffline GO -- --------------------------------------------------------------------------------------- -- This procedures extract informations required for database mail diagnosis -- --------------------------------------------------------------------------------------- If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'Maint.DiagDbMail' GO create Procedure Maint.DiagDbMail as Begin -- Lire les éléments envoyés -- Voir la queue de message SQL EXEC msdb.dbo.sysmail_help_queue_sp @queue_type = 'mail' ; SELECT top 5 S.send_request_date, S.mailItem_id, S.sent_status, S.recipients, s.subject FROM msdb.dbo.sysmail_sentitems S order by S.sent_date desc, S.mailItem_id desc; SELECT top 100 * FROM msdb.dbo.sysmail_event_log order by log_id desc; End -- Maint.DiagDbMail GO If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yUtl.ConvertToHexString' GO Create function yUtl.ConvertToHexString ( @binValue varbinary(max) ) returns nvarchar(max) as Begin DECLARE @charvalue nvarchar (max) DECLARE @i int DECLARE @length int Declare @pwdHexString Char(16) If @Binvalue IS NULL RETURN (N'NULL') SELECT @charvalue = '0x' SELECT @i = 1 SELECT @length = datalength (@binvalue) SELECT @pwdHexString = '0123456789ABCDEF' WHILE (@i <= @length) BEGIN DECLARE @tempint int DECLARE @firstint int DECLARE @secondint int Set @tempint = CONVERT (int, SUBSTRING (@binvalue, @i, 1)) Set @firstint = FLOOR (@tempint / 16) Set @secondint = @tempint - (@firstint * 16) Set @charvalue = @charvalue + SUBSTRING (@pwdHexString, @firstint + 1, 1) + SUBSTRING (@pwdHexString, @secondint + 1, 1) Set @i = @i + 1 END return(@charvalue) End -- yUtl.ConvertToHexString GO --select * --from --yUtl.YourSQLDba_ApplyFilterDb ( --' --', --' --F%' --) --GO ---------------------------------------------------------------------------------------- If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'Tools.CompareRows' GO ------------------------------------------------------------------------------------- -- This highly flexible procedure allows rows comparison from many different sources. -- It could be a table (with an optional filter), or a query. It can reside into the -- same database, or onto different database, on the same server or on -- different servers, provide that the necessary linked server are defined. -- Both source and target are independently configurable -- The only condition is that they returns the same columns. -- Generated query is printed for debugging purposes. -- Column list is mandatoty, and at least one row source for the source and the target. --------------------------------------------------------------------------------------- If OBJECT_ID('Tools.CompareRows') is not null drop procedure Tools.CompareRows go create proc Tools.CompareRows @ColList nvarchar(max) -- list of columns to compare (must include primary key) , @Srctab as sysname = '' -- schema mandatory, could be substituted by @SrcQry , @SrcQry as nvarchar(max) = '' -- if specified override @SrcTab, must include db.schema , @TgtTab as sysname = '' -- schema mandatory, could be substituted by @TgtQry , @TgtQry as nvarchar(max) = '' -- if specified override @TgtTab, must include db.schema , @SrcWhereClause nvarchar(max) = '' -- optional where clause for @srcTab , @TgtWhereClause nvarchar(max) = '' -- optional where clause for @TgtTab , @SrcDB as sysname = '' -- source db (default to current one) , @TgtDB as Sysname = '' -- target db (default to source) , @SrcInstance as sysname = '' -- linked source server, default local , @TgtInstance as sysname = '' -- linked target server, default local as Begin declare @sql nvarchar(max) set @sql = ' With SrcRows as ( ) , tgtRows As ( ) , UnionOfDataSetsToCompare as ( Select "(source) [].[]." as DataSetId , From SrcRows UNION ALL Select "(target) [].[]." as DataSetId , From TgtRows ) select MAX(DataSetId) as DataSetid , from UnionOfDataSetsToCompare group by Having MAX(DataSetId) = MIN(DataSetId) order by ' -- assume some behavior for missing parameters If @SrcDB = '' Set @SrcDB = DB_NAME() -- current db if no @SrcDb If @TgtDB = '' Set @TgtDB = @SrcDB -- Same db if no @tgtDg If @TgtTab = '' Set @TgtTab = @Srctab -- Same table name if no @TgtTab If @TgtWhereClause = '' Set @SrcWhereClause = @TgtWhereClause If @SrcQry <> '' Set @sql = REPLACE(@sql, '', @SrcQry) If @TgtQry = '' And @TgtTab = '' Set @TgtQry = @SrcQry If @TgtQry <> '' Set @sql = REPLACE(@sql, '', @TgtQry) If @Srctab = '' Set @sql = REPLACE(@sql, '(source) [].[].' , '@SrcQry') If @Tgttab = '' Set @sql = REPLACE(@sql, '(target) [].[].' , '@TgtQry') If @Srctab = '' And @SrcQry = '' Begin Print 'Provide either @srcTab or @srcQry parameter' Return End Set @sql = REPLACE(@sql, '', 'Select from [].[]. ') Set @sql = REPLACE(@sql, '', 'Select from [].[]. ') -- replace tags Set @sql = REPLACE (@sql, '', @ColList) Set @sql = REPLACE (@sql, '', @Srctab) Set @sql = REPLACE (@sql, '', @Tgttab) Set @sql = REPLACE (@sql, '', @SrcWhereClause) Set @sql = REPLACE (@sql, '',@TgtWhereClause) Set @sql = REPLACE (@sql, '', @SrcDB ) Set @sql = REPLACE (@sql, '', @TgtDB ) -- remove the linked server syntax part if not specified If @SrcInstance = '' Set @sql = REPLACE (@sql, '[].', '') Set @sql = REPLACE (@sql, '', @SrcInstance ) If @TgtInstance = '' Set @sql = REPLACE (@sql, '[].', '') Set @sql = REPLACE (@sql, '', @TgtInstance ) -- replace double quotes by real single quotes Set @sql = REPLACE (@sql, '"', '''') Exec yExecNLog.PrintSqlCode @sql, @numbering=1 -- show the query for debugging purpose exec (@sql) -- execute it End go --exec Tools.CompareRows -- @ColList = 'ContactID, NameStyle, Title, FirstName, MiddleName, LastName, Suffix -- , EmailAddress, EmailPromotion, Phone, PasswordHash, PasswordSalt, rowguid -- , ModifiedDate' --, @Srctab = 'Person.Contact' --, @SrcDb = 'AdventureWorks' --, @TgtDb = 'AdventureWorksCopy' --exec Tools.CompareRows -- @ColList = 'ContactID, NameStyle, Title, FirstName, MiddleName, LastName, Suffix -- , EmailAddress, EmailPromotion, Phone, PasswordHash, PasswordSalt, rowguid -- , ModifiedDate' --, @SrcQry = 'Select * from AdventureWorks.Person.Contact where phone like "440%"' --, @TgtQry = 'Select * from AdventureWorksCopy.Person.Contact where phone like "440%"' --, @SrcInstance = 'ASQL9' --go ---------------------------------------------------------------------------------------- go If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'Audit.GenerateIt' GO Create procedure Audit.GenerateIt @db sysname , @schema sysname , @tabListLike nvarchar(max) , @expirationDate datetime As Begin set nocount on declare @Sql nvarchar(max) declare @SqlDyn nvarchar(max) Declare @Info nvarchar(max) Set @Info = 'Audit defined on ['+@db+'].['+@schema+'] for table names that match like '+@tabListLike Exec yExecNLog.LogAndOrExec @context = 'Audit.GenerateIt' , @Info = @Info Set @Sql = ' Use [] Select T.OBJECT_id, @schema, ltrim(rtrim(T.name)) From YourSqlDba.yUtl.SplitParamInRows (@TabListLike) as A join sys.tables T ON T.name like A.line Collate Latin1_general_ci_ai And SCHEMA_NAME(T.schema_id) = @Schema Collate Latin1_general_ci_ai ' Set @Sql = replace (@sql, '', @db) Create table #tabList (objID INT primary key clustered, schName sysname, TAB sysname) Insert into #tabList Exec sp_executeSql @Sql, N'@TabListLike nvarchar(max), @Schema sysname', @TabListLike, @Schema Declare @objId Int Declare @TAB sysname Select @objId = MIN(objId)-1 from #tablist While(1=1) Begin Select top 1 @objId = objId , @TAB = TAB From #tabList Where objId > @objId If @@ROWCOUNT = 0 break Set @Sql = ' Use [] If schema_id("yAudit_") Is NULL exec("Create schema [yAudit_]") If schema_id("yAudit__TxSeq") Is NULL exec("Create schema [yAudit__TxSeq]") ' Set @Sql = replace (@sql, '', @db) Set @Sql = replace (@sql, '', @schema) Set @Sql = replace (@sql, '"', '''') print @sql Exec(@sql) Set @Sql = ' Use [] If object_id("[yAudit_].[]") IS NOT NULL Drop Table [yAudit_].[] If object_id("[yAudit__TxSeq].[]") IS NOT NULL Drop Table [yAudit__TxSeq].[] ' Set @Sql = replace (@sql, '', @db) Set @Sql = replace (@sql, '', @schema) Set @Sql = replace (@sql, '', @TAB) Set @Sql = replace (@sql, '"', '''') print @sql Exec(@sql) Declare @ColsRedefToAllowInsert Nvarchar(max) Set @Sql = ' Use [] Select @ColsRedefToAllowInsert = ( Select convert (nvarchar(max), ", "+ Case When Is_Identity = 1 Then "convert(bigInt, 0) as ["+name+"]" When type_name(system_type_id) in ("timestamp", "rowversion") Then "convert(varbinary(8), 0) as ["+name+"]" Else "["+name+"]" End ) as [text()] From sys.columns Where object_id = object_id("[].[]") Order by column_id For XML PATH("") ) ' Set @Sql = replace (@sql, '', @db) Set @Sql = replace (@sql, '', @schema) Set @Sql = replace (@sql, '', @TAB) Set @Sql = replace (@sql, '"', '''') print @sql Exec sp_executeSql @Sql, N'@ColsRedefToAllowInsert Nvarchar(max) OUTPUT', @ColsRedefToAllowInsert Output Set @Sql = ' Use [] Select distinct top 0 convert(bigint, 0) as [y_TxSeq] , convert(nchar(1), " ") as [y_Op] , convert(nchar(1), " ") as [y_BeforeOrNew] , getdate() as [y_EvTime] , app_name() as [y_App] , host_name() as [y_Wks] , suser_sname() as [y_Who] , user_name() as [y_DbUser] <*> into [yAudit_].[] From [].[] Create table [yAudit__TxSeq].[] (seq bigInt identity, dummyInsert int) ' Set @Sql = replace (@sql, '', @db) Set @Sql = replace (@sql, '', @schema) Set @Sql = replace (@sql, '', @TAB) Set @Sql = replace (@sql, '"', '''') Set @Sql = REPLACE (@Sql, '<*>', @ColsRedefToAllowInsert) print @sql Exec(@sql) Set @SqlDyn = ' Create trigger [].[_yAudit] ON [].[] For insert, delete, update as Begin /*:_yAudit_expirationDate*/ If @@rowcount = 0 return If Trigger_nestlevel()> 1 Return Set nocount on Declare @op Nchar(1) select top 1 @op = "D" from deleted select top 1 @op = case when @op = "D" Then "U" Else "I" End from inserted Declare @txSeq BigInt begin tran IncBox save tran inc insert into [yAudit__TxSeq].[] (dummyInsert) values (0) Set @txSeq = @@identity rollback tran inc -- identity do not rollback commit tran IncBox ; With WhenHowWho as (Select getdate() as EventTime, app_name() as Through, host_name() as FromWks, suser_sname() as Who, user_name() as DbUser) , BeforeValues as (Select @txSeq as TxSeq, @op as Op, "B" as BeforeOrNew, What.*, Tx.* From WhenHowWho as What cross join Deleted as tx) , NewValues as (Select @txSeq as TxSeq, @op as Op, "N" as BeforeOrNew, What.*, Tx.* From WhenHowWho as What cross join Inserted as tx) insert into [yAudit_].[] Select * From BeforeValues union all Select * From NewValues End ' Set @SqlDyn = replace (@sqlDyn, '', @schema) Set @SqlDyn = replace (@sqlDyn, '', @TAB) Set @SqlDyn = replace (@sqlDyn, '', convert(nvarchar(8), @expirationDate,112) ) Set @SqlDyn = replace (@sqlDyn, '"', '''') Set @Sql = ' Use [] If object_id("[].[_yAudit]") IS NOT NULL Drop trigger [].[_yAudit]; Exec sp_executeSql @SqlDyn ' Set @Sql = replace (@sql, '', @db) Set @Sql = replace (@sql, '', @schema) Set @Sql = replace (@sql, '', @TAB) Set @Sql = replace (@sql, '"', '''') print '@SqlDyn='+nchar(10)+@sqlDyn print '@Sql='+@sql Exec sp_executeSql @Sql, N'@sqlDyn nvarchar(max)', @SqlDyn End -- While End -- Audit.GenerateIt go If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'Audit.SuspendIt' GO Create procedure Audit.SuspendIt @db sysname , @schema sysname , @tabListLike nvarchar(max) As Begin set nocount on declare @Sql nvarchar(max) Declare @Info nvarchar(max) Set @Info = 'Audit suspended on ['+@db+'].['+@schema+'] for table names that match like '+@tabListLike Exec yExecNLog.LogAndOrExec @context = 'Audit.SuspendIt' , @Info = @Info Set @Sql = ' Use [] Select T.OBJECT_id, @schema, ltrim(rtrim(T.name)) From YourSqlDba.yUtl.SplitParamInRows (@TabListLike) as A join sys.tables T ON T.name like A.line Collate Latin1_general_ci_ai And SCHEMA_NAME(T.schema_id) = @Schema Collate Latin1_general_ci_ai ' Set @Sql = replace (@sql, '', @db) Create table #tabList (objID INT primary key clustered, schName sysname, TAB sysname) Insert into #tabList Exec sp_executeSql @Sql, N'@TabListLike nvarchar(max), @Schema sysname', @TabListLike, @Schema Declare @objId Int Declare @TAB sysname Select @objId = MIN(objId)-1 from #tablist While(1=1) Begin Select top 1 @objId = objId , @TAB = TAB From #tabList Where objId > @objId If @@ROWCOUNT = 0 break Set @Sql = ' Use [] alter table [].[] disable trigger [_yAudit] ' Set @Sql = replace (@Sql, '', @db) Set @Sql = replace (@Sql, '', @schema) Set @Sql = replace (@Sql, '', @TAB) Set @Sql = replace (@Sql, '"', '''') print @sql Exec sp_executeSql @Sql End -- While End -- Audit.SuspendIt go If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'Audit.ReactivateIt' GO Create procedure Audit.ReactivateIt @db sysname , @schema sysname , @tabListLike nvarchar(max) As Begin set nocount on declare @Sql nvarchar(max) declare @SqlDyn nvarchar(max) Declare @Info nvarchar(max) Set @Info = 'Audit reactivated on ['+@db+'].['+@schema+'] for table names that match like '+@tabListLike Exec yExecNLog.LogAndOrExec @context = 'Audit.ReactivateIt' , @Info = @Info Set @Sql = ' Use [] Select T.OBJECT_id, @schema, ltrim(rtrim(T.name)) From YourSqlDba.yUtl.SplitParamInRows (@TabListLike) as A join sys.tables T ON T.name like A.line Collate Latin1_general_ci_ai And SCHEMA_NAME(T.schema_id) = @Schema Collate Latin1_general_ci_ai ' Set @Sql = replace (@sql, '', @db) Create table #tabList (objID INT primary key clustered, schName sysname, TAB sysname) Insert into #tabList Exec sp_executeSql @Sql, N'@TabListLike nvarchar(max), @Schema sysname', @TabListLike, @Schema select * from #tablist Declare @objId Int Declare @TAB sysname Select @objId = MIN(objId)-1 from #tablist While(1=1) Begin Select top 1 @objId = objId , @TAB = TAB From #tabList Where objId > @objId If @@ROWCOUNT = 0 break Set @Sql = ' Use [] alter table [].[] enable trigger [_yAudit] ' Set @Sql = replace (@Sql, '', @db) Set @Sql = replace (@Sql, '', @schema) Set @Sql = replace (@Sql, '', @TAB) print @sql Exec sp_executeSql @sql End -- While End -- Audit.ReactivateIt go If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'Audit.RemoveIt' GO Create procedure Audit.RemoveIt @db sysname , @schema sysname , @tabListLike nvarchar(max) , @jobNo Int = NULL As Begin set nocount on declare @Sql nvarchar(max) Declare @Info nvarchar(max) Set @Info = 'Audit removed on ['+@db+'].['+@schema+'] for table names that match like '+@tabListLike Exec yExecNLog.LogAndOrExec @context = 'Audit.RemoveIt' , @Info = @Info , @jobNo = @jobNo Set @Sql = ' Use [] Select T.OBJECT_id, @schema, ltrim(rtrim(T.name)) From YourSqlDba.yUtl.SplitParamInRows (@TabListLike) as A join sys.tables T ON T.name like A.line Collate Latin1_general_ci_ai And SCHEMA_NAME(T.schema_id) = @Schema Collate Latin1_general_ci_ai ' Set @Sql = replace (@sql, '', @db) Create table #tabList (objID INT primary key clustered, schName sysname, TAB sysname) Insert into #tabList Exec sp_executeSql @Sql, N'@TabListLike nvarchar(max), @Schema sysname', @TabListLike, @Schema Declare @objId Int Declare @TAB sysname Select @objId = MIN(objId)-1 from #tablist While(1=1) Begin Select top 1 @objId = objId , @TAB = TAB From #tabList Where objId > @objId If @@ROWCOUNT = 0 break Set @Sql = ' Use [] If object_id("[].[_yAudit]") IS NOT NULL Drop trigger [].[_yAudit] If object_id("yAudit_.") IS NOT NULL Drop table [yAudit_].[] If object_id("yAudit__TxSeq.") IS NOT NULL Drop table [yAudit__TxSeq].[] ' Set @Sql = replace (@Sql, '', @db) Set @Sql = replace (@Sql, '', @schema) Set @Sql = replace (@Sql, '', @TAB) Set @Sql = replace (@Sql, '"', '''') print @sql Exec sp_executeSql @Sql End -- While End -- Audit.RemoveIt go If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'Audit.ProcessExpiredDataAudits' GO Create procedure Audit.ProcessExpiredDataAudits @db sysname , @jobNo Int = NULL as Begin Declare @schema sysname , @tabListLike nvarchar(max) , @sql nvarchar(max) create table #triggerMatch (sch sysname, TAB sysname, primary key clustered (sch, TAB)) Set @sql = ' use [] ;With TrigDetails as ( Select TR.name as TRG , TR.object_id , Object_name(TR.parent_id) as TAB , schema_name(convert(int, objectpropertyex(TR.parent_id, "schemaId"))) as SCH From sys.triggers TR ) , TabWithAuditTriggerExpired as ( Select TRG , Stuff( Stuff(M.definition, 1, charindex(TAB+"_yAudit_expirationDate", M.definition) -10, ""), 9, len(M.definition), "") as ExpDate , TAB , SCH From TrigDetails TR Join sys.sql_modules M On M.object_id = TR.object_id Where TAB+"_yAudit" = TRG -- expiration date is located as a comment into the trigger code And M.definition like "%"+TAB+"_yAudit_expirationDate%" ) Select SCH, TAB From TabWithAuditTriggerExpired Where getdate() > convert(datetime, expDate, 112) ' Set @sql = replace (@sql, '', @db) Set @sql = replace (@sql, '"', '''') Insert into #triggerMatch (sch, TAB) Exec sp_executeSql @sql If @@ROWCOUNT > 0 Begin Declare @Info nvarchar(max) Set @Info = 'Start removing audit expired on ['+@db+'] ' Exec yExecNLog.LogAndOrExec @context = 'Audit.ProcessExpiredDataAudits' , @Info = @Info , @jobNo = @jobNo End While (1=1) Begin Select top 1 @schema = sch From #triggerMatch If @@ROWCOUNT = 0 Break Select @tabListLike = ( Select CONVERT(nvarchar(max), '||') + TAB as [text()] From #triggerMatch Where sch = @schema Order by TAB For XML PATH('') ) Set @tabListLike = REPLACE(@tabListLike , '||', yUtl.UnicodeCrLf()) Exec Audit.RemoveIt @db = @db, @schema = @schema, @tabListLike = @tabListLike, @jobNo = @JobNo Delete -- remove processed schema From #triggerMatch Where sch = @schema End End -- Audit.ProcessExpiredDataAudits go If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'Audit.ProcessDataAuditsCleanup' GO Create procedure Audit.ProcessDataAuditsCleanup @db sysname , @jobNo Int = NULL as Begin Declare @Sql nvarchar(max) Declare @Info nvarchar(max) If @jobNo is NOT NULL -- may be call from ProcessDataAuditsCleanupForAllDb Begin Set @Info = 'Audit traces cleanup on ['+@db+'] to preserve space' Exec yExecNLog.LogAndOrExec @context = 'Audit.ProcessDataAuditsCleanup' , @Info = @Info , @jobNo = @jobNo End Set @Sql = ' use [] declare @trunc table (seq int primary key clustered, sch sysname, tb sysname) ;With SelectedTrigger as ( Select schema_name(convert(int, objectpropertyex(TR.parent_id, "schemaId"))) as sch , TR.name as trg , Object_name(TR.parent_id) as Tb From sys.triggers TR ) Insert into @trunc (seq, sch, tb) Select ROW_NUMBER() over(order by sch, tb) as Seq , sch , Tb From SelectedTrigger Where trg = tb + "_yAudit" Declare @sch sysname , @tb sysname , @seq int , @sql nvarchar(max) Set @seq = 0 While (1=1) Begin Select top 1 @seq = seq, @sch = sch, @tb = tb From @trunc Where seq > @seq Order by seq If @@ROWCOUNT = 0 Break Set @Sql = "Truncate table [yAudit_].[]" Set @Sql = REPLACE(@sql, "", @sch) Set @Sql = REPLACE(@sql, "", @tb) Exec sp_executeSql @Sql End -- While ' Set @sql = replace (@sql, '', @db) Set @sql = replace (@sql, '"', '''') Begin Try Exec sp_executeSql @sql End Try Begin Catch Exec yExecNLog.LogAndOrExec @context='Audit.ProcessDataAuditsCleanup', @err='?', @JobNo = @jobNo End Catch End -- Audit.ProcessDataAuditsCleanup go If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'Audit.ProcessDataAuditsCleanupForAllDb' GO Create proc Audit.ProcessDataAuditsCleanupForAllDb as Begin set nocount on DECLARE @RC int DECLARE @name sysname declare @db TABLE (name sysname primary Key) declare @jobNo int Insert into @db select name from sys.databases set @name = '' While (1=1) Begin Select top 1 @name = name from @db where name > @name order by name If @@ROWCOUNT = 0 break If DATABASEPROPERTYEX(@Name, 'Updateability') <> N'READ_WRITE' Continue print @name Exec Audit.ProcessExpiredDataAudits @name, @jobNo Exec Audit.ProcessDataAuditsCleanup @name, @jobNo End End -- Audit.ProcessDataAuditsCleanupForAllDb GO Drop function if exists maint.HistoryView go Create Function maint.HistoryView (@StartDateTime datetime, @EndDatetime datetime, @errOnly Int) -- --------------------------------------------------------------------------------------- -- Function to list filter history in a more readeable form -- --------------------------------------------------------------------------------------- Returns Table as Return ( Select * From (Select StartDateTime=@StartDateTime, EndDateTime=ISNULL(@EndDateTime, Getdate()), ErrOnly=@ErrOnly) as Prm CROSS APPLY ( Select * -- partitionning by JobNo, Seq ensures that SuccessFound, ErrFound, SomeSqlFound are evaluated -- for the same YourSqlDba Action , SuccessFound=Max(Ld.isSuccess) Over (Partition By LD.JobNo, LD.Seq) , SqlFound=Max(Ld.isSql) Over (Partition By LD.JobNo, LD.Seq) , ErrFound=Max(Ld.isErr) Over (Partition By LD.JobNo, LD.Seq) From ( Select D.cmdStartTime, D.Secs, LDet.*, LDF.IsSuccess, LDF.IsSql, LDF.IsErr From -- By listing Job events in a time range, we may encounter more than a single job -- To analyze if there is error, we consider the one with most events in that range -- as the one to consider for error reporting. -- HistoryView is used also to detect errors at end of maintenance, so it is important. -- This is mainly what happen for example when main maintenance run without errors, but -- for example a log backup job would encounter an error in the same time range. Log backup -- isn't the job in focus for reporting. -- Similary if time range focus on Log backup, log backup job has the most events. ( Select Top 1 JobFocus=JD.JobNo, NbEvent=Count(*) From Maint.JobHistoryDetails as JD Where JD.cmdStartTime Between Prm.StartDateTime And Prm.EndDateTime Group By JD.JobNo Order by nbEvent Desc ) as focus -- get events in the range CROSS JOIN ( Select JD.JobNo, JD.Seq, JD.cmdStartTime, JD.Secs From Maint.JobHistoryDetails as JD Where JD.cmdStartTime Between Prm.StartDateTime And Prm.EndDateTime ) as D -- seek into details for Status JOIN Maint.JobHistoryLineDetails as LDet ON LDet.JobNo = D.JobNo And LDet.seq = D.Seq -- signal event with success, some SQL or errors for the job in focus only -- some actions do not record a success status, as they are reporting of something that happened outside logAndOrExec CROSS APPLY ( -- analyze results for error situations Select isSuccess, isSql, isErr From (Select isSuccess=IIF(LDet.typ = 'STATUS' And LDet.Txt Like 'Success%', 1, 0)) as isSuccess -- some actions may do not record a success status, even if SQL is executed by logAndExec and trapped etc. -- so we want to know if some SQL was there CROSS APPLY (Select isSql=IIF(LDet.typ = 'Sql' And Ldet.JobNo = JobFocus, 1, 0)) as isSql -- some actions record an err status, as the SQL is executed by logAndExec -- some other actions record an errY status that comes from YourSqlDba but not for a specific -- SQL execution CROSS APPLY (Select isErr=IIF(LDet.typ Like 'Err%' And Ldet.JobNo = JobFocus, 1, 0)) as isErr Where LDet.JobNo = JobFocus UNION ALL -- When this is not the focus job, assume all is ok, do not signal error for job without focus. Select isSuccess=1, isSql=0, isErr=0 Where LDet.JobNo <> JobFocus ) as LDF ) as LD ) as Dis -- -- to optimize if none of these columns are requested OUTER APPLY ( Select J.MaintJobName, J.SqlAgentJobName, J.JobStart, J.JobEnd, JsonPrms From Dbo.MainContextInfo(Dis.JobNo) as J ) as JobInfo Where ISNULL(Prm.errOnly,0) = 0 OR (Prm.errOnly = 1 And ((Dis.SuccessFound=0 And Dis.SqlFound=1) Or (Dis.ErrFound=1))) ) -- maint.HistoryView go Drop function if exists maint.GetFormattedReportElements go Create Function maint.GetFormattedReportElements ( @email_Address nvarchar(200) , @command nvarchar(200) -- Help to select maintenance emails format , @MaintJobName nvarchar(200) , @StartOfMaint datetime , @JobNo Int , @SendOnErrorOnly int ) -- --------------------------------------------------------------------------------------- -- Function to list filter history in a more readeable form -- --------------------------------------------------------------------------------------- Returns Table as Return ( Select FormattedColInfo.* From ( Select ToPrm.* , StartEnd.* , JobNameSource From ( Select email_Address=@email_Address, Command=@Command, maintJobName=@MaintJobName , JobNo=@JobNo, SendOnErrorOnly=@SendOnErrorOnly, StartOfMaintPrm= @StartOfMaint , crlf=yUtl.UnicodeCrLf() ) as ToPrm -- jobStart and jobEnd are more precise, if a jobNo is specified. CROSS APPLY ( Select * From (Select JobStart, JobEnd From Maint.JobHistory Where JobNo=ToPrm.JobNo) as JH CROSS APPLY (Select StartOfMaint=ISNULL(JH.jobStart,ToPrm.StartOfMaintPrm)) As StartOfMaint -- JobEnd may be missing if no job is created. Review code so that it is always created CROSS APPLY (Select EndOfMaint=ISNULL(JH.jobEnd,Getdate())) as EndOfMaint CROSS APPLY (Select StartOfMaintTxt=CONVERT(NVARCHAR,StartOfMaint,121)) StartOfMaintTxt CROSS APPLY (Select EndOfMaintTxt=CONVERT(NVARCHAR,EndOfMaint,121)) EndOfMaintTxt ) as StartEnd CROSS APPLY ( Select JobNameSource=Coalesce(SqlAgentJobName, ToPrm.Command, 'Manual Maintenance Job') From Dbo.MainContextInfo(ToPrm.Jobno) as C LEFT JOIN(values ('SaveDbOnNewFileSet%'),('DeleteOldBackups%'),('YourSQLDba_DoMaint%') ) as J(CmdLike) On ToPrm.Command Like J.CmdLike ) as JobNameSource ) as Prm CROSS APPLY (Select ServerInstance=Convert(Nvarchar(128),SERVERPROPERTY('ServerName'))) As ServerInstance CROSS APPLY (Select YourSqlDbaVersion=VersionNumber From Install.VersionInfo ()) as YourSqlDbaVersion CROSS APPLY (Select JobSuccess=IIF(Not Exists(Select * From MAINT.HistoryView(Prm.StartOfMaint, Prm.EndOfMaint, 1)),1,0)) as JobSuccess CROSS JOIN (Select shortResultMessTmp='#shortResultMess#') as shortResultMessTmp Cross Apply (Select shortResultMess=IIF(JobSuccess=1, 'Maintenance succeeded', 'Error detected by maintenance process')) as shortResultMess Cross Apply (Select ErrColor=IIF(JobSuccess=1, 'color="Green"', 'color="Red"')) as ErrColor CROSS JOIN WhoCalledWhat as ctx --extract the full predigree of the call, who, which program, and the query at the top of the stack -- have
where for crLf and keep crlf after
for readability if debug is needed Cross Apply (Select MainCallWithBreak=Replace(Ctx.MainCall, crlf, '
')) as MainCallWithBreak Cross Apply (Select MainCallWithBreakAndCrLf=Replace(MainCallWithBreak, '
', '
' + crLf)) as MainCallWithBreakAndCrLf Cross Apply (Select mailPriority = IIF(JobSuccess=1, 'Normal', 'High')) as MailPriority Cross Apply (Select reportSource = IIF(ctx.Prog NOT Like 'SqlAgent%', 'Manual Maintenance Job', 'SQL Server Agent Job:')) as reportSource Cross Apply (Select InstructionBloc=IIF(JobSuccess=1, '===InstructionOk===', '===InstructionErr===')) as InstructionBloc Cross Apply (Select HowToShowHistory=c.TxtInCmt From Dbo.GetCmtBetweenDelim(InstructionBloc, 'maint.GetFormattedReportElements') as C ) as ActionToTakeIf /*===InstructionOk===

To list ALL maintenance commands ran by the maintenance process,
execute the following command in a query window connected to the
SQL Server instance that ran the maintenance:

Select cmdStartTime, JobNo, seq, Typ, line, Txt 
From 
  (Select ShowErrOnly=1, ShowAll=NULL) as Enum
  cross apply YourSQLDba.Maint.HistoryView('#StartOfMaintTxt#', '#EndOfMaintTxt#', ShowAll) 
Order By cmdStartTime, Seq, TypSeq, Typ, Line

===InstructionOk===*/ /*===InstructionErr=== To list only the errors, copy & paste the following command in a query window
connected to the SQL Server instance that ran the maintenance.

Select cmdStartTime, JobNo, seq, Typ, line, Txt 
From
  (Select ShowErrOnly=1, ShowAll=NULL) as Enum
  cross apply YourSQLDba.Maint.HistoryView('#StartOfMaintTxt#', '#EndOfMaintTxt#', ShowErrOnly) 
Order By cmdStartTime, JobNo, Seq, TypSeq, Typ, Line



To bring back quickly any databases online from offline, run this command:
Exec YourSQLDba.Maint.BringBackOnlineAllOfflineDb

===InstructionErr===*/ -- relative column order is important especially between -- shortResultMessTmp, shortResultMess, ErrColor and StartOfMaintTxt, EndOfMaintTxt CROSS APPLY ( Select mailPriority, JobNameSource, reportSource, email_Address , SendOnErrorOnly, JobSuccess, shortResultMessTmp, shortResultMess, ErrColor , HowToShowHistory, YourSqlDbaVersion, StartOfMaintTxt, EndOfMaintTxt, ServerInstance , Prog, Host, MainCallWithBreakAndCrLf , Subject=ServerInstance+', '+ReportSource+', '+JobNameSource ) as FormattedColInfo -- code to test /* Declare @jobNo Int Select Top 1 @jobNo=jobNo From Maint.JobHistory Select * From maint.GetFormattedReportElements ( 'pelforjunk@outlook.com' , 'UneCommandeTest' , 'nomdejobYourSqlDba' , Getdate() , @JobNo , 0 ) */ ) -- maint.GetFormattedReportElements go -- ------------------------------------------------------------------------------ -- Procedure which send exec report and errors report -- ------------------------------------------------------------------------------ If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yMaint.SendExecReports' GO create proc yMaint.SendExecReports @email_Address nvarchar(200) , @command nvarchar(200) -- Help to select maintenance emails format , @MaintJobName nvarchar(200) , @StartOfMaint datetime , @JobNo Int , @SendOnErrorOnly int as Begin Declare @msgBody nvarchar(max) Declare @startOfMaintTxt nvarchar(30) Declare @EndOfMaintTxt nvarchar(30) Declare @Subject nvarchar(512) Declare @jobSuccess Int Declare @mailPriority nvarchar(6) Select @msgBody = msgBody , @startOfMaintTxt = startOfMaintTxt , @EndOfMaintTxt = EndOfMaintTxt , @Subject = Subject , @MailPriority = mailPriority , @jobSuccess = JobSuccess From maint.GetFormattedReportElements ( @email_Address , @command , @MaintJobName , @StartOfMaint , @JobNo , @SendOnErrorOnly ) as ReportElements CROSS APPLY (Select JsonReportElements=(Select ReportElements.* FOR JSON PATH)) as jsonReportElements CROSS APPLY (Select MsgBody=g.Code From Dbo.GetTemplateFromCmtAndReplaceTags ('===MsgBody===', NULL, jsonReportElements) as g) as MsgBody /*===MsgBody=== Maintenance report from YourSqlDba #YourSqlDbaVersion#


Server:#ServerInstance#
#reportSource##JobNameSource#
Start, end: #StartOfMaintTxt#,   #EndOfMaintTxt#
Result:#shortResultMessTmp#
#HowToShowHistory# Command lauched from #Host# by #reportSource# #JobNameSource#

#MainCallWithBreakAndCrLf#


===MsgBody===*/ -- Return without sending a message if the job is success and message must be sent only in case of error If @JobSuccess=1 And @SendOnErrorOnly=1 Return EXEC Msdb.dbo.sp_send_dbmail @profile_name = 'YourSQLDba_EmailProfile' , @recipients = @email_Address , @importance = @mailPriority , @subject = @Subject , @body = @MsgBody , @body_format = 'HTML' End -- yMaint.SendExecReports GO If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'Maint.ShowJobErrors' GO -- this procedure allows calling HistoryView from SqlAgent history create proc Maint.ShowJobErrors @JobNo Int as Begin Select cmdStartTime, JobNo, seq, Typ, line, Txt From (Select JobStart, JobEnd From Maint.JobHistory Where JobNo=@Jobno) as Times CROSS APPLY ( Select cmdStartTime, JobNo, seq, Typ, line, Txt, typSeq From YourSQLDba.Maint.HistoryView(JobStart, jobEnd, 1) ) as H Order By H.cmdStartTime, H.Seq, H.TypSeq, H.Typ, H.Line End Go -- ------------------------------------------------------------------------------ -- Procedure that performs the CheckFullRecoveryModel policy. Database not in FULL Recovery -- model will generate an error of the maintenance. It is possible to exclude -- this check for particular databases with the parameter @ExcDbFromPolicy_CheckFullRecoveryModel -- ------------------------------------------------------------------------------ If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yMaint.CheckFullRecoveryModelPolicy' GO create proc yMaint.CheckFullRecoveryModelPolicy @jobNo Int , @IncDb nVARCHAR(max) , @ExcDb nVARCHAR(max) , @ExcDbFromPolicy_CheckFullRecoveryModel nvarchar(max) as Begin Declare @dblist nvarchar(max) Declare @context nvarchar(max) Declare @DbCount int Exec yExecNLog.LogAndOrExec @context = 'yMaint.CheckFullRecoveryModelPolicy' , @Info = 'Check Recovery policy' , @JobNo = @jobNo -- Add the exclusions of @ExcDbFromPolicy_CheckFullRecoveryModel to the selection Set @ExcDb = @ExcDb + CHAR(10) + @ExcDbFromPolicy_CheckFullRecoveryModel Set @dblist = '' Select @dblist = @dblist + ',' + x.DbName From sys.databases db join yUtl.YourSQLDba_ApplyFilterDb(@IncDb, @ExcDb) x on db.name = x.DbName collate database_default Where x.FullRecoveryMode <> 1 And db.source_database_id is Null AND x.DbName Not In ('master', 'YourSQLDba', 'msdb', 'model') AND x.DbName Not Like 'ReportServer%TempDB' AND x.DbName Not Like 'YourSQLDba%' AND DatabasepropertyEx(DbName, 'Status') = 'Online' -- To Avoid db that can't be processed Set @dbcount = @@ROWCOUNT Set @dblist = Stuff( @dblist, 1, 1, '') If @dbcount > 0 Begin declare @err nvarchar(max) Set @err = 'Violation of Recovery model policy for db :'+@dbList Exec yExecNLog.LogAndOrExec @context = 'yMaint.CheckFullRecoveryModelPolicy' , @YourSqlDbaNo = '006' , @err = @err , @Info = 'If you are sure you want those databases in SIMPLE recovery model you can use the «@ExcDbFromPolicy_CheckFullRecoveryModel» parameter of the «YourSQLDba_DoMaint» to exclude databases from the check' , @JobNo = @JobNo End End -- yMaint.CheckFullRecoveryModelPolicy GO -- ------------------------------------------------------------------------------ -- Procedure who perform log shrink -- ------------------------------------------------------------------------------ If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yMaint.ShrinkLog' GO create proc yMaint.ShrinkLog @Db nvarchar(128) , @JobNo Int , @MustLogBackupToShrink int output as Begin Declare @DatSize Int Declare @LogSize Int Declare @primaryFileName sysname Declare @Sql Nvarchar(max) = 'Select @primaryFileName=name from ['+@Db+'].sys.database_files Where data_space_id=1' Exec Sp_executeSql @Sql, N'@primaryFileName sysname Output', @primaryFileName output -- Here we workaround a bad practice that consist to have more than one log file -- So we ensure to have the most pertinent log file, by guessing that the biggest is the best Declare @LogFileName sysname Declare @LogPhysFileName sysname Select Top 1 @LogFileName = FileName, @LogPhysFileName=physical_name From dbo.DbsFileSizes(@db) Where type_desc='LOG' Order by fSizeInMb Desc -- we seek to guess an appropriate log size to data size ratio -- We make the assumption that aside the primary file, some other secondary -- files contibute less to log growth (history, blob) -- So in computing data size to log size ratio, we sum entire space of the primary file -- and 1/5 the size of other filegroup of type rows Select @DatSize=SUM(fSizeInMb/SizeDivisor) From ( Select FileName, fSizeInMb, SizeDivisor From Dbo.DbsFileSizes (@Db) CROSS APPLY (Select sizeDivisor=IIF(fileName=@PrimaryFileName, 1, 5)) as sizeDivisor Where type_desc = 'ROWS' ) as S Select Top 1 @LogSize=fSizeInMb From Dbo.DbsFileSizes (@Db) Where type_desc = 'LOG' Order by fSizeInMb Desc Declare @newSize Int Set @MustLogBackupToShrink = 0 -- Test if there is nothing that prevent log truncation and shrink -- The goal is to avoid causing errors to other transactions or replication/mirroring/backup processes. -- because of concurrent DBCC ShrinkFile -- In SQL2012 SP2 it happens frequently that a status LOG_BACKUP is there when there is not current log backup If exists (Select * from sys.databases where name = @Db And log_reuse_wait not in (0,2)) Begin -- Wait for 10 sec and try again WAITFOR DELAY '00:00:10'; If exists (Select * from sys.databases where name = @Db And log_reuse_wait not in (0,2)) BEGIN Print 'Log shrinking delayed for '+@Db Return ---- ******* Exit here END End Print 'Database '+@Db print 'Actual data size ' + convert(nvarchar(30), @datSize)+'Mb' print 'Actual log size ' + convert(nvarchar(30), @logSize)+'Mb' -- Condition to no perform a log shrink If (@logSize < @DatSize * 0.20) Or -- log size < 20% data size (@logSize < 10) And -- log size < 10 meg (@DatSize * 0.20 < 10) -- target datasize reduction must be greater than 10 meg Return -- new log size is reduced to one fifth of datafile Set @newSize = @DatSize * 0.20 Print 'Log shrink in process for '+@Db /*===ShrinkTemplate=== ---------------------------------------------------------------------------------------------- -- Shrink of log file () ---------------------------------------------------------------------------------------------- USE [#DbName#] Begin Try DBCC SHRINKFILE (N'#name#', #targetSize#) with no_infomsgs -- if still here, shrink is successful, so erase past shrink failure Delete YourSqlDba.Maint.DbccShrinkLogState Where dbName = Db_name() End Try Begin Catch Declare @errm nvarchar(4000); Set @errm = yExecNLog.FormatBasicBeginCatchErrMsg () -- first error already logged, do not do it again Insert into YourSqlDba.Maint.DbccShrinkLogState (DbName, FailedShrinkTime) Select Db_name(), Getdate() Where Not Exists (Select * From YourSqlDba.Maint.DbccShrinkLogState Where dbName = Db_name()) -- FailedShrinkTime -- or when there was an error during last shrink If Exists ( -- not succeed shrink happen since 2 hours so error still in log Select * From YourSqlDba.Maint.DbccShrinkLogState Where dbName = Db_name() And Datediff(hh, FailedShrinkTime, Getdate()) > 2 ) Begin -- If there is not succeed shrink since 2 hours, notify it as a YourSqlDba error Exec yExecNLog.LogAndOrExec @context = 'yMaint.ShrinkLog' , @YourSqlDbaNo = '015' , @Info = 'Shrink Log error' , @err = @errm , @JobNo = #JobNo# End End Catch ===ShrinkTemplate===*/ Select @Sql = R.Code From (Select DbName=@Db, name=@LogFileName, physName=@LogPhysFileName , TargetSize=Str(@newSize,10), JobNo=CONVERT(nvarchar, @JobNo)) as TagCols CROSS APPLY (Select toReplace=(Select TagCols.* for Json Path, INCLUDE_NULL_VALUES)) as ToReplace CROSS APPLY Dbo.GetTemplateFromCmtAndReplaceTags ('===ShrinkTemplate===', NULL, ToReplace) as R Exec yExecNLog.LogAndOrExec @context = 'yMaint.ShrinkLog' , @Info = 'Log Shrink' , @sql = @sql , @JobNo = @JobNo /*===GetLogSize=== Select @logSize = (size / 128) From [#DbName#].sys.database_files df ===GetLogSize===*/ Select @Sql = R.Code From (Select ToReplace = (Select DbName=@Db for Json Path, INCLUDE_NULL_VALUES)) as ToReplace CROSS APPLY Dbo.GetTemplateFromCmtAndReplaceTags ('===GetLogSize===', NULL, ToReplace) as R print @sql Exec sp_executeSql @sql , N'@logSize Int Output' , @logSize Output -- if log doesn't shrink, shrink needs to be done more than once, with log backups in between -- a return value instruct the caller to do so If (Abs(@newSize - @logSize) / @newSize) > 0.01 Set @MustLogBackupToShrink = 1 End -- yMaint.ShrinkLog GO -- ------------------------------------------------------------------------------ -- Utility proc to shrink all logs -- Intended for use with non YourSqlDba backup solution like CommVault -- when its does its log backups. -- Must be call as Commvault post-job, through SQLCMD, to perform log shrinking -- See https://tinyurl.com/YourSqlDbaAncCommVault for a more detailed overview. -- ------------------------------------------------------------------------------ Drop Proc If Exists Maint.ShrinkAllLogs GO Create Proc Maint.ShrinkAllLogs as Begin Declare @Sql Nvarchar(max) Declare @jobNo Int Declare @ignore int Select Top 1 @JobNo=JobNo From Maint.JobHistory Order by JobNo Desc Drop Table IF Exists #Db Select DbName=name Into #Db From sys.databases Where user_access_desc IN ('MULTI_USER','SINGLE_USER') And state_desc ='ONLINE' And recovery_model_desc <> 'SIMPLE' Declare @Db sysname While (1=1) Begin Select Top 1 @Db=DbName From #Db If @@ROWCOUNT=0 Break Delete #Db Where DbName=@Db exec yMaint.ShrinkLog @Db = @Db , @JobNo = @jobNo , @MustLogBackupToShrink = @ignore output End End GO -- ------------------------------------------------------------------------------ -- Utility proc to bring back all Db offline in normal mode -- in case YourSqlDba put them offline because of a disconnected drive -- ------------------------------------------------------------------------------ If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'Maint.BringBackOnlineAllOfflineDb' GO CREATE proc Maint.BringBackOnlineAllOfflineDb as Begin Declare @sql nvarchar(max) Select name, cast (databasepropertyex(name, 'status') as Sysname) as Status into #Db From sys.databases Where databasepropertyex(name, 'status') = 'OFFLINE' Declare @n sysname, @status sysname While exists (select * from #Db) Begin Select top 1 @n = name, @status = Status from #Db Set @sql = ' Alter database [] Set online ' Set @sql = yExecNLog.Unindent_TSQL(@sql) Exec yExecNLog.QryReplace @sql output, '', @n Exec (@sql) print @sql Delete from #Db where name = @n End End -- Maint.BringBackOnlineAllOfflineDb GO If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yMaint.LogCleanup' GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO ----------------------------------------------------------------------------- -- yMaint.LogCleanup (for entries older than 30 days) -- Mail logs -- Backup history logs -- Job history -- Cycle SQL Server error log ----------------------------------------------------------------------------- create proc yMaint.LogCleanup @jobNo Int as Begin declare @d nvarchar(8) declare @lockResult int declare @sql nvarchar(max) Begin try Set @sql = 'Exec msdb.dbo.sysmail_delete_log_sp @logged_before = "";' Set @sql = replace (@sql, '', convert(nvarchar(8), dateadd(dd, -30, getdate()), 112)) Set @sql = replace (@sql, '"', '''') Exec yExecNLog.LogAndOrExec @context = 'yMaint.LogCleanup' , @info = 'Cleanup log entries older than 30 days, begins with mail' , @sql = @sql , @JobNo = @JobNo Set @sql = 'EXECUTE msdb.dbo.sysmail_delete_mailitems_sp @sent_before = "";' Set @sql = replace (@sql, '', convert(nvarchar(8), dateadd(dd, -30, getdate()), 112)) Set @sql = replace (@sql, '"', '''') Exec yExecNLog.LogAndOrExec @context = 'yMaint.LogCleanup' , @info = 'Cleanup log entries older than 30 days, for mailitems' , @sql = @sql , @JobNo = @JobNo -- clean backup history Set @sql = 'exec Msdb.dbo.sp_delete_backuphistory @oldest_date = "" ' Set @sql = replace (@sql, '', convert(nvarchar(8), dateadd(dd, -30, getdate()), 112)) Set @sql = replace (@sql, '"', '''') Exec yExecNLog.LogAndOrExec @context = 'yMaint.LogCleanup' , @info = 'Cleanup log entries older than 30 days, for backup history' , @sql = @sql , @JobNo = @JobNo -- clean sql agent job history Set @sql = 'EXECUTE Msdb.dbo.sp_purge_jobhistory @oldest_date = ""' Set @sql = replace (@sql, '', convert(nvarchar(8), dateadd(dd, -30, getdate()), 112)) Set @sql = replace (@sql, '"', '''') Exec yExecNLog.LogAndOrExec @context = 'yMaint.LogCleanup' , @info = 'Cleanup log entries older than 30 days, for job history' , @sql = @sql , @JobNo = @JobNo -- clean job maintenance job history (SQL Server own maintenance) Set @sql = 'EXECUTE Msdb.dbo.sp_maintplan_delete_log null,null,""' Set @sql = replace (@sql, '', convert(nvarchar(8), dateadd(dd, -30, getdate()), 112)) Set @sql = replace (@sql, '"', '''') Exec yExecNLog.LogAndOrExec @context = 'yMaint.LogCleanup' , @info = 'Cleanup log entries older than 30 days, for SQL Server job maintenace plans' , @sql = @sql , @JobNo = @JobNo -- archive current log, and start a new one Set @sql = 'Execute sp_cycle_errorlog' Set @sql = replace (@sql, '', convert(nvarchar(8), dateadd(dd, -30, getdate()), 112)) Set @sql = replace (@sql, '"', '''') Exec yExecNLog.LogAndOrExec @context = 'yMaint.LogCleanup' , @info = 'Recycle Sql Server error log, start a new one' , @sql = @sql , @JobNo = @JobNo -- cleanup YourSqlDba's job history (keep no more than 30 days) Delete H From ( Select distinct JobNo -- From Maint.JobHistory Where JobStart < dateadd(dd, -30, getdate()) ) as T join Maint.JobHistory H On H.JobNo = T.JobNo End try Begin catch Exec yExecNLog.LogAndOrExec @context = 'yMaint.LogCleanup' , @Info = 'Error caught in proc' , @err = '?' , @JobNo = @JobNo End Catch End -- yMaint.LogCleanup GO If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yMaint.IntegrityTesting' GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO ---------------------------------------------------------------------------------------- -- yMaint.IntegrityTesting -- Process integrity testing using CREATE proc yMaint.IntegrityTesting @jobNo Int , @SpreadCheckDb Int as Begin declare @cmptlevel Int declare @dbName nvarchar(512) declare @sql nvarchar(max) declare @lockResult int declare @errorN int declare @seqCheckNow Int declare @doFullCheckDb Int declare @sizeDb bigInt Declare @action XML Declare @seq Int Set @DbName = '' --drop table if exists #db;select dbName = name into #db from sys.databases; declare @SpreadCheckDb int = 7, @seqCheckNow int Update Maint.JobSeqCheckDb Set @seqCheckNow = (seq + 1) % MinSpread, seq = @seqCheckNow From ( Select MinSpread=Min(MaxSpread) From ( -- do not let seq get higher than the number of databases Select MaxSpread=(Select NbOfDb=Count(*) From #Db) UNION ALL Select MaxSpread=@SpreadCheckDb ) as MinPrm ) as MinPrm --drop table if exists #tmp --insert into #tmp ----------------------------------------------------------------------------------------------------------- -- This query finds a db processing order that helps to evently distribute the DBCC work based on -- database size, because I suppose the work for DBCC CheckDb is somewhat proportional to db size. -- Either we do a full DBCC checkdb or a DBCC checkdb with physical_only -- -- So the idea of the query is to rank databases by size and then from each group this rank makes -- I choose to process one only one of every n database where n is either the minimum of -- @spreadCheckDb or the number of database. Suppose spreadCheckDb is 7 and there is only three databases -- that qualifies, we are going to cycle among theses 3, without waiting for n to reach spreadcheckDb -- from values 4 to 7 without doing any fullcheckdb. -- This smooths a lot TOTAL difference (and hence execution time) between Db size to procesd. -- However there is little remaining increasing size at each increasing n value. To alleviate even more -- this effect, I introduce a factor to sorting by size that bias size both up or down based on database id. -- This bias applied to sort order give a more even distribution for close database sizes -- Obviously there is nothing that can be done for large disrcrepancies (over 40%) in database sizes at top sizes -- and this remains unavoidable ---------------------------------------------------------------------------------------------------------- -- !!!some initialisation code to test isolately the query below, keep the comment -- Drop table if exists #Db -- Select DbName=Name Into #Db From Sys.Databases -- declare @SpreadCheckdb int=3, @seqCheckNow int = 0 Select SpreadSet.*, CheckTurnValue, DbTurn into #DbToCheck From (Select SpreadCheckDb = @SpreadCheckDb, seqCheckNow = @seqCheckNow) as Prm CROSS APPLY ( -- this query gives a sizeOrder starting to 1 in each group -- so it simplify computation of shift in turn sequence Select * -- this value helps compute a value to distribute and then execution time more -- order based on size by using size*bias to sort processing order. , SizeOrderInSpreadGroup=row_number() Over(Order by BiaisedValueFromSize) - 1 From (Select NbOfDb=count(*) From #db) as NbOfDb CROSS JOIN ( -- Get database Sizes by the sum of size all of their files Select BdSizes.*, cmptlevel=D.compatibility_level, D.page_verify_option_desc From ( -- Sum by db name SELECT Db.dbname, sizedb = SUM(S.fSizeInMb) FROM #db as Db CROSS APPLY dbo.DbsFileSizes (Db.DbName) as S GROUP BY Db.dbname ) as BdSizes JOIN Sys.Databases as D -- get complementary info about the database ON D.name = BdSizes.Dbname ) as Dbs -- If the number of database is lower than SpreadCheckPrm, reduce maximum of sequence to the minimum of both -- otherwise no database is going to match for those runs where seq of Maint.JobSeqCheckDb is higher than the -- number of databases Cross Apply (Select MinSpreadSetSize=MIN(x) From (Values (SpreadCheckDb),(NbOfdb)) as t(x)) as maxSpreadSetSize -- A bias is introduced to avoid bigger total execution time with bigger DB -- Actually this bias is broken down by taking one of the db every n db where n is either -- the least of SpreadCheckDb Prm or the number of databases to process, but this is prone to bigger execution times -- The compute factor below, will allow sizes to shift a little higher or lower depending on dbId Cross Apply (Select BiasToApplyToSizeInSequenceOrder=IIF(Db_Id(DbName)%2=1, 1.20, 0.8)) as BiasToApplyToSizeInSequenceOrder Cross Apply (Select BiaisedValueFromSize=Dbs.SizeDb * BiasToApplyToSizeInSequenceOrder) as BiaisedValueFromSize ) as SpreadSet -- Decide if it is this Bd turn in increasing order CROSS APPLY (Select CheckTurnValue=SizeOrderInSpreadGroup % MinSpreadSetSize) as CheckTurnValue CROSS APPLY (Select DbTurn=IIF( page_verify_option_desc <> 'CHECKSUM' Or CheckTurnValue = SeqCheckNow, 1, 0)) as doFullCheckDb While(1 = 1) -- simulate simple do -- loop Begin -- process on database at the time in name order Select top 1 @DbName = DbName , @cmptlevel = cmptlevel , @doFullCheckDb = DbTurn , @sizeDb = sizedb From #DbToCheck Where DbName > @DbName -- next Dbname greater than @dbname Order By DbName -- dbName order -- exit loop if no more name greater than the last one used If @@rowcount = 0 Break ----------------------------------------------------------------------------------------------- -- Very Large Databases : Not using DBCC CHECKDB but instead CHECKTABLE -- On sunday only, CheckAlloc and CheckCatalog being are done first on the database. -- CHECKTABLE are done everyday spreaded across the number of day to spread the job -- For VLDB Integrity testing DBCC Checktable proceed par parts all the spread period everyday ----------------------------------------------------------------------------------------------- if (@sizeDb > 10000000) -- Database sizes are in MB. begin SET DATEFIRST 7 DECLARE @DayOfWeek int SELECT @DayOfWeek = DATEPART(WEEKDAY, GETDATE()) CREATE TABLE #tableNames (Query nvarchar(max), seq int) set @sql = ' Use [] set nocount on ;With TableSizeStats as ( select object_schema_name(Ps.object_id) as scn --collate Latin1_General_CI_AS , object_name(Ps.object_id) as tb --collate Latin1_General_CI_AS From sys.dm_db_partition_stats ps JOIN sys.tables t ON ps.object_id = t.object_id join sys.indexes i on i.object_id=t.object_id where object_name(Ps.object_id) not like "Temp%" Group by Ps.object_id UNION SELECT object_schema_name(o.id), o.name FROM sysobjects o INNER JOIN sysindexes i ON o.id = i.id WHERE o.xtype = "V" -- View ) INSERT INTO #tableNames (Query, seq) Select "Use []; DBCC CHECKTABLE ("""+scn+"."+tb+""")" as Query, row_number() over (order by scn, tb) as seq From TableSizeStats where scn is not null and tb is not null and (abs(checksum(tb)) % ) = ' -- On Saturday IF (@DayOfWeek = 7) BEGIN Set @sql = replace(@sql,'', 'DBCC CHECKALLOC (""); DBCC CHECKCATALOG ("");' ) END ELSE BEGIN Set @sql = replace(@sql,'', '' ) END Set @sql = replace(@sql,'', @dbName ) Set @sql = replace(@sql,'', @SpreadCheckDb ) Set @sql = replace(@sql,'', @seqCheckNow ) set @sql = replace(@sql,'"','''') -- useful to avoid duplicating of single quote in boilerplate Set @ErrorN = 0 Exec yExecNLog.LogAndOrExec @context = 'yMaint.IntegrityTesting' , @sql = @sql , @JobNo = @JobNo , @ErrorN = @ErrorN Output -- For real integrity problem, we put database offline to avoid worsening of integrity problems. -- But when only error 5128 occurs there is no integrity problem. -- DBCC use an internal database snapshot and if there is a lack of space -- error message 5128 happens 'Write to sparse file '%ls' failed due to lack of disk space.' -- So we don't put the DB offline, if it is THE ONLY problem. -- LogAndOfExec takes care of returning 1 if any errors other than 5128 happens, and 5128 if it is the only type of error If @errorN <> 0 And @errorN <> 5128 Begin If @errorN <> 5128 Exec yMaint.PutDbOffline @DbName, @JobNo End WHILE EXISTS(SELECT TOP 1 1 FROM #tableNames) BEGIN DECLARE @query nvarchar(max), @seqquery int SELECT top 1 @query=query, @seqquery=seq from #tableNames delete from #tableNames where seq=@seqquery set @query = replace(@query,'"','''') -- useful to avoid duplicating of single quote in boilerplate Set @query = replace(@query,'', @dbName ) Set @ErrorN = 0 Exec yExecNLog.LogAndOrExec @context = 'yMaint.IntegrityTesting' , @sql = @query , @JobNo = @JobNo , @ErrorN = @ErrorN Output -- For real integrity problem, we put database offline to avoid worsening of integrity problems. -- But when only error 5128 occurs there is no integrity problem. -- DBCC use an internal database snapshot and if there is a lack of space -- error message 5128 happens 'Write to sparse file '%ls' failed due to lack of disk space.' -- So we don't put the DB offline, if it is THE ONLY problem. -- LogAndOfExec takes care of returning 1 if any errors other than 5128 happens, -- and 5128 if it is the only type of error If @errorN <> 0 Begin If @errorN <> 5128 Exec yMaint.PutDbOffline @DbName, @JobNo End END drop table #tableNames END -- If for Very Large Databases ELSE BEGIN -- Regular databases, either do Physical_ONLY most of the time, or once every n run without Physical_only Set @sql = 'DBCC checkDb("") '+ IIF(@doFullCheckDb = 0,' WITH PHYSICAL_ONLY ','') Set @sql = replace(@sql,'', @dbName ) set @sql = replace(@sql,'"','''') -- useful to avoid duplicating of single quote in boilerplate Set @ErrorN = 0 Exec yExecNLog.LogAndOrExec @context = 'yMaint.IntegrityTesting' , @sql = @sql , @JobNo = @JobNo , @ErrorN = @ErrorN Output If @errorN <> 0 Begin If Not exists -- check if this Txt has no error 5128, put it offline ( Select * From ( -- get current Txt, which is the latest (highest seq) for this spid and this job Select Top 1 JobNo, Seq From Maint.JobHistoryDetails Where jobNo = @jobNo order by JobNo, seq desc ) as lastAct JOIN Maint.JobHistoryLineDetails as LD ON LD.JobNo = LastAct.JobNo And LD.seq = LastAct.Seq -- if the logged error is the one below, this is due to lack of space -- and we don't put the database offline for this And Ld.Txt Like 'Error 5128%' ) Exec yMaint.PutDbOffline @DbName, @JobNo End -- if error END -- Regular database case End -- While boucle banque par banque End -- yMaint.IntegrityTesting GO If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yMaint.UpdateStats' GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO CREATE proc yMaint.UpdateStats @JobNo Int , @SpreadUpdStatRun Int as Begin declare @seqStatNow Int declare @cmptlevel Int declare @dbName sysname declare @sql nvarchar(max) declare @lockResult int Declare @seq Int -- row sequence for row by row processing Declare @scn sysname -- schema name Declare @tb sysname -- table name declare @sampling Int -- page count to get an idea if the size of the table Declare @idx sysname -- index name Declare @object_id int -- a proof that an object exists Begin Try Create table #TableNames ( scn sysname , tb sysname , sampling nvarchar(3) , seq int , primary key clustered (seq) ) Update Maint.JobSeqUpdStat Set @seqStatNow = (seq + 1) % @SpreadUpdStatRun, seq = @seqStatNow Set @DbName = '' While(1 = 1) -- simple do loop Begin Select top 1 -- first next in alpha sequence after the last one. @DbName = DbName , @cmptLevel = CmptLevel From #Db Where DbName > @DbName Order By DbName -- exit if nothing after the last one processed If @@rowcount = 0 Break -- -- If database is not updatable, skip update stats for this database If DATABASEPROPERTYEX(@DbName, 'Updateability') = N'READ_ONLY' Continue -- If database is in emrgency, skip update stats for this database If DatabasepropertyEx(@DbName, 'Status') = 'OFFLINE' Continue -- makes query boilerplate with replacable parameter identified by -- labels between "<" et ">" -- this query select table for which to perform update statistics truncate table #TableNames set @sql = ' Use [] set nocount on ;With TableSizeStats as ( select object_schema_name(Ps.object_id) as scn --collate , object_name(Ps.object_id) as tb --collate , Sum(Ps.Page_count) as Pg From sys.dm_db_index_physical_stats (db_id(""), NULL, NULL, NULL, "LIMITED") Ps Where ( OBJECTPROPERTYEX ( Ps.object_id , "IsTable" ) = 1 Or OBJECTPROPERTYEX ( Ps.object_id , "IsView" ) = 1) Group by Ps.object_id ) Insert into #tableNames (scn, tb, seq, sampling) Select scn , tb , row_number() over (order by scn, tb) as seq , Case When Pg > 5000001 Then "0" When Pg between 1000001 and 5000000 Then "1" When Pg between 500001 and 1000000 Then "5" When pg between 200001 and 500000 Then "10" When Pg between 50001 and 200000 Then "20" When Pg between 5001 and 50000 Then "30" else "100" End From TableSizeStats where scn is not null and tb is not null and (abs(checksum(tb)) % ) = ' set @sql = replace(@sql,'',convert(nvarchar(100), Serverproperty('collation'))) Set @sql = replace(@sql,'', convert(nvarchar(20), @seqStatNow)) Set @sql = replace(@sql,'', convert(nvarchar(20), @SpreadUpdStatRun)) set @sql = replace(@sql,'"','''') -- to avoid doubling of quotes in boilerplate set @sql = replace(@sql,'',@DbName) Exec yExecNLog.LogAndOrExec @context = 'yMaint.UpdateStats' , @Info = 'Table selection for update statistics' , @sql = @sql , @JobNo = @JobNo , @forDiagOnly = 1 set @seq = 0 While (1 = 1) begin Select top 1 @scn = scn, @tb = tb, @sampling = sampling, @seq = seq from #TableNames where seq > @seq order by seq if @@rowcount = 0 break Set @sql = 'Select @object_id = object_id("..") ' set @sql = replace (@sql, '', @DbName) set @sql = replace (@sql, '', @scn) set @sql = replace (@sql, '', @tb) set @sql = replace (@sql, '"', '''') Exec sp_executeSql @Sql, N'@object_id int output', @object_id output If @object_id is not null Begin Set @sql = 'update statistics [].[].[] WITH sample PERCENT' set @sql = replace (@sql, '', @DbName) set @sql = replace (@sql, '', @scn) set @sql = replace (@sql, '', @tb) If @sampling = 0 set @sql = replace (@sql, 'WITH Sample PERCENT', '') Else BEGIN If @sampling < 100 set @sql = replace (@sql, '', Str(@sampling)) Else set @sql = replace (@sql, 'Sample PERCENT', 'FULLSCAN') END set @sql = replace (@sql, '"', '''') Exec yExecNLog.LogAndOrExec @context = 'yMaint.UpdateStats' , @Info = 'update statistics selected' , @sql = @sql , @JobNo = @JobNo End end -- While End -- While boucle banque par banque End try Begin catch Exec yExecNLog.LogAndOrExec @jobNo = @jobNo, @context = 'yMaint.UpdateStats Error', @err = '?' End Catch End -- yMaint.UpdateStats GO If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yMaint.ReorganizeOnlyWhatNeedToBe' GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO CREATE proc yMaint.ReorganizeOnlyWhatNeedToBe @JobNo int as Begin declare @cmptlevel Int declare @dbName sysname declare @sql nvarchar(max) declare @lockResult int Declare @seq Int -- row sequence in work table Declare @scn sysname -- schema name Declare @tb sysname -- table name Declare @td sysname -- object type Declare @idx sysname -- index name Declare @colName sysname -- index column name Declare @pgLock int -- index page_locking flag Declare @partitionNum Int Declare @frag float Declare @index_type_desc NVARCHAR(60) Declare @Page_count BigInt Declare @alloc_unit_type_desc NVARCHAR(60) Declare @TotPartNb Int Declare @Info nvarchar(max) Declare @ReorgType nvarchar(10) Begin Try Declare @recMode sysname Create table #IndexNames ( scn sysname null , tb sysname null , td sysname null , idx sysname null , pgLock int null , partitionnum Int null , frag float null , index_type_desc NVARCHAR(60) null , Page_count BigInt null , alloc_unit_type_desc NVARCHAR(60) null , TotPartNb Int null , colname Sysname null , ReorgType as Case When (frag between 10.0 and 50.0 And pgLock = 1 and page_count > 8) Then 'Reorg' When (frag > 50.0 and page_count > 8) Or (frag > 10.0 and pgLock = 0 and page_count > 8) Then 'Rebuild' Else '' End , seq int , primary key clustered (seq) ) Set @DbName = '' While(1 = 1) -- Emulate simple loop, exit internally by a break statement on a given condition Begin -- read only one database at the time -- Top 1 clause with order is used to get the next database -- in alphebetic order and which is next to the last database name processed or "" -- makes simpler shorter and ffaster code than using cursors Select top 1 @DbName = DbName , @cmptLevel = CmptLevel From #Db Where DbName > @DbName Order By DbName -- If there is no next database to the last one read If @@rowcount = 0 Break -- exit -- If database is not updatable, GO to the next in the list If DATABASEPROPERTYEX(@DbName, 'Updateability') = N'READ_ONLY' Continue -- If database is not updatable, GO to the next in the list If DatabasepropertyEx(@DbName, 'Status') IN (N'EMERGENCY', N'OFFLINE') Continue truncate table #IndexNames set @sql = ' Use [] set nocount on select IDX.object_id, IDX.index_id, IDX.name as IndexName, IDX.allow_page_locks, IDX.type_desc into #Indexes From sys.indexes IDX join sys.objects OBJ on IDX.object_id = OBJ.object_id join sys.schemas S on S.schema_id = OBJ.schema_id Where OBJ.type_desc = "User_Table" insert into #IndexNames ( scn, tb, td, IDX, pglock, partitionnum, frag, index_type_desc , Page_count, alloc_unit_type_desc, TotPartNb, ColName , seq) select S.name --collate , OBJ.name --collate , OBJ.type_desc --collate , IDX.IndexName , IDX.allow_page_locks , PS.partition_number AS partitionnum , PS.avg_fragmentation_in_percent AS frag , IDX.type_desc , PS.Page_count , PS.alloc_unit_type_desc , Max (partition_number) OVER(PARTITION BY IDX.object_id, IDX.index_id) as TotPartNb , ( select top 1 SC.name from sys.columns SC Where SC.object_id = IDX.object_id And Columnproperty(OBJ.object_id, SC.name, "IsIndexable") = 1 -- Version 1.2 Order by SC.column_id ) as ColName , row_number() over (order by S.name, OBJ.name, IDX.IndexName, PS.partition_number) as seq From #Indexes IDX join sys.objects OBJ on IDX.object_id = OBJ.object_id join sys.schemas S on S.schema_id = OBJ.schema_id CROSS APPLY sys.dm_db_index_physical_stats (db_id(""), IDX.object_id, IDX.index_id, NULL, "LIMITED") PS Where PS.avg_fragmentation_in_percent > 5 DROP TABLE #Indexes ' -- Version 1.2 If not exists (select * from sys.databases where name = @DbName And compatibility_level >= 90) Begin Set @sql = replace (@sql, 'sys.dm_db_index_physical_stats (db_id(""), NULL, NULL, NULL, "LIMITED")', '(select 0 as partition_number, 100 as avg_fragmentation_in_percent, 1000 as Page_count, "" as alloc_unit_type_desc)' ) Set @sql = replace (@sql, 'join --cross join', 'Cross join') Set @sql = replace (@sql, 'on Idx.object_id = Ps.object_id And Idx.index_id = Ps.index_id', '') End -- Version 1.2 set @sql = replace(@sql,'',convert(nvarchar(100), Serverproperty('collation'))) set @sql = replace(@sql,'"','''') -- trick to use " instead of doubling quotes in query string set @sql = replace(@sql,'',@DbName) Exec yExecNLog.LogAndOrExec @context = 'yMaint.ReorganizeOnlyWhatNeedToBe' , @Info = 'Get index list of indexes to reorganize' , @sql = @sql , @JobNo = @JobNo , @forDiagOnly = 1 -- select 'trace', * from #IndexNames -- makes query boilerplate with replacable parameter identified by -- labels between "<" et ">" -- build only one message for tables that need not defrag of any indexes Select @info = ( Select Convert (nvarchar(max), '') + scn + '.' + tb + NCHAR(10) as [text()] from #IndexNames --Where index_type_desc <> 'HEAP' Group By scn, tb Having Min(ReorgType) = '' for XML PATH('') ) set @Info = 'Index and heap Reorg' + nchar(10) + 'Defragmentation not needed to be done in ' + @DbName+ ' for tables:' + NCHAR(10) + @info Exec yExecNLog.LogAndOrExec @context = 'yMaint.ReorganizeOnlyWhatNeedToBe' , @Info = @info , @JobNo = @JobNo , @forDiagOnly = 0 -- process defrag set @seq = 0 While (1 = 1) begin Select top 1 @scn = scn, @tb = tb, @idx = idx, @pgLock = pgLock, @partitionNum = partitionnum, @index_type_desc = index_type_desc, @alloc_unit_type_desc = alloc_unit_type_desc, @TotPartNb = TotPartNb, @Colname = Colname, @ReorgType = ReorgType, @seq = seq from #IndexNames I where seq > @seq -- And index_type_desc <> 'HEAP' order by seq if @@rowcount = 0 break If @index_type_desc <> 'HEAP' Begin Set @sql = Case When @ReorgType = 'Reorg' Then ' ALTER INDEX [] ON [].[].[] Reorganize PARTITION = With (LOB_COMPACTION = On) ' When @ReorgType = 'Rebuild' Then ' ALTER INDEX [] ON [].[].[] Rebuild; ' Else '' End End Else -- don't try to handle heap Begin -- don't try to reorganize Heap -- If @page_count > 8 And @colName is not NULL -- Version 1.2 -- Set @sql = -- ' -- Use [] -- Create clustered index [IdxDefrag] ON [].[] ([]) with (fillfactor = 95); -- Exec("Drop index [].[].[IdxDefrag]") -- ' -- Else Set @sql = '' End set @sql = replace (@sql, '', @scn collate database_default) set @sql = replace (@sql, '', @tb collate database_default) set @sql = replace (@sql, '', isnull(@idx, '') collate database_default) set @sql = replace (@sql, '', @colName collate database_default) -- if no clustered index set @sql = replace (@sql, '', @DbName collate database_default) set @sql = replace (@sql, '"', '''') If @TotPartNb > 1 Set @sql = replace(@sql, '', Convert(nvarchar(20), @partitionNum)) Else Set @sql = replace(@sql, 'PARTITION = ', '') If @sql <> '' Exec yExecNLog.LogAndOrExec @context = 'yMaint.ReorganizeOnlyWhatNeedToBe' , @Info = 'Index and heap Reorg' , @sql = @sql , @JobNo = @JobNo End -- While loop index by index End -- While loop database by database End try Begin catch Exec yExecNLog.LogAndOrExec @jobNo = @jobNo, @context = 'yMaint.ReorganizeOnlyWhatNeedToBe Error', @err='?' End Catch End -- yMaint.ReorganizeOnlyWhatNeedToBe GO -- ------------------------------------------------------------------------------ -- Function that get the installation language of the instance -- ------------------------------------------------------------------------------ If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yInstall.InstallationLanguage' GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO CREATE Procedure yInstall.InstallationLanguage @language nvarchar(512) output as Begin create table #SVer(ID int, Name sysname, Internal_Value int, Value nvarchar(512)) insert #SVer exec master.dbo.xp_msver Language Select @language = Value from #SVer where Name = N'Language' End -- yInstall.InstallationLanguage GO -- ------------------------------------------------------------------------------ -- Function that builds backup file name -- ------------------------------------------------------------------------------ If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yMaint.MakeBackupFileName' GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO CREATE function yMaint.MakeBackupFileName ( @DbName sysname , @bkpTyp Char(1) , @FullBackupPath nvarchar(512) , @Language nvarchar(512) , @Ext nvarchar(7) = NULL , @TimeStampNamingForBackups Int = 1 ) returns nvarchar(max) as Begin -- ===================================================================================== -- Find weekday name which is part of generated backup name -- ===================================================================================== -- Find weekday from date. Declare @DayOfWeek nvarchar(8) Declare @DayOfWeekNo Int Declare @DayOfWeekNoStr Char(1) Declare @filename nvarchar(512) declare @BackupTimeStamp nvarchar(60) If @DbName <> 'msdb' Begin Set @BackupTimeStamp = Convert(nvarchar(30), getdate(), 120) Set @BackupTimeStamp = STUFF (@BackupTimeStamp, 11, 1, '_') Set @BackupTimeStamp = STUFF (@BackupTimeStamp, 14, 1, 'h') Set @BackupTimeStamp = STUFF (@BackupTimeStamp, 17, 1, 'm') End Else Begin -- for MSDB we don't keep time part in the timestamp just date part because -- MSDB is taken in backup many times a day Set @BackupTimeStamp = Convert(nvarchar(10), getdate(), 121) end -- use independant Set datefirst setting using @@datefirst -- to get a predictible @dayOfWeekNo. Set datefirst value is dependent of language Set @DayOfWeekNo = ((@@datefirst + DatePart(dw, getdate())) % 7) + 1 -- @DayOfWeekNo = Sat = 0 Sun = 1 Mon = 2.... -- translate Sat = 0 by Sat = 6, Sun = 1 par Sun = 7 an so on Set @DayOfWeekNoStr = Substring('6712345', @DayOfWeekNo, 1) Set @DayOfWeek = Case When @Language like 'Français%' Then -- default french language server case @DayOfWeekNoStr when '1' then 'Lun' when '2' then 'Mar' when '3' then 'Mer' when '4' then 'Jeu' when '5' then 'Ven' when '6' then 'Sam' when '7' then 'Dim' end Else -- else default to us-english case @DayOfWeekNoStr when '1' then 'Mon' when '2' then 'Tue' when '3' then 'Wed' when '4' then 'Thu' when '5' then 'Fri' when '6' then 'Sat' when '7' then 'Sun' end End -- Make file name boiler plate with replaceable parameters identified by label between "<" et ">" Set @filename = '_[_]_.' -- replace parameters .... Set @filename = replace(@filename,'', yUtl.NormalizePath(@FullBackupPath)) If @bkpTyp = 'F' Set @filename = replace(@filename,'', 'database') Else If @bkpTyp = 'D' Set @filename = REPLACE(@filename,'', 'differential') Else Set @filename = replace(@filename,'', 'logs') -- generate logs by day by default If @TimeStampNamingForBackups IS NULL Or @TimeStampNamingForBackups = 1 Begin Set @filename = replace(@filename,'', @DayOfWeek) Set @filename = replace(@filename,'', @BackupTimeStamp) End Else Set @filename = replace(@filename,'[_]_', ''); -- set extension and db name as part of the file name Set @filename = replace(@filename,'', case when @bkpTyp = 'F' Then ISNULL(@Ext, 'Bak') else ISNULL(@Ext, 'Trn') end) Set @filename = replace(@filename,'', @DbName) -- nom de la Bd Return (@filename) End -- yMaint.MakeBackupFileName GO -- ------------------------------------------------------------------------------ -- Function that builds backup command -- ------------------------------------------------------------------------------ If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yMaint.MakeBackupCmd' GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO create function yMaint.MakeBackupCmd ( @DbName sysname , @bkpTyp Char(1) , @fileName nvarchar(512) , @overwrite Int , @name nvarchar(512) , @EncryptionAlgorithm nvarchar(10) , @EncryptionCertificate nvarchar(100) ) returns nvarchar(max) as Begin Declare @sql nvarchar(max) -- Make query boilerplate with replaçable parameters delimited by "<" and ">" -- double quotes are replaced by 2 single quotes. This trick avoid the unreadability -- of double single quotes Set @sql = ' backup [] to disk = "" with , checksum, name = "", bufferCount = 20, MAXTRANSFERSIZE = 4096000 ' set @sql = replace(@sql,'"','''') -- trick that avoid doubling single quote in the boilerplate If @bkpTyp = 'F' Or @bkpTyp = 'D' Set @sql = replace(@sql,'', 'database') Else Set @sql = replace(@sql,'', 'log') Set @sql = replace(@sql,'', @DbName) -- nom de la Bd Set @sql = replace(@sql,'', case when @overwrite = 1 Then 'Init, Format' else 'noInit' end) Set @sql = replace(@sql,'', case when @bkpTyp = 'D' Then ', DIFFERENTIAL' else '' end) Set @sql = Replace(@sql, '', @filename) If @EncryptionAlgorithm<>'' and @EncryptionCertificate<>'' BEGIN Set @sql = Replace(@sql, '',',ENCRYPTION (ALGORITHM = , SERVER CERTIFICATE = )') Set @sql = Replace(@sql, '',@EncryptionAlgorithm) Set @sql = Replace(@sql, '',@EncryptionCertificate) END ELSE Set @sql = Replace(@sql, '','') Set @name = case when @name like 'SaveDbOnNewFileSet%' Then 'SaveDbOnNewFileSet' Else 'YourSQLDba' End + ':'+replace(left(convert(varchar(8), getdate(), 108),5), ':', 'h')+': '+@filename -- backup name (not file backup name, but name parameter of backup command) -- is limited to 128, must be truncated accordingly before time stamps -- patindex below finds position just before timestamps in the name Declare @pos int Declare @fin nvarchar(100) If len(@name) > 128 Begin If @bkpTyp = 'F' Set @pos = Patindex ('%[_]_________________________[_]database.Bak', @name) Else Set @pos = Patindex ('%[_]_________________________[_]logs.trn', @name); Set @fin = Substring(@name, @pos, 255) Set @name = left(@name, 128 - len(@fin) - 3) + '...' + @fin End Set @sql = replace(@sql,'', @name) Return (@sql) End -- yMaint.MakeBackupCmd GO -- ------------------------------------------------------------------------------ -- SP that takes built backup command and run it remotely -- by the fact that the command is -- an exec through the remote server (ex: Exec [].YourSqlDba.yMirroring.DoRestore ) -- This SP is an activated stored proc linked to queue YourSQLDbaTargetQueueMirrorRestore -- ------------------------------------------------------------------------------ If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yMirroring.Broker_AutoActivated_LaunchRestoreToMirrorCmd' GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO create procedure yMirroring.Broker_AutoActivated_LaunchRestoreToMirrorCmd as begin Declare @RecvReqDlgHandle uniqueidentifier; Declare @RecvReqMsg xml Declare @RecvReqMsgName sysname; Declare @JobNo int Declare @seq int Declare @sql nvarchar(max) Declare @ReplyMsg xml; Declare @errorN Int; Declare @err nvarchar(max); WHILE (1=1) BEGIN -- The RECEIVE is not in transaction to prevent the call «Exec yExecNLog.LogAndOrExec» -- fromg freezing. Because there is no transaction only 1 procedure should be activated -- for this Queue. WAITFOR ( RECEIVE TOP(1) @RecvReqDlgHandle = conversation_handle, @RecvReqMsg = convert(xml, message_body), @RecvReqMsgName = message_type_name FROM YourSqlDbaTargetQueueMirrorRestore ), TIMEOUT 1000; IF (@@ROWCOUNT = 0) BEGIN BREAK; END IF @RecvReqMsgName = N'//YourSQLDba/MirrorRestore/End' BEGIN END CONVERSATION @RecvReqDlgHandle END IF @RecvReqMsgName = N'//YourSQLDba/MirrorRestore/Request' BEGIN Set @JobNo = @RecvReqMsg.value('JobNo[1]', 'int') Set @seq = @RecvReqMsg.value('Seq[1]', 'int') Set @sql = @RecvReqMsg.value('sql[1]', 'nvarchar(max)') Exec yExecNLog.LogAndOrExec @context = 'yMirroring.Broker_AutoActivated_LaunchRestoreToMirrorCmd' , @Info = '-- Remote restore diagnostics here ' , @sql = @sql , @JobNo = @JobNo , @errorN = @errorN output , @err = @err output SELECT @ReplyMsg = (SELECT @JobNo as JobNo , @seq as Seq , Case When @errorN > 0 Then 'Failure: ' Else 'Success: ' End+ @sql+ case when @errorN > 0 Then @err Else '' End as Info FOR XML PATH('') ); SEND ON CONVERSATION @RecvReqDlgHandle MESSAGE TYPE [//YourSQLDba/MirrorRestore/Reply] (@ReplyMsg); END --IF @RecvReqMsgName = N'//YourSQLDba/MirrorRestore/Request' IF @RecvReqMsgName not in (N'//YourSQLDba/MirrorRestore/Request', N'//YourSQLDba/MirrorRestore/End') Begin declare @Info nvarchar(max) Set @Info = 'Message name unexpected: ' + @RecvReqMsgName Exec yExecNLog.LogAndOrExec @context = 'yMirroring.Broker_AutoActivated_LaunchRestoreToMirrorCmd' , @Info = @Info , @JobNo = @JobNo End END --WHILE (1=1) End GO -- --------------------------------------------------------------------------------------------- -- SP that build backup command and queue it, so it can run in parallel -- The queue auto activate stored proc yMirroring.Broker_AutoActivated_LaunchRestoreToMirrorCmd -- which read the command and run it to the remote server (by the fact that the command is -- an exec through the remote server (ex: Exec [].YourSqlDba.yMirroring.DoRestore ) -- --------------------------------------------------------------------------------------------- If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yMirroring.QueueRestoreToMirrorCmd' GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO create procedure yMirroring.QueueRestoreToMirrorCmd @context nvarchar(4000) = '' , @JobNo Int , @DbName sysname , @bkpTyp Char(1) , @fileName nvarchar(512) , @MirrorServer sysname , @MigrationTestMode Int -- behaves differently at restore... See yMirroring.DoRestore , @ReplaceSrcBkpPathToMatchingMirrorPath nvarchar(max) = '' , @ReplacePathsInDbFilenames nvarchar(max) = '' , @BrokerDlgHandle uniqueidentifier OUT as Begin Declare @sql nvarchar(max) Declare @Info nvarchar(max) Declare @err nvarchar(max) Declare @RequestMsg xml Declare @seq int -- If the mirror server is disabled or this is a system database then return -- easier to trace in profiler if written this way If isnull(@MirrorServer, '') = '' Return(0) If @DbName in ('master', 'model', 'msdb', 'tempdb', 'YourSQLDba') Return( 0 ) -- Test that the Mirror server was defined If Not Exists (Select * From Mirroring.TargetServer Where MirrorServerName = @MirrorServer) Begin Set @err = 'Mirror server «' + @MirrorServer + '» not defined. Use stored procedure «Mirroring.AddServer»' Exec yExecNLog.LogAndOrExec @context = 'yMirroring.QueueRestoreToMirrorCmd' , @Info = 'Error at launch restore to mirror server' , @YourSqlDbaNo = '008' , @Err = @Err , @JobNo = @JobNo Return( 0 ) End -- Make query boilerplate with replaçable parameters delimited by "<" and ">" -- double quotes are replaced by 2 single quotes. This trick avoid the unreadability -- of double single quotes Set @sql = ' Exec [].YourSqlDba.yMirroring.DoRestore @BackupType="" , @Filename="" , @DbName="" , @MigrationTestMode= , @ReplaceSrcBkpPathToMatchingMirrorPath="" , @ReplacePathsInDbFilenames = "" ' Set @sql = REPLACE(@sql, '', @bkpTyp) Set @sql = REPLACE(@sql, '', @fileName) Set @sql = REPLACE(@sql, '', @DbName) Set @sql = REPLACE(@sql, '', @MirrorServer) Set @sql = REPLACE(@sql, '', convert(nvarchar,@MigrationTestMode)) Set @sql = REPLACE(@sql, '', yUtl.NormalizeLineEnds (isNull(@ReplaceSrcBkpPathToMatchingMirrorPath,''))) Set @sql = REPLACE(@sql, '', yUtl.NormalizeLineEnds (isnull(@ReplacePathsInDbFilenames,''))) Set @sql = REPLACE(@sql, '"', '''') Set @Info = 'Restore to mirror server sent to Broker (waiting for activation):' + @sql Exec yExecNLog.LogAndOrExec @yourSqlDbaNo='020' , @context='yMirroring.QueueRestoreToMirrorCmd' , @Info = @info , @jobNo = @JobNo Set @seq = scope_identity() Select @RequestMsg = ( Select @JobNo as JobNo, @seq as Seq, @sql as sql For Xml Path('') ) BEGIN TRAN begin try If @BrokerDlgHandle Is Null Begin BEGIN DIALOG @BrokerDlgHandle FROM SERVICE [//YourSQLDba/MirrorRestore/InitiatorService] TO SERVICE '//YourSQLDba/MirrorRestore/TargetService' ON CONTRACT [//YourSQLDba/MirrorRestore/Contract] WITH ENCRYPTION = OFF; End; SEND ON CONVERSATION @BrokerDlgHandle MESSAGE TYPE [//YourSQLDba/MirrorRestore/Request] (@RequestMsg); COMMIT TRAN End try Begin catch Exec yExecNLog.LogAndOrExec @yourSqlDbaNo='020' , @context='yMirroring.QueueRestoreToMirrorCmd' , @Info = 'Restore to mirror server sent to Broker (waiting for activation)' , @err = '?' , @sql = @sql , @jobNo = @JobNo End catch End -- yMirroring.QueueRestoreToMirrorCmd GO If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'Maint.DropOrphanLogins' GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO create procedure Maint.DropOrphanLogins as begin create table #logins (name sysname primary key clustered) declare @sql nvarchar(max) Select @sql = ( select convert(nvarchar(max), '') + 'select suser_sname(sid) from ['+name+'].sys.database_principals where suser_sname(sid) is not null union '+nchar(10) as [text()] From sys.databases for XML path('') )+ 'Select '''' as name' insert into #logins Exec(@sql) Select @sql = ( Select convert(nvarchar(max), '') + 'drop login ['+sp.name+']'+nchar(10) as [text()] from sys.server_principals SP left join #logins L ON SP.name = L.Name Where type_desc = 'SQL_LOGIN' and L.name is null for XML path('') ) print @sql Exec(@sql) End go -- ------------------------------------------------------------------------------ -- Procedure to delete old backup files selected by all the following conditions: -- -- 1. The files must be in the files path @path. -- (subdirectories are not selected). -- -- 2. The files name must contain the date and time of its creation. -- The format is like -- '%[_][[][0-9][0-9][0-9][0-9]-[0-9][0-9]-[0-9][0-9][_][0-9][0-9]h[0-9][0-9]m[0-9][0-9][_]___][_]%' -- Example: AdventureWorks_[2009-04-27_00h06m53_Mon]_database.Bak -- and -- The files name must end with the optional @extension. -- -- 3. ( @BkpRetDays is not NULL -- and -- The beginning of the file name is in the selected database list in the -- temporary table @tDb -- and -- AgeInMinutes > (@BkpRetDays * 1440) -- AgeInMinutes is the age of the file in minutes -- ) -- Or -- ( @BkpRetDaysForUnSelectedDb is not NULL -- and -- The file was not selected by @tDb -- and -- AgeInMinutes > (@BkpRetDaysForUnSelectedDb * 1440) -- AgeInMinutes is the age of the file in minutes -- ) -- -- In all cases, the msdb database file backup is always deleted by -- the Maint.DeleteOldBackups procedure when @extension = .bak -- ------------------------------------------------------------------------------ If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'Maint.DeleteOldBackups' GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO CREATE Procedure Maint.DeleteOldBackups @oper nvarchar(200) = 'YourSQLDba_Operator' , @command nvarchar(200) = 'DeleteOldBackups' -- main command , @MaintJobName nvarchar(200) = 'YourSqlDba_DeleteOldBackups' , @path nVARCHAR(max) -- Path to the files , @BkpRetDays Int = NULL -- Number of days to keep the backup files -- selected by there database name. -- by default no cleanup. , @BkpRetDaysForUnSelectedDb int = NULL -- Optional number of days to keep the backup -- files not selected by there database name. -- by default no cleanup. , @RefDate Datetime = NULL -- Optional reference date and time for the clean up -- Format: '20090925 18:00' -- yyyymmdd hh:mm , @extension sysname = '' -- Optional file extention -- any file extension of any length is accepted -- Examples: .bak for full backups -- or .trn for log backups -- or '' for all files in the @path , @IncDb nVARCHAR(max) = '' , @ExcDb nVARCHAR(max) = '' , @JobNo Int = NULL -- job number of the maintenance task , @SendOnErrorOnly int = 1 -- 1 = send an email only when there is an error , @DeleteOnlyLogDiffBackups int = 0 -- 1 = delete only logBackups and differential backups as Begin Set NoCount On Declare @Info nvarchar(max) Declare @FullFilePath nvarchar(max) declare @err nvarchar(max) If @RefDate is NULL Set @RefDate = convert(datetime, getdate(), 120) If Right(@path, 1) <> '\' Set @path = @path + '\' Declare @StartOfCleanup datetime set @StartOfCleanup = getdate() If @JobNo is NULL -- Maint.DeleteOldBackups was called from a query window, so we create a global context for it Begin -- Create a new job entry in the job history table -- the query below is a first step in re-engeneering some parts of YourSqlDba -- it allows to globalize in the current connection context the parameters -- and makes easy to obtain them throught Select * from dbo.MainContextInfo () in a tabular form Declare @Sql Nvarchar(max) Select @sql=S.Sql From (Select oper = @oper , command = @command , W.SqlAgentJobName , MaintJobName = @MaintJobName , FullBackupPath = @Path , LogBackupPath = @Path , FullBkpExt = @Extension , LogBkpExt = @Extension , FullBkpRetDays = @BkpRetDays , LogBkpRetDays = @BkpRetDays , ConsecutiveDaysOfFailedBackupsToPutDbOffline = 9999 , IncDb = @IncDb , ExcDb = @ExcDb , W.Host , W.Prog , W.Who , W.MainCall , W.jobId , W.StepId From dbo.WhoCalledWhat as W ) as Prm Cross Apply ( Select JsonPrm= ( Select oper, command, SqlAgentJobName, MaintJobName='DeleteOldBackups' , FullBackupPath , FullBkpRetDays , LogBkpRetDays , FullBkpExt , LogBkpExt , IncDb, ExcDb , Host, Prog, Who, MainCall , JobId , StepId For JSON PATH, WITHOUT_ARRAY_WRAPPER ) ) as JsonPrm CROSS APPLY dbo.ScriptMakeProcessMaintenancePrmGlobal (JsonPrm) as S Exec (@Sql) -- Execute SQL generated by previous query exec yExecNLog.AddJobEntry @jobName = 'DeleteOldBackups' , @JobNo = @JobNo output -- if null in output a new is made, otherwise append job specified End Exec yExecNLog.LogAndOrExec @context = 'Maint.DeleteOldBackups' , @Info = 'Start of backup cleanup' , @JobNo = @JobNo -- Create a table of the databases selected declare @tDb table ( DbName sysname collate database_default primary key clustered , DbOwner sysname NULL -- because actual owner may be invalid after a restore , FullrecoveryMode int -- If = 1 log backup allowed , cmptLevel tinyInt ) insert into @tDb SELECT * FROM YourSQLDba.yUtl.YourSQLDba_ApplyFilterDb (@IncDb, @ExcDb) Where DatabasepropertyEx(DbName, 'Status') = 'Online' -- Avoid db that can't be processed --select * from @tDb -- remove snapshot database from the list Delete Db From @tDb Db Where Exists ( Select * From sys.databases d Where d.name COLLATE Database_default = db.DbName and source_database_Id is not null ) --select * from @tDb -- create table of directory info lines declare @FilesFromFolder table ( line nvarchar(1000) collate database_default) If LEFT(@extension,1)<> '.' Set @extension = '.'+@extension Insert into @FilesFromFolder Select * from yUtl.Clr_GetFolderList (@path, '*'+@extension) If Exists(Select * from @FilesFromFolder Where line = '') Begin Set @err = ( Select CONVERT(nvarchar(max),'')+Line+NCHAR(10) as [text()] From @FilesFromFolder Where line <> '' for XML PATH('') ) Exec yExecNLog.LogAndOrExec @context = 'Maint.DeleteOldBackups' , @err = @err , @JobNo = @JobNo Return End --SELECT * --From @FilesFromFolder declare @dbFiles table ( Seq int primary key clustered , DbName sysname null , FileName nvarchar(max) null , Creation_Date nvarchar(23) null , RefDate nvarchar(23) null , AgeInMinutes Int null ) ;With FilesReturnedBy_Clr_GetFolderList as ( SELECT ROW_NUMBER() OVER (ORDER BY d.line) As Seq , ltrim(rtrim(d.line)) as FileName , patindex ('%[_][[][0-9][0-9][0-9][0-9]-[0-9][0-9]-[0-9][0-9][_][0-9][0-9]h[0-9][0-9]m[0-9][0-9][_]___][_]%' , d.line) as posPatternDate , patindex ('MSDB_[[]%', d.line) as PosMsdb FROM @FilesFromFolder as d ) , T1 as ( select seq , FileName , Case When PosMsDb > 0 Then Substring(FileName, posMsdb+6, 10) + ' 00:00' Else Substring(FileName, posPatternDate+2, 16) End as DateCreate From FilesReturnedBy_Clr_GetFolderList Where PosMsDb > 0 Or PosPatternDate > 0 ) , T2 as (select seq, FileName, replace(DateCreate, 'h', ':') as DateCreate From T1) , T3 as (select seq, FileName, replace(DateCreate, '_', ' ') as DateCreate From T2) , T4 as ( select Distinct -- distinct helped to circumvent a funny run-time error seq , FileName , convert(datetime, DateCreate, 121) as Creation_Date , @RefDate As RefDate -- There is 1440 minutes per day , datediff(mi, convert(datetime, DateCreate, 121), @RefDate) As AgeInMinutes From T3 ) Insert into @dbFiles Select F.Seq, db.DbName, F.FileName, F.Creation_Date, F.RefDate, F.AgeInMinutes From T4 as f Left Join @tDb as db On (db.DbName + '_[') = (Substring(f.FileName, 1, len(db.DbName) + 2 )) Where ( (@BkpRetDays is not NULL) and (f.AgeInMinutes > (@BkpRetDays * 1440)) and (db.DbName Is Not Null) -- The file was selected by @tDb and ((@DeleteOnlyLogDiffBackups = 1 and F.FileName like '%_logs%') or (@DeleteOnlyLogDiffBackups = 1 and F.FileName like '%_differential%') or @DeleteOnlyLogDiffBackups = 0) ) Or (Substring(f.FileName, 1, 6) = 'MSDB_[') -- Always delete old backups from MSDB Or ( (@BkpRetDaysForUnSelectedDb is not NULL) -- Delete files not seleted by @tDb and (db.DbName Is Null) -- The file was not selected by @tDb and (f.AgeInMinutes > (@BkpRetDaysForUnSelectedDb * 1440) )) --SELECT * --, (@BkpRetDays * 1440) as 'BkpRetDays in minutes' --, (@BkpRetDaysForUnSelectedDb * 1440) as 'BkpRetDaysForUnSelectedDb in minutes' --From @DbFiles --Order by FileName Declare @Cmd nvarchar(1000) declare @filename nvarchar(max) declare @dbName sysname declare @SeqFile int declare @context nvarchar(max) Set @SeqFile = 0 Set @filename = '' While (1=1) Begin Select top 1 @filename = FileName, @SeqFile = seq, @dbName = dbName From @DbFiles Where Seq > @SeqFile Order by seq If @@rowcount = 0 Break Set @FullFilePath = @path+@Filename Exec yUtl.Clr_DeleteFile @FullFilePath, @Err output If @err <> '' -- If file is not found no error is generated Begin Exec yExecNLog.LogAndOrExec @context = 'Maint.DeleteOldBackups' , @err = @err , @JobNo = @JobNo end Else Begin Set @FullFilePath = @FullFilePath + ' deleted' Exec yExecNLog.LogAndOrExec @context = 'Maint.DeleteOldBackups' , @info = @FullFilePath , @JobNo = @JobNo End End -- While -- From here, send execution report and any error message if found -- If the operator is missing, emit an error message -- and exit now to put error status in the SQL Agent job. Declare @email_Address sysname -- to read email address of the operator select @email_Address = email_Address from Msdb..sysoperators where name = @oper and enabled = 1 If @@rowcount = 0 -- here the error is loggued into job Exec yExecNLog.LogAndOrExec @context = 'Maint.DeleteOldBackups' , @YourSqlDbaNo = '009' , @Info = 'Maint.DeleteOldBackups' , @JobNo = @JobNo , @err = ' The operator name supplied to the procedure Maint.DeleteOldBackups, must exist and be enabled in msdb..sysoperators ' Exec yExecNLog.LogAndOrExec @context = 'Maint.DeleteOldBackups' , @Info = 'End of backup cleanup' , @JobNo = @JobNo If @email_Address is NOT NULL -- Do not perform message report if caller is Maint.YourSqlDba_DoMaint because the caller will do And Not Exists (Select * From Dbo.MainContextInfo(@JobNo) as Ctx Where Ctx.MainCall Not Like '%Exec %Maint.YourSqlDba_DoMaint$') Exec yMaint.SendExecReports @email_Address = @email_Address , @command = @command , @MaintJobName = @MaintJobName , @StartOfMaint = @StartOfCleanup , @JobNo = @JobNo , @SendOnErrorOnly = @SendOnErrorOnly -- 1 = Send email only when there is a error End -- Maint.DeleteOldBackups GO If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yMirroring.MirrorLoginSync' GO Create Procedure yMirroring.MirrorLoginSync @servername sysname , @loginname sysname , @type char(1) , @password_hash varbinary(256) , @sid varbinary(85) , @policy_checked nvarchar(3) , @expiration_checked nvarchar(3) , @deflanguage sysname , @sysadmin int , @securityadmin int , @serveradmin int , @setupadmin int , @processadmin int , @diskadmin int , @dbcreator int , @bulkadmin int , @jobNo int = NULL , @is_disabled int = 0 As Begin declare @sql nvarchar(max) declare @loginExists int declare @password_hash_local varbinary(256) declare @sid_local varbinary(85) declare @is_disabled_local int Set @loginExists = 0 -- Update local domain on new server if needed before trying a select/drop/alter login If @type IN ('G', 'U') and left(@loginname, len(@servername+'\')) = @servername+'\' Set @loginname = Replace(@loginname, @servername+'\', convert(sysname, serverproperty('machinename'))+'\') Select @loginExists = 1 , @password_hash_local = sl.password_hash , @sid_local = sp.sid , @is_disabled_local = sp.is_disabled From sys.server_principals sp Left join sys.sql_logins sl on sp.name = sl.name Where sp.name = @loginname -- If Login is the same with same SID, same password and same disabled values, we can skip this one If @loginExists = 1 AND @sid = @sid_local AND IsNull(@password_hash, 0x) = IsNull(@password_hash_local, 0x) AND @is_disabled_local = @is_disabled Return(0) Begin Try Set @sql = '' -- If login already exists and needs a sid or password update, we drop it so we can recreate it with good password and good sid If @loginExists = 1 AND ( @sid <> @sid_local Or IsNull(@password_hash, 0x) <> IsNull(@password_hash_local, 0x)) Begin Set @sql = @sql + 'DROP LOGIN [];' Set @loginExists = 0 End -- If login needs to be created If @loginExists = 0 Begin If @type IN ('G', 'U') Set @sql = @sql + 'CREATE LOGIN [] FROM WINDOWS WITH DEFAULT_LANGUAGE=;' Else Set @sql = @sql + ' CREATE LOGIN [] WITH PASSWORD= HASHED , SID= , CHECK_POLICY= , CHECK_EXPIRATION=, DEFAULT_LANGUAGE=; ' End -- If login has been disabled, disable it If @is_disabled_local = 0 AND @is_disabled = 1 Set @sql = @sql +'ALTER Login [] DISABLE;' -- If login has been enabled, enable it If @is_disabled_local = 1 AND @is_disabled = 0 Set @sql = @sql +'ALTER Login [] ENABLE;' If @sysadmin = 1 Set @sql = @sql + 'EXEC sp_addsrvrolemember "", "sysadmin";' If @securityadmin = 1 Set @sql = @sql + 'EXEC sp_addsrvrolemember "", "securityadmin";' If @serveradmin = 1 Set @sql = @sql + 'EXEC sp_addsrvrolemember "", "serveradmin";' If @setupadmin = 1 Set @sql = @sql + 'EXEC sp_addsrvrolemember "", "setupadmin";' If @processadmin = 1 Set @sql = @sql + 'EXEC sp_addsrvrolemember "", "processadmin";' If @diskadmin = 1 Set @sql = @sql + 'EXEC sp_addsrvrolemember "", "diskadmin";' If @dbcreator = 1 Set @sql = @sql + 'EXEC sp_addsrvrolemember "", "dbcreator";' If @bulkadmin = 1 Set @sql = @sql + 'EXEC sp_addsrvrolemember "", "bulkadmin";' Set @sql = REPLACE(@sql, '', @loginname) Set @sql = REPLACE(@sql, '', yUtl.ConvertToHexString(@password_hash)) Set @sql = REPLACE(@sql, '', yUtl.ConvertToHexString(@sid)) Set @sql = REPLACE(@sql, '', @policy_checked) Set @sql = REPLACE(@sql, '', @expiration_checked) If @defLanguage is Not NULL Set @sql = REPLACE(@sql, '', @deflanguage) Else Begin Set @sql = REPLACE(@sql, ' WITH DEFAULT_LANGUAGE=', '') Set @sql = REPLACE(@sql, ', DEFAULT_LANGUAGE=', '') End Set @sql = REPLACE(@sql, '"', '''') Exec yExecNLog.LogAndOrExec @context = 'yMirroring.MirrorLoginSync' , @sql = @sql , @Info = 'Synchronizing accounts to mirror Server ' , @JobNo = @JobNo End Try Begin Catch End Catch End --yMirroring.MirrorLoginSync GO If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yMirroring.LaunchLoginSync' GO Create Procedure yMirroring.LaunchLoginSync @MirrorServer sysname , @JobNo int = null As Begin declare @MirrorServerName sysname declare @sql nvarchar(max) declare @servername sysname declare @loginname sysname declare @type char(1) declare @password_hash varbinary(256) declare @sid varbinary(85) declare @policy_checked nvarchar(3) declare @expiration_checked nvarchar(3) declare @deflanguage sysname declare @sysadmin int declare @securityadmin int declare @serveradmin int declare @setupadmin int declare @processadmin int declare @diskadmin int declare @dbcreator int declare @bulkadmin int declare @is_disabled int Set NoCount On SELECT p.name , Convert(sysname, serverproperty('machinename')) as servername , p.type , IsNull(sl.password_hash, 0x) As password_hash , p.sid , Case When sl.is_policy_checked = 1 Then 'ON' Else 'OFF' End As is_policy_checked , Case When sl.is_expiration_checked = 1 Then 'ON' Else 'OFF' End As is_expiration_checked , p.default_language_name , l.sysadmin , l.securityadmin , l.serveradmin , l.setupadmin , l.processadmin , l.diskadmin , l.dbcreator , l.bulkadmin , p.is_disabled INTO #Logins FROM sys.server_principals p LEFT JOIN sys.sql_logins sl ON sl.name = p.name Left Join sys.syslogins l on l.sid = p.sid WHERE p.type IN ( 'S', 'G', 'U' ) AND p.name <> 'YourSQLDba' AND p.name <> 'SA' AND p.name Not Like 'AUTORITE NT\%' AND p.name Not Like 'NT AUTHORITY\%' AND p.name Not Like 'NT SERVICE\%' AND p.name Not Like 'BUILTIN\Administra%' AND p.name Not Like '##Ms[_]Policy%##' CREATE UNIQUE CLUSTERED INDEX Logins_P ON #Logins (name) Set @MirrorServerName = '' While 1= 1 Begin Select Top 1 @MirrorServerName=MirrorServerName From Mirroring.TargetServer Where MirrorServerName > @MirrorServerName AND MirrorServerName = @MirrorServer If @@rowcount = 0 break Set @loginname = '' While 1=1 Begin Select Top 1 @loginname = name , @servername = servername , @type = type , @password_hash = password_hash , @sid = sid , @policy_checked = is_policy_checked , @expiration_checked = is_expiration_checked , @deflanguage = default_language_name , @sysadmin = sysadmin , @securityadmin = securityadmin , @serveradmin = serveradmin , @setupadmin = setupadmin , @processadmin = processadmin , @diskadmin = diskadmin , @dbcreator = dbcreator , @bulkadmin = bulkadmin , @is_disabled = is_disabled From #Logins Where name > @loginname Order by name If @@rowcount = 0 break Set @sql = 'Exec [].YourSqlDba.yMirroring.MirrorLoginSync @servername = "", @loginname = "", @type = "", @password_hash = , @sid = , @policy_checked = "", @expiration_checked = "", @deflanguage = "", @sysadmin = , @securityadmin = , @serveradmin = , @setupadmin = , @processadmin = , @diskadmin = , @dbcreator = , @bulkadmin = , @jobNo = NULL, @is_disabled=' Set @sql = yExecNLog.Unindent_TSQL(@sql) Set @sql = REPLACE(@sql, '', @MirrorServerName) Set @sql = REPLACE(@sql, '', @servername) Set @sql = REPLACE(@sql, '', @loginname) Set @sql = REPLACE(@sql, '', @type) Set @sql = REPLACE(@sql, '', yUtl.ConvertToHexString(@password_hash)) Set @sql = REPLACE(@sql, '', yUtl.ConvertToHexString(@sid)) Set @sql = REPLACE(@sql, '', @policy_checked) Set @sql = REPLACE(@sql, '', @expiration_checked) Set @sql = REPLACE(@sql, '', @deflanguage) Set @sql = REPLACE(@sql, '', @sysadmin) Set @sql = REPLACE(@sql, '', @securityadmin) Set @sql = REPLACE(@sql, '', @serveradmin) Set @sql = REPLACE(@sql, '', @setupadmin) Set @sql = REPLACE(@sql, '', @processadmin) Set @sql = REPLACE(@sql, '', @diskadmin) Set @sql = REPLACE(@sql, '', @dbcreator) Set @sql = REPLACE(@sql, '', @bulkadmin) Set @sql = REPLACE(@sql, '',@is_disabled) Set @sql = REPLACE(@sql, '"', '''') Declare @Info nvarchar(max) Set @Info = 'Synchronizing account: "' + @loginname+'"' Exec yExecNLog.LogAndOrExec @context = 'yMirroring.LaunchLoginSync' , @Info = @Info , @sql = @sql , @jobNo = @jobno End -- for each login End -- for each server End -- yMirroring.LaunchLoginSync GO If Db_name() <> 'YourSqlDba' Use YourSqlDba go Exec yUtl.DropObj 'yMirroring.ReportYourSqlDbaVersionOnTargetServers' GO Create Procedure yMirroring.ReportYourSqlDbaVersionOnTargetServers @MirrorServer sysname , @LogToHistory int = 1 , @silent int = 0 , @remoteVersion nvarchar(100) = NULL OUTPUT , @jobNo int = null As Begin set nocount on Declare @sql nvarchar(max) Declare @err nvarchar(max) Declare @Info nvarchar(max) -- Ensure that target servers are still in sys.servers, otherwise remove them If not exists ( select * from sys.servers S Where S.name = @MirrorServer collate database_default And S.is_linked = 1 ) Begin Set @remoteVersion = 'Server undefined' Set @Err = 'No linked server is defined under the name: ['+@MirrorServer+']' If @silent = 0 Print @Info If @LogToHistory = 1 And @silent = 0 Begin Exec yExecNLog.LogAndOrExec @jobNo = @jobNo , @context = 'yMirroring.ReportYourSqlDbaVersionOnTargetServers' , @YourSqlDbaNo = '021' , @Err = @err , @raiseError = 0 End Return -- don't go further End -- Check if YourSQLDba is installed at remote Begin try Set @sql = ' Declare @Exists Int Set @RemoteVersionInfo="" Select @exists = Dbid from Openquery ([], "select Db_Id(""YourSQLDba"") as DbId") as x If @Exists Is NULL Set @RemoteVersionInfo = "Remote YourSqlDba is missing" ' Set @sql = REPLACE( @sql, '', @MirrorServer) Set @sql = REPLACE( @sql, '"', '''') --Print @sql Exec sp_executeSql @sql, N'@LogToHistory int = 1, @remoteVersionInfo nvarchar(100) Output', @LogToHistory = @LogToHistory, @remoteVersionInfo = @remoteVersion Output If @RemoteVersion = 'Remote YourSqlDba is missing' Begin Set @err = 'YourSQLDba must be installed on ['+@MirrorServer+'] for mirroring purpose. Run YourSQLDba_InstallOrUpdateScript.sql on this server.' If @silent = 0 Print @Info If @LogToHistory = 1 And @silent = 0 Begin Exec yExecNLog.LogAndOrExec @jobNo = @jobNo , @context = 'yMirroring.ReportYourSqlDbaVersionOnTargetServers' , @YourSqlDbaNo = '021' , @Err = @Err , @raiseError = 0 End Return -- don't go further End End try Begin catch If ERROR_NUMBER () = 7416 Print 'Access to the remote server is denied because no login-mapping exists.' set @remoteVersion = 'no remote mapping exists' return End catch Set @sql = ' Declare @Exists Int Set @RemoteVersionInfo="" Select @exists = Objectid from Openquery ([], "select OBJECT_ID(""YourSQLDba.Install.versioninfo"") as ObjectId") as x If @exists IS NULL Set @RemoteVersionInfo = "Version before Install.VersionInfo" ' Set @sql = REPLACE( @sql, '', @MirrorServer) Set @sql = REPLACE( @sql, '"', '''') --Print @sql Exec sp_executeSql @sql, N'@LogToHistory int = 1, @remoteVersionInfo nvarchar(100) Output', @LogToHistory = @LogToHistory, @remoteVersionInfo = @remoteVersion Output If @RemoteVersion = 'Version before Install.VersionInfo' Begin Set @err = 'Versions of YourSQLDba on [' + @@servername + '] And ['+@MirrorServer+'] need to be the same for mirroring purpose. Re-run YourSQLDba_InstallOrUpdateScript.sql on both servers.' If @silent = 0 Print @Info If @LogToHistory = 1 And @silent = 0 Begin Exec yExecNLog.LogAndOrExec @jobNo = @jobNo , @context = 'yMirroring.ReportYourSqlDbaVersionOnTargetServers' , @YourSqlDbaNo = '021' , @err = @err , @raiseError = 0 End Return -- don't go further End Set @sql = ' Declare @Exists Int Set @RemoteVersionInfo="" Select @RemoteVersionInfo = versionNumber from Openquery ([], "select versionNumber From YourSQLDba.Install.VersionInfo() F") as x ' Set @sql = REPLACE( @sql, '', @MirrorServer) Set @sql = REPLACE( @sql, '"', '''') --Print @sql Exec sp_executeSql @sql, N'@LogToHistory int = 1, @remoteVersionInfo nvarchar(100) Output', @LogToHistory = @LogToHistory, @remoteVersionInfo = @remoteVersion Output If (Select versionNumber From YourSQLDba.Install.VersionInfo()) <> @RemoteVersion Begin Set @err = 'Versions of YourSQLDba on [' + @@servername + '] And ['+@MirrorServer+'] need to be the same for mirroring purpose. Re-run YourSQLDba_InstallOrUpdateScript.sql on both servers.' If @silent = 0 Print @Info If @LogToHistory = 1 And @silent = 0 Begin Exec yExecNLog.LogAndOrExec @jobNo = @jobNo , @context = 'yMirroring.ReportYourSqlDbaVersionOnTargetServers' , @YourSqlDbaNo = '021' , @err = @err , @raiseError = 0 End End End go --declare @DbName sysname, @DoBackup char(1), @FullBackupPath nvarchar(512), @overwrite int --Select @DbName = 'LeDbName', @DoBackup = 'L', @FullBackupPath = 'c:\unedestin\', @overwrite = 1 --Select yMaint.MakeBackupCmd (@DbName, @DoBackup, @FullBackupPath, @overwrite) --GO -- ------------------------------------------------------------------------------ -- Proc for doing backup. MUST BE CALLED from YourSqlDba_DoMaint because -- many parameters are passed through jobMaintHistory record that match JobNo -- ------------------------------------------------------------------------------ If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yMaint.Backups' GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO CREATE proc yMaint.Backups @jobNo Int as Begin Set nocount On declare @Info nvarchar(max) declare @DbName sysname Declare @filename nvarchar(512) declare @sql nvarchar(max) -- Sql Command Declare @sql2 nvarchar(max) Declare @FullRecoveryMode Int -- recovery mode of the database Declare @seq Int -- row seq. in work tables Declare @ctx sysname -- context id Declare @email_Address sysname declare @d datetime -- start hour --declare @StartOfDay Datetime declare @lockResult Int declare @errorN Int -- return code for full backups declare @errorN_BkpPartielInit Int -- return code for log backups declare @FailedBkpCnt Int -- failed backups count on a given database Declare @MustLogBackupToShrink int Declare @MaintJobName nVarchar(200) Declare @DoBackup nvarchar(5) Declare @DoFullBkp nvarchar(5) Declare @DoDiffBkp nvarchar(5) Declare @DoLogBkp nvarchar(5) Declare @TimeStampNamingForBackups Int Declare @FullBkpRetDays Int Declare @LogBkpRetDays Int Declare @NotifyMandatoryFullDbBkpBeforeLogBkp int Declare @BkpLogsOnSameFile int Declare @SpreadUpdStatRun int Declare @SpreadCheckDb int Declare @FullBackupPath nvarchar(512) Declare @LogBackupPath nvarchar(512) Declare @ConsecutiveDaysOfFailedBackupsToPutDbOffline Int Declare @IncDb nVARCHAR(max) Declare @ExcDb nVARCHAR(max) Declare @JobId uniqueidentifier Declare @StepId Int Declare @Language nvarchar(512) Declare @jobStart Datetime Declare @MirrorServer sysname Declare @MigrationTestMode Int Declare @BrokerDlgHandle uniqueidentifier Declare @FullBkExt nvarchar(7) Declare @LogBkExt nvarchar(7) Declare @err nvarchar(max) Declare @msg nvarchar(max) Declare @ReplaceSrcBkpPathToMatchingMirrorPath nvarchar(max) Declare @ReplacePathsInDbFilenames nvarchar(max) Declare @EncryptionAlgorithm nvarchar(10) = '' Declare @EncryptionCertificate nvarchar(100) = '' -- replace null by empty string Set @ReplaceSrcBkpPathToMatchingMirrorPath = ISNULL(@ReplaceSrcBkpPathToMatchingMirrorPath, '') Set @ReplacePathsInDbFilenames = ISNULL(@ReplacePathsInDbFilenames , '') create table #MustLogBackupToShrink (i int) Declare @DbTable table (dbname sysname, FullRecoveryMode int) Insert into @Dbtable select dbname, FullRecoveryMode from #Db Select @MaintJobName = MaintJobName , @DoFullBkp = DoFullBkp , @DoLogBkp = DoLogBkp , @FullBkpRetDays = FullBkpRetDays , @TimeStampNamingForBackups = TimeStampNamingForBackups , @LogBkpRetDays = LogBkpRetDays , @NotifyMandatoryFullDbBkpBeforeLogBkp = NotifyMandatoryFullDbBkpBeforeLogBkp , @BkpLogsOnSameFile = BkpLogsOnSameFile , @FullBackupPath = yUtl.NormalizePath(FullBackupPath ) , @LogBackupPath = yUtl.NormalizePath(LogBackupPath ) , @FullBkExt = FullBkExt , @LogBkExt = LogBkExt , @ConsecutiveDaysOfFailedBackupsToPutDbOffline = ConsecutiveDaysOfFailedBackupsToPutDbOffline , @IncDb = IncDb , @ExcDb = ExcDb , @jobStart = JobStart , @MirrorServer = MirrorServer , @MigrationTestMode = MigrationTestMode , @JobId = JobId , @StepId = StepId , @MirrorServer = MirrorServer , @ReplaceSrcBkpPathToMatchingMirrorPath = ReplaceSrcBkpPathToMatchingMirrorPath , @ReplacePathsInDbFilenames= ReplacePathsInDbFilenames , @DoDiffBkp = DoDiffBkp , @EncryptionAlgorithm = EncryptionAlgorithm , @EncryptionCertificate = EncryptionCertificate From dbo.MainContextInfo (@JobNo) -- for now eventually we are going to use the function instead of working with vars... If ISNULL(@EncryptionAlgorithm, '') <> '' AND ISNULL(@EncryptionCertificate, '') <> '' Begin -- backups on the same file are not supported for encrypted backups Set @BkpLogsOnSameFile=0 End -- check if MirrorServer is still valid If ISNULL(@MirrorServer, '') <> '' Begin Declare @remoteVersion nvarchar(100) Exec yMirroring.ReportYourSqlDbaVersionOnTargetServers @jobNo = @jobNo, @MirrorServer = @MirrorServer, @LogToHistory = 1, @remoteVersion = @remoteVersion OUTPUT If (select VersionNumber from Install.VersionInfo()) <> @remoteVersion Begin Set @MirrorServer = '' -- this disable restore to remote server end End -- clean-up entries for now inexistent (removed databases) Delete LB From Maint.JobLastBkpLocations LB LEFT JOIN master.sys.databases D ON LB.dbName = D.name COLLATE Database_default Where D.Name is NULL And LB.keepTrace = 0 If @DoFullBkp = 1 Set @DoBackup = 'F' If @DoDiffBkp = 1 Set @DoBackup = 'D' If @DoLogBkp = 1 Set @DoBackup = 'L' -- ============================================================================== -- Start of backup processing -- ============================================================================== -- Delete old full backups, only when full backup must be done -- FulBkpRet is the amount of day 0=today, none is done, 1=yesterday If @DoFullBkp = 1 And @FullBkpRetDays >= 0 -- no cleanup if < 0 or null Begin Exec Maint.DeleteOldBackups @Path = @FullBackupPath , @IncDb = @IncDb , @ExcDb = @ExcDb , @BkpRetDays = @FullBkpRetDays , @RefDate = @jobStart , @extension = @FullBkExt , @BkpRetDaysForUnSelectedDb = NULL -- Dont cleanup other backup files , @JobNo = @JobNo End -- If If @DoDiffBkp = 1 And @FullBkpRetDays >= 0 -- no cleanup if < 0 or null Begin Exec Maint.DeleteOldBackups @Path = @FullBackupPath , @IncDb = @IncDb , @ExcDb = @ExcDb , @BkpRetDays = @FullBkpRetDays , @RefDate = @jobStart , @extension = @FullBkExt , @BkpRetDaysForUnSelectedDb = NULL -- Dont cleanup other backup files , @JobNo = @JobNo , @DeleteOnlyLogDiffBackups = 1 -- Cleanup only log and differential files if we're doing a differential backup, keep other full backups End -- If -- Delete Log backups older than n days If (@DoLogBkp = 1 Or @DoFullBkp = 1 Or @DoDiffBkp = 1) And @LogBkpRetDays >= 0 -- no cleanup if < 0 or null Begin Exec YourSQLDba.Maint.DeleteOldBackups @Path = @LogBackupPath , @IncDb = @IncDb , @ExcDb = @ExcDb , @BkpRetDays = @LogBkpRetDays , @RefDate = @jobStart , @extension = @LogBkExt , @BkpRetDaysForUnSelectedDb = NULL -- Dont cleanup other backup files , @JobNo = @JobNo End Begin Try -- Get the installation language of the SQL Server instance Exec yInstall.InstallationLanguage @Language output -- ===================================================================================== -- main database backup loop by database -- ===================================================================================== set @info = ( Select CONVERT(nvarchar(max), '|') + case when d.FullRecoveryMode = 1 Then '(Full recovery) ' Else '(Simple Recovery)' End + d.dbName + '|' from @DbTable D Order by d.dbname for XML PATH('') ) Set @info = 'Database list obtained by @incBd and @ExecDb' + nchar(10) + REPLACE(@info, '|', nchar(10)) If ISNULL(ltrim(@Info),'') = '' Set @info = 'No databases either qualify by name or are available' Exec yExecNLog.LogAndOrExec @context = 'yMaint.Backups' , @Info = @info , @JobNo = @JobNo Set @DbName = '' While(1 = 1) -- T-SQL lacks simple Do Loop, work around... Begin -- this query get the next database (get the first when @dbname='') Select top 1 -- the first one next in alpha order (because top 1 + Where + Order by) @DbName = DbName From @DbTable Where DbName > @DbName -- next db in alpha order Order By DbName -- ... database name alpha order -- Loop exit if last database processed (in alphabetic order) If @@rowcount = 0 Begin set @msg = @dbName + ' is the last database processed in the backups ' Exec yExecNLog.LogAndOrExec @context = 'yMaint.Backups' , @Info = @msg , @JobNo = @JobNo Break -- exit, no more db to process End If @DbName = 'MSDB' -- Skip over, because it is always backuped up at the end Continue Set @msg = 'Checking if '+@dbname + ' must be processed...' Exec yExecNLog.LogAndOrExec @context = 'yMaint.Backups' , @info = @msg , @JobNo = @JobNo If DatabasepropertyEx(@DbName, 'Status') <> 'ONLINE' -- if not online don't try to maintain Continue -- Validation block only, is log backup can be done? If @DoLogBkp = 1 -- log backups ? Begin -- If the database is read_only it is impossible to take log backup because -- first full backup is not recorded to the database, which void log backup -- And if the database is read-only what is the point to backup its log -- it is not supposed to grow If DATABASEPROPERTYEX(@DbName, 'Updateability') = 'READ_ONLY' Continue -- this Database don't move so no need to backup the log -- If the database is in simple recovery, it is impossible to do a save -- This situation is signaled if the user asked explicitely for it -- using @incDb. This is for production database forgotten in simple recovery mode If DATABASEPROPERTYEX(@DbName, 'Recovery') NOT IN ('Full', 'BULK_LOGGED') Begin -- User explicity asked for this database, and it is in simple recovery mode -- It must be told to him that log backups can be fulfilled If replace(replace(replace(@IncDb, ' ', ''), char(10), ''), char(13), '') <> '' Begin -- User explicity stated by @incDb that he wants a log backup but that it can't done -- so signal it as an error. Set @msg = 'Forbidden log backup of ['+@DbName+'] because it is in simple recovery mode ' Exec yExecNLog.LogAndOrExec @context = 'yMaint.Backups' , @YourSqlDbaNo = '012' , @Info = @Msg , @JobNo = @JobNo End -- if user asked for this database Continue -- Jump to the next database End -- if simple recovery mode Else Begin -- full recovery mode -- if log backup can't be performed because no full backup is done -- let it know to the user, if the option is not turned off by the user If Not Exists ( select * from sys.database_recovery_status where database_id = db_id(@DbName) and last_log_backup_lsn is not null -- backup can't be done ) Begin If @NotifyMandatoryFullDbBkpBeforeLogBkp = 1 Begin Set @err = 'Log backup forbidden before doing a first full backup of ' + '['+@DbName+'] status is ' + CONVERT(nvarchar(100), DATABASEPROPERTYEX(@DbName, 'status') ) Exec yExecNLog.LogAndOrExec @context = 'yMaint.Backups' , @YourSqlDbaNo = '013' , @Info = 'Log backups' , @err = @err , @JobNo = @JobNo End Else Begin Set @err = 'Log backup forbidden before doing a first full backup of ' + '['+@DbName+']' Exec yExecNLog.LogAndOrExec @context = 'yMaint.Backups' , @YourSqlDbaNo = '013' , @Info = 'Log backups' , @err = @err , @JobNo = @JobNo End Continue -- jump to next one End -- if log backup can't be performed End End -- if log backups -- Get backup commande for full backup or log backup If @DoFullBkp = 1 Begin Set @fileName = yMaint.MakeBackupFileName (@DbName, 'F', @FullBackupPath, @Language, @FullBkExt, @TimeStampNamingForBackups) Set @ctx = 'Full backups' End Else If @DoDiffBkp = 1 Begin Set @fileName = yMaint.MakeBackupFileName (@DbName, 'D', @FullBackupPath, @Language, @FullBkExt, @TimeStampNamingForBackups) Set @ctx = 'Diff backups' End Else Begin -- for log backups I want to continue to use the same file for the rest of the day -- usually it is there because the proc does an initial log backup with any full backup Select @fileName = lastLogBkpFile From Maint.JobLastBkpLocations Where dbName = @DbName If @@rowcount = 0 Or @filename IS NULL -- backup done manualy Or @BkpLogsOnSameFile = 0 -- backup the log on a new file Begin Set @fileName = yMaint.MakeBackupFileName (@DbName, 'L', @LogBackupPath, @Language, @LogBkExt, @TimeStampNamingForBackups) End Set @Info = 'Log backups' Select -- get most up-to-date value for mirroring parameter @ReplaceSrcBkpPathToMatchingMirrorPath = ReplaceSrcBkpPathToMatchingMirrorPath , @ReplacePathsInDbFilenames = ReplacePathsInDbFilenames , @MirrorServer = MirrorServer , @MigrationTestMode = MigrationTestMode From Maint.JobLastBkpLocations Where dbName = @DbName End -- If there is row record for this database update it If Exists(Select * from Maint.JobLastBkpLocations Where dbName = @DbName) Begin -- Mirror server change to reflect now from this backup. Accept a mirror server only at full backup -- but if there is no or no more mirrorServer ensure to stop mirroring any time If @DoFullBkp = 1 Or @MirrorServer = '' Or @DoDiffBkp = 1 Update Maint.JobLastBkpLocations Set mirrorServer = @MirrorServer , MigrationTestMode = @MigrationTestMode , ReplaceSrcBkpPathToMatchingMirrorPath = @ReplaceSrcBkpPathToMatchingMirrorPath , ReplacePathsInDbFilenames = @ReplacePathsInDbFilenames , lastFullBkpFile = Case When @DoFullBkp = 1 Then @FileName Else lastFullBkpFile End , lastDiffBkpFile = Case When @DoDiffBkp = 1 Then @FileName Else lastDiffBkpFile End , EncryptionAlgorithm = ISNULL(@EncryptionAlgorithm,'') , EncryptionCertificate = ISNULL(@EncryptionCertificate,'') Where dbName = @DbName End Else -- Insert new row records for this database, if it doesn't exists Insert into Maint.JobLastBkpLocations (dbName, lastLogBkpFile, MirrorServer, lastFullBkpDate, ReplaceSrcBkpPathToMatchingMirrorPath, ReplacePathsInDbFilenames,EncryptionAlgorithm,EncryptionCertificate) Select @DbName, Null, @MirrorServer, getdate(), @ReplaceSrcBkpPathToMatchingMirrorPath, @ReplacePathsInDbFilenames , ISNULL(@EncryptionAlgorithm,''), ISNULL(@EncryptionCertificate,'') Where Not Exists(Select * from Maint.JobLastBkpLocations Where dbName = @DbName) -- raise flag to not let dbcc log shrink go, when any type of backup occurs on this database Declare @resourceName sysname ='YourSqlDbaBkpOf_'+@dbName Exec sp_getapplock @dbprincipal='public', @Resource=@resourceName, @lockMode='Shared', @lockOwner='session' Set @sql = yMaint.MakeBackupCmd ( @DbName , @DoBackup , @fileName , IIF(@DoBackup = 'F', 1, 0) -- overwrite if full backup , @MaintJobName , @EncryptionAlgorithm , @EncryptionCertificate ) -- Launch backup Exec yExecNLog.LogAndOrExec @context = 'yMaint.backups' , @sql = @sql , @JobNo = @JobNo , @errorN = @errorN output -- drop flag to let dbcc log shrink go, since backup is done Exec sp_releaseapplock @Resource=@resourceName, @lockOwner='Session' If @DoFullBkp = 1 Begin Exec Audit.ProcessExpiredDataAudits @dbName, @jobNo -- remove expired audits since we have them in backup Exec Audit.ProcessDataAuditsCleanup @dbname, @JobNo -- clean active audits sunce we have them in backup End -- Restore the backup to the mirror server (internally the procedure check is mirrorServer is in backup locations) Exec yMirroring.QueueRestoreToMirrorCmd @context = @ctx , @JobNo = @JobNo , @DbName = @DbName , @bkpTyp = @DoBackup , @fileName = @fileName , @MirrorServer = @MirrorServer , @MigrationTestMode = @MigrationTestMode , @ReplaceSrcBkpPathToMatchingMirrorPath = @ReplaceSrcBkpPathToMatchingMirrorPath , @ReplacePathsInDbFilenames = @ReplacePathsInDbFilenames , @BrokerDlgHandle = @BrokerDlgHandle OUT -- do not shrink log while a full or diff backup is performed on the database If @DoLogBkp = 1 And APPLOCK_TEST ('public', @resourceName, 'exclusive', 'session')=1 Begin -- shrink the log after backup (the procedure acts depending on the size) -- ShrinkLog may perform no shrink depending on internal database state (sys.databases.log_reuse_wait value) Set @sql2 = ' set nocount on declare @MustLogBackupToShrink int Exec yMaint.ShrinkLog @Db = "", @JobNo=, @MustLogBackupToShrink = @MustLogBackupToShrink output truncate table #MustLogBackupToShrink insert into #MustLogBackupToShrink Values(@MustLogBackupToShrink) ' Set @sql2 = replace(@sql2, '', @DbName) Set @sql2 = replace(@sql2, '', convert(nvarchar, @JobNo)) Set @sql2 = replace(@sql2, '"', '''') Exec yExecNLog.LogAndOrExec @context = 'yMaint.backups' , @sql = @sql2 , @Info = 'Log shrinking attempt' , @JobNo = @JobNo , @errorN = @errorN output If exists(select * from #MustLogBackupToShrink Where @MustLogBackupToShrink = 1) Exec yExecNLog.LogAndOrExec @context = 'yMaint.backups' , @sql = @sql , @Info = 'Supplementary log backup to help log shrinking' , @JobNo = @JobNo , @errorN = @errorN output End -- If a full backup must be done, and if the database is in full recovery mode -- an initial log backup must be done If (@DoFullBkp = 1 or @DoDiffBkp = 1) And DATABASEPROPERTYEX(@DbName, 'Recovery') <> 'Simple' Begin Set @fileName = yMaint.MakeBackupFileName(@DbName, 'L', @LogBackupPath, @Language, @LogBkExt, @TimeStampNamingForBackups) Set @sql = yMaint.MakeBackupCmd ( @DbName , 'L' -- say explicitely full backup command , @fileName , 1 , @MaintJobName , @EncryptionAlgorithm , @EncryptionCertificate ) -- Launch first log backup that creates the file that will be used -- to stored log backups usually for the rest of the days unless -- end-user launch Maint.SaveDbOnNewFileSet Exec yExecNLog.LogAndOrExec @context = 'yMaint.backups' , @sql = @sql , @Info = 'Log backups (init)' , @JobNo = @JobNo , @errorN = @errorN_BkpPartielInit output -- Restore the backup to the mirror server if enabled Exec yMirroring.QueueRestoreToMirrorCmd @context = 'yMaint.backups (queue restore of log backup init)' , @JobNo = @JobNo , @DbName = @DbName , @bkpTyp = N'L' , @fileName = @fileName , @MirrorServer = @MirrorServer , @MigrationTestMode = @MigrationTestMode , @ReplaceSrcBkpPathToMatchingMirrorPath = @ReplaceSrcBkpPathToMatchingMirrorPath , @ReplacePathsInDbFilenames = @ReplacePathsInDbFilenames , @BrokerDlgHandle = @BrokerDlgHandle OUT If @errorN_BkpPartielInit = 0 -- version Begin Update Maint.JobLastBkpLocations Set lastLogBkpFile = @filename Where dbName = @DbName -- shrink the log after backup (the procedure acts depending on the size) -- Exec yMaint.ShrinkLog @DbName, @JobNo End End -- the decision to put a database offline only occurs on full db backup -- initial log backup error are taken into account at this time to If @DoFullBkp = 1 or @DoDiffBkp = 1 Begin -- increment error count on any of the two backup types If @errorN <> 0 Or @errorN_BkpPartielInit <> 0 Begin Update Maint.JobLastBkpLocations Set FailedBkpCnt = FailedBkpCnt + 1 , @FailedBkpCnt = FailedBkpCnt + 1 , LastFullBkpDate = getdate() -- record the day when it happens again Where dbName = @DbName And datediff(hh, lastFullBkpDate, getdate()) > 24 -- increment if it happens on different days And @DoDiffBkp <> 1 If @FailedBkpCnt >= @ConsecutiveDaysOfFailedBackupsToPutDbOffline -- if to many error put in offline mode Exec yMaint.PutDbOffline @DbName, @JobNo End Else Update Maint.JobLastBkpLocations Set FailedBkpCnt = 0 , LastFullBkpDate = getdate() -- record the day when it succeed Where dbName = @DbName And @DoDiffBkp <> 1 End End -- Loop While (1 = 1) process each database selected -- a full backup of msdb always occurs even after log backup -- to get the most accurate up-to-date log history Set @fileName = yMaint.MakeBackupFileName('MsDb', 'F', @FullBackupPath, @Language, @FullBkExt, @TimeStampNamingForBackups) Set @sql = yMaint.MakeBackupCmd ('Msdb', 'F', @fileName, 1, '', @EncryptionAlgorithm, @EncryptionCertificate) Exec yExecNLog.LogAndOrExec @context = 'yMaint.backups' , @sql = @sql , @Info = 'Full Msdb backup to save the most up-to-date backup history' , @JobNo = @JobNo , @errorN = @errorN output -- If @BrokerDlgHandle is not null it tells us that we queued at least one restore to the mirror server -- so we send un message to indicate that mirror restore are over and we wait untill all the restore -- are completed If @BrokerDlgHandle IS Not Null Begin Exec yExecNLog.LogAndOrExec @context = 'yMaint.backups' , @Info = 'Waiting for mirror restore to complete' , @JobNo = @JobNo; -- Send the End message to the queue SEND ON CONVERSATION @BrokerDlgHandle MESSAGE TYPE [//YourSQLDba/MirrorRestore/End]; Declare @RecvReqMsg xml Declare @RecvReqMsgName sysname Declare @TimeoutConsec int Set @TimeoutConsec = 0 While (1=1) Begin -- «WHERE conversation_handle = @BrokerDlgHandle» is very important so we receive only messages -- that were queued by this procedure. Waitfor ( RECEIVE TOP(1) @RecvReqMsg = convert(xml, message_body), @RecvReqMsgName = message_type_name FROM YourSqlDbaInitiatorQueueMirrorRestore WHERE conversation_handle = @BrokerDlgHandle ), timeout 600000 -- attends 10 minutes 60 sec * 10 min * 1000 millisec If @@ROWCOUNT = 0 -- may be a restore last more than 10 minutes, so 10 minutes without message Begin set @TimeoutConsec = @TimeoutConsec +1 -- but we won't wait forever If @TimeoutConsec > 18 -- 6 timeout = 1 hour, then max wait of 3 hour without messages Break Else Continue End Else Set @TimeoutConsec = 0 If @RecvReqMsgName = N'http://schemas.microsoft.com/SQL/ServiceBroker/EndDialog' Begin END CONVERSATION @BrokerDlgHandle BREAK End --If @RecvReqMsgName = N'http://schemas.microsoft.com/SQL/ServiceBroker/EndDialog' If @RecvReqMsgName = N'//YourSQLDba/MirrorRestore/Reply' Begin Set @JobNo = @RecvReqMsg.value('JobNo[1]', 'int') Set @seq = @RecvReqMsg.value('Seq[1]', 'int') Set @Info = 'Reply from queued mirror restore ' + nchar(10) + @RecvReqMsg.value('Info[1]', 'nvarchar(max)') Exec yExecNLog.LogAndOrExec @context = 'yMaint.backups' , @Info = @info , @JobNo = @JobNo End --If @RecvReqMsgName = N'//YourSQLDba/MirrorRestore/Reply' End --While RestoreEnded = 0 End --If @BrokerDlgHandle IS Not Null End try Begin catch Exec yExecNLog.LogAndOrExec @jobNo = @jobNo , @context = 'yMaint.Backups' , @Info = 'Error in yMaint.backups' , @err = '?' End Catch End -- yMaint.Backups GO ---------------------------------------------------------------------------------------------------------- -- Cleanup YourSqlDba tables for removed servers. -- Install a the same YourSqlDba account on existing YourSqlDba mirror servers -- and do a linked server login mapping impersonnation between the local account and the remote one. -- Replicate local YourSqlDba account to to remote server. -- Process is very safe, since nobody knows YourSqlDba account on both side -- If multiple servers mirror their database to a single server, one must explicitely sets the same -- YourSqlDba account password on source servers, so the same account is going to be replicated -- by every participating server. ---------------------------------------------------------------------------------------------------------- If Db_name() <> 'YourSqlDba' Use YourSqlDba GO Exec yUtl.DropObj 'Mirroring.SetYourSqlDbaAccountForMirroring' GO Create Procedure Mirroring.SetYourSqlDbaAccountForMirroring @YourSqlDbaAccountForMirroringPwd Nvarchar(max) = NULL as Begin Set nocount on Declare @MirrorServerName sysname Declare @Sql nvarchar(max) declare @loginExists int declare @password_hash_local varbinary(256) declare @original_password_hash_local varbinary(256) declare @err int = 0 declare @newPwd nvarchar(max) = NULL If @YourSqlDbaAccountForMirroringPwd = 'choose some password' Begin Raiserror ('Seriously, we don''t accept place holder ''choose some password'' as valid password, password rejected, please specify another one', 11, 1) Return End -- remember actual password in hashed form Set @original_password_hash_local = convert(varbinary(max), LOGINPROPERTY('YourSqlDba', 'PasswordHash')) -- get new password if specified or compute a new random value SET @newPwd = ISNULL(@YourSqlDbaAccountForMirroringPwd, replace(convert(nvarchar(max), newid(), 0)+convert(nvarchar(max), newid(), 0), '-', '')) Set @sql = 'Alter login YourSqlDba With password = '''+@NewPwd+'''' Exec (@sql) -- Get new password hash for remote login, which is easy with login property. Set @password_hash_local = convert(varbinary(max), LOGINPROPERTY('YourSqlDba', 'PasswordHash')); -- but if no password input was specified, set actual local password back to its original value -- now that we have the new password hash for remote login, otherwise this means that admin set also -- local password of YourSqlDba account with the same value If @YourSqlDbaAccountForMirroringPwd IS NULL Begin Set @sql = 'Alter login YourSqlDba With password='+yUtl.ConvertToHexString(@Original_password_hash_Local)+' HASHED' Exec (@sql) End Set @MirrorServerName = '' While (1=1) Begin Select top 1 @MirrorServerName = MirrorServerName From Mirroring.TargetServer Where MirrorServerName > @MirrorServerName Order By MirrorServerName If @@ROWCOUNT = 0 Break -- Reinstall YourSqlDba mapping If Exists ( Select * From Sys.Servers S JOIN Sys.linked_logins LL ON LL.server_id = S.server_id JOIN Sys.server_principals P ON P.principal_id = LL.local_principal_id Where P.Name = 'YourSqlDba' And S.Name = @MirrorServerName And S.is_linked = 1 ) Begin Print 'Drop previous YourSqlDba login mapping from ' + @MirrorServerName Exec Master.dbo.sp_Droplinkedsrvlogin @rmtsrvname = @MirrorServerName, @locallogin = 'YourSqlDba' End Print 'Reinstall YourSqlDba login mapping on ' + @MirrorServerName EXEC master.dbo.sp_addlinkedsrvlogin @rmtsrvname = @MirrorServerName, @locallogin = 'YourSqlDba', @rmtUser='YourSqlDba', @rmtpassword=@newPwd, @useself='False' -- Make YourSqlDba be the same with same account on other serveur. Set @sql = ' Print "Synchronize YourSqlDba account on " Execute ( " Use YourSqlDba Begin try -- proceed only if YourSqlDba database and its account exists Declare @currentSysAdmin sysname = SUSER_SNAME() If SUSER_SID(""YourSqlDba"") IS NOT NULL AND DB_ID(""YourSqlDba"") IS NOT NULL Begin Exec (""alter authorization on database::yoursqldba to [""+@currentSysAdmin+""]"") Alter LOGIN YourSqlDba WITH PASSWORD= HASHED Exec (""alter authorization on database::yoursqldba to [YourSqlDba]"") End End try Begin catch Declare @msg nvarchar(max) = ""Msg ""+convert(varchar, error_number())+"" ""+Error_message() Raiserror (@Msg, 11, 1) End catch " ) At [] ' Set @sql = REPLACE(@sql, '', @MirrorServerName) Set @sql = REPLACE(@sql, '', yUtl.ConvertToHexString(@password_hash_Local)) Set @sql = REPLACE(@sql, '"', '''') Begin try Print @sql Exec(@Sql) End Try Begin Catch Set @err = 1 Declare @msg nvarchar(max) = error_message () Print @Msg End Catch End -- for each link server return @err End -- Mirroring.SetYourSqlDbaAccountForMirroring GO If Db_name() <> 'YourSqlDba' Use YourSqlDba go ---------------------------------------------------------------------------------------------------------- -- Cleanup YourSqlDba tables for removed servers. -- Check access of mirror servers through YourSqlDba account. If a single one fails, email -- and action to do set YourSqlDba password and set YourSqlDba account bridge to MirrorServer. -- Return a success or status ---------------------------------------------------------------------------------------------------------- Exec yUtl.DropObj 'yMirroring.CleanMirrorServerForMissingServerAndCheckServerAccessAsYourSqlDbaAccount' GO Create Procedure yMirroring.CleanMirrorServerForMissingServerAndCheckServerAccessAsYourSqlDbaAccount @oper sysname = NULL , @MirrorServer sysname = NULL As Begin Declare @err Int = 0 -- cleanup inconsistent mirror references of the past Delete Mirroring.TargetServer Where isnull(MirrorServerName, '') = '' Delete M From Mirroring.TargetServer M Where Not Exists(Select * From Sys.Servers S Where S.Name = M.MirrorServerName Collate Database_Default And S.is_linked = 1) ;With Vue_Update as ( Select MirrorServer, ISNULL(TS.MirrorServerName, '') as ServerNameReplacement from Maint.JobLastBkpLocations JBL -- cleanup mirroring.TargetServers, Maint.JobLastBkpLocations LEFT JOIN Mirroring.TargetServer TS ON TS.MirrorServerName = JBL.MirrorServer Where JBL.MirrorServer <> '' ) Update Vue_Update Set MirrorServer = ServerNameReplacement Declare @sql nvarchar(max) Declare @MirrorServerName sysname -- when called from maintenance SP, but there is no linked server under that name If ISNULL(@MirrorServer, '') <> '' And Not Exists (Select * From Sys.servers Where name = @MirrorServer And is_linked = 1) Set @err = 1 -- imeprsonate YourSqlDba account to test connection Execute as login = 'yoursqldba' -- for each server, check remote access as YourSqlDba Set @MirrorServerName = '' declare @i int While (@err = 0) -- or break from the inside Begin Select top 1 @MirrorServerName = MirrorServerName From Mirroring.TargetServer Where MirrorServerName > @MirrorServerName Order By MirrorServerName If @@ROWCOUNT = 0 Break Begin try Set @sql = ' Select @i=Dbid from Openquery ([], "select Db_Id(""Master"") as DbId") as x ' Set @sql = REPLACE( @sql, '', @MirrorServerName) Set @sql = REPLACE( @sql, '"', '''') Exec sp_executeSql @sql, N'@i int output', @i output End try Begin catch print error_number() print error_message() Set @err = 1 --7202 --Could not find server in sys.servers. Verify that the correct server name was specified. If necessary, execute the stored procedure sp_addlinkedserver to add the server to sys.servers. --18456 --Failure to open session with 'yoursqldba'. --7437 --Linked servers cannot be used under impersonation without a mapping for the impersonated login. End catch End -- While REVERT; -- leave YourSqlDba account persona If @err = 0 -- all mirror servers provide access through YourSqlDba account Return; -- try to auto-repair broken connections, which is possible only if currently -- with an account that have sysadmin privileges that maps to a sysadmin account on each Mirror servers -- Must not be YourSqlDba, because we just tested it and it failed. If SUSER_SNAME () <> 'YourSqlDba' And IS_SRVROLEMEMBER('sysadmin', SUSER_SNAME () )=1 -- Mirror server exists or not specified And (Exists (Select * From Sys.servers Where name = @MirrorServer And is_linked = 1) Or ISNULL(@MirrorServer, '') = '') Begin Exec @err = Mirroring.SetYourSqlDbaAccountForMirroring If @err = 0 Return 0; End -- If here auto-repaired was not performed or couldn't be performed -- figures out who to notify if necessary Declare @email_address nvarchar(512) = NULL ;With MostSusceptibleOperator as ( select email_Address from Msdb..sysoperators Where enabled = 1 And name = @oper -- if called from YourSqlDba_DoMaint UNION ALL SELECT top 1 S.recipients as email_Address -- @oper is not specified, tries figure it out last message from YourSqlDba FROM msdb.dbo.sysmail_sentitems S Where s.subject like '%YourSqlDba%' And sent_status = 'Sent' And @oper is NULL ) Select @email_address = email_Address From MostSusceptibleOperator If @email_address IS NULL -- still can't figure out who to notify, nothing else to do Return Declare @body nvarchar(max) If ISNULL(@MirrorServer,'') <> '' -- if mirror server yoursqldba If Exists (Select * From Sys.servers Where name = @MirrorServer And is_linked = 1) -- real server Set @body = -- link couldn't be repaired send email to ask for it ' Ensure that you are granted admin access to every remote linked server defined for your mirror servers and execute the following command on corresponding local servers:

Exec YourSQLDba.Mirroring.SetYourSqlDbaAccountForMirroring
If the same MirrorServer has multiple source servers specify a common password on every of them:

Exec YourSQLDba.Mirroring.SetYourSqlDbaAccountForMirroring @YourSqlDbaAccountForMirroringPwd = ''choose some password''
' Else -- says that the parameter is invalid, @mirrorServer doesn't match linked server Set @body = ' Specified @mirrorServer parameter doesn''t match with any linked servers names. Do Mirroring.Addserver to add the missing server or correct the parameter. ' EXEC Msdb.dbo.sp_send_dbmail @profile_name = 'YourSQLDba_EmailProfile' , @recipients = @email_Address , @importance = 'High' , @subject = 'YourSqlDba : Reset YourSqlDba account for MirrorServer or correct @mirrorServer parameter' , @body = @body , @body_format = 'HTML' Print 'Message sent to '+@email_Address Print 'Subject: ' + @body return 1 End Go If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yUtl.DedupSeqOfChars' GO Create Function yUtl.DedupSeqOfChars (@Dup nvarchar(5), @Str Nvarchar(max)) Returns Table as Return ( Select s = NoMoreRepeatingChar, NoMoreRepeatingChar -- return both values with different names for compatibility purposes From (Select StrWithCharToDedup=@Str, Dup=@Dup) as vPrm Cross Apply (Select StartEndPair=NChar(0x25BA)+NChar(0x25C4)) As vStartEndPair Cross Apply (Select EndStartPair=NChar(0x25C4)+NChar(0x25BA)) as vEndStartPair Cross Apply (Select DupCharReplacedByStartEndPairs=Replace(StrWithCharToDedup, Dup, StartEndPair)) as vDupCharToStartEndPair Cross Apply (Select EndStartPairsRemoved=replace(DupCharReplacedByStartEndPairs, EndStartPair, '')) as vEndStartPairsRemoved Cross Apply (Select NoMoreRepeatingChar=replace(EndStartPairsRemoved, StartEndPair, Dup)) as vNoRepeatingChar ) GO ------------------------------------------------------------------------------------------- -- Maint Stored proc. that is scheduled for maintenance ------------------------------------------------------------------------------------------- Drop Proc If Exists Maint.SetSyncWith_YourSqlDba_DoMaint GO Create Proc Maint.SetSyncWith_YourSqlDba_DoMaint @WaitType Sysname = 'Exclusive' AS Begin -- Exclusive mode is intented to be used when synchronizing external backup process with CommVault -- See https://tinyurl.com/YourSqlDbaAndCommVault for a more detailed overview. If @WaitType In ('Exclusive', 'Shared') exec sp_getapplock @resource='YourSqlDba.Do_Maint', @lockMode=@WaitType, @lockOwner='Session', @DbPrincipal='dbo' Else Raiserror ('@WaitType parameter must either be Exclusive or Shared',11,1) with nowait; End GO Drop Proc If Exists Maint.SignalEndOf_YourSqlDba_DoMaint GO Create Proc Maint.SignalEndOf_YourSqlDba_DoMaint AS -- To cancel lock acquired by Maint.SetSyncWith_YourSqlDba_DoMaint exec sp_releaseapplock @resource='YourSqlDba.Do_Maint', @lockOwner='Session', @DbPrincipal='dbo' GO If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'Maint.YourSqlDba_DoMaint' GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO Drop proc If Exists Maint.YourSqlDba_DoMaint GO CREATE proc Maint.YourSqlDba_DoMaint @oper nvarchar(200) , @command nvarchar(200) = 'YourSqlDba_DoMaint' -- main command , @MaintJobName nvarchar(200) = 'Ad-Hoc Job' -- a name is given to override mecanism that gets this information from Sql Agent job when NULL , @DoInteg int = 0 , @DoUpdStats int = 0 , @DoReorg int = 0 , @DoBackup nvarchar(5) = '' , @FullBackupPath nvarchar(512) = NULL , @LogBackupPath nvarchar(512) = NULL , @TimeStampNamingForBackups Int = 1 -- by default all backups are timestamped, when using deduplication tools, it is better to keep same backup name , @FullBkExt nvarchar(7) = 'BAK' -- default backup extension for full backups , @LogBkExt nvarchar(7) = 'TRN' -- default backup extension for transaction log backups , @FullBkpRetDays Int = NULL -- by default no cleanup of full backups , @LogBkpRetDays Int = NULL -- by default no cleanup of log backups , @NotifyMandatoryFullDbBkpBeforeLogBkp int = 1 , @BkpLogsOnSameFile int = 1 , @SpreadUpdStatRun int = 7 , @SpreadCheckDb int = 7 , @ConsecutiveDaysOfFailedBackupsToPutDbOffline Int = 9999 -- max consecutives failure when of full backup and initial log backup , @MirrorServer sysname = '' , @MigrationTestMode Int = 0 , @ReplaceSrcBkpPathToMatchingMirrorPath nvarchar(max) = '' -- replaces on srcBkpPath to match corresponding path from mirror , @ReplacePathsInDbFilenames nvarchar(max) = '' -- replaces in db files names to restore , @IncDb nVARCHAR(max) = '' -- @IncDb : See comments later for further explanations , @ExcDb nVARCHAR(max) = '' -- @ExcDb : See comments later for further explanations , @ExcDbFromPolicy_CheckFullRecoveryModel nVARCHAR(max) = '' -- @ExcDbFromPolicy_CheckFullRecoveryModel : -- See comments later for further explanations , @EncryptionAlgorithm nvarchar(10) = '' , @EncryptionCertificate nvarchar(100) = '' --, @JobId UniqueIdentifier = NULL -- job id of SQL Server Agent Job that launched the job --, @StepId Int = NULL -- stepid of SQL Server Agent Jobstep that launched the job as Begin Set nocount On -- YourSqlDba does always a shared lock to prevent external backup process with CommVault -- See https://tinyurl.com/YourSqlDbaAndCommVault for a more detailed overview. exec Maint.SetSyncWith_YourSqlDba_DoMaint @WaitType = 'Shared' -- reporting is heavily supported by email, and this info must be avail on-hand before the begin try Declare @email_Address sysname -- to read email address of the operator select @email_Address=email_address from Msdb..sysoperators Where enabled = 1 And name = @oper -- if called from YourSqlDba_DoMaint Begin Try declare @sql nvarchar(max) -- SQL query declare @StartOfMaint datetime -- when maintenance started declare @JobNo Int -- job number declare @SendOnErrorOnly Int=0 -- when to send and error message declare @lockResult Int Declare @SqlBinRoot nvarchar(512) Declare @pathBkp nvarchar(512) Declare @JobId UniqueIdentifier -- job id of SQL Server Agent Job that launched the job Declare @StepId Int -- stepid of SQL Server Agent Jobstep that launched the job -- If maintenance is called from SqlAgent we manage this: -- Log viewer has a poor display of job history. It supresses line feeds and truncate output -- The only way to have a nice output is through a simple select, and by checking -- option : Include Step output in history Set @SendOnErrorOnly = 0 Select @ReplacePathsInDbFilenames = finished.NoMoreRepeatingChar From (Select r0=Isnull(@ReplacePathsInDbFileNames, '')) as vr0 Cross Apply (Select r1=Replace(r0, nChar(10), '')) as vr1 Cross Apply (Select r2=Replace(r1, nChar(10), '')) as vr2 Cross Apply yUtl.DedupSeqOfChars(' ', r2) as finished Select @ReplaceSrcBkpPathToMatchingMirrorPath = finished.NoMoreRepeatingChar From (Select r0=Isnull(@ReplaceSrcBkpPathToMatchingMirrorPath, '')) as vr0 Cross Apply (Select r1=Replace(r0, nChar(10), '')) as vr1 Cross Apply (Select r2=Replace(r1, nChar(10), '')) as vr2 Cross Apply yUtl.DedupSeqOfChars(' ', r2) as finished -- the query below is a first step in re-engeneering some parts of YourSqlDba -- it allows to globalize in the current connection context the parameters -- and makes easy to obtain them throught Select * from dbo.MainContextInfo () in a tabular form Select @sql=S.Sql From (Select oper = @oper , command = @command , W.SqlAgentJobName , MaintJobName = @MaintJobName , DoInteg = @DoInteg , DoUpdStats = @DoUpdStats , DoReorg = @DoReorg , DoBackup = @DoBackup , DoFullBkp = IIF( @DoBackup = 'F' , 1 , 0 ) , DoLogBkp = IIF( @DoBackup = 'L' , 1 , 0 ) , DoDiffBkp = IIF( @DoBackup = 'D' , 1 , 0 ) , IncDb = @IncDb , ExcDb = @ExcDb , MigrationTestMode = @MigrationTestMode , FullBackupPath = @FullBackupPath , LogBackupPath = @LogBackupPath , TimeStampNamingForBackups = @TimeStampNamingForBackups , FullBkExt = @FullBkExt , LogBkExt = @LogBkExt , FullBkpRetDays = @FullBkpRetDays , LogBkpRetDays = @LogBkpRetDays , NotifyMandatoryFullDbBkpBeforeLogBkp = @NotifyMandatoryFullDbBkpBeforeLogBkp , BkpLogsOnSameFile = @BkpLogsOnSameFile , SpreadUpdStatRun = @SpreadUpdStatRun , SpreadCheckDb = @SpreadCheckDb , ConsecutiveDaysOfFailedBackupsToPutDbOffline = @ConsecutiveDaysOfFailedBackupsToPutDbOffline , MirrorServer = @MirrorServer , ReplaceSrcBkpPathToMatchingMirrorPath = @ReplaceSrcBkpPathToMatchingMirrorPath , ReplacePathsInDbFilenames = @ReplacePathsInDbFilenames , ExcDbFromPolicy_CheckFullRecoveryModel = @ExcDbFromPolicy_CheckFullRecoveryModel , EncryptionAlgorithm = @EncryptionAlgorithm , EncryptionCertificate = @EncryptionCertificate , W.Host , W.Prog , W.Who , W.MainCall , W.JobId , W.StepId From dbo.WhoCalledWhat as W ) as Prm Cross Apply ( Select JsonPrm= ( Select oper, command, SqlAgentJobName, MaintJobName , DoInteg, DoUpdStats, DoReorg, DoBackup, DoFullBkp, DoDiffBkp, DoLogBkp , FullBackupPath, LogBackupPath, TimeStampNamingForBackups, FullBkExt, LogBkExt, FullBkpRetDays, LogBkpRetDays , NotifyMandatoryFullDbBkpBeforeLogBkp, BkpLogsOnSameFile , SpreadUpdStatRun, SpreadCheckDb , ConsecutiveDaysOfFailedBackupsToPutDbOffline , MirrorServer, MigrationTestMode, ReplaceSrcBkpPathToMatchingMirrorPath, ReplacePathsInDbFilenames , IncDb, ExcDb, ExcDbFromPolicy_CheckFullRecoveryModel , EncryptionAlgorithm, EncryptionCertificate , Host, Prog, Who, StepId, JobId , MainCall For JSON PATH, WITHOUT_ARRAY_WRAPPER ) ) as JsonPrm cross apply dbo.ScriptMakeProcessMaintenancePrmGlobal (JsonPrm) as S Exec (@Sql) -- Execute SQL generated by previous query -- record beginning of any job now exec yExecNLog.AddJobEntry @jobName = @MaintJobName , @JobNo = @JobNo output -- new or actual job Exec yExecNLog.LogAndOrExec @context = 'Maint.YourSqlDba_DoMaint' , @Info = 'Beginning of job' , @JobNo = @JobNo If @email_Address IS NULL Exec yExecNLog.LogAndOrExec @context = 'Maint.YourSqlDba_DoMaint' , @YourSqlDbaNo = '009' , @Info = 'Maint.YourSqlDba_DoMaint' , @JobNo = @JobNo , @err = ' The operator name supplied to the procedure Maint.YourSqlDba_DoMaint, must exist and be enabled in msdb..sysoperators ' If Exists (Select * From WhoCalledWhat Where Prog Like 'SqlAgent%') Select Convert(Nvarchar(256),'If an error is reported for this job, run the following EXEC command in a query window:') UNION ALL Select 'Select cmdStartTime, JobNo, seq, Typ, line, Txt From YourSQLDba.Maint.HistoryView(''' + convert(nvarchar, @StartOfMaint, 120) + ''', ''' + convert(nvarchar, Getdate(), 120) + ''', 1) Order By cmdStartTime, JobNo, Seq, TypSeq, Typ, Line' If ISNULL(@EncryptionAlgorithm, '') <> '' AND ISNULL(@EncryptionCertificate, '') <> '' Begin -- backups on the same file are not supported for encrypted backups Set @BkpLogsOnSameFile=0 End -- alter admin when a valid linked server is specified, that this one or another needs a YourSqlDba password account reset If ISNULL(@MirrorServer, '') <> '' Begin Declare @rc Int Exec @rc = yMirroring.CleanMirrorServerForMissingServerAndCheckServerAccessAsYourSqlDbaAccount @oper=@oper, @MirrorServer=@MirrorServer If @rc <> 0 Begin Raiserror ('YourSqlDba account must be reset manually, check YourSqlDba e-mail', 11, 1); Return End End Exec Install.PrintVersionInfo If @ReplaceSrcBkpPathToMatchingMirrorPath<> '' Begin If charindex('>', @ReplaceSrcBkpPathToMatchingMirrorPath) = 0 Begin Raiserror ('Parameter @ReplaceSrcBkpPathToMatchingMirrorPath content must be separated by a ''>'' char between the search and the replace expression', 11, 1) End If right(rtrim(@ReplaceSrcBkpPathToMatchingMirrorPath),1) <> '|' Begin Raiserror ('Parameter @ReplaceSrcBkpPathToMatchingMirrorPath content must be ended by a pipe char ''|'' ', 11, 1) End End If @ReplacePathsInDbFilenames <> '' Begin If charindex('>', @ReplacePathsInDbFileNames) = 0 Begin Raiserror ('Parameter @ReplacePathsInDbFileNames content must be separated by a ''>'' char between the search and the replace expression', 11, 1) End If right(rtrim(@ReplacePathsInDbFileNames),1) <> '|' Begin Raiserror ('Parameter @ReplacePathsInDbFileNames content must be ended by a pipe char ''|'' ', 11, 1) End End Set @FullBackupPath = yUtl.NormalizePath(@FullBackupPath) Set @LogBackupPath = yUtl.NormalizePath(@LogBackupPath) If @doBackup = 'C' Set @doBackup = 'F' -- translate 'C' = complete to 'F' = Full If @doBackup = 'P' Set @doBackup = 'L' -- translate 'P' = complete to 'L' = Log exec master.dbo.xp_instance_regread N'HKEY_LOCAL_MACHINE' , N'Software\Microsoft\MSSQLServer\Setup' , N'SqlBinRoot' , @SqlBinRoot OUTPUT , 'no_output' exec master.dbo.xp_instance_regread N'HKEY_LOCAL_MACHINE' , N'Software\Microsoft\MSSQLServer\MSSQLServer' , N'DefaultData' , @pathBkp OUTPUT , 'no_output' -- remind backup directory used, very useful when it comes to restore If @FullBackupPath IS NOT NULL and @FullBackupPath <> @pathBkp And (@DoBackup IN ('F','D')) Begin Declare @tmp nvarchar(512) Set @tmp = @FullBackupPath If right(@tmp, 1) = '\' Set @tmp = stuff(@tmp, len(@tmp), 1, '') EXEC xp_instance_regwrite N'HKEY_LOCAL_MACHINE' , N'Software\Microsoft\MSSQLServer\MSSQLServer' , N'BackupDirectory' , REG_SZ , @tmp End -- use to timestamp filename set @StartOfMaint = getdate() -- Remove trace of backup location for databases no longer there Delete LB From Maint.JobLastBkpLocations LB LEFT JOIN master.sys.databases D ON LB.dbName = D.name COLLATE Database_default Where D.Name is NULL And LB.keepTrace = 0 If @FullBackupPath IS NULL Or @LogBackupPath IS NULL Begin If @DoBackup IN ('F', 'L', 'D') Begin Raiserror ('Specify @FullBackupPath and/or @LogBackupPath to the procedure ', 11, 1) End End -- Error message if operator is missing, exit now to let error status in Sql agent job select @email_Address = email_Address from Msdb..sysoperators where name = @oper and enabled = 1 If @@rowcount = 0 Begin Raiserror (' A valid operator name must be supplied to the procedure', 11, 1) End --Exec yExecNLog.LogAndOrExec -- test logging mecanism on severe errord that does connexion lost (severity 20 and above) -- @context = 'Maint.YourSqlDba_DoMaint' --, @Info = 'Test fatal err' --, @JobNo = @JobNo --, @sql = 'raiserror (''test err fatale'', 25, 1) with log ' -- Advise user that best practices are not followed If @DoBackup <> 'L' Exec PerfMon.ReportIgnoredBestPractices @email_Address = @email_Address If Exists(Select * From Dbo.MainContextInfo (NULL) Where DoInteg=1 Or DoUpdStats=1 Or DoReorg=1 Or DoBackup IN ('F','D')) Begin -- Warns it this version of YourSqlDba is quite Old If GETDATE() > yInstall.NextUpdateTime() And datepart(dd, getdate()) = 1 -- just do it once a month Begin declare @msgBody nvarchar(max) declare @subject nvarchar(max) declare @version nvarchar(20) Select @version = VersionNumber From Install.VersionInfo() If CONVERT(nvarchar(20), SERVERPROPERTY('LCID')) <> '1036' Begin set @subject = yInstall.DoubleLastSpaceInFirst78Colums ('YourSqlDba '+@Version+' reminder. Time to check for the free newer YourSqlDba version at https://onedrive.live.com/redir?resid=12C385255443C4ED%217080&authkey=%21AAUr-EDkGO3RESc&page=View&wd=target%28Introduction.one%7Cc7014943-14b8-4c1d-9ae7-429002e0759c%2FQuick%20Start%20%20download%7C7baefd6f-3103-45b4-899f-8c9f4be9e119%2F%29&wdorigin=703, then open it and and run it.') Set @msgBody = ' This message is to remind you to get the latest and most reliable YourSqlDba code for this Sql instance: .

By applying the latest version you get rid of this monthly reminder.

Update is very easy. Just get the latest script from versions links from YourSqlDba documentation home page, then open it copy/paste and then run it.

Actually this project is subject to frequent improvments as the support of our large user community help us to find many uses cases. It is located on YourSqlDba''s Github home project and from this home page there is a Read me section where you can also find a link to the most recent script version.
' End Else Begin set @subject = yInstall.DoubleLastSpaceInFirst78Colums ('YourSqlDba '+@Version+' Rappel: Il est temps de vérifier la disponiblité d''une version plus récente de YourSqlDba à YourSqlDba.codeplex.com') Set @msgBody = ' Ce message a pour but de vous rappeller de récupérer la version la plus récente de YourSqlDba pour l''instance: .

L''application de la dernière version fait disparaître ce message.

La mise à jour est très simple. Obtenez le script en cliquant sur le lien de la plus récente version à partir de la Page d''acceuil de la documentation de YourSqlDba et puis ouvrez, copier/collez le script puis exécutez-le.

Ce projet fait l''objet d''améliorations fréquentes compte tenu que le support de notre grande communauté d''utilisateurs nous aide à découvrir beaucoup de cas d''utilisation. Il est localisé sur ce site Github et à partir de cette page d''acceuil se trouve une section Lisez-moi, ou se trouve également un lien vers la version la plus récente.
' End Set @msgBody = replace(@msgBody, '', convert(sysname, serverproperty('ServerName'))) Set @msgBody = replace(@msgBody, '', convert(sysname, serverproperty('ServerName'))) EXEC Msdb.dbo.sp_send_dbmail @profile_name = 'YourSQLDba_EmailProfile' , @recipients = @email_Address , @importance = 'Normal' , @subject = @subject , @body = @msgBody , @body_format = 'HTML' End End -- avoid easy mistake (a narrow space between 2 quotes) Set @DoBackup = replace(@DoBackup, ' ', '') -- add '\' to path name just in case it is missing If right(@FullBackupPath,1)<> '\' Set @FullBackupPath = @FullBackupPath + '\' If right(@LogBackupPath,1)<> '\' Set @LogBackupPath = @LogBackupPath + '\' -- Record all databases online, and if they are in full recovery mode or not (log backup allowed or not) -- The function udf_YourSQLDba_ApplyFilterDb apply filter parameters on this list Create table #Db ( DbName sysname primary key clustered , DbOwner sysname NULL -- because actual owner may be invalid after a restore , FullRecoveryMode int -- If = 1 log backup allowed , cmptLevel tinyInt , DbIsCaseInsensitive tinyInt ) Insert into #Db Select F.*, DbIsCaseInsensitive from yUtl.YourSQLDba_ApplyFilterDb (@IncDb, @ExcDb) as F JOIN Sys.databases as D ON D.Name collate database_default = F.DbName CROSS APPLY (Select DbIsCaseInsensitive =cast(COLLATIONPROPERTY(D.collation_name,'ComparisonStyle') as int) & 1) as DbIsCaseInsensitive Where DatabasepropertyEx(DbName, 'Status') = 'Online' -- Avoid db that can't be processed -- remove snapshot database from the list Delete Db From #Db Db Where Exists(Select * From sys.databases d Where d.name = db.DbName and source_database_Id is not null) -- if any database is defined as Case sensitive issue an error message asking to exclude it from -- yoursqldba process. -- create database TestiscaseSensitive collate french_cs_as declare @err nvarchar(max) Select @err = 'The following case sensitive database(s) will not be processed by YoursqlDba :'+ Stuff ( (Select convert(nvarchar(max), ','+DbName) as [text()] From #Db Where DbIsCaseInsensitive=0 Order by DbName For XML PATH('')) , 1, 1, '' ) If @err is not null Exec yExecNLog.LogAndOrExec @context = 'Maint.YourSqlDba_DoMaint pre-checks' , @YourSqlDbaNo = '007' , @err = @err , @Info = 'Case sensitive databases are not processed by YourSqlDba. Exclude them from maintenance by setting «@ExcDb» parameter of the «YourSQLDba_DoMaint» to exclude databases from the check' , @JobNo = @JobNo Delete From #Db Where DbIsCaseInsensitive = 0 -- ============================================================================== -- perform integrity tests or not -- ============================================================================== If @DoInteg = 1 Exec yMaint.IntegrityTesting @jobNo, @SpreadCheckDb -- ============================================================================== -- perform Update stat -- ============================================================================== If @DoUpdStats = 1 Exec yMaint.UpdateStats @jobNo, @SpreadUpdStatRun -- ============================================================================== -- Reorganize index -- ============================================================================== If @DoReorg = 1 Exec yMaint.ReorganizeOnlyWhatNeedToBe @jobNo -- ============================================================================== -- backup start -- ============================================================================== -- on complete backups suppress old files just before backup start If @DoBackup IN ('F', 'L', 'D') Begin Exec yMaint.backups @jobNo End -- If @DoBackup -- If backups are to be mirrored than we Launch a login synchronisation on the mirror server If isnull(@MirrorServer, '') <> '' And (@DoBackup = 'F' Or @DoBackup = 'D') Exec yMirroring.LaunchLoginSync @MirrorServer = @MirrorServer, @JobNo = @JobNo -- Check for databases that are in SIMPLE recovery mode and not excluded form this policy -- with the @ExcDbFromPolicy_CheckFullRecoveryModel parameter If @DoBackup = 'F' Or @DoBackup = 'D' Begin Exec yMaint.CheckFullRecoveryModelPolicy @jobNo, @IncDb, @ExcDb, @ExcDbFromPolicy_CheckFullRecoveryModel End End Try Begin Catch -- make error go through the log declare @msg nvarchar(4000) Select @Msg=yExecNLog.FormatBasicBeginCatchErrMsg() -- write it into Maint.JobHistoryLineDetails Insert Into Maint.JobHistoryLineDetails (jobNo, Seq, TypSeq, Typ, Line, Txt) Select D.JobNo, D.Seq, TypSeq=99, typ='ErrLog', lineOrd=1, line=@Msg From Maint.JobHistoryDetails as D Where D.JobNo = @JobNo End catch -- Close App lock that signal that Maint.YourSqlDba_DoMaint Exec Maint.SignalEndOf_YourSqlDba_DoMaint -- From here send execution report and any error message if found -- also update JobEnd Exec yExecNLog.LogAndOrExec @context = 'Maint.YourSqlDba_DoMaint' , @Info = 'End of maintenance' , @JobNo = @JobNo -- send report and avoid raising another error if no operator Select @SendOnErrorOnly = IIF(@DoBackup='L', 1, 0) If @email_Address is NOT NULL Exec yMaint.SendExecReports @email_Address = @email_Address , @command = @command , @MaintJobName = @MaintJobName , @StartOfMaint = @StartOfMaint , @JobNo = @JobNo , @SendOnErrorOnly = @SendOnErrorOnly -- if some error is found in job If Exists ( Select * From Maint.JobHistoryLineDetails Where JobNo=@Jobno And (Typ like 'Err%' Or (Typ like 'Status' And line like 'fail%')) ) Begin Declare @FormatMessage Nvarchar(4000) = NULL Set @FormatMessage = '--->>>>'+nchar(10)+space(300)+ 'To show error in query windows do : EXEC YourSqlDba.Maint.ShowJobErrors '+convert(nvarchar,@jobNo) +nchar(10)+space(300)+'<<<---' Raiserror (@formatMessage,11,1) End End -- Maint.YourSqlDba_DoMaint GO -- ------------------------------------------------------------------------------ -- Function that get path only from complete file path -- ------------------------------------------------------------------------------ If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yUtl.GetPathFromName' GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO create function yUtl.GetPathFromName ( @pathAndFileName nvarchar(512) ) returns nvarchar(max) as Begin Declare @filename nvarchar(512) Declare @rPathAndFileName nvarchar(512) Set @rPathAndFileName = Reverse (@PathAndFileName) Set @filename = Reverse (Stuff(@rPathAndFileName, 1, charindex('\', @rPathAndFileName)-1, '')) Return (@filename) End -- yUtl.GetPathFromName --select yUtl.GetPathFromName ('c:\backup\sub\toto.bak') -- some testing --select yUtl.GetPathFromName (NULL) -- some testing GO GRANT CONNECT TO guest; GO If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'Maint.SaveDbOnNewFileSet' GO create proc Maint.SaveDbOnNewFileSet @DbName nvarchar(128) , @FullBackupPath nvarchar(512) = null , @LogBackupPath nvarchar(512) = null , @oper nvarchar(128) = null , @MirrorServer sysname = '' , @MigrationTestMode Int = 0 , @ReplaceSrcBkpPathToMatchingMirrorPath nvarchar(max) = NULL , @ReplacePathsInDbFileNames nvarchar(max) = NULL , @DoBackup nvarchar(1) = 'F' , @EncryptionAlgorithm nvarchar(10) = '' , @EncryptionCertificate nvarchar(100) = '' WITH execute as Self as Begin Declare @command nvarchar(200) Set @command = 'SaveDbOnNewFileSet' -- main command Declare @nomTache nvarchar(512) Declare @allowed int Declare @sql nvarchar(max) set @nomTache = 'SaveDbOnNewFileSet of ' + @DbName Set @FullBackupPath = yUtl.NormalizePath(@FullBackupPath) Set @LogBackupPath = yUtl.NormalizePath(@LogBackupPath) -- Check backup permissions with original login EXECUTE AS LOGIN = ORIGINAL_LOGIN(); Set @sql = N' Use [] Set @allowed = 0 Declare @username sysname; Set @username = USER_NAME() Declare @loginName sysname; Set @loginName = SUSER_NAME() Declare @DbName sysname; Set @DbName = db_name() If @username <> @loginName Set @username = @loginName + ":" + @username If IS_MEMBER ("db_owner") = 1 OR IS_MEMBER ("db_backupoperator") = 1 Or ( select count(*) from [].sys.database_permissions where class_desc = "DATABASE" and grantee_principal_id = USER_ID() And permission_name IN ("BACKUP DATABASE", "BACKUP LOG") ) = 2 Print "User "+ @username +" autorized to do backup" Else Begin Raiserror ("User [%s] is not granted required rigths to full backups [%s]!", 11, 1, @username, @DbName) Return End Set @allowed = 1 ' Set @sql = replace (@sql, '"', '''') Set @sql = replace (@sql, '', @DbName) --print @sql Exec sp_ExecuteSql @sql, N'@allowed int output', @allowed output If @allowed = 0 Begin Return End -- Reset sp impersonation to proceed with backup REVERT If not exists(Select * from master.sys.databases where name = @DbName) Begin Raiserror ('Database [%s] doesn''t exists !', 11, 1, @DbName) Return End If @FullBackupPath is NULL Select @FullBackupPath = yUtl.GetPathFromName(lastFullBkpFile) From Maint.JobLastBkpLocations Where dbName = @DbName If @FullBackupPath IS NULL -- toujours null Begin raiserror('No maintenance done yet on this database, parameter @FullBackupPath is then mandatory',11,1) return End If @LogBackupPath is NULL Select @LogBackupPath = yUtl.GetPathFromName(lastLogBkpFile) From Maint.JobLastBkpLocations Where dbName = @DbName If @EncryptionAlgorithm is NULL Select @EncryptionAlgorithm = EncryptionAlgorithm From Maint.JobLastBkpLocations Where dbName = @DbName If @EncryptionCertificate is NULL Select @EncryptionCertificate = EncryptionCertificate From Maint.JobLastBkpLocations Where dbName = @DbName If @LogBackupPath IS NULL -- toujours null Begin If DatabasePropertyEx(@DbName, 'Recovery') = 'Simple' Set @LogBackupPath = @FullBackupPath Else Begin raiserror('No maintenance done yet on this database, parameter @LogBackupPath is then mandatory',11,1) return End End If isnull(@MirrorServer, '') = '' Select @MirrorServer = MirrorServer , @MigrationTestMode = MigrationTestMode , @ReplaceSrcBkpPathToMatchingMirrorPath = ReplaceSrcBkpPathToMatchingMirrorPath , @ReplacePathsInDbFileNames = ReplacePathsInDbFilenames From Maint.JobLastBkpLocations Where dbName = @DbName Set @oper = isnull(@oper, 'YourSQLDba_Operator') Exec Maint.YourSqlDba_DoMaint @oper = @oper , @command = @command , @MaintJobName = @nomTache , @DoBackup = @DoBackup , @FullBackupPath = @FullBackupPath , @LogBackupPath = @LogBackupPath , @IncDb = @DbName , @ConsecutiveDaysOfFailedBackupsToPutDbOffline = 9999 -- doesn't apply here , @MirrorServer = @MirrorServer , @MigrationTestMode = @MigrationTestMode , @ReplaceSrcBkpPathToMatchingMirrorPath = @ReplaceSrcBkpPathToMatchingMirrorPath , @ReplacePathsInDbFileNames = @ReplacePathsInDbFileNames , @ExcDbFromPolicy_CheckFullRecoveryModel = '%' , @EncryptionAlgorithm = @EncryptionAlgorithm , @EncryptionCertificate = @EncryptionCertificate End -- Maint.SaveDbOnNewFileSet GO Exec yUtl.DropObj 'Maint.SaveDbCopyOnly' GO Create proc Maint.SaveDbCopyOnly @DbName nvarchar(512) , @PathAndFilename nvarchar(512) -- complete file name and path must be specified , @errorN int = 0 output With Execute as Self As Begin Declare @sql nvarchar(max) Declare @cmd nvarchar(1000) Set nocount on -- Exécuter backup with initial login EXECUTE AS LOGIN = ORIGINAL_LOGIN(); Print '----------------------------------------------------------' Print 'Saving Of ' + @DbName + ' to ' + @PathAndFilename Print '----------------------------------------------------------' Print '' Set @sql = ' BACKUP DATABASE [] TO DISK ="" WITH stats=1, INIT, format, COPY_ONLY, NAME = "SaveDbCopyOnly: " ' Set @sql = Replace( @sql, '', @DbName ) Set @sql = Replace( @sql, '', @PathAndFilename ) Set @sql = Replace( @sql, '"', '''' ) Set @sql = yExecNLog.Unindent_TSQL(@sql) Print @sql Print '' Exec (@sql) Set @errorN = @@error -- Revenir à l'impersonification de la Stored Procedure REVERT End -- Maint.SaveDbCopyOnly GO Exec yUtl.DropObj 'Maint.duplicateDb' GO Create proc Maint.duplicateDb @sourceDb nvarchar(512) , @TargetDb nvarchar(512) , @PathAndFilename nvarchar(512) = NULL -- complete name including path otherwise use last backup location + @TargetDb + '.bak' , @KeepBackupFile bit = 0 -- by default destroy intermediate backup file, otherwise specify 1 to keep it With Execute as Self as Begin Declare @sql nvarchar(max) Declare @AlterLogicalFiles nvarchar(max) Declare @cmd nvarchar(1000) Declare @FullBackupPath nvarchar(512) Declare @NoSeq int Declare @name sysname Declare @separateur int Declare @physical_name nvarchar(260) Declare @ClauseMove nvarchar(max) Declare @BackupErr int Set nocount on If @PathAndFilename is NULL Begin Select @FullBackupPath = yUtl.GetPathFromName(lastFullBkpFile) From Maint.JobLastBkpLocations Where dbName = @sourceDb If @FullBackupPath IS NULL Begin raiserror('No maintenance has been done yet on this database, complete @PathAndFilename parameter',11,1) return End Set @PathAndFilename = @FullBackupPath + @TargetDb + '.Bak' End Exec Maint.SaveDbCopyOnly @DbName=@sourceDb, @PathAndFilename=@PathAndFilename, @errorN = @BackupErr output Print '' -- Stop processing it any backup error If @BackupErr <> 0 Return Create Table #dbfiles( noseq int, name sysname, physical_name nvarchar(260), separateur int) -- Set @sql = ' Use Insert Into #dbfiles (noseq, name, physical_name, separateur ) Select ROW_NUMBER() OVER(ORDER BY name), name , physical_name , Charindex("\", Reverse(physical_name)) FROM [].sys.database_files ' Set @sql = replace(@sql, '"', '''') Set @sql = replace(@sql, '', @sourceDb) Set @sql = yExecNLog.Unindent_TSQL(@sql) Exec (@sql) Print '----------------------------------------------------------------------------------------------------' Print 'Database ' + @TargetDb + ' is created from ' + @PathAndFilename Print '----------------------------------------------------------------------------------------------------' Print '' Set @AlterLogicalFiles = '' -- Generate restore command Set @sql = 'RESTORE DATABASE [] FROM DISK="" WITH stats=1,REPLACE ' Set @NoSeq = 1 While 1=1 Begin Select @name=name, @physical_name=physical_name, @separateur=separateur From #dbfiles Where noseq = @NoSeq If @@rowcount = 0 break Set @ClauseMove = ', MOVE "" TO ""' Set @ClauseMove = Replace( @ClauseMove, '', @name ) Set @ClauseMove = Replace( @ClauseMove, '', Left(@physical_name, len(@physical_name) - @separateur) ) Set @ClauseMove = Replace( @ClauseMove, '' , Replace( Right(@physical_name, @separateur), @sourceDb, @TargetDb )) Set @sql = Replace(@sql, '', @ClauseMove + nchar(13) + nchar(10) + '') If Replace(@name, @sourceDb, @TargetDb) <> @name Begin Set @AlterLogicalFiles = @AlterLogicalFiles + ' ALTER DATABASE [] MODIFY FILE (NAME="", NEWNAME="")' + nchar(13) + nchar(10) Set @AlterLogicalFiles = replace (@AlterLogicalFiles, '', @TargetDb) Set @AlterLogicalFiles = replace (@AlterLogicalFiles, '', @name) Set @AlterLogicalFiles = replace (@AlterLogicalFiles, '', Replace(@name, @sourceDb, @TargetDb) ) End Set @NoSeq = @NoSeq + 1 End Drop Table #dbfiles Set @sql = Replace(@sql, '', '') Set @sql = replace (@sql, '"', '''') Set @sql = replace (@sql, '', @TargetDb) Set @sql = replace (@sql, '', @PathAndFilename) Set @sql = yExecNLog.Unindent_TSQL(@sql) Set @AlterLogicalFiles = replace (@AlterLogicalFiles, '"', '''') Set @AlterLogicalFiles = yExecNLog.Unindent_TSQL(@AlterLogicalFiles) -- Execute restore with original login permission EXECUTE AS LOGIN = ORIGINAL_LOGIN(); Print @sql Exec (@sql) Print '' If Len(@AlterLogicalFiles) > 0 Begin Print @AlterLogicalFiles Exec (@AlterLogicalFiles) End REVERT If @KeepBackupFile = 0 Begin Print '' Print '----------------------------------------------------------' Print 'Deleting database backup file ' + @PathAndFilename Print '----------------------------------------------------------' Print '' Declare @err nvarchar(4000) Exec yUtl.Clr_DeleteFile @PathAndFilename, @Err output If @err is not NULL Print @err End End -- Maint.duplicateDb GO If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'Maint.duplicateDbFromBackupHistory' GO Create proc Maint.duplicateDbFromBackupHistory @SourceDb nvarchar(512) , @TargetDb nvarchar(512) , @DoLogBackup int = 1 , @RestoreToSimpleRecoveryModel int = 1 With Execute as Self as Begin Declare @sql nvarchar(max) Declare @AlterLogicalFiles nvarchar(max) Declare @cmd nvarchar(1000) Declare @lastFullBkpFile nvarchar(512) Declare @lastLogBkpFile nvarchar(512) Declare @NoSeq int Declare @name sysname Declare @separateur int Declare @physical_name nvarchar(260) Declare @ClauseMove nvarchar(max) Declare @RestoreLog nvarchar(max) Declare @position smallint Declare @LogBkpFile nvarchar(512) Declare @MediaSetId int Declare @EncryptionAlgorithm nvarchar(10) Declare @EncryptionCertificate nvarchar(100) Set nocount on Select @lastFullBkpFile = lastFullBkpFile , @lastLogBkpFile = lastLogBkpFile , @EncryptionAlgorithm = EncryptionAlgorithm , @EncryptionCertificate = EncryptionCertificate From Maint.JobLastBkpLocations Where dbName = @SourceDb If @SourceDb = @TargetDb Begin raiserror('@SourceDb and @TargetDb can''t be the same',11,1) return End If IsNull(@lastLogBkpFile, '') = '' Begin raiserror('No log backups has been done yet on this database. Use «DuplicateDb» stored procedure to Duplicate this database',11,1) return End -- If sprecified do a last log backup for the database If @DoLogBackup = 1 Begin Print '----------------------------------------------------------------------------------------------------' Print 'Doing a log backup on source database « ' + @SourceDb + '» to have the most up to date data' Print '----------------------------------------------------------------------------------------------------' Print '' Set @sql = yMaint.MakeBackupCmd( @SourceDb, 'L', @lastLogBkpFile, 0, Null, @EncryptionAlgorithm, @EncryptionCertificate) Exec(@sql) End Create Table #dbfiles( noseq int, name sysname, physical_name nvarchar(260), separateur int) -- Set @sql = ' Use Insert Into #dbfiles (noseq, name, physical_name, separateur ) Select ROW_NUMBER() OVER(ORDER BY name), name , physical_name , Charindex("\", Reverse(physical_name)) FROM [].sys.database_files ' Set @sql = replace(@sql, '"', '''') Set @sql = replace(@sql, '', @sourceDb) Set @sql = yExecNLog.Unindent_TSQL(@sql) Exec (@sql) Print '----------------------------------------------------------------------------------------------------' Print 'Database ' + @TargetDb + ' is created from ' + @SourceDb + ' backup chain' Print '----------------------------------------------------------------------------------------------------' Print '' Set @AlterLogicalFiles = '' -- Generate restore command Set @sql = 'RESTORE DATABASE [] FROM DISK="" WITH stats=1,REPLACE,NORECOVERY Restore Log [] With Recovery ' Set @NoSeq = 1 While 1=1 Begin Select @name=name, @physical_name=physical_name, @separateur=separateur From #dbfiles Where noseq = @NoSeq If @@rowcount = 0 break Set @ClauseMove = ', MOVE "" TO ""' Set @ClauseMove = Replace( @ClauseMove, '', @name ) Set @ClauseMove = Replace( @ClauseMove, '' , Left(@physical_name, len(@physical_name) - @separateur) ) Set @ClauseMove = Replace( @ClauseMove, '' , Replace( Right(@physical_name, @separateur), @sourceDb, @TargetDb )) Set @sql = Replace(@sql, '', @ClauseMove + nchar(13) + nchar(10) + '') If Replace(@name, @sourceDb, @TargetDb) <> @name Begin Set @AlterLogicalFiles = @AlterLogicalFiles + ' ALTER DATABASE [] MODIFY FILE (NAME="", NEWNAME="")' + nchar(13) + nchar(10) Set @AlterLogicalFiles = replace (@AlterLogicalFiles, '', @TargetDb) Set @AlterLogicalFiles = replace (@AlterLogicalFiles, '', @name) Set @AlterLogicalFiles = replace ( @AlterLogicalFiles, '' , Replace(@name, @sourceDb, @TargetDb) ) End Set @NoSeq = @NoSeq + 1 End -- Find all log backups associated with the full backup Set @MediaSetId = 0 While 1=1 Begin Select Top 1 @MediaSetId= bm.media_set_id, @LogBkpFile = bm.physical_device_name From ( Select bs.database_name, bs.first_lsn From YourSQLDba.Maint.JobLastBkpLocations lb join msdb.dbo.backupset bs on bs.database_name = lb.dbName collate database_default And RIGHT( bs.name, Len(lb.lastFullBkpFile)) = lb.lastFullBkpFile collate database_default Where lb.lastFullBkpFile = @lastFullBkpFile And (bs.name like 'YourSqlDba%' or bs.name like 'SaveDbOnNewFileSet%') And bs.type = 'D' ) X Join msdb.dbo.backupset bs On bs.database_name = X.database_name And bs.database_backup_lsn = X.first_lsn Join msdb.dbo.backupmediafamily bm On bm.media_set_id = bs.media_set_id Where bs.type = 'L' And bm.media_set_id > @MediaSetId If @@ROWCOUNT = 0 Break -- Generate instruction to restore all logs backups of this database -- if any error they are displayed from the called proc with a raiserror Declare @rc int Exec @rc=yMaint.CollectBackupHeaderInfoFromBackupFile @LogBkpFile If @rc <> 0 Return -- Restore all log backups Set @position = 0 while 1=1 Begin Select Top 1 @position = Position From Maint.TemporaryBackupHeaderInfo Where spid = @@spid And BackupType = 2 And Position > @position Order by Position If @@rowcount= 0 break Set @RestoreLog = 'Restore Log [] From Disk="" With FILE=, NoRecovery' Set @RestoreLog = Replace(@RestoreLog, '', @TargetDb) Set @RestoreLog = Replace(@RestoreLog, '', @LogBkpFile) Set @RestoreLog = Replace(@RestoreLog, '', Convert(nvarchar(255), @position)) Set @Sql = replace(@Sql, '', @RestoreLog + Char(13) + Char(10) + '' ) End End Drop Table #dbfiles Set @sql = replace(@sql, '', '') Set @sql = Replace(@sql, '', '') Set @sql = replace (@sql, '"', '''') Set @sql = replace (@sql, '', @TargetDb) Set @sql = replace (@sql, '', @lastFullBkpFile) Set @sql = yExecNLog.Unindent_TSQL(@sql) Set @AlterLogicalFiles = replace (@AlterLogicalFiles, '"', '''') Set @AlterLogicalFiles = yExecNLog.Unindent_TSQL(@AlterLogicalFiles) -- Execute restore with original login permission EXECUTE AS LOGIN = ORIGINAL_LOGIN(); Begin Try --Print @sql Exec (@sql) End Try Begin Catch Declare @Info nvarchar(max) Set @Info = 'Error_no: '+ Convert(varchar(10), ERROR_NUMBER())+','+ 'Severity: '+ Convert(varchar(10), ERROR_SEVERITY())+','+ 'Status: '+ Convert(varchar(10), ERROR_STATE())+','+ 'LineNo: '+ Convert(varchar(10), ERROR_LINE())+','+ 'Msg: '+ ERROR_MESSAGE() raiserror(@Info,11,1) return End Catch REVERT Print '' If Len(@AlterLogicalFiles) > 0 Begin --Print @AlterLogicalFiles Exec (@AlterLogicalFiles) End -- Ensure database is in SIMPLE recovery model if parameter @RestoreToSimpleRecoveryModel is set to 1 If @RestoreToSimpleRecoveryModel = 1 Begin Set @sql = 'ALTER DATABASE [] SET RECOVERY SIMPLE' Set @sql = REPLACE(@sql, '', @TargetDb) Exec (@sql) End End -- Maint.duplicateDbFromBackupHistory GO If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'Maint.RestoreDb' GO Create proc Maint.RestoreDb @TargetDb nvarchar(512) -- database name to restore , @PathAndFilename nvarchar(512) -- complete file and path name must be given , @ReplaceExistingDb int = 0 -- set to 1 to overwrite existing database «REPLACE option» With Execute as Self as Begin If exists (select * from master.sys.databases where name = @TargetDb) and @ReplaceExistingDb = 0 begin Print 'Database ' + @TargetDb Print 'already exists and you did not allow to replace it with parameter @ReplaceExistingDb' Print 'Restore action is cancelled' Return end Declare @pathData nvarchar(512) Declare @pathLog nvarchar(512) Declare @FileType char(1) Declare @sql nvarchar(max) Declare @FileId int Declare @NoSeq int Declare @LogicalName sysname Declare @PhysicalName sysname Declare @DbName sysname Declare @NewPhysicalName sysname Declare @ClauseMove nvarchar(max) Declare @AlterLogicalFiles nvarchar(max) declare @rc int Set nocount on -- get default data and log location Exec master.dbo.xp_instance_regread N'HKEY_LOCAL_MACHINE' , N'Software\Microsoft\MSSQLServer\MSSQLServer' , N'DefaultData' , @pathData OUTPUT Exec master.dbo.xp_instance_regread N'HKEY_LOCAL_MACHINE' , N'Software\Microsoft\MSSQLServer\MSSQLServer' , N'DefaultLog' , @pathLog OUTPUT -- if default data and log location is not specified in server properties, Use master database file location If @pathData Is Null Select Top 1 @pathData = Left( physical_name, Len(physical_name) - Charindex('\', Reverse(physical_name))) FROM master.sys.database_files Where type = 0 If @pathLog Is Null Select Top 1 @pathLog = Left( physical_name, Len(physical_name) - Charindex('\', Reverse(physical_name))) FROM master.sys.database_files Where type = 1 -- recover database name from datase backup file -- if there is any errors thay are displayed from CollectBackupHeaderInfoFromBackupFile with a raiserrpr Exec @rc=yMaint.CollectBackupHeaderInfoFromBackupFile @PathAndFilename If @rc <> 0 Return Select @DbName = DatabaseName From Maint.TemporaryBackupHeaderInfo Where spid = @@spid Exec @rc=yMaint.CollectBackupFileListFromBackupFile @PathAndFilename If @rc <> 0 Return Print '----------------------------------------------------------------------------------------------------' Print 'Database ' + @TargetDb + ' is created from ' + @PathAndFilename Print '----------------------------------------------------------------------------------------------------' Print '' Set @AlterLogicalFiles = '' -- Generate restore command Set @sql = 'RESTORE DATABASE [] FROM DISK="" WITH ' Set @FileId = -1 Set @NoSeq = 0 While 1=1 Begin Select Top 1 @FileType = Type , @FileId = FileId , @LogicalName=LogicalName , @PhysicalName=RIGHT(PhysicalName, Charindex('\', Reverse(PhysicalName)) - 1) From Maint.TemporaryBackupFileListInfo Where Spid = @@spid And FileId > @FileId Order by spid, FileId If @@rowcount = 0 break Set @ClauseMove = 'MOVE "" TO "\"' Set @ClauseMove = Replace( @ClauseMove, '', @LogicalName ) If Replace(@LogicalName, @DbName, @TargetDb) <> @LogicalName Begin Set @AlterLogicalFiles = @AlterLogicalFiles + ' ALTER DATABASE [] MODIFY FILE (NAME="", NEWNAME="")' + nchar(13) + nchar(10) Set @AlterLogicalFiles = replace (@AlterLogicalFiles, '', @TargetDb) Set @AlterLogicalFiles = replace (@AlterLogicalFiles, '', @LogicalName) Set @AlterLogicalFiles = replace ( @AlterLogicalFiles , '' , Replace(@LogicalName, @DbName, @TargetDb) ) End -- Try only a replace of the old database name by the new database name -- in filename on disk. If it doesn't work we will have no choice to generate distinct names If Charindex(@DbName, @PhysicalName) > 0 Begin Set @ClauseMove = Replace( @ClauseMove , '' , Case When @FileType = 'L' Then @pathLog Else @pathData End ) Set @ClauseMove = Replace( @ClauseMove , '' , Replace(@PhysicalName, @DbName, @TargetDb) ) End Else Begin -- Log file name will be renamed by database name followed by «_Log.ldf» If @FileType = 'L' Begin Set @ClauseMove = Replace( @ClauseMove, '', @pathLog ) Set @ClauseMove = Replace( @ClauseMove, '', @TargetDb + '_Log.ldf' ) End -- Data file name are named from database name -- A sequential number is added for databases that have many file name If @FileType = 'D' Begin Set @ClauseMove = Replace( @ClauseMove, '', @pathData ) If @NoSeq = 0 Set @ClauseMove = Replace( @ClauseMove, '', @TargetDb + '.mdf' ) Else Set @ClauseMove = Replace( @ClauseMove , '' , @TargetDb + convert(nvarchar, @NoSeq) + '.ndf') Set @NoSeq = @NoSeq + 1 End -- Catalog file for full text search are named from database name -- with extension «.FtCatalog» plus a sequential number If @FileType = 'F' Begin Set @ClauseMove = Replace( @ClauseMove, '', @pathData ) Set @ClauseMove = Replace( @ClauseMove , '' , @TargetDb + '.FTCatalog' + convert(nvarchar, @NoSeq) ) Set @NoSeq = @NoSeq + 1 End End Set @sql = Replace( @sql , '' , @ClauseMove + nchar(13) + nchar(10) + ',') End Set @sql = Replace(@sql, ',', '') Set @sql = replace (@sql, '"', '''') Set @sql = replace (@sql, '', @TargetDb) Set @sql = replace (@sql, '', @PathAndFilename) Set @sql = replace ( @sql , '' , Case When @ReplaceExistingDb = 1 Then ', REPLACE' Else '' End ) Set @sql = yExecNLog.Unindent_TSQL(@sql) Set @AlterLogicalFiles = replace (@AlterLogicalFiles, '"', '''') Set @AlterLogicalFiles = yExecNLog.Unindent_TSQL(@AlterLogicalFiles) -- Execute a Restore with original login's permissions EXECUTE AS LOGIN = ORIGINAL_LOGIN(); Print @sql Exec (@sql) Print '' If Len(@AlterLogicalFiles) > 0 Begin Print @AlterLogicalFiles Exec (@AlterLogicalFiles) End REVERT End -- Maint.RestoreDb GO ALTER DATABASE YourSQLDba Set Trustworthy on GO GRANT connect to guest GO grant execute on Maint.SaveDbOnNewFileSet to guest GO grant execute on Maint.SaveDbCopyOnly to guest GO grant execute on Maint.DuplicateDb to guest GO grant execute on Maint.DuplicateDbFromBackupHistory to guest GO grant execute on Maint.RestoreDb to guest GO -- some tests --Exec Maint.SaveDbOnNewFileSet -- @DbName = 'RegardMaurice' --, @FullBackupPath = null --, @LogBackupPath = null GO -- ------------------------------------------------------------------------------ -- Procedure to visualize last statement running or ran -- ------------------------------------------------------------------------------ If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yUtl.TextSplitInRows' GO create FUNCTION yUtl.TextSplitInRows ( @sql nvarchar(max) ) RETURNS @TxtSql TABLE (i int identity, txt nvarchar(max)) AS Begin declare @i int, @d Datetime If @i > 0 Insert into @txtSql (txt) values ('-- Seq:'+ltrim(str(@i))+ ' Time:'+convert(nvarchar(20), @d, 120) + ' ' + replicate('-', 10) ) If @sql is null Or @sql = '' Begin Insert into @txtSql (txt) values ('') return End declare @Start int, @End Int, @line nvarchar(max), @EOLChars int Set @Start = 1 Set @End=0 While(@End < len(@sql)) Begin ;With NearestEndOfLines as ( Select charindex(nchar(13)+nchar(10), @sql, @Start) as EOLPos, 2 as EOLChars union All Select charindex(nchar(13), @sql, @Start) as EOLPos, 1 as EOLChars union All Select charindex(nchar(10), @sql, @Start) as EOLPos, 1 as EOLChars ) Select top 1 @End = Case When EOLPos > 0 Then EOLPos Else LEN(@Sql) End -- End of String @Sql , @EOLChars = Case When EOLPos > 0 Then EOLChars Else 1 End -- EOL length From NearestEndOfLines Order by EOLPos, EolChars Desc -- get nearest EndOfLines Set @line = Substring(@sql, @Start, @End-@Start+@EOLChars) Set @Start = @End+@EOLChars Insert into @txtSql (txt) values (replace (replace (@line, nchar(10), ''), nchar(13), '')) End RETURN End -- yUtl.TextSplitInRows GO -- --------------------------------------------------------------------------------------- -- Procedure to show maintenance log history -- --------------------------------------------------------------------------------------- If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'Maint.ShowHistory' GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO create proc Maint.ShowHistory @JobNo Int = NULL , @FilterErr Int = 0 , @DispLimit Int = NULL , @Diag int = 0 as Begin Print 'this proc is deprecated, use HistoryView' End -- Maint.ShowHistory GO --------------------------------------------------------------------------------------------- If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'Install.AddOrReplaceMaintenance' GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO create proc Install.AddOrReplaceMaintenance @JobNameSuffix nvarchar(512) = '' , @FullBackupPath nvarchar(512) , @LogBackupPath nvarchar(512) , @ConsecutiveDaysOfFailedBackupsToPutDbOffline Int , @FullMaintenanceScript Nvarchar(max) = NULL Output , @LogBackupScript Nvarchar(max) = NULL Output As --Declare @FullBackupPath nvarchar(512) --Set @FullBackupPath = 'C:\SQL2005Backups\' -- Begin --------------------------------------------------------------------------------------- -- Setup of 2 maintenance tasks --------------------------------------------------------------------------------------- Declare @nomJob Sysname If right(@FullBackupPath, 1)<>'\' Set @FullBackupPath = @FullBackupPath + '\' If right(@LogBackupPath, 1)<>'\' Set @LogBackupPath = @LogBackupPath + '\' Declare @JobLogFile sysname Set @JobLogFile = @FullBackupPath + 'MaintenanceReport.txt' Declare @svrName nvarchar(30) set @svrName = convert(nvarchar(30), serverproperty('servername')) Select @svrname Declare @sql nvarchar(max) DECLARE @jobId uniqueidentifier set @jobId = NULL Set @nomJob = N'YourSQLDba_FullBackups_And_Maintenance'+ISNULL(@JobNameSuffix, '') Declare @operator sysname Select @jobId = job_Id, @operator = OP.name from msdb.dbo.sysjobs J left join msdb.dbo.sysoperators OP On Op.Id = notify_email_operator_id where J.name = @nomJob If @@rowcount = 0 Begin if @operator is NULL Set @operator = 'YourSQLDba_Operator' Print 'Adding job maintenance task '+@nomJob EXEC msdb.dbo.sp_add_job @job_name = @nomJob, @enabled = 1, @notify_level_eventlog = 0, @notify_level_email = 2, @notify_email_operator_name = @operator, @notify_level_netsEnd = 2, @notify_level_page = 2, @delete_level = 0, @description = N'Maintenance: Integrity tests, update statistics, index reorg, Full backups', @category_name = N'Database Maintenance', @owner_login_name = N'YourSQLDba', @job_id = @jobId OUTPUT Print 'Maintenance server parameter setup ' exec msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = @svrName End Else Begin if @operator is NULL Set @operator = 'YourSQLDba_Operator' Print 'Updating job maintenance task '+@nomJob EXEC msdb.dbo.sp_update_job @job_name = @nomJob, @enabled = 1, @notify_level_eventlog = 0, @notify_level_email = 2, @notify_email_operator_name = @operator, @notify_level_netsEnd = 2, @notify_level_page = 2, @delete_level = 0, @description = N'Maintenance: Integrity tests, update statistics, index reorg, Full backups', @category_name = N'Database Maintenance', @owner_login_name = N'YourSQLDba' End set @sql = N' exec Maint.YourSqlDba_DoMaint @oper = "" , @MaintJobName = "YourSQLDba: DoInteg,DoUpdateStats,DoReorg,Full backups" , @DoInteg = 1 , @DoUpdStats = 1 , @DoReorg = 1 , @DoBackup = "F" , @FullBackupPath = "" , @LogBackupPath = "" -- Flush database backups older than the number of days , @FullBkpRetDays = 0 -- Flush log backups older than the number of days , @LogBkpRetDays = 8 -- Spread Update Stats over 7 days , @SpreadUpdStatRun = 7 -- Spread Check DB without "PHYSICAL_ONLY" over 7 days , @SpreadCheckDb = 7 -- Maximum number of consecutive days of failed full backups allowed -- for a database before putting that database (Offline). , @ConsecutiveDaysOfFailedBackupsToPutDbOffline = -- Each database inclusion filter must be on its own line between the following quote pair , @IncDb = " " -- Each database exclusion filter must be on its own line between the following quote pair , @ExcDb = " " -- Each database exclusion filter must be on its own line between the following quote pair -- exclusion here applies to DB for which we dont''t want to check the recovery model , @ExcDbFromPolicy_CheckFullRecoveryModel = " " , @EncryptionAlgorithm = "" , @EncryptionCertificate = "" ' Set @sql = replace (@sql, '"', '''') Set @sql = replace (@sql, '', @FullBackupPath) Set @sql = replace (@sql, '', @LogBackupPath) Set @sql = replace (@sql, '', @operator) Set @sql = replace ( @sql , '' , convert(nvarchar(10),@ConsecutiveDaysOfFailedBackupsToPutDbOffline)) Set @sql = yExecNLog.Unindent_TSQL(@sql) Set @FullMaintenanceScript = @Sql Declare @step_name sysname Declare @on_success_action int Declare @on_success_step_id int Declare @on_fail_action int Declare @on_fail_step_id int Declare @step_id Int Declare @schedule_id int Set @step_name = N'Exec YourSQLDba: Maintenance and Full Backups' If Not Exists(select * from msdb.dbo.sysjobsteps where job_Id = @jobId And step_name = @step_name) Begin Print 'Step Add '+@step_name EXEC msdb.dbo.sp_add_jobstep @job_name = @nomJob, @step_name = @step_name , @step_id = 1, @cmdexec_success_code = 0, @on_success_action = 1, @on_fail_action = 2, @retry_attempts = 0, @retry_interval = 0, @os_run_priority = 0, @subsystem = N'TSQL', @command = @sql, @database_name = N'YourSQLDba', @output_file_name = @JobLogFile , @flags = 0 -- overwrite log file End Else Begin Print 'Step Update '+@step_name select @step_id = step_id , @on_success_action = on_success_action , @on_fail_action = on_fail_action , @on_success_step_id = on_success_step_id , @on_fail_Step_id = on_fail_Step_id from msdb.dbo.sysjobsteps where job_Id = @jobId And step_name = @step_name EXEC msdb.dbo.sp_update_jobstep @job_name = @nomJob, @step_name = @step_name , @step_id = @step_id, @cmdexec_success_code = 0, @on_success_action = @on_success_action, @on_success_step_id = @on_success_step_id, @on_fail_action = @on_fail_action, @on_fail_Step_id = @on_fail_Step_id, @retry_attempts = 0, @retry_interval = 0, @os_run_priority = 0, @subsystem = N'TSQL', @command = @sql, @database_name = N'YourSQLDba', @output_file_name = @JobLogFile , @flags = 0 -- overwrite log file End Declare @schedule_name sysname Set @schedule_name = N'Schedule for Maintenance and full backups' Set @schedule_id = NULL Select @schedule_id = s.schedule_id From msdb.dbo.sysschedules s Join msdb.dbo.sysjobschedules js On s.schedule_id = js.schedule_id And js.job_id = @jobId Where name = @schedule_name If @schedule_id Is Null Begin Declare @startDate Int = convert(int,Convert(nvarchar, getdate()+1, 112)) Print 'Adding Schedule '+ @schedule_name Exec msdb.dbo.sp_add_schedule @schedule_name = @schedule_name , @enabled = 1 , @freq_type = 8 , @freq_interval = 127 , @freq_subday_type = 1 , @freq_subday_interval = 0 , @freq_relative_interval = 0 , @freq_recurrence_factor = 1 , @active_start_date = @startDate , @active_end_date = 99991231 , @active_start_time = 000000 , @active_end_time = 235959 , @owner_login_name = 'YourSQLDba' , @schedule_id = @schedule_id OUTPUT EXEC msdb.dbo.sp_attach_schedule @job_name = @nomJob , @schedule_id = @schedule_id End Else Begin Print 'Schedule update '+ @schedule_name Exec msdb.dbo.sp_update_schedule @schedule_id = @schedule_id , @enabled = 1 , @freq_type = 8 , @freq_interval = 127 , @freq_subday_type = 1 , @freq_subday_interval = 0 , @freq_relative_interval = 0 , @freq_recurrence_factor = 1 , @active_start_date = NULL , @active_end_date = 99991231 , @active_start_time = 000000 , @active_end_time = 235959 , @owner_login_name = 'YourSQLDba' End -- --------------------------------------------------------------------------------------------------- set @jobId = NULL Set @nomJob = N'YourSQLDba_LogBackups'+ISNULL(@JobNameSuffix, '') Select @jobId = job_Id, @operator = OP.name from msdb.dbo.sysjobs J left join msdb.dbo.sysoperators OP On Op.Id = notify_email_operator_id where J.name = @nomJob If @@rowcount = 0 Begin if @operator is NULL Set @operator = 'YourSQLDba_Operator' Print 'Adding job maintenance task '+@nomJob EXEC msdb.dbo.sp_add_job @job_name = @nomJob, @enabled = 1, @notify_level_eventlog = 0, @notify_level_email = 2, @notify_email_operator_name = @operator, @notify_level_netsEnd = 2, @notify_level_page = 2, @delete_level = 0, @description = N'Log backups', @category_name = N'Database Maintenance', @owner_login_name = N'YourSQLDba', @job_id = @jobId OUTPUT Print 'Maintenance task''s server parameter setup '+@nomJob exec msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = @svrName End Else Begin if @operator is NULL Set @operator = 'YourSQLDba_Operator' Print 'Updating job maintenance task '+@nomJob EXEC msdb.dbo.sp_update_job @job_name = @nomJob, @enabled = 1, @notify_level_eventlog = 0, @notify_level_email = 2, @notify_email_operator_name = @operator, @notify_level_netsEnd = 2, @notify_level_page = 2, @delete_level = 0, @description = N'Log backups', @category_name = N'Database Maintenance', @owner_login_name = N'YourSQLDba' End set @sql = N' exec Maint.YourSqlDba_DoMaint @oper = "" , @MaintJobName = ''Log backups'' , @DoBackup = ''L'' , @FullBackupPath = "" , @LogBackupPath = "" -- Specify to user that full database backups are mandatory before log backups , @NotifyMandatoryFullDbBkpBeforeLogBkp = 1 , @BkpLogsOnSameFile = 1 -- Each database inclusion filter must be on its own line between the following quote pair , @IncDb = " " -- Each database exclusion filter must be on its own line between the following quote pair , @ExcDb = " " , @EncryptionAlgorithm = "" , @EncryptionCertificate = "" ' Set @sql = replace (@sql, '"', '''') Set @sql = replace (@sql, '', @FullBackupPath) Set @sql = replace (@sql, '', @LogBackupPath) Set @sql = replace (@sql, '', @operator) Set @sql = yExecNLog.Unindent_TSQL(@sql) Set @LogBackupScript = @Sql Set @step_name = N'Exec YourSQLDba_DoMaint Log Backups' If Not Exists(select * from msdb.dbo.sysjobsteps where job_Id = @jobId And step_name = @step_name) Begin Print 'Step Add '+@step_name EXEC msdb.dbo.sp_add_jobstep @job_name = @nomJob, @step_name = @step_Name, @step_id = 1, @cmdexec_success_code = 0, @on_success_action = 1, @on_fail_action = 2, @retry_attempts = 0, @retry_interval = 0, @os_run_priority = 0, @subsystem = N'TSQL', @command = @sql, @database_name = N'YourSQLDba', @output_file_name = @JobLogFile , @flags = 2 -- append to the log file End Else Begin Print 'Step Update '+@step_name select @step_id = step_id , @on_success_action = on_success_action , @on_fail_action = on_fail_action , @on_success_step_id = on_success_step_id , @on_fail_Step_id = on_fail_Step_id from msdb.dbo.sysjobsteps where job_Id = @jobId And step_name = @step_name EXEC msdb.dbo.sp_update_jobstep @job_name = @nomJob, @step_name = @step_name , @step_id = @step_id, @cmdexec_success_code = 0, @on_success_action = @on_success_action, @on_success_step_id = @on_success_step_id, @on_fail_action = @on_fail_action, @on_fail_Step_id = @on_fail_Step_id, @retry_attempts = 0, @retry_interval = 0, @os_run_priority = 0, @subsystem = N'TSQL', @command = @sql, @database_name = N'YourSQLDba', @output_file_name = @JobLogFile , @flags = 2 -- append output to previous job step End Set @schedule_name = N'Schedule for Log backups' Set @schedule_id = NULL Select @schedule_id = s.schedule_id From msdb.dbo.sysschedules s Join msdb.dbo.sysjobschedules js On s.schedule_id = js.schedule_id And js.job_id = @jobId Where name = @schedule_name If @schedule_id Is Null Begin Print 'Adding Schedule '+ @schedule_name Exec msdb.dbo.sp_add_schedule @schedule_name = @schedule_name , @enabled = 1 , @freq_type = 8 , @freq_interval = 127 , @freq_subday_type = 4 , @freq_subday_interval = 15 , @freq_relative_interval = 0 , @freq_recurrence_factor = 1 , @active_start_date = NULL , @active_end_date = 99991231 , @active_start_time = 001000 , @active_end_time = 235959 , @owner_login_name = 'YourSQLDba' , @schedule_id = @schedule_id OUTPUT EXEC msdb.dbo.sp_attach_schedule @job_name = @nomJob , @schedule_id = @schedule_id End Else Begin Print 'Schedule update '+ @schedule_name Exec msdb.dbo.sp_Update_schedule @schedule_id = @schedule_id , @enabled = 1 , @freq_type = 8 , @freq_interval = 127 , @freq_subday_type = 4 , @freq_subday_interval = 15 , @freq_relative_interval = 0 , @freq_recurrence_factor = 1 , @active_start_date = NULL , @active_end_date = 99991231 , @active_start_time = 001000 , @active_end_time = 235959 , @owner_login_name = 'YourSQLDba' End End --------------------------------------------------------------------------------------------- -- To be done once when YourSqlDba script is run for the first time on a server --------------------------------------------------------------------------------------------- GO If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'Install.InitialSetupOfYourSqlDba' GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO create proc Install.InitialSetupOfYourSqlDba @FullBackupPath nvarchar(512) = NULL , @LogBackupPath nvarchar(512) = NULL , @email nvarchar(512) , @sourceEmail nvarchar(512) = '' , @SmtpMailServer nvarchar(128) , @SmtpMailPort int = 25 , @SmtpMailEnableSSL bit = 0 , @EmailServerAccount nvarchar(512) = NULL , @EmailServerPassword nvarchar(512) = NULL , @ConsecutiveDaysOfFailedBackupsToPutDbOffline Int , @FullMaintenanceScript nvarchar(max) = '' Output , @LogBackupScript nvarchar(max) = '' Output As --Declare @FullBackupPath nvarchar(512) --Set @FullBackupPath = 'C:\SQL2005Backups\' -- Begin Set nocount on If @ConsecutiveDaysOfFailedBackupsToPutDbOffline < 1 Begin print 'YourSQLDba initial configuration failed' print '' print 'You must read the description of the @ConsecutiveDaysOfFailedBackupsToPutDbOffline' print 'parameter for the InitialSetupOfYourSqlDba procedure in the "YourSQLDba guide".' Return End Declare @oper sysname Set @oper = 'YourSQLDba_Operator' ------------------------------------------------------------- -- database mail setup for YourSQLDba ------------------------------------------------------------- If not Exists ( Select * From sys.configurations Where name = 'show advanced options' And value_in_use = 1 ) Begin EXEC sp_configure 'show advanced options', 1 Reconfigure End -- To enable the feature. If not Exists ( Select * From sys.configurations Where name = 'Database Mail XPs' And value_in_use = 1 ) Begin EXEC sp_configure 'Database Mail XPs', 1 Reconfigure End DECLARE @profile_name sysname , @account_name sysname , @SMTP_servername sysname , @email_address NVARCHAR(128) , @display_name NVARCHAR(128) , @rv INT -- Set profil name here SET @profile_name = 'YourSQLDba_EmailProfile'; SET @account_name = lower(replace(convert(sysname, Serverproperty('servername')), '\', '.')) -- Init email account name If @sourceEmail = '' Begin SET @email_address = lower(@account_name+'@YourSQLDba.com') SET @display_name = lower(convert(sysname, Serverproperty('servername'))+' : YourSQLDba ') End Else Begin SET @email_address = @sourceEmail SET @display_name = @sourceEmail End -- if account exists remove it If Exists (Select * From msdb.dbo.sysmail_account WHERE name = @account_name ) Begin Exec @rv = msdb.dbo.sysmail_delete_account_sp @account_name = @account_name If @rv <> 0 Begin Raiserror('Cannot remove existing database mail account (%s)', 16, 1, @account_Name); return End End; -- if profile exists remove it If Exists (Select * From msdb.dbo.sysmail_profile WHERE name = @profile_name) Begin Exec @rv = msdb.dbo.sysmail_delete_profile_sp @profile_name = @profile_name If @rv <> 0 Begin Raiserror('Cannot remove existing database mail profile (%s)', 16, 1, @profile_name); return End End -- Proceed email config in a single tx to leave nothing inconsistent Begin transaction ; declare @profileId Int -- Add the profile Exec @rv = msdb.dbo.sysmail_add_profile_sp @profile_name = @profile_name If @rv<>0 Begin Raiserror('Failure to create database mail profile (%s).', 16, 1, @profile_Name); Rollback transaction; return End; -- Grant access to the profile to the DBMailUsers role EXECUTE msdb.dbo.sysmail_add_principalprofile_sp @profile_name = @profile_name, @principal_name = 'public', @is_default = 1 ; -- Add the account Exec @rv = msdb.dbo.sysmail_add_account_sp @account_name = @account_name , @email_address = @email_address , @display_name = @display_name , @mailserver_name = @SmtpMailServer , @port = @SmtpMailPort , @enable_ssl = @SmtpMailEnableSSL , @username = @EmailServerAccount , @password = @EmailServerPassword; If @rv<>0 Begin Raiserror('Failure to create database mail account (%s).', 16, 1, @account_Name) ; Rollback transaction; return End -- Associate the account with the profile. Exec @rv = msdb.dbo.sysmail_add_profileaccount_sp @profile_name = @profile_name , @account_name = @account_name , @sequence_number = 1 ; If @rv<>0 Begin Raiserror('Failure when adding account (%s) to profile (%s).', 16, 1, @account_name, @profile_Name) ; Rollback transaction; return End; COMMIT transaction; EXEC msdb.dbo.sp_set_sqlagent_properties @email_save_in_sent_folder = 1 EXEC master.dbo.xp_instance_regwrite N'HKEY_LOCAL_MACHINE' , N'SOFTWARE\Microsoft\MSSQLServer\SQLServerAgent' , N'UseDatabaseMail' , N'REG_DWORD' , 1 EXEC master.dbo.xp_instance_regwrite N'HKEY_LOCAL_MACHINE' , N'SOFTWARE\Microsoft\MSSQLServer\SQLServerAgent' , N'DatabaseMailProfile' , N'REG_SZ' , @profile_Name Declare @NetStop sysname Declare @SqlAgentServiceName sysname Set @SqlAgentServiceName = convert(sysname, Serverproperty('instancename')) If @SqlAgentServiceName IS NOT NULL Set @NetStop = 'Net Stop "SQLAgent$'+@SqlAgentServiceName+'"' Else Set @NetStop = 'Net Stop SQLSERVERAGENT ' Declare @NetStart sysname If @SqlAgentServiceName IS NOT NULL Set @NetStart = 'Net Start "SQLAgent$'+@SqlAgentServiceName+'"' Else Set @NetStart = 'Net Start SQLSERVERAGENT ' -- If XP_cmdshell is activated temporary to restart automatically SQL Agent Exec yMaint.SaveXpCmdShellStateAndAllowItTemporary Begin try -- intercepte erreurs pour être sur que restore va se faire Select 'Review your job parameters if job already existed ' As Msg print @netstop EXEC xp_cmdShell @netStop, 'NO_OUTPUT' print @netstart EXEC xp_cmdShell @netStart, 'NO_OUTPUT' end try begin catch declare @error nvarchar(max) set @error = str(error_number()) + ERROR_MESSAGE () print @error end catch Exec yMaint.RestoreXpCmdShellState DECLARE @retval INT SELECT @retval = 0 while (1=1) Begin EXECUTE master.dbo.xp_sqlagent_is_starting @retval OUTPUT If @retval <> 1 Break print 'SQL Server Agent is starting. InitialSetupOfYourSqlDba is waiting for 1 second.' waitfor delay '00:00:01' end If exists(SELECT * FROM msdb.dbo.sysoperators Where name = @oper) Exec msdb.dbo.sp_delete_operator @name = @oper; Exec msdb.dbo.sp_add_operator @name = @oper, @email_address = @email Declare @pathBkp Nvarchar(512); Exec master.dbo.xp_instance_regread N'HKEY_LOCAL_MACHINE' , N'Software\Microsoft\MSSQLServer\MSSQLServer' , N'BackupDirectory' , @pathBkp OUTPUT , 'no_output' -- prendre répertoire SQL backup par défaut si pas complété Select @FullBackupPath = ISNULL(@FullBackupPath, @pathBkp), @LogBackupPath = ISNULL(@LogBackupPath, @pathBkp) Exec Install.AddOrReplaceMaintenance '', @FullBackupPath, @LogBackupPath, @ConsecutiveDaysOfFailedBackupsToPutDbOffline, @FullMaintenanceScript Output, @LogBackupScript Output Declare @Msg Nvarchar(max) Set @msg = '
Initial setup of YourSqlDba : Review YourSqlDba jobs step


Full maintenance job step:

#FullMaintenanceScript#


Log backups jobs:

#LogBackupScript#
' Set @msg = replace(@Msg, '#FullMaintenanceScript#', replace(replace(@FullMaintenanceScript, nchar(13), ''),nchar(10),'
')) Set @msg = replace(@Msg, '#LogBackupScript#', replace(replace(@LogBackupScript, nchar(13), ''),nchar(10),'
')) EXEC Msdb.dbo.sp_send_dbmail @profile_name = 'YourSQLDba_EmailProfile' , @recipients = @email , @importance = 'High' , @subject = 'YourSqlDba installed' , @body = @Msg , @body_format = 'HTML' End -- Install.InitialSetupOfYourSqlDba GO -- This procedure removes from SQL Server Agent's jobs steps commands strings -- which meets the selection criterias contained in -- @SelectSearchArg and @UnSelectSearchArg, -- the parameter string supplied by the "@prm" parameter. -- The parameter string must begin with a '@' character. -- The removal begins from the '@' character and ends before the next '@' character -- or at the end of the command string in the jobstep. Exec yUtl.DropObj 'yInstall.CleanUpParam' GO Create proc yInstall.CleanUpParam @prm sysname , @SelectSearchArg nvarchar(1000) , @UnSelectSearchArg nvarchar(1000) = '' as Begin Set nocount on declare @sql nvarchar(max) declare @job_id uniqueidentifier declare @step_id int declare @pos int declare @PosDeb int declare @PosFin int While (1=1) -- while there is steps to correct Begin select @job_id=job_id, @step_id=step_id, @sql=command from msdb.dbo.sysjobsteps Where command like @SelectSearchArg And command not like @UnSelectSearchArg And command like '%'+@prm+'[^a-z0-9]%' If @@rowcount = 0 break set @pos = patindex('%'+@prm+'[^a-z0-9]%', @sql) -- assume the first parameter is always valid Set @PosDeb = @pos Set @PosFin = @pos+1 While (substring(@sql, @PosFin,1) <> '@') Begin --print substring(@sql, @PosFin,1) Set @PosFin = @PosFin +1 If @PosFin >= len(@Sql) Break End If substring(@sql, @PosFin,1) = '@' Set @PosFin = @PosFin -1 -- place the end position before the '@' -- if last param remove comma before if necessary If @PosFin >= len(@Sql) Begin While (substring(@sql, @Pos, 1) <> ',') Begin --print substring(@sql, @PosFin,1) Set @Pos = @Pos -1 If @pos = 1 Break End If @pos > 1 Set @PosDeb = @pos End Print '========================== Job step before update ============================' Print @sql Set @sql = Stuff(@sql, @PosDeb, @PosFin - @PosDeb + 1, '') Print '========================== Job step after update ============================' Print @sql Print '======================================================================' Update JS Set command = @sql from msdb.dbo.sysjobsteps JS Where @job_id=job_id and @step_id=step_id End End -- yInstall.CleanUpParam GO Exec yInstall.CleanUpParam @prm = '@genjour' , @SelectSearchArg = '%YourSQLDba%@DoBackup = ''F''%' Exec yInstall.CleanUpParam @prm = '@NotifyMandatoryFullDbBkpBeforeLogBkp' , @SelectSearchArg = '%YourSQLDba%@DoBackup = ''F''%' Exec yInstall.CleanUpParam @prm = '@genjour' , @SelectSearchArg = '%YourSQLDba%@DoBackup = ''L''%' Begin -- remove comments prededing the @jobId parameter from YourSQLDba_DoMaint calls in SQL Server Agent Update JS Set command = replace( command , '-- Agent job number to track step to retrieve step script in maintenance report' , '') from msdb.dbo.sysjobsteps JS Where command like '%YourSQLDba_DoMaint%-- Agent job number to track step to retrieve step script in maintenance report%' -- remove @jobId parameter from YourSQLDba_DoMaint calls in SQL Server Agent Exec yInstall.CleanUpParam @prm = '@jobId' , @SelectSearchArg = '%YourSQLDba_DoMaint%$(ESCAPE_NONE(JOBID))%' End -- remove @jobId parameter and comments from DeleteOldBackups calls in SQL Server Agent Exec yInstall.CleanUpParam @prm = '@jobId' , @SelectSearchArg = '%YourSQLDba.Maint.DeleteOldBackups%@JobId%=%$(ESCAPE_NONE(JOBID))%' Begin -- remove comments prededing the @StepId parameter from YourSQLDba_DoMaint calls in SQL Server Agent Update JS Set command = replace( command , '-- Agent job step number to track step to retrieve step script in maintenance report' , '') from msdb.dbo.sysjobsteps JS Where command like '%%YourSQLDba_DoMaint%-- Agent job step number to track step to retrieve step script in maintenance report%' -- remove @StepId parameter from YourSQLDba_DoMaint calls in SQL Server Agent Exec yInstall.CleanUpParam @prm = '@StepId' , @SelectSearchArg = '%YourSQLDba_DoMaint%$(ESCAPE_NONE(STEPID))%' End -- remove @StepId parameter and comments from DeleteOldBackups calls in SQL Server Agent Exec yInstall.CleanUpParam @prm = '@StepId' , @SelectSearchArg = '%YourSQLDba.Maint.DeleteOldBackups%@StepId%=%$(ESCAPE_NONE(STEPID))%' GO Exec yUtl.DropObj 'yInstall.AddUpEndParam' GO Create proc yInstall.AddUpEndParam @SelectSearchArg nvarchar(1000) , @UnSelectSearchArg nvarchar(1000) , @prm nvarchar(1000) as Begin Set nocount on declare @sql varchar(max) declare @job_id uniqueidentifier declare @step_id int declare @pos int declare @PosDeb int declare @PosFin int set @prm = yExecNLog.Unindent_TSQL(@prm) While (1=1) -- while there is steps to correct Begin select @job_id=job_id, @step_id=step_id, @sql=command from msdb.dbo.sysjobsteps Where command like @SelectSearchArg And command not like @UnSelectSearchArg If @@rowcount = 0 break Print '========================== Job step before update ============================' Print @sql -- suppress trailing spaces, tabs and carrige return at the end of the sql statement While (1=1) Begin If substring(@sql,len(@sql), 1) not in (' ', char(10), char(13), char(9)) Break Set @sql = substring(@sql, 1, len(@sql)-1) End -- add params Set @sql = yExecNLog.Unindent_TSQL(@sql + @prm) Print '========================== Job step after update ============================' Print @sql Print '======================================================================' Update JS Set command = @sql from msdb.dbo.sysjobsteps JS Where @job_id=job_id and @step_id=step_id End -- While there is steps to correct End -- yInstall.AddUpEndParam GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO Exec yInstall.AddUpEndParam @SelectSearchArg = '%exec Maint.YourSqlDba_DoMaint%@DoBackup = ''F''%' , @UnSelectSearchArg = '%@ExcDbFromPolicy_CheckFullRecoveryModel%' , @prm = ' -- Each database exclusion filter must be on its own line between the following quote pair , @ExcDbFromPolicy_CheckFullRecoveryModel = '' '' ' GO print 'Existing installation, if any is updated to this version.' GO If Db_name() <> 'YourSqlDba' Use YourSqlDba exec yUtl.DropObj 'yInstall.ReplaceParamValue' GO -- This function replace the parameters name in the "@command" string -- and subtract 1 day from the number of days of retention. Create Function yInstall.ReplaceParamValue ( @command nvarchar(max) , @paramName sysname , @newParamValue nvarchar(max) ) returns nvarchar(max) as Begin Declare @ParamPos int Declare @equalPos int Declare @paramValuePos int Declare @paramValueEndPos int Declare @paramValueLength int Declare @paramFullLength int Declare @paramValue nvarchar(max) Declare @cmdRep nvarchar(max) Set @ParamPos = PATINDEX ('%'+@paramName+'[^a-z0-9_]%=%',@command) If @ParamPos = 0 -- the parameter is not in the command return (@command) Set @equalPos = @ParamPos + PATINDEX('%=%', Substring(@command, @ParamPos, 4000)) - 1 Set @paramValuePos = @equalPos + PATINDEX('%[0-9]%', Substring(@command, @equalPos, 4000)) - 1 Set @paramValueEndPos = @paramValuePos + PATINDEX('%[^0-9]%', Substring(@command, @paramValuePos, 4000)) - 2 Set @paramValueLength = @paramValueEndPos - @paramValuePos + 1 Set @paramValue= substring(@command, @paramValuePos, @paramValueLength) Set @paramFullLength = @paramValueEndPos - @ParamPos + 1 Set @cmdRep = Stuff ( @command , @ParamPos , @paramFullLength , @ParamName + ' = '+ @newParamValue ) return (@cmdRep) End -- yInstall.ReplaceParamValue GO If Db_name() <> 'YourSqlDba' Use YourSqlDba exec yUtl.DropObj 'yInstall.ReplaceRetDays' GO -- This function replace the parameters name in the "@command" string -- and subtract 1 day from the number of days of retention. Create Function yInstall.ReplaceRetDays ( @command nvarchar(max) , @paramName sysname , @newParamName sysname ) returns nvarchar(max) as Begin Declare @ParamPos int Declare @equalPos int Declare @paramValuePos int Declare @paramValueEndPos int Declare @paramValueLength int Declare @paramFullLength int Declare @paramValue nvarchar(max) Declare @newParamValue nvarchar(max) Declare @cmdRep nvarchar(max) Set @ParamPos = PATINDEX ('%'+@paramName+'[^a-z0-9_]%=%',@command) If @ParamPos = 0 -- the parameter is not in the command return (@command) Set @equalPos = @ParamPos + PATINDEX('%=%', Substring(@command, @ParamPos, 4000)) - 1 Set @paramValuePos = @equalPos + PATINDEX('%[0-9nN]%', Substring(@command, @equalPos, 4000)) - 1 Set @paramValueEndPos = @paramValuePos + PATINDEX('%[^0-9nullNULL]%', Substring(@command, @paramValuePos, 4000)) - 2 Set @paramValueLength = @paramValueEndPos - @paramValuePos + 1 Set @paramValue= substring(@command, @paramValuePos, @paramValueLength) Set @paramFullLength = @paramValueEndPos - @ParamPos + 1 Set @newParamValue = CASE When @paramValue = 'null' Or @paramValue = 'NULL' Then 'NULL' When @paramValue = '0' Then 'NULL' Else convert(nvarchar(30) ,CONVERT(int, @paramValue) - 1 ) End Set @cmdRep = Stuff ( @command , @ParamPos , @paramFullLength , @newParamName + ' = '+ @newParamValue ) return (@cmdRep) End -- yInstall.ReplaceRetDays GO Exec yUtl.DropObj 'Install.UpdateMaintenanceTasksParam' GO Create proc Install.UpdateMaintenanceTasksParam @paramName sysname , @paramValue nvarchar(max) as Begin Update msdb.dbo.sysjobsteps Set command = yInstall.ReplaceParamValue(command, @paramName, @paramValue ) Where command like '%'+'YourSQLDba_DoMaint%'+@paramName+'[^a-z0-9_]%' End -- Install.UpdateMaintenanceTasksParam go If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yInstall.DoReplacesInJobAndTasks' GO Create proc yInstall.DoReplacesInJobAndTasks @search nvarchar(1000) , @replace nvarchar(1000) = '' as Begin Set nocount on Set @search = replace(@search, '"', '''') Set @replace = replace(@replace, '"', '''') Update JS Set JS.step_name = replace (js.step_name, @search, @replace) from msdb.dbo.sysjobsteps JS Where step_name like '%'+@search+'%' Update JS Set command = replace(command, @search, @replace) from msdb.dbo.sysjobsteps JS Where command like '%'+@search+'%' Update JS Set JS.output_file_name = replace (js.output_file_name, @search, @replace) from msdb.dbo.sysjobsteps JS Where output_file_name like '%'+@search+'%' Update J Set J.name = replace(J.name, @search, @replace) from msdb.dbo.sysjobs J Where name like '%'+@search+'%' Update J Set description = replace(description, @search, @replace) from msdb.dbo.sysjobs J Where description like '%'+@search+'%' Update OP Set OP.name = replace(name, @search, @replace) From msdb.dbo.sysoperators OP Where name like '%'+@search+'%' End -- yInstall.DoReplacesInJobAndTasks GO -- script to migrate previous YourSQLDba database to YourSqlDba SET NOCOUNT ON --Select -- yInstall.ReplaceRetDays(command, '@FullBkpRet', '@FullBkpRetDays') --From msdb.dbo.sysjobsteps --Where command like '%'+'Maint.YourSqlDba_DoMaint%@FullBkpRet'+'[^a-z0-9_]%' -- version 4.0.10 Exec yInstall.DoReplacesInJobAndTasks '@UpdStatDaySpread', '@SpreadUpdStatRun' Update msdb.dbo.sysjobsteps Set command = yInstall.ReplaceRetDays(command, '@FullBkpRet', '@FullBkpRetDays') Where command like '%'+'Maint.YourSqlDba_DoMaint%@FullBkpRet'+'[^a-z0-9_]%' --Select -- yInstall.ReplaceRetDays(command, '@LogBkpRet', '@LogBkpRetDays') --From msdb.dbo.sysjobsteps --Where command like '%'+'Maint.YourSqlDba_DoMaint%@LogBkpRet'+'[^a-z0-9_]%' Update msdb.dbo.sysjobsteps Set command = yInstall.ReplaceRetDays(command, '@LogBkpRet', '@LogBkpRetDays') Where command like '%'+'Maint.YourSqlDba_DoMaint%@LogBkpRet'+'[^a-z0-9_]%' --Select -- yInstall.ReplaceRetDays(command, '@BackupRetentionDaysForSelectedDb', '@BkpRetDays') --From msdb.dbo.sysjobsteps --Where command like '%'+'Maint.DeleteOldBackups%@BackupRetentionDaysForSelectedDb'+'[^a-z0-9_]%' Update msdb.dbo.sysjobsteps Set command = yInstall.ReplaceRetDays(command, '@BackupRetentionDaysForSelectedDb', '@BkpRetDays') Where command like '%'+'Maint.DeleteOldBackups%@BackupRetentionDaysForSelectedDb'+'[^a-z0-9_]%' --Select -- yInstall.ReplaceRetDays(command, '@BackupRetentionDays', '@BkpRetDaysForUnSelectedDb') --From msdb.dbo.sysjobsteps --Where command like '%'+'Maint.DeleteOldBackups%@BackupRetentionDays'+'[^a-z0-9_]%' Update msdb.dbo.sysjobsteps Set command = yInstall.ReplaceRetDays(command, '@BackupRetentionDays', '@BkpRetDaysForUnselectedDb') Where command like '%'+'Maint.DeleteOldBackups%@BackupRetentionDays'+'[^a-z0-9_]%' Exec yInstall.DoReplacesInJobAndTasks '@MaxFailedBackupAttemptsToOffline', '@ConsecutiveFailedbackupsDaysToPutDbOffline' -- Version 6.2.3 Exec yInstall.DoReplacesInJobAndTasks '@ConsecutiveFailedbackupsDaysToPutDbOffline', '@ConsecutiveDaysOfFailedBackupsToPutDbOffline' GO -- ------------------------------------------------------------------------------ -- Create network map table -- ------------------------------------------------------------------------------ If Db_name() <> 'YourSqlDba' Use YourSqlDba GO -- if the table doesn't exists create the latest version If object_id('Maint.NetworkDrivesToSetOnStartup') is null Begin Declare @sql nvarchar(max) Set @sql = ' Create table Maint.NetworkDrivesToSetOnStartup ( DriveLetter nchar(2) , Unc nvarchar(255) , constraint Pk_NetworkDrivesToSetOnStartup primary key clustered (DriveLetter) ) ' Exec yExecNLog.QryReplace @sql output, '"', '''' Exec (@sql) If Object_Id('tempdb..##NetworkDrivesToSetOnStartup') IS NOT NULL Exec ( ' Insert Into Maint.NetworkDrivesToSetOnStartup ([DriveLetter],[Unc]) Select [DriveLetter],[Unc] From ##NetworkDrivesToSetOnStartup Drop table ##NetworkDrivesToSetOnStartup ' ) End GO -- ------------------------------------------------------------------------------ -- Stored procedure to define network drive on SQL Server startup -- ------------------------------------------------------------------------------ If Db_name() <> 'YourSqlDba' Use YourSqlDba GO Exec yUtl.DropObj 'Maint.CreateNetworkDrives' GO Create proc Maint.CreateNetworkDrives @DriveLetter nvarchar(2) , @unc nvarchar(255) as Begin Declare @errorN int Declare @cmd nvarchar(4000) Set nocount on Exec yMaint.SaveXpCmdShellStateAndAllowItTemporary Set @DriveLetter=rtrim(@driveLetter) Set @Unc=rtrim(@Unc) If Len(@DriveLetter) = 1 Set @DriveLetter = @DriveLetter + ':' If Len(@Unc) >= 1 Begin Set @Unc = yUtl.NormalizePath(@Unc) Set @Unc = Stuff(@Unc, len(@Unc), 1, '') End Set @cmd = 'net use /Delete' Set @cmd = Replace( @cmd, '', @DriveLetter) begin try Print @cmd exec xp_cmdshell @cmd, no_output end try begin catch end catch -- suppress previous network drive definition If exists(select * from Maint.NetworkDrivesToSetOnStartup Where DriveLetter = @driveLetter) Begin Delete from Maint.NetworkDrivesToSetOnStartup Where DriveLetter = @driveLetter End Begin Try Set @cmd = 'net use ' Set @cmd = Replace( @cmd, '', @DriveLetter ) Set @cmd = Replace( @cmd, '', @unc ) Print @cmd exec xp_cmdshell @cmd Insert Into Maint.NetworkDrivesToSetOnStartup (DriveLetter, Unc) Values (@DriveLetter, @unc) Exec yMaint.RestoreXpCmdShellState End Try Begin Catch Set @errorN = ERROR_NUMBER() -- return error code Print convert(nvarchar, @errorN) + ': ' + ERROR_MESSAGE() Exec yMaint.RestoreXpCmdShellState End Catch End -- Maint.CreateNetworkDrives GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO Exec yUtl.DropObj 'Maint.DisconnectNetworkDrive' GO Create proc Maint.DisconnectNetworkDrive @DriveLetterOrUNC nvarchar(255) As Begin Declare @errorN int Declare @DriveLetter nvarchar(255) Declare @cmd nvarchar(4000) Set nocount on If Len(@DriveLetterOrUNC) = 1 Set @DriveLetterOrUNC = @DriveLetterOrUNC + ':' Set @DriveLetterOrUNC = yUtl.NormalizePath(@DriveLetterOrUNC) -- because on past relaxed parameter validation the table may have variant of drive letter or unc format. -- make it uniform to make the rest of the code to work properly. ;With UpdateView as ( Select DriveLetter , Unc , left(yUtl.NormalizePath(left(rtrim(DriveLetter)+':', 2)),2) as NormalizedDriveLetter , Stuff(yUtl.NormalizePath(rtrim(Unc)), len(yUtl.NormalizePath(rtrim(Unc))), 1, '') as NormalizedUnc From Maint.NetworkDrivesToSetOnStartup ) Update UpdateView Set DriveLetter = NormalizedDriveLetter, Unc = NormalizedUnc -- no matter how drive letter or unc where stored with or without ending '\', make it work Set @DriveLetter = Null Select @DriveLetter = DriveLetter From Maint.NetworkDrivesToSetOnStartup Where DriveLetter = left(@DriveLetterOrUNC,2) Or Unc = @DriveLetterOrUNC If @DriveLetter Is Not Null Begin Begin Try Set @cmd = 'net use /DELETE' Set @cmd = Replace( @cmd, '', @DriveLetter ) Print @cmd exec yMaint.SaveXpCmdShellStateAndAllowItTemporary exec xp_cmdshell @cmd exec yMaint.RestoreXpCmdShellState Delete From Maint.NetworkDrivesToSetOnStartup Where DriveLetter = left(yUtl.NormalizePath(@DriveLetterOrUNC),2) Or Unc = yUtl.NormalizePath(@DriveLetterOrUNC) End Try Begin Catch Set @errorN = ERROR_NUMBER() -- return error code Print convert(nvarchar, @errorN) + ': ' + ERROR_MESSAGE() exec yMaint.RestoreXpCmdShellState End Catch End Else Begin Print 'No network drive match this criteria. ' + 'Run the following command to list existing network drives :' + ' «Exec YourSQLDba.Maint.ListNetworkDrives»' End End -- Maint.DisconnectNetworkDrive GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO Exec yUtl.DropObj 'Maint.ListNetworkDrives' GO Create proc Maint.ListNetworkDrives As Begin Set nocount on Select DriveLetter, Unc From Maint.NetworkDrivesToSetOnStartup End -- Maint.ListNetworkDrives GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO If object_id('yMirroring.InactivateYourSqlDbaJobs') is not null drop proc yMirroring.InactivateYourSqlDbaJobs GO Create Procedure yMirroring.InactivateYourSqlDbaJobs As Begin Select ROW_NUMBER() OVER (ORDER BY job_id) As Seq, job_id Into #jobs From msdb.dbo.sysjobsteps Where command like '%YourSQLDba_DoMaint%' Declare @job_id uniqueidentifier Declare @sql nvarchar(max) Declare @seq int Set @seq = 0 while 1=1 Begin Select Top 1 @Seq=Seq, @job_id=job_id From #jobs Where Seq > @Seq If @@rowcount = 0 break Set @sql = 'msdb.dbo.sp_update_job "", @enabled= 0' Set @sql = Replace( @sql, '', convert(nvarchar(36), @job_id)) Set @sql = Replace( @sql, '"', '''') --Print @sql Exec( @sql ) End Drop table #jobs End -- yMirroring.InactivateYourSqlDbaJobs GO Exec yUtl.DropObj 'Mirroring.DropServer' GO Create Procedure Mirroring.DropServer @MirrorServer sysname = '' , @silent int = 0 As Begin Declare @sql nvarchar(max) Declare @remoteServerYourSqlDbaVersion Nvarchar(40) Declare @ObjectId int Set NoCount on Exec yMirroring.ReportYourSqlDbaVersionOnTargetServers @MirrorServer = @MirrorServer , @remoteVersion = @remoteServerYourSqlDbaVersion Output , @LogToHistory = 0 , @silent = @silent If @remoteServerYourSqlDbaVersion IN ('Server undefined', 'Remote YourSqlDba is missing)' ) Return Delete From Mirroring.TargetServer Where MirrorServerName=@MirrorServer Declare @srvLogins Table (loginName sysname primary key clustered) Insert into @srvLogins select p.name from sys.servers S Join sys.Linked_logins L ON L.server_Id = S.server_id Join sys.server_principals P On P.principal_id = l.local_principal_id Where S.name = @MirrorServer And S.is_linked = 1 EXEC master.dbo.sp_droplinkedsrvlogin @rmtsrvname=@MirrorServer,@locallogin=NULL Declare @name sysname -- drop dependants logins for this linked server Set @name = '' -- otherwise the linked server is not removed While(1=1) Begin Select top 1 @name = loginName from @SrvLogins Where loginName > @name Order by loginName If @@ROWCOUNT = 0 break Print 'Remove existing linked server login '+@name Exec sp_droplinkedsrvlogin @MirrorServer, @name End -- Set options for the linked server to be able to do Exec ... AT EXEC master.dbo.sp_serveroption @server=@MirrorServer, @optname=N'rpc', @optvalue=N'true' EXEC master.dbo.sp_serveroption @server=@MirrorServer, @optname=N'rpc out', @optvalue=N'true' Print 'Remove existing Linked Server' + @mirrorServer Exec sp_dropServer @MirrorServer Print '-------------------------------------------------------------------' Print ' Mirror server succesfully uninstalled' Print '-------------------------------------------------------------------' End -- Mirroring.DropServer GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO Exec yUtl.DropObj 'Mirroring.AddServer' GO Create Procedure Mirroring.AddServer @MirrorServer nvarchar(512) , @remoteLogin nvarchar(512) , @remotePassword nvarchar(512) , @ExcSysAdminLoginsInSync int = 0 , @ExcLoginsFilter nvarchar(max) = '' , @MirrorServerDataSrc nvarchar(512) = '' , @YourSqlDbaAccountForMirroringPwd nvarchar(512) = NULL As Begin Declare @sql nvarchar(max) Declare @Info nvarchar(2048) Declare @remoteServerYourSqlDbaVersion nvarchar(100) Set NoCount on -- Create a link server for the Mirror If Exists (Select * From sys.servers where name = @MirrorServer And is_linked = 1) Begin EXEC Mirroring.DropServer @MirrorServer End -- Get SqlAgent Login Account Declare @SqlAgentLoginAccount as sysname select @SqlAgentLoginAccount = login_name from sys.dm_exec_sessions Where program_name = 'SQLAgent - Generic Refresher' If @@rowcount = 0 Begin Raiserror('SqlAgent must be running in order to identify its starting account and authorize it to the remote server', 11, 1) Return End IF (LEN(@MirrorServerDataSrc) > 0) BEGIN EXEC master.dbo.sp_addlinkedserver @server = @MirrorServer, @srvproduct='', @provider='SQLNCLI', @datasrc=@MirrorServerDataSrc END ELSE BEGIN EXEC master.dbo.sp_addlinkedserver @server = @MirrorServer, @srvproduct=N'SQL Server' END EXEC master.dbo.sp_addlinkedsrvlogin @rmtsrvname = @MirrorServer, @locallogin = NULL , @useself = N'True' -- enable SQLAgent to run remotely something AT the mirror server Print 'Adding delegate account "'+@remoteLogin+ '" for SQL Agent Login account : "'+@SqlAgentLoginAccount+'"' If left(@SqlAgentLoginAccount, 2)= '.\' Begin Set @SqlAgentLoginAccount = STUFF(@SqlAgentLoginAccount, 1, 1, convert(sysname, serverproperty('machineName'))) End EXEC master.dbo.sp_addlinkedsrvlogin @rmtsrvname = @MirrorServer , @locallogin = @SqlAgentLoginAccount , @useself = N'False' , @rmtUser = @RemoteLogin , @rmtPassWord = @RemotePassWord -- add also yourself for debugging purposes (to check the linkServer access) -- unless already done Declare @localLogin sysname Set @localLogin = SUSER_SNAME() If @localLogin <> @SqlAgentLoginAccount And @localLogin <> 'YourSQLDba' Begin Print 'Adding delegate account "'+@remoteLogin+ '" for account "'+@localLogin+'"' EXEC master.dbo.sp_addlinkedsrvlogin @rmtsrvname = @MirrorServer , @locallogin = @localLogin , @useself = N'False' , @rmtUser = @RemoteLogin , @rmtPassWord = @RemotePassWord End -- Set options for the linked server EXEC master.dbo.sp_serveroption @server=@MirrorServer, @optname=N'rpc', @optvalue=N'true' EXEC master.dbo.sp_serveroption @server=@MirrorServer, @optname=N'rpc out', @optvalue=N'true' EXEC master.dbo.sp_serveroption @server=@MirrorServer, @optname=N'query timeout', @optvalue=N'86400' Insert Into Mirroring.TargetServer (MirrorServerName ) Select @MirrorServer Where Not Exists (Select * From Mirroring.TargetServer Where MirrorServerName=@MirrorServer) -- if user specify a YourSqlDba password, it is set locally and remotely to the specified value Exec Mirroring.SetYourSqlDbaAccountForMirroring @YourSqlDbaAccountForMirroringPwd; Exec yMirroring.ReportYourSqlDbaVersionOnTargetServers @MirrorServer = @MirrorServer , @remoteVersion = @remoteServerYourSqlDbaVersion Output , @LogToHistory = 0 If @remoteServerYourSqlDbaVersion <> (Select v.VersionNumber from Install.VersionInfo () as v) Begin Delete Mirroring.TargetServer Where MirrorServerName=@MirrorServer Print '************ AddServer Failure **********************' If @remoteServerYourSqlDbaVersion <> 'no remote mapping exists' Begin Print 'YourSqlDba.Mirror.AddServer : Problem occurred with linked server YourSqlDba Database version: '+@remoteServerYourSqlDbaVersion Print 'Install or Upgrade YourSqlDba on the remote server and run Mirroring.AddServer again' Print 'Rollbacking remote server addition because YourSqlDba version mismatch between local server and linked server' EXEC Mirroring.DropServer @MirrorServer, @silent = 1 End Else Begin Print 'YourSqlDba.Mirror.AddServer : Problem occurred: '+@remoteServerYourSqlDbaVersion Print 'Adjust Linked server remote logins mapping. Then test link server connection by browsing linked server databases ' Print 'You can also do YourSqlDba.Mirror.DropServer followed by YourSqlDba.Mirror.AddServer with checking for proper remote user and password ' End Print '*****************************************************' Raiserror ('See print text for Mirroring.Addserver failure',11,1) Return End -- Synchronise logins on the mirror server Exec yMirroring.LaunchLoginSync @MirrorServer=@MirrorServer Print '-------------------------------------------------------------------' Print ' Mirror server succesfully installed' Print '-------------------------------------------------------------------' End -- Mirroring.AddServer GO If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yMirroring.DoRestore' GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO Create Procedure yMirroring.DoRestore @BackupType nchar(1) , @Filename nvarchar(255) , @DbName nvarchar(255) -- In test migrationTesmode=1, only Full backup are restored -- there is a default param because FailOver call DoRestore but never in this mode , @MigrationTestMode Int = 0 , @ReplaceSrcBkpPathToMatchingMirrorPath nvarchar(max) = '' , @ReplacePathsInDbFileNames nvarchar(max) = '' As Begin Declare @pathData nvarchar(512) Declare @pathLog nvarchar(512) Declare @FileType char(1) Declare @sql nvarchar(max) Declare @sqlcmd nvarchar(max) Declare @FileId int Declare @NoSeq int Declare @LogicalName sysname Declare @PhysicalName sysname Declare @NewPhysicalName sysname Declare @ClauseMove nvarchar(max) Declare @Position smallint Declare @ErrorMessage nvarchar(2048) Declare @ReplSrch nvarchar(512) Declare @ReplBy nvarchar(512) Set nocount on If @ReplacePathsInDbFileNames = '' -- user did not specified any relocation parameter for DB files, so use default location Begin -- get default data and log location Exec master.dbo.xp_instance_regread N'HKEY_LOCAL_MACHINE' , N'Software\Microsoft\MSSQLServer\MSSQLServer' , N'DefaultData' , @pathData OUTPUT Exec master.dbo.xp_instance_regread N'HKEY_LOCAL_MACHINE' , N'Software\Microsoft\MSSQLServer\MSSQLServer' , N'DefaultLog' , @pathLog OUTPUT -- if default data and log locations are not specified in server properties, use model database files locations If @pathData Is Null Select Top 1 @pathData = Left( physical_name, Len(physical_name) - Charindex('\', Reverse(physical_name))) FROM model.sys.database_files Where type = 0 If @pathLog Is Null Select Top 1 @pathLog = Left( physical_name, Len(physical_name) - Charindex('\', Reverse(physical_name))) FROM model.sys.database_files Where type = 1 End Else -- user did specified replacement parameter for database files location Begin -- extract file path string replacement to do if any, because directories can be at a different places -- Parameter contains both search and replace parameter in the form /* 'stringToSearch1>StringToReplace1| stringToSearch2>StringToReplace2' */ -- where '>' is the divider of the pair. Each pair must be on its own line and ends with '|' -- Parameter can be empty Set @ReplacePathsInDbFileNames = replace(@ReplacePathsInDbFileNames, '>', '>') Declare @ReplacesOnFiles Table (seqRep int primary key, replSrch nvarchar(512) NULL, replBy nvarchar(512) NULL) ;With ReplacePairs as (Select * From yUtl.SplitParamInRows (@ReplacePathsInDbFileNames) as x) , Pairs(seq, pair, posSep) as (Select no, line, CHARINDEX ('>', line) From ReplacePairs) insert @ReplacesOnFiles (seqRep, replSrch, replBy) Select seq, left(pair, posSep-1), right(pair, len(pair)-posSep) From pairs Where posSep > 1 End -- If user specified a restore location remapping performs replacements on backup file name. If @ReplaceSrcBkpPathToMatchingMirrorPath <> '' Begin -- extract replacement information on backup location to restore location -- on one side it is a network path and on the other it is a local path -- or it could but 2 network path expressed differently. -- Parameter contains both search and replace parameter in the form /* 'stringToSearch1>StringToReplace1 stringToSearch2>StringToReplace2' */ -- where '>' is the divider of the pair. Each pair must be on its own line -- Parameter can be empty -- Since the all call of this command get through an xml message ">" becomes ">" -- so it must be turned back to > Set @ReplaceSrcBkpPathToMatchingMirrorPath = replace(@ReplaceSrcBkpPathToMatchingMirrorPath, '>', '>') Declare @ReplacesOnRestorePath Table (seqRep int primary key, replSrch nvarchar(512) NULL, replBy nvarchar(512) NULL) ;With ReplacePairs as (Select * From yUtl.SplitParamInRows (@ReplaceSrcBkpPathToMatchingMirrorPath) as x) , Pairs(seq, pair, posSep) as (Select no, line, charindex('>', Line) From ReplacePairs) Insert @ReplacesOnRestorePath (seqRep, replSrch, replBy) Select seq, left(pair, posSep-1), right(pair, len(pair)-posSep) From pairs Where posSep > 1 -- process replaces on backup file name and path location Declare @seqRep Int Set @SeqRep = 0 While (1=1) Begin Select top 1 @SeqRep = SeqRep, @ReplSrch = replSrch, @ReplBy = replBy From @ReplacesOnRestorePath Where seqRep > @seqRep Order by seqRep If @@rowcount = 0 Break Set @Filename = replace(@Filename, @replSrch, @replBy) End End Begin Try -- an internal raiserror to collectBackup... procedure makes unnecessary to test return code -- in case of error it will jump to the catch block to be reported Exec yMaint.CollectBackupHeaderInfoFromBackupFile @Filename Exec yMaint.CollectBackupFileListFromBackupFile @Filename -- recover database name from datase backup file Select @DbName = DatabaseName From Maint.TemporaryBackupHeaderInfo Where spid = @@spid If @BackupType='F' Begin -- If database already exists with a status different than «RESTORING» -- we must generate an error to prevent restoring over a good database -- the exception is that when this is a MigrationTestMode, we just don't restore over online database -- the goal when MigrationTestMode=1 it that if the user wants a new copy of the database, he just have to remove it If DATABASEPROPERTYEX(@DbName, 'Status' ) = 'ONLINE' And @MigrationTestMode = 1 Begin Return -- in MigrationTestMode=1 Online database are left as is there is no restore over them End If DATABASEPROPERTYEX(@DbName, 'Status' ) Is Not Null And DATABASEPROPERTYEX(@DbName, 'Status' ) <> 'RESTORING' Begin Raiserror (N'To restore a full backup to the mirror server the database %s must be in «RESTORING» state or not exists', 11, 1, @DbName) End -- previous database must be removed to have accurate information abut its last_lsn in msdb -- Generate restore command Set @sql = ' If databasepropertyex("", "status")="RESTORING" Begin Exec ( " Restore Database [] with recovery; Drop DATABASE []; " ) End; RESTORE DATABASE [] FROM DISK="" WITH ,CHECKSUM ,REPLACE ,NORECOVERY ,bufferCount = 20 ,MAXTRANSFERSIZE = 4096000 ' Set @FileId = -1 Set @NoSeq = 0 -- generate the move command which is requiered where original location -- from db source server don't match with destination location on destination server While 1=1 Begin Select Top 1 @FileType = Type , @FileId = FileId , @LogicalName=LogicalName , @PhysicalName=PhysicalName From Maint.TemporaryBackupFileListInfo Where spid = @@spid And FileId > @FileId Order by FileId If @@rowcount = 0 break If @ReplacePathsInDbFileNames <> '' -- user specified relocation parameters Begin -- check for replaces to do to "relocate" location Set @SeqRep = 0 While (1=1) Begin Select top 1 @SeqRep = SeqRep, @ReplSrch = replSrch, @ReplBy = replBy From @ReplacesOnFiles Where seqRep > @seqRep Order by seqRep If @@rowcount = 0 Break -- perform replacements as long as there are Set @PhysicalName = replace(@PhysicalName, @replSrch, @replBy) End -- while there is replacements on file names to perform Set @ClauseMove = 'MOVE "" TO ""' Set @ClauseMove = Replace( @ClauseMove, '', @PhysicalName ) Set @ClauseMove = Replace( @ClauseMove, '', @LogicalName ) End Else Begin -- use default Db location parameters Set @ClauseMove = 'MOVE "" TO "\"' If @FileType = 'L' -- log location not usually the same that other files Set @ClauseMove = Replace( @ClauseMove, '', @pathLog ) --bug restore Else Set @ClauseMove = Replace( @ClauseMove, '', @pathData ) -- strip the path out of physical name that comes from Maint.TemporaryBackupFileListInfo -- which is produced by CollectBackupHeaderInfoFromBackupFile Set @PhysicalName=RIGHT(@PhysicalName, Charindex('\', Reverse(@PhysicalName))-1) Set @ClauseMove = Replace( @ClauseMove, '', @PhysicalName ) Set @ClauseMove = Replace( @ClauseMove, '', @LogicalName ) End Set @sql = Replace(@sql, '', @ClauseMove + nchar(13) + nchar(10) + ' ,') End Set @sql = Replace(@sql, ',', '') Set @sql = replace (@sql, '"', '''') Set @sql = replace (@sql, '', @DbName) Set @sql = replace (@sql, '', @Filename) Set @sql = yExecNLog.Unindent_TSQL(@sql) End -- In @MigrationTestMode =1 only full backup can be restored, because they are put online after restore -- so we skip request for this type of restore If @BackupType='D' And @MigrationTestMode = 0 Begin Set @sql = '' Set @Position = 0 -- To restore a log backup the database must exists and have the status «RESTORING» If DATABASEPROPERTYEX(@DbName, 'Status' ) Is Null Or DATABASEPROPERTYEX(@DbName, 'Status' ) <> 'RESTORING' Begin Raiserror (N'To restore a DIFFERENTIAL backup to the mirror server the database %s must be in «RESTORING» state', 11, 1, @DbName) End while 1=1 Begin -- check database state to see which file of the log backup has to be restored -- funny enough restore database appears also in msdb.dbo.backupSet -- this information (position) is obtained through the last_lsn restore versus -- last_lsn into the backup Select Top 1 @Position = H.Position --first position that match the last_lsn From ( Select database_name, Max(last_lsn) as last_lsn From msdb.dbo.backupset B Group By database_name ) X Join Maint.TemporaryBackupHeaderInfo H ON H.spid = @@spid And H.DatabaseName = X.database_name collate database_default AND H.LastLSN > X.last_lsn Where H.Position > @Position Order By H.Position If @@rowcount = 0 break -- Generate restore command. -- Do not handle move command. To acheive this there is an need to add column createLsn -- to Maint.TemporaryBackupFileListInfo and generate the move command only for the lsn -- that is between the backup lsn. Also proceeed to replace in the file name. -- Some job but not overwhelming Set @sqlcmd = 'RESTORE DATABASE [] FROM DISK="" WITH FILE=, NORECOVERY, CHECKSUM,bufferCount = 20,MAXTRANSFERSIZE = 4096000 ' Set @sqlcmd = replace (@sqlcmd, '"', '''') Set @sqlcmd = replace (@sqlcmd, '', @DbName) Set @sqlcmd = replace (@sqlcmd, '', @Filename) Set @sqlcmd = replace (@sqlcmd, '', CONVERT(nvarchar(10), @Position)) Set @sql = REPLACE( @sql, '', @sqlcmd) Set @sql = @sql + char(10) + '' End Set @sql = REPLACE( @sql, '', '') End -- In @MigrationTestMode =1 only full backup can be restored, because they are put online after restore -- so we skip request for this type of restore If @BackupType='L' And @MigrationTestMode = 0 Begin Set @sql = '' Set @Position = 0 -- To restore a log backup the database must exists and have the status «RESTORING» If DATABASEPROPERTYEX(@DbName, 'Status' ) Is Null Or DATABASEPROPERTYEX(@DbName, 'Status' ) <> 'RESTORING' Begin Raiserror (N'To restore a LOG backup to the mirror server the database %s must be in «RESTORING» state', 11, 1, @DbName) End while 1=1 Begin -- check database state to see which file of the log backup has to be restored -- funny enough restore database appears also in msdb.dbo.backupSet -- this information (position) is obtained through the last_lsn restore versus -- last_lsn into the backup Select Top 1 @Position = H.Position --first position that match the last_lsn From ( Select database_name, Max(last_lsn) as last_lsn From msdb.dbo.backupset B Group By database_name ) X Join Maint.TemporaryBackupHeaderInfo H ON H.spid = @@spid And H.DatabaseName = X.database_name collate database_default AND H.LastLSN > X.last_lsn Where H.Position > @Position Order By H.Position If @@rowcount = 0 break -- Generate restore command. -- Do not handle move command. To acheive this there is an need to add column createLsn -- to Maint.TemporaryBackupFileListInfo and generate the move command only for the lsn -- that is between the backup lsn. Also proceeed to replace in the file name. -- Some job but not overwhelming Set @sqlcmd = 'RESTORE LOG [] FROM DISK="" WITH FILE=, NORECOVERY, CHECKSUM,bufferCount = 20,MAXTRANSFERSIZE = 4096000 ' Set @sqlcmd = replace (@sqlcmd, '"', '''') Set @sqlcmd = replace (@sqlcmd, '', @DbName) Set @sqlcmd = replace (@sqlcmd, '', @Filename) Set @sqlcmd = replace (@sqlcmd, '', CONVERT(nvarchar(10), @Position)) Set @sql = REPLACE( @sql, '', @sqlcmd) Set @sql = @sql + char(10) + '' End Set @sql = REPLACE( @sql, '', '') End If @sql <> '' -- could be still NULL which is also false. Begin Declare @maxSeverity Int Declare @Msgs nvarchar(max) Exec yExecNLog.ExecWithProfilerTrace @sql, @maxSeverity output, @Msgs Output If @maxseverity <=10 Begin Set @msgs = @sql + @msgs Exec yExecNLog.PrintSqlCode @msgs -- In @MigrationTestMode =1 only full backup can be restored -- and we do recover database after full restore If @MigrationTestMode = 1 -- we want to make Database available right away for test in MigrationTestMode Begin Set @Sql = 'Restore Database ['+@DbName+'] With recovery' Exec yExecNLog.ExecWithProfilerTrace @sql, @maxSeverity output, @Msgs Output End End Else Begin Raiserror (N'%s: %s %s', 11, 1, @@SERVERNAME, @Sql, @Msgs) End End End Try Begin Catch Select @ErrorMessage = ERROR_MESSAGE() Raiserror (N'yMirroring.DoRestore error / %s', 11, 1, @ErrorMessage ) End Catch End -- yMirroring.DoRestore GO If Db_name() <> 'Master' Use master GO -- previous version cleanup if object_id('dbo.CreateNetworkDrive') is not null exec sp_procoption N'dbo.CreateNetworkDrive', N'startup', N'false' If object_id('dbo.CreateNetworkDrive') is not null drop proc dbo.CreateNetworkDrive GO If object_id('YouSqlDbaAutostart_ReconnectNetworkDrive') is not null drop proc YouSqlDbaAutostart_ReconnectNetworkDrive go -- new version If object_id('YourSqlDbaAutostart_ReconnectNetworkDrive') is not null drop proc YourSqlDbaAutostart_ReconnectNetworkDrive go Create proc YourSqlDbaAutostart_ReconnectNetworkDrive As Begin ------------------------------------------------------------------- -- The "YouSqlDbaAutostart_ReconnectNetworkDrive" procedure is part of YourSQLDba. ------------------------------------------------------------------- Declare @DriveLetter nchar(2) Declare @unc nvarchar(255) Declare @cmd nvarchar(4000) Declare @sql nvarchar(4000) Set @DriveLetter = '' while 1=1 Begin Select Top 1 @DriveLetter=DriveLetter, @unc=Unc From YourSQLDba.Maint.NetworkDrivesToSetOnStartup Where DriveLetter > @DriveLetter if @@ROWCOUNT = 0 break Begin Try set @sql = ' If Db_name() <> "YourSqlDba" Use YourSqlDba Print @cmd exec YourSQLDba.yMaint.SaveXpCmdShellStateAndAllowItTemporary exec xp_cmdshell @cmd, NO_OUTPUT exec YourSQLDba.yMaint.RestoreXpCmdShellState ' Set @sql = Replace( @Sql, '"', '''') Set @cmd = 'net use /Delete' Set @cmd = Replace( @cmd, '', @DriveLetter ) Exec sp_executeSql @Sql, N'@cmd nvarchar(4000)', @cmd Set @cmd = 'net use ' Set @cmd = Replace( @cmd, '', @DriveLetter ) Set @cmd = Replace( @cmd, '', @unc ) Exec sp_executeSql @Sql, N'@cmd nvarchar(4000)', @cmd End Try Begin Catch declare @msg nvarchar(max) Set @msg = STR(error_number())+' '+ERROR_MESSAGE () print @msg exec YourSQLDba.yMaint.RestoreXpCmdShellState End Catch End End -- YourSqlDbaAutostart_ReconnectNetworkDrive GO exec sp_procoption N'YourSqlDbaAutostart_ReconnectNetworkDrive', N'startup', N'true' GO -- ------------------------------------------------------------------------- -- Prepare databases for upgrade by changing their names and doing a backup -- before upgrade. Users are automatically kicked out of the database. -- The goal in changing names is prevent other users or applications -- or services to connect. The DBA needs to have a means to have exclusive -- access to new datasource definitions or connect strings -- reflecting the new databases names. -- Suffix supplied by @DbNameSuffixForMaintenance is -- added to the name of databases supplied by @dbList. The backup -- reflect the name of the new database name and is placed into the backup path. -- Backup can be bypassed by supplying empty string to @PathOfBackupBeforeMaintenance -- but it is obviously not recommanded. -- A little table with a long name : "RecoveryModelBeforePrepDbForMaintenanceMode" -- is used as its name implies to keep track of the database recovery model -- so if the upgrade process changes it, it will be brought to its original state -- after running ReturnDbToNormalUseFromMaintenanceMode -- To minimize the increase in size of the log file during the upgrade, it is possible to -- set @SetRecoveryModeToSimple to 1. Doing so will put the database into SIMPLE -- recovery mode until the «ReturnDbToNormalUseFromMaintenanceMode» is called. -- ------------------------------------------------------------------------- If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'Maint.PrepDbForMaintenanceMode' GO Create Procedure Maint.PrepDbForMaintenanceMode @DbList nVARCHAR(max) = '' -- @DbList : See comments later for further explanations , @DbNameSuffixForMaintenance nvarchar(128) , @PathOfBackupBeforeMaintenance nvarchar(512) = NULL , @SetRecoveryModeToSimple int = 0 as Begin Set nocount on Set @DbNameSuffixForMaintenance= isnull(@DbNameSuffixForMaintenance, '') Set @PathOfBackupBeforeMaintenance = ISNULL (@PathOfBackupBeforeMaintenance, '') If Right(@PathOfBackupBeforeMaintenance ,1) = '\' Set @PathOfBackupBeforeMaintenance = Left(@PathOfBackupBeforeMaintenance, len(@PathOfBackupBeforeMaintenance) - 1) Select d.name collate database_default as Dbname, bl.lastLogBkpFile, bl.EncryptionAlgorithm, bl.EncryptionCertificate, row_number() over (order by line) seq into #Tmp From yUtl.SplitParamInRows (@dbList) AS X join master.sys.databases d on d.name = x.line collate database_default left join Maint.JobLastBkpLocations bl on bl.dbName = d.name collate database_default Where d.name Not Like ('%[_]' + replace(@DbNameSuffixForMaintenance, '_', '[_]')); Declare @name sysname Declare @sql nvarchar(max) Declare @seq int Declare @lastLogBkpFile nvarchar(512) Declare @msgErr nvarchar(max) Declare @EncryptionAlgorithm nvarchar(10) Declare @EncryptionCertificate nvarchar(100) Set @seq = 0 While (1=1) Begin Select top 1 @name = DbName, @seq = seq, @lastLogBkpFile = lastLogBkpFile, @EncryptionAlgorithm = EncryptionAlgorithm, @EncryptionCertificate = EncryptionCertificate from #Tmp Where seq > @seq Order by seq If @@rowcount = 0 break Begin Try Set @sql = ' If Db_name() <> "Master" Use master; Update [YourSQLDba].[Maint].[JobLastBkpLocations] Set keepTrace=1 Where dbName="" If Not Exists (Select * From [].sys.tables Where name="RecoveryModelBeforePrepDbForMaintenanceMode") Select convert(sysname, DATABASEPROPERTYEX ("", "recovery")) as recovery_model_desc Into [].dbo.RecoveryModelBeforePrepDbForMaintenanceMode Alter database [] Set Single_User With Rollback Immediate Alter database [] MODIFY NAME = [_] Alter database [_] Set MULTI_USER With Rollback Immediate ' Set @sql = replace(@sql, '', @name) Set @sql = replace(@sql, '', @DbNameSuffixForMaintenance) Set @sql = replace(@sql, '"', '''') --print @sql exec(@sql) Set @sql = ' use [_]; Begin Transaction PrepDbForMaintenanceMode With mark "Mark to point in time restore for RestoreDbAtStartOfMaintenanceMode" Update dbo.RecoveryModelBeforePrepDbForMaintenanceMode Set recovery_model_desc = recovery_model_desc Commit Transaction PrepDbForMaintenanceMode ' Set @sql = replace(@sql, '', @name) Set @sql = replace(@sql, '', @DbNameSuffixForMaintenance) Set @sql = replace(@sql, '"', '''') --print @sql exec(@sql) Print @name + ' renamed to ' + @name + '_' + @DbNameSuffixForMaintenance + ' for maintenance' End Try Begin Catch Set @msgErr = @name + '> ' + ERROR_MESSAGE() Raiserror (N'%s', 11, 1, @msgErr) End Catch If @PathOfBackupBeforeMaintenance = '' And @lastLogBkpFile Is Null Begin Raiserror (N'The database has no log backups and you did not specified a value for parameter @PathOfBackupBeforeMaintenance so it will not be possible to restore the database state at the start of the maintenance in case of a failure of the maintenance process', 11, 1) End Else Begin Begin Try -- Always make a log backup if the database has a log backup file exists for this database If @lastLogBkpFile IS Not Null Begin Set @sql = yMaint.MakeBackupCmd( @name + '_' + @DbNameSuffixForMaintenance, 'L', @lastLogBkpFile, 0, Null, @EncryptionAlgorithm, @EncryptionCertificate) exec(@sql) End If @PathOfBackupBeforeMaintenance <> '' Begin Set @sql = 'EXECUTE [YourSQLDba].[Maint].[SaveDbCopyOnly] @dbname = "_",@PathAndFilename="\_.Bak"' Set @sql = replace(@sql, '', @name) Set @sql = replace(@sql, '', @DbNameSuffixForMaintenance) Set @sql = replace(@sql, '', @PathOfBackupBeforeMaintenance) Set @sql = replace(@sql, '"', '''') exec(@sql) End End Try Begin Catch Set @msgErr = @name + '_' + @DbNameSuffixForMaintenance + '> ' + ERROR_MESSAGE() Raiserror (N'%s', 11, 1, @msgErr) End Catch End -- If specified with the parameter @SetRecoveryModeToSimple, set the -- recovery model to simple during the maintenance if @SetRecoveryModeToSimple = 1 begin Set @sql = ' if DATABASEPROPERTYEX ("_", "recovery") <> "SIMPLE" Alter database [_] Set RECOVERY SIMPLE WITH NO_WAIT ' Set @sql = replace(@sql, '', @name) Set @sql = replace(@sql, '', @DbNameSuffixForMaintenance) Set @sql = replace(@sql, '"', '''') Begin Try --print @sql exec(@sql) Print @name + '_' + @DbNameSuffixForMaintenance + ' is in SIMPLE recovery model' End Try Begin Catch Set @msgErr = @name + '_' + @DbNameSuffixForMaintenance + '> ' + ERROR_MESSAGE() Raiserror (N'%s', 11, 1, @msgErr) End Catch end End End -- Maint.PrepDbForMaintenanceMode GO -- ------------------------------------------------------------------------- -- procedure you need to use ReturnDbToNormalUseFromMaintenanceMode -- ------------------------------------------------------------------------- If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yMaint.PrepareRestoreDbToLogMarkCommand' GO Create Procedure yMaint.PrepareRestoreDbToLogMarkCommand @DbName nVARCHAR(max) , @FullBkpFile nvarchar(512) , @LogMarkName nvarchar(32) , @SqlCmd nvarchar(max) output As Begin Declare @sql nvarchar(max) Declare @RestoreLog nvarchar(max) Declare @position smallint Declare @LogBkpFile nvarchar(512) Declare @MediaSetId int Set @SqlCmd = ' Restore Database [] From Disk = "" With NoRecovery ,stats=1, replace Restore Log [] With Recovery ' -- Find all log backups associated with the full backup Set @MediaSetId = 0 While 1=1 Begin Select Top 1 @MediaSetId= bm.media_set_id, @LogBkpFile = bm.physical_device_name From ( Select bs.database_name, bs.first_lsn From YourSQLDba.Maint.JobLastBkpLocations lb join msdb.dbo.backupset bs on bs.database_name = lb.dbName collate database_default And RIGHT( bs.name, Len(lb.lastFullBkpFile)) = lb.lastFullBkpFile collate database_default Where lb.lastFullBkpFile = @FullBkpFile And (bs.name like 'YourSqlDba%' or bs.name like 'SaveDbOnNewFileSet%') And bs.type = 'D' ) X Join msdb.dbo.backupset bs On bs.database_name = X.database_name And bs.database_backup_lsn = X.first_lsn Join msdb.dbo.backupmediafamily bm On bm.media_set_id = bs.media_set_id Where bs.type = 'L' And bm.media_set_id > @MediaSetId If @@ROWCOUNT = 0 Break Exec yMaint.CollectBackupHeaderInfoFromBackupFile @LogBkpFile -- Restore all log backup until the log mark Set @position = 0 while 1=1 Begin Select Top 1 @position = Position From Maint.TemporaryBackupHeaderInfo Where Spid = @@spid And BackupType = 2 And Position > @position Order by Position If @@rowcount= 0 break Set @RestoreLog = 'Restore Log [] From Disk="" With FILE=, NoRecovery, STOPATMARK=""' Set @RestoreLog = Replace(@RestoreLog, '', Convert(nvarchar(255), @position)) Set @SqlCmd = replace(@SqlCmd, '', @RestoreLog + Char(13) + Char(10) + '' ) Set @SqlCmd = replace(@SqlCmd, '', @LogBkpFile) End End Set @SqlCmd = replace(@SqlCmd, '', '') Set @SqlCmd = replace(@SqlCmd, '', @DbName) Set @SqlCmd = replace(@SqlCmd, '', @LogMarkName) Set @SqlCmd = replace(@SqlCmd, '', @FullBkpFile) Set @SqlCmd = replace(@SqlCmd, '"', '''') End -- yMaint.PrepareRestoreDbToLogMarkCommand GO -- ------------------------------------------------------------------------- -- Restore databases to their state before maintenance process is started. -- They are still in maintenance mode and original backup remains available -- for other maintenance attempts. -- Requires that PrepDbForMaintenanceMode was used in the way necessary to -- generate a backup (i.e. by supplying a valid backup path, not empty string). -- Your must supply in @bdlist each database you want to restore. -- Can be used to abort maintenance attempt and report it later, but after this -- procedure you need to use ReturnDbToNormalUseFromMaintenanceMode -- ------------------------------------------------------------------------- If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'Maint.RestoreDbAtStartOfMaintenanceMode' GO Create Procedure Maint.RestoreDbAtStartOfMaintenanceMode @DbList nVARCHAR(max) , @DbNameSuffixForMaintenance nvarchar(128) , @PathOfBackupBeforeMaintenance nvarchar(512) = NULL as Begin Set nocount on Set @DbNameSuffixForMaintenance = isnull(@DbNameSuffixForMaintenance, '') Set @PathOfBackupBeforeMaintenance = ISNULL (@PathOfBackupBeforeMaintenance, '') If Right(@PathOfBackupBeforeMaintenance ,1) = '\' Set @PathOfBackupBeforeMaintenance= Left(@PathOfBackupBeforeMaintenance, len(@PathOfBackupBeforeMaintenance) - 1) Select d.name collate database_default as Dbname , lastLogBkpFile , lastFullBkpFile , row_number() over (order by line) seq into #Tmp From yUtl.SplitParamInRows (@dbList) AS X join master.sys.databases d on d.name = x.line + '_' + @DbNameSuffixForMaintenance collate database_default left join Maint.JobLastBkpLocations bl on bl.dbName = x.line collate database_default Declare @name sysname Declare @sql nvarchar(max) Declare @seq int Declare @lastLogBkpFile nvarchar(512) Declare @lastFullBkpFile nvarchar(512) Declare @msgErr nvarchar(max) Set @seq = 0 While (1=1) Begin Select top 1 @name = DbName , @seq = seq , @lastLogBkpFile = lastLogBkpFile , @lastFullBkpFile = lastFullBkpFile from #Tmp Where seq > @seq Order by seq If @@rowcount = 0 break If @PathOfBackupBeforeMaintenance = '' And @lastLogBkpFile Is Null Begin Raiserror (N'No backup for database %s', 11, 1, @name) --Print 'No backup for database «' + @name + '»' End Else Begin -- If a backup file is specified we restore form the Full backup in this path. -- Else we Restore the last Full Backup and all the log Backup until the start of the maintenance mode Begin Try If @PathOfBackupBeforeMaintenance <> '' Begin -- Kill all connection Before launching the RESTORE Command Set @sql = ' ALTER DATABASE [] SET Single_User WITH ROLLBACK IMMEDIATE ALTER DATABASE [] SET MULTI_USER WITH ROLLBACK IMMEDIATE Restore Database [] From Disk = "\.Bak" With stats=1, replace ' Set @sql = replace(@sql, '', @name) Set @sql = replace(@sql, '', @PathOfBackupBeforeMaintenance) Set @sql = replace(@sql, '"', '''') Set @sql = yExecNLog.Unindent_TSQL( @sql ) --print @sql exec(@sql) End Else Begin Exec yMaint.PrepareRestoreDbToLogMarkCommand @DbName=@name , @FullBkpFile=@lastFullBkpFile , @LogMarkName='PrepDbForMaintenanceMode' , @SqlCmd=@sql out -- Kill all connection Before launching the RESTORE Command Set @sql = ' ALTER DATABASE [] SET Single_user WITH ROLLBACK IMMEDIATE ALTER DATABASE [] SET MULTI_USER WITH ROLLBACK IMMEDIATE '+@Sql Set @sql = replace(@sql, '', @name) Set @sql = replace(@sql, '', @PathOfBackupBeforeMaintenance) Set @sql = replace(@sql, '"', '''') Set @sql = yExecNLog.Unindent_TSQL( @sql ) --print @sql exec(@sql) End Print @name + ' restored ' End Try Begin Catch Set @msgErr = @name + '> ' + ERROR_MESSAGE() Raiserror (N'%s', 11, 1, @msgErr) End Catch End End Drop Table #Tmp End -- Maint.RestoreDbAtStartOfMaintenanceMode GO -- -------------------------------------------------------------------------- -- Restore databases names to their original value and original recovery mode. -- Database list need to be supplied, and suffix use to rename the database. -- If the database is part of regular YourSqlDba full backups, then a new -- file backup set (a new total backup and a new log backup are directed to -- a new file set) so you keep backup before maintenance process. -- Backup files generated by PrepDbForMaintenanceMode at start of maintenance process -- are also left there and you must perform a manual cleanup of them. -- ------------------------------------------------------------------------- If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'Maint.ReturnDbToNormalUseFromMaintenanceMode' GO Create Procedure Maint.ReturnDbToNormalUseFromMaintenanceMode @DbList nVARCHAR(max) = '' -- @DbList : See comments later for further explanations , @DbNameSuffixForMaintenance nvarchar(128) as Begin Set nocount on Set @DbNameSuffixForMaintenance= isnull(@DbNameSuffixForMaintenance, '') Select d.name as Dbname, row_number() over (order by line) seq into #Tmp From yUtl.SplitParamInRows (@dbList) AS X join master.sys.databases d on d.name collate database_default = x.line + '_' + @DbNameSuffixForMaintenance Declare @dbOrig sysname Declare @sql nvarchar(max) Declare @seq int Declare @msgErr nvarchar(max) Declare @DbAndSuffix sysname Declare @recovery_model_saved Int Declare @recovery_model sysname Set @seq = 0 Select * from #tmp Begin Try While (1=1) Begin Select top 1 @DbAndSuffix = DbName, @seq = seq from #Tmp Where seq > @seq Order by seq If @@rowcount = 0 break -- remove the suffix from the name Set @dbOrig = STUFF( @DbAndSuffix , len(@DbAndSuffix)-Len(@DbNameSuffixForMaintenance) , Len(@DbNameSuffixForMaintenance)+1, '' ) Set @sql = ' Use []; Set @recovery_model_saved = convert(int, objectpropertyex(object_id("dbo.RecoveryModelBeforePrepDbForMaintenanceMode"), "isUserTable")) ' Set @sql = replace(@sql, '', @DbAndSuffix) Set @sql = replace(@sql, '"', '''') Exec Sp_ExecuteSql @Sql, N'@recovery_model_saved int output', @recovery_model_saved Output If @Recovery_model_saved = 1 Begin Set @sql = 'select @recovery_model = recovery_model_desc From [].dbo.RecoveryModelBeforePrepDbForMaintenanceMode' Set @sql = replace(@sql, '', @DbAndSuffix) Exec Sp_ExecuteSql @Sql, N'@recovery_model sysname output', @recovery_model Output Set @sql = ' If Db_name() <> "Master" Use Master; Alter database [] SET Single_User WITH ROLLBACK IMMEDIATE Alter database [] SET Multi_User Alter Database [] Set RECOVERY Drop Table [].dbo.RecoveryModelBeforePrepDbForMaintenanceMode ' Set @sql = replace(@sql, '', @DbAndSuffix) Set @sql = replace(@sql, '', @recovery_model) Set @sql = replace(@sql, '"', '''') Exec (@sql) End Set @sql = ' If Db_name() <> "Master" Use Master; Alter database [] SET Single_user WITH ROLLBACK IMMEDIATE Alter database [] MODIFY NAME = [] Alter database [] Set MULTI_USER With Rollback Immediate ' Set @sql = replace(@sql, '', @DbAndSuffix) Set @sql = replace(@sql, '', @dbOrig) Set @sql = replace(@sql, '"', '''') Exec (@sql) If Exists(Select * From [YourSQLDba].[Maint].[JobLastBkpLocations] Where dbName=@DbOrig And lastFullBkpFile Is Not Null) Begin Exec [YourSQLDba].[Maint].[SaveDbOnNewFileSet] @DbName=@DbOrig Update [YourSQLDba].[Maint].[JobLastBkpLocations] Set keepTrace=0 Where dbName=@DbOrig End Print @dbOrig + ' returned to normal use' End End Try Begin Catch Set @msgErr = @DbOrig + '> ' + ERROR_MESSAGE() Raiserror (N'%s', 11, 1, @msgErr) End Catch End -- Maint.ReturnDbToNormalUseFromMaintenanceMode GO -- required since all objects are qualified by YourSqlDba declare @job_id UniqueIdentifier declare @step_id int declare @tmp table (job_id UniqueIdentifier, step_id int) Insert into @tmp Select job_id, step_id from msdb.dbo.sysjobsteps Where step_name like '%YourSqlDba%' And database_name not like '%YourSqlDba%' -- for an unknow reason a direct update of database_name on this column doesn't work. -- so we look using sp_update_jobstep while (1=1) Begin Select top 1 @job_id = job_id, @step_id = step_id from @tmp If @@rowcount = 0 break EXEC msdb.dbo.sp_update_jobstep @job_id = @job_id, @step_id = @step_id, @database_name = N'YourSQLDba' Delete from @tmp where job_id = @job_id And step_id = @step_id End go -- --------------------------------------------------------------------------------------- -- Proc to create database export -- --------------------------------------------------------------------------------------- If objectpropertyEx(object_id('yExport.CreateExportDatabase'), 'isProcedure') = 1 Drop procedure yExport.CreateExportDatabase GO create procedure yExport.CreateExportDatabase @dbName sysname , @collation sysname = NULL , @stopOnError Int = 1 , @jobNo int as Begin set nocount on declare @sql nvarchar(max); set @sql = '' declare @sqlM nvarchar(max); set @sqlM = '' declare @minSizeData Int declare @minSizeLog Int declare @rc int Declare @fgId Int Declare @type_desc sysname Declare @fSpec nvarchar(max) Declare @fgn sysname Declare @Name sysname Declare @PhysicalName nvarchar(512) Declare @DataSpaceid int Declare @fileGroupName sysname Declare @fileGroupNameAv sysname Declare @FileId int Declare @Size nvarchar(40) Declare @maxSize nvarchar(40) Declare @maxSizeUnit nvarchar(40) Declare @Growth nvarchar(40) Declare @GrowthMode nvarchar(2) Declare @context nvarchar(200) Declare @Info nvarchar(max) Declare @err nvarchar(max) If databasepropertyex(@dbName+'_Export','status') IS NOT NULL Begin Set @err = 'Error - Database "' + @dbName + '_Export" must be removed first as it is the destination name of exported database "' + @dbName + '"' Exec yExecNLog.LogAndOrExec @context = 'yExport.CreateExportDatabase' , @Info = 'Database for export must not be there' , @err = @err , @jobNo = @jobNo , @raiseError = @stopOnError return(1) End Set @sql = ' CREATE DATABASE [_Export] ON Log On Collate ' Set @sql = REPLACE(@Sql, '', @dbName) If @collation Is Null Set @sql = REPLACE(@Sql, '', convert(sysname, DatabasepropertyEx(@dbName, 'Collation'))) else Set @sql = REPLACE(@Sql, '', @collation) Set @fileId = 0 Set @DataSpaceid = 0 Set @fileGroupNameAv = '' Set @fSpec = ' ' While (1=1) begin Set @sqlM = -- fichiers data, du groupe primaire en premier, puis des autres ' use [] Select Top 1 @FileId = file_id , @dataSpaceId = data_space_id , @fileGroupName = Filegroup_Name (data_space_id) , @Name = name , @PhysicalName = physical_name , @Size = str(Case when size / 10 < 1024*200 Then 1024*200 else (size / 10) * 8 End)+"KB" -- translate to KB actually 8Kb pages , @MaxSize = Case When max_Size <= 0 Then "Unlimited" When max_Size = 268435456 Then "2" Else STR(max_size * 8,10) End , @maxSizeUnit = Case when max_Size = -1 Then "" when max_Size = 268435456 Then "TB" Else "KB" End , @Growth = Case When is_percent_growth = 1 then Str(Growth,10) Else 1024*200 End -- translate to KB 8KB pages , @GrowthMode = Case When is_percent_growth = 1 Then "%" Else "KB" End From sys.database_files d Where data_space_id > 0 And -- no log files Str(data_space_id)+Str(File_id) > Str(@dataSpaceId)+Str(@Fileid) And (convert(nvarchar, serverproperty("productversion")) not like "9.%" Or type_desc <> "FULLTEXT") -- exclude unusual file setup made when a sql2005 database with full text is restored to a version above And not exists(select * from sys.fulltext_Catalogs F where F.name = replace(d.name, "ftrow_", "")) Order by data_space_id, File_id ' Set @sqlM = replace (@sqlM, '', @dbName) Set @sqlM = replace (@sqlM, '"', '''') Exec sp_executeSql @SqlM ,N' @FileId int output , @dataSpaceId int output , @fileGroupName sysname output , @Name sysname Output , @PhysicalName nvarchar(512) Output , @Size nvarchar(40) Output , @MaxSize nvarchar(40) Output , @maxSizeUnit nvarchar(40) Output , @Growth nvarchar(40) Output , @GrowthMode nvarchar(2) Output ' , @FileId = @FileId Output , @dataSpaceId = @dataSpaceId Output , @fileGroupName = @fileGroupName Output , @Name = @name Output , @PhysicalName = @PhysicalName output , @Size = @Size Output , @maxSize = @maxSize Output , @maxSizeUnit = @maxSizeUnit Output , @Growth = @Growth Output , @GrowthMode = @GrowthMode Output if @@ROWCOUNT = 0 Break If @FileGroupNameAv <> @fileGroupName Begin Set @fSpec = REPLACE( @fSpec, '' , Case -- avoid use of primary keyword and add a comma if more that one file When @fileGroupName = 'Primary' Then '' Else 'FILEGROUP ' +@FileGroupName End) Set @FileGroupNameAv = @fileGroupName End Else Set @fSpec = REPLACE(@fSpec, ', ', ', ') Set @fSpec = REPLACE(@fSpec, '', ' ( NAME = , FILENAME = "" , SIZE = , MAXSIZE = , FILEGROWTH = ) , ' ) Set @fSpec = REPLACE(@fSpec, '', Replace (@name, @dbName, @dbName+'_Export')) Set @fSpec = REPLACE(@fSpec, '', Replace (@physicalName, @dbName, @dbName+'_Export') ) Set @fSpec = REPLACE(@fSpec, '', @Size) Set @fSpec = REPLACE(@fSpec, '', @maxSize + @maxSizeUnit) Set @fSpec = REPLACE(@fSpec, '', @Growth + @growthMode) End Set @fSpec = REPLACE(@fSpec, ', ', '') -- remove remaining tag Set @fSpec = REPLACE(@fSpec, '', '') -- remove remaining tag Set @Sql = REPLACE (@sql, '', @fSpec) -- insert it into create database stmt Set @fileId = 0 Set @fSpec = ' ' While (1=1) begin Set @sqlM = -- fichiers data, du groupe primaire en premier, puis des autres ' use [] Select Top 1 @FileId = file_id , @dataSpaceId = data_space_id , @fileGroupName = Filegroup_Name (data_space_id) , @Name = name , @PhysicalName = physical_name , @Size = str(Case when size / 10 < 1024*200 Then 1024*200 else (size / 10) * 8 End)+"KB" -- translate to KB actually 8Kb pages , @MaxSize = Case When max_Size <= 0 Then "Unlimited" When max_Size = 268435456 Then "2" Else STR(max_size * 8,10) End , @maxSizeUnit = Case when max_Size = -1 Then "" when max_Size = 268435456 Then "TB" Else "KB" End , @Growth = Case When is_percent_growth = 1 then Str(Growth,10) Else 1024*200 End -- translate to KB 8KB pages , @GrowthMode = Case When is_percent_growth = 1 Then "%" Else "KB" End From sys.database_files Where data_space_id = 0 And -- log files Str(File_id) > Str(@Fileid) Order by File_id ' Set @sqlM = replace (@sqlM, '', @dbName) Set @sqlM = replace (@sqlM, '"', '''') Exec sp_executeSql @SqlM ,N' @FileId int output , @dataSpaceId int output , @fileGroupName sysname output , @Name sysname Output , @PhysicalName nvarchar(512) Output , @Size nvarchar(40) Output , @MaxSize nvarchar(40) Output , @maxSizeUnit nvarchar(40) Output , @Growth nvarchar(40) Output , @GrowthMode nvarchar(2) Output ' , @FileId = @FileId Output , @dataSpaceId = @dataSpaceId Output , @fileGroupName = @fileGroupName Output , @Name = @name Output , @PhysicalName = @PhysicalName output , @Size = @Size Output , @maxSize = @maxSize Output , @maxSizeUnit = @maxSizeUnit Output , @Growth = @Growth Output , @GrowthMode = @GrowthMode Output if @@ROWCOUNT = 0 Break Set @fSpec = REPLACE(@fSpec, '', '( NAME = , FILENAME = "" , SIZE = , MAXSIZE = , FILEGROWTH = ) , ') Set @fSpec = REPLACE(@fSpec, '', Replace (@name, @dbName, @dbName+'_Export')) Set @fSpec = REPLACE(@fSpec, '', Replace (@physicalName, @dbName, @dbName+'_Export')) Set @fSpec = REPLACE(@fSpec, '', @size) Set @fSpec = REPLACE(@fSpec, '', @maxSize+@maxSizeUnit) Set @fSpec = REPLACE(@fSpec, '', @Growth+@GrowthMode) End Set @fSpec = REPLACE(@fSpec, ', ', '') -- remove remaining tag Set @Sql = REPLACE (@sql, '', @fSpec) -- put it into create database Set @sql = replace(@sql, '"', '''') Exec yExecNLog.LogAndOrExec @jobNo = @jobNo , @context = 'yExport.CreateExportDatabase' , @Info = 'Running create database for database export' , @sql = @sql , @raiseError = @stopOnError End -- yExport.CreateExportDatabase GO If Db_name() <> 'YourSqlDba' Use YourSqlDba GO if objectpropertyEx(object_id('yExport.ExportData'), 'isProcedure') = 1 Drop Procedure yExport.ExportData GO Create Procedure yExport.ExportData @dbName sysname , @stopOnError Int = 1 , @jobNo Int as Begin Set nocount on declare @sql nvarchar(max) -- Declare @nbRow int declare @rc int declare @Ks sysname -- schéma de foreign key declare @USn sysname -- schéma de clé primaire référencée par foreign key declare @Kn sysname -- nom de foreign key declare @Sn sysname -- nom de schema d'index ou de table declare @Tn sysname -- nom de table declare @UTn sysname -- nom de table de clé primaire référencée par foreign key declare @mn sysname -- module name Declare @seqFk Int Declare @cn sysname -- nom de colonne Declare @iden int -- clause identity Declare @defIden sysname -- définition de la clause identity Declare @fgDef sysname -- définition du filegroup de table pour les LOB Declare @fgDat sysname -- définition de filegroup de table pour les rangées Declare @fgLob sysname -- définition du filegroup de table pour les LOB Declare @fgIdx sysname -- définition du filegroup de l'index Declare @is_computed int -- si colonne calculée Declare @computedColDef nvarchar(max) -- si colonne calculée, sa définition declare @Ucn sysname -- nom de colonne de clé primaire référencée par foreign key declare @In sysname -- nom d'index ou de clé primaire ou de contrainte unique declare @Pk Int -- indicateur clé primaire declare @typDesc Sysname -- type d'index clustered, nonclustered declare @dcn sysname -- nom de contrainte default declare @DefName sysname -- définition du default declare @typ sysname -- type d'une colonne ou type d'un objet selon le bout de code local declare @nouvTyp sysname -- nouveau type d'une colonne dans cas de char, varchar, text, image declare @lc nvarchar(8) -- définition de longueur d'une colonne declare @nullSpec nvarchar(8) -- spéc. NULL, NOT NULL Declare @seq Int -- sequence de traitement dans les tables Declare @seqT Int -- sequence des tables Declare @seqC Int -- séquence des colonnes Declare @Def nvarchar(max) -- définition de l'expression qui donne le defaut d'une colonne Declare @Cols nvarchar(max) -- liste des colonnes Declare @ligCols nvarchar(max) -- liste des colonnes sur une même ligne Declare @ColsSelect nvarchar(max) -- liste des colonnes d'une table pour select into, ou colonne d'un index selon usage Declare @colsCreateTable nvarchar(max) -- liste des colonnes d'une table pour alter constraint Declare @colsInsertInto nvarchar(max) -- liste alter des colonnes d'une table pour alter null not null Declare @uCols nvarchar(max) -- liste des colonnes de la clé primaire référencée par la clé unique Declare @ColIdxChar Int Declare @schemaAlt int -- says that a view nust be used to pump the data Declare @ko int -- ordre des colonnes dans la clé Declare @iUniq int -- index unique ou pas Declare @iUniqC Int -- contrainte unique mais pas nécessairement primary key Declare @FKOnClause NVARCHAR(255) Declare @is_not_trusted int -- indique si la contrainte de foreigh key est activée Declare @Info nvarchar(max) Declare @seqIx Int Declare @BigLig nvarchar(max) Declare @IndexOnView int Declare @Created int Declare @FunctionCreated int Declare @TableCreated int Declare @Anull int Declare @qIden int declare @err nvarchar(max) Begin try Create table #Schemas ( Sn sysname Not NULL primary key clustered ) -- table des définitions des types create table #UserDefTypes ( seq int primary key clustered , sn sysname NOT NULL -- nom schema , un sysname NOT NULL -- nom user type , typ sysname NOT NULL -- type , lc nvarchar(10) NULL -- longueur facultative , nullspec nvarchar(10) NULL -- ajouter null ou not null ) -- table des définitions de foreigh key -- if object_id('tempdb..#RefConstraints') is not null drop table #RefConstraints create table #RefConstraints ( seq int primary key clustered , Sn sysname not NULL , Tn sysname not NULL , Kn sysname not NULL , USn sysname not NULL , UTn Sysname Not NULL , UKn sysname not NULL , RefObjId Int not NULL , KeyId Int not NULL , MATCH_OPTION sysname not NULL , UPDATE_RULE sysname not NULL , DELETE_RULE sysname not NULL , Is_not_trusted int not null ) -- liste des colonnes impliquées dans contraintes d'intégrité référentielle des foreigh key -- if object_id('tempdb..#ColsRefConstraints') is not null drop table #ColsRefConstraints create table #ColsRefConstraints ( Sn sysname NOT NULL , Tn sysname NOT NULL , Kn sysname NOT NULL , ordCol Int NOT NULL , cn sysname NOT NULL , USn sysname NOT NULL , UKn sysname NOT NULL , UTn sysname NOT NULL , Ucn sysname NOT NULL ) Create unique clustered index iKC on #ColsRefConstraints (Sn, Tn, Kn, OrdCol) -- liste des tables d'une BD -- if object_id('tempdb..#TablesToExport') is not null drop table #TablesToExport create table #TablesToExport ( seq int primary key clustered , sn sysname NOT NULL -- nom schema , tn sysname NOT NULL -- nom table , Id int NOT NULL -- id de la table , Iden int NOT NULL -- a un identity , fgLob sysname NOT NULL Default '' -- filegroup pour LOB , fgDat sysname NOT NULL Default '' -- filegroup du Data , fgDef sysname NOT NULL Default '' -- default filegroup amoung filegroups ) -- --------------------------------------------------------------------------------------------------- -- table qui conserve les instructions pour rebâtir les statistiques d'origine crées par auto-stats -- --------------------------------------------------------------------------------------------------- -- informations pour regénérer des statistiques sur colonnes des statistiques auto-générées d'une BD -- if object_id('tempdb..#Stats') is not null drop table #Stats create table #Stats ( seq int primary key clustered , sn sysname NOT NULL -- nom schema , tn sysname NOT NULL -- nom table , cn sysname NOT NULL -- nom colonne ) -- liste des colonnes des tables -- if object_id('tempdb..#ColsTablesAMigr') is not null drop table #ColsTablesAMigr create table #ColsTablesAMigr ( sn sysname NOT NULL -- nom schema , tn sysname NOT NULL -- nom table , cn sysname NOT NULL -- nom colonne , typ sysname NOT NULL -- type , defIden sysname NOT NULL -- si elle a une définition identity , lc sysname NOT NULL -- nouvelle longueur comme dans définition de table , DefName sysname NOT NULL -- nom du défaut s'il existe , Def nvarchar(max) NOT NULL -- expression qui le représente s'il existe , nullSpec sysname NOT NULL -- signale si la colonne peut être mise à null , is_computed int not null -- signale si c'est une colonne calculée , computedColDef nvarchar(max) NULL -- expression de colonne calculée si c'est le cas , OrdCol int NOT NULL -- position relative croissante des colonnes, trous possibles dans séquence ) Create unique clustered index iTC on #ColsTablesAMigr (Sn, Tn, OrdCol) -- liste des index des tables -- if object_id('tempdb..#Indexes') is not null drop table #Indexes Create table #Indexes ( sn sysname NOT NULL , tn sysname NOT NULL , IdxName sysname NOT NULL , type_desc sysname NOT NULL , is_unique int NOT NULL , is_primary_key int NOT NULL , is_unique_constraint int NOT NULL , object_id Int NOT NULL , index_id Int NOT NULL , fgIdx sysname NOT NULL Default '' , IndexOnView int null ) Create unique clustered index iIX on #Indexes (Sn, Tn, IdxName) -- liste des colonnes des index des tables Declare @seqIxc Int -- if object_id('tempdb..#IndexesCols') is not null drop table #IndexesCols Create table #IndexesCols ( sn sysname NOT NULL , tn sysname NOT NULL , IdxName sysname NOT NULL , cn sysname NOT NULL , Seq Int Identity NOT NULL -- pour rendre la clé ci dessous unique, pas uilisée ailleurs , Ko int NOT NULL , ColIdxChar int not NULL -- pour signaler si type Char ou pas ) Create unique clustered index iIXC on #IndexesCols (sn, tn, IdxName, seq, ko) print '===========================================================================================' print '-- ['+@dbName+'] Data export ' print '===========================================================================================' -- optimiser l'insertion massive, plus tard remettre les options en place Set @sql= ' Alter database [_export] Set recovery Simple ' Set @sql = replace(@sql, '', @dbName) Exec yExecNLog.LogAndOrExec @jobNo = @jobNo , @context = 'yExport.ExportData' , @Info = 'Put Export Db is simple recovery' , @sql = @sql , @raiseError = @stopOnError -- --------------------------------------------------------------------------------------------------- -- generate stmt to rebuild stats -- --------------------------------------------------------------------------------------------------- Set @sql = ' use [] ;With ColWithStats as ( select Distinct Schema_name(OB.schema_id) as sn , Ob.name as Tn , c.name as Cn From sys.stats Ixs join sys.objects OB ON OB.object_id = Ixs.Object_id Join sys.stats_columns Ixc ON Ixc.object_id = Ixs.object_id And Ixc.stats_id = Ixs.stats_id join sys.columns C On c.object_id = Ixc.object_id And c.column_id = Ixc.column_id Where objectpropertyEx(ixs.object_id, "IsUserTable") = 1 And not exists(Select * from sys.indexes I where I.name = Ixs.name) And Schema_name (OB.schema_id) NOT IN ("sys") And objectpropertyEx(OB.object_id, "isMsShipped") = 0 -- on veut pas toucher aux objets -- systèmes ex: Dt% And not (ob.name = "sysdiagrams" and Schema_name(OB.schema_id)="dbo") ) Insert into #Stats (seq, sn, tn, cn) Select row_number() over (order by sn, tn, cn) as Seq , sn , Tn , Cn From ColWithStats ' set @sql = replace (@sql, '', @dbName) Set @sql = replace(@sql, '"', '''') Exec yExecNLog.LogAndOrExec @jobNo = @jobNo , @context = 'yExport.ExportData' , @Info = 'Recording info to rebuild original stats' , @sql = @sql , @raiseError = @stopOnError -- --------------------------------------------------------------------------------------------------- -- List existing schema to recreate them -- --------------------------------------------------------------------------------------------------- Set @sql = ' Use [] truncate table #Schemas Insert into #Schemas (sn) select name as Sn from (select distinct schema_id from sys.objects) as Ob join sys.schemas S on S.schema_id = Ob.schema_id where name not in ("dbo", "sys") ' set @sql = replace (@sql, '', @dbName) set @sql = replace (@sql, '', convert(sysname, Serverproperty('Collation'))) Set @sql = replace(@sql, '"', '''') Exec yExecNLog.LogAndOrExec @jobNo = @jobNo , @context = 'yExport.ExportData' , @Info = 'Recording info to rebuild original schema' , @sql = @sql , @raiseError = @stopOnError -- --------------------------------------------------------------------------------------------------- -- save definitions of foreign key, primary key, index clustered (non primaire), and index -- to recreate them after data load -- --------------------------------------------------------------------------------------------------- Set @sql = ' Use [] truncate table #RefConstraints Insert into #RefConstraints (Seq, Sn, Tn, Kn, USn, UTn, RefObjId, KeyId, UKn, MATCH_OPTION, UPDATE_RULE, DELETE_RULE, is_not_trusted) select row_number() Over (Order by TU.constraint_catalog, TU.constraint_schema, TU.Table_name) , TU.constraint_schema , TU.Table_name , TU.constraint_name , isnull(rc.UNIQUE_CONSTRAINT_SCHEMA,"") , isnull(object_name(FK.referenced_object_id), "") , FK.referenced_object_id , FK.Key_index_id , isnull(rc.UNIQUE_CONSTRAINT_NAME,"") , isnull(RC.MATCH_OPTION,"") , isnull(RC.UPDATE_RULE,"") , isnull(RC.DELETE_RULE,"") , fk.is_not_trusted from information_schema.constraint_table_usage TU Join sys.foreign_keys FK On FK.name = TU.Constraint_name join INFORMATION_SCHEMA.REFERENTIAL_CONSTRAINTS RC on rc.CONSTRAINT_NAME = TU.CONSTRAINT_NAME ' set @sql = replace (@sql, '', @dbName) set @sql = replace (@sql, '', convert(sysname, Serverproperty('Collation'))) Set @sql = replace(@sql, '"', '''') Exec yExecNLog.LogAndOrExec @jobNo = @jobNo , @context = 'yExport.ExportData' , @Info = 'Recording referential constrains info to rebuild them' , @sql = @sql , @raiseError = @stopOnError -- query that extract relations between foreign key and their columns matching with primary key and their columns Set @sql = ' truncate table #ColsRefConstraints Insert into #ColsRefConstraints (Sn, Tn, Kn, OrdCol, Cn, USn, UKn, UTn, UCn) Select K.Sn, K.Tn, K.Kn, cu.Ordinal_position, cu.Column_name , ISNULL (S.name, "") , ISNULL (Ix.name, "") , ISNULL (Ob.name, "") , ISNULL (c.name, "") From #RefConstraints K JOIN [].INFORMATION_SCHEMA.KEY_COLUMN_USAGE CU ON CU.CONSTRAINT_SCHEMA = K.Sn Collate And CU.CONSTRAINT_NAME = K.Kn Collate left JOIN -- index clé primaire ou index unique référencé (IX.name) [].sys.indexes IX on Ix.object_id = K.RefObjId And Ix.index_id = K.KeyId left JOIN -- table référencé (Ob.name) [].sys.objects Ob on ob.Object_Id = K.RefObjId left JOIN -- schema si index unique référencé (S.name) [].sys.schemas S on S.Schema_id = Ob.Schema_id LEFT JOIN -- id colonnes de la clé primaire ou de l"index unique référencé [].sys.index_columns Ixc ON Ixc.object_id = K.refObjId And Ixc.index_id = K.KeyId And Ixc.key_Ordinal = CU.ordinal_position LEFT JOIN -- colonnes de la clé primaire ou de l"index unique référencé (C.name) [].sys.columns c ON c.object_id = Ixc.object_id And c.column_id = Ixc.column_id ' set @sql = replace (@sql, '', convert(sysname, Serverproperty('Collation'))) set @sql = replace (@sql, '', @dbName) Set @sql = replace(@sql, '"', '''') Exec yExecNLog.LogAndOrExec @jobNo = @jobNo , @context = 'yExport.ExportData' , @Info = 'Recording referential constrains relations between columns ' , @sql = @sql , @raiseError = @stopOnError -- --------------------------------------------------------------------------------------------------- -- rebuild table one at the time -- tablelock hint on insert allows minimally logged operation in version above sql2005 -- when table is empty and still a heap -- --------------------------------------------------------------------------------------------------- -- make table list Set @sql = ' Use [] Truncate table #TablesToExport Insert into #TablesToExport(seq, sn, tn, Id, iden, fgLob, fgDat, fgDef) Select ROW_NUMBER() OVER (Order by S.name, T.name) , S.name as sn , T.name as tn , T.object_id as Id , Case When II.object_id is Not NULL Then 1 Else 0 End as Iden , Case -- on remplace DATA par PRIMARY car on laisse tomber le fichier DATA When T.lob_data_space_id >= 1 AND T.lob_data_space_id <= 2 Then "Primary" Else isnull(filegroup_name(T.lob_data_space_id), "") End As FgLob , Case When I.data_space_id <= 2 Then "Primary" Else isnull(filegroup_name(I.data_space_id), "") End As FgDat , (select top 1 name from sys.filegroups where is_default =1) as fgDef from sys.tables T join sys.indexes I on I.object_id = T.object_id And index_id in (0,1) join sys.Schemas S On S.schema_id = T.schema_id left join sys.identity_columns II On II.object_id = T.object_id Where objectpropertyEx(I.object_id, "isMsShipped") = 0 -- avoid system tables Dt% And not (T.name = "sysdiagrams" And S.name = "dbo") -- special case to handle ' set @sql = replace (@sql, '', convert(sysname, Serverproperty('Collation'))) Set @sql = replace(@sql, '', @dbName) Set @sql = replace(@sql, '"', '''') Exec yExecNLog.LogAndOrExec @jobNo = @JobNo , @context = 'yExport.ExportData' , @Info = 'Recording tables to migrate ' , @sql = @sql , @raiseError = @stopOnError --------------------------------------------------------------------------------------- -- collect useful column info that will allow to inactivate and reactivate -- défaults --------------------------------------------------------------------------------------- Set @sql = ' use [] truncate table #ColsTablesAMigr ;With TabList as ( /* (Select "dbo" as sn, name as tn, object_id as id, 0 as iden, * from [].sys.tables ) as T */ Select * From #TablesToExport as T ) , colNamesTypesCharLenPrecScale as ( Select object_id , sc.name collate Latin1_General_CI_AI as column_name , st.name collate Latin1_General_CI_AI as data_type , column_id , case when sc.max_length> 1 And type_name(sc.system_type_id) like "N%CHAR" then sc.max_length / 2 else sc.max_length End character_maximum_length -- longueur en caractères pas en byte , sc.precision as numeric_precision , sc.scale as numeric_scale From sys.columns sc left join sys.types ST -- ne plus utiliser type_name() en dehors du contexte de Bd On ST.user_type_id = Sc.user_type_id ) , CompleteBaseInfoOnTable as ( Select T.Sn As Sn , T.Tn As Tn , T.Iden As Iden , sc.name As Cn , Cn.data_type As Typ , Cn.column_id As OrdCol , Cn.character_maximum_Length as CharMaxLen , convert(nvarchar(30), Cn.character_maximum_Length) as StrCharMaxLen , Cn.numeric_precision , Cn.numeric_scale , isnull(d.definition,"") As def , Sc.is_nullable as is_nullable , Sc.is_computed as is_computed , Scc.definition as computedColDef , Coalesce ( Case When d.name is NULL Then "[DF_"+sn+"_"+tn+"_"+cn.column_name+"]" End , Case When M.name is NULL Then "[DF_Bind_"+sn+"_"+tn+"_"+cn.column_name+"]" End , "" ) As DefName , II.column_id as IdenColumn_id , II.Seed_Value as IdenSeed_Value , II.Increment_value as IdenIncrement_Value From TabList as T Join colNamesTypesCharLenPrecScale as Cn On Cn.object_id = T.Id Join sys.columns Sc On Sc.object_id = T.Id And Sc.name = Cn.column_name left join sys.computed_columns scc -- pour obtenir définition de la colonne calculée on sc.is_computed = 1 And -- optimiser avant joindre scc.object_id = Sc.object_id And scc.column_id = sc.column_id left join sys.objects m on m.object_id = Sc.default_object_id left Join -- un seule par table sys.identity_columns II On T.iden = 1 And -- join pas si pa siden sur table II.object_id = Sc.object_id And II.column_id = Sc.column_id left Join -- pas nécessairement de défaut sys.default_constraints d On d.parent_object_id = T.Id And d.parent_column_id = sc.column_id ) Insert into #ColsTablesAMigr (sn, tn, cn, typ, lc, defIden, DefName, def, nullSpec, is_computed, computedColDef, ordCol) Select Sn , Tn , Cn as cn , Typ as Typ , Case -- définition / susbtitution de la longueur When Typ like "%CHAR%" or Typ like "%BINARY%" Then Case When StrCharMaxLen = "-1" Then "(Max)" Else "(" + StrCharMaxLen +")" End When Typ IN ("Decimal", "Numeric") Then "("+ convert(nvarchar, numeric_precision)+"," + convert(nvarchar, numeric_scale)+ ")" Else "" -- pas de longueur spécifiable pour ce type End as lc , Case -- clause identity à mettre ? When IdenColumn_Id is NULL Then "" Else "Identity ("+convert(varchar(40), IdenSeed_value)+","+convert(varchar(40), IdenIncrement_value)+")" End as DefIden , DefName , Def , Case -- retiennent atribut nullable orginal When is_nullable = 0 Then "NOT NULL" Else "NULL" End as nullSpec , is_computed , computedColDef , OrdCol -- ordre de la colonne dans la table From CompleteBaseInfoOnTable ' set @sql = replace (@sql, '', convert(sysname, Serverproperty('Collation'))) Set @sql = replace(@sql, '', @dbName) Set @sql = replace(@sql, '"', '''') Exec yExecNLog.LogAndOrExec @jobNo = @JobNo , @context = 'yExport.ExportData' , @Info = 'Recording column info. of tables to migrate' , @sql = @sql , @raiseError = @stopOnError ------------------------------------------------------------- -- info to recreate user defined types ------------------------------------------------------------- Set @sql = ' use [] ;With moreConvientUserTypesNameInfo as ( Select Sh.name as Schema_name , U.name as Uname , S.name as Typ , U.max_length as charMaxLen , convert(varchar, U.max_length) as StrcharMaxLen , U.precision as numeric_precision , U.scale as numeric_scale , Case When U.is_Nullable = 0 Then "NOT NULL" Else "NULL" End as NullSPec From sys.types U join sys.schemas SH On SH.schema_id = U.Schema_id join sys.types S On S.user_type_id = U.system_type_id where U.is_user_defined = 1 ) Insert into #UserDefTypes ( seq -- no seq pour traitement seq , sn -- nom schema , un -- nom user type , typ -- type , lc -- longueur facultative , nullspec -- ajouter null ou not null ) Select Row_number() Over (Order by Schema_name, Uname) as Seq , Schema_name , Uname , Typ , Case -- définition / susbtitution de la longueur When Typ like "%char%" or Typ like "%binary%" Then Case When StrCharMaxLen = "-1" Then "(Max)" Else "("+StrCharMaxLen+")" End When Typ IN ("Decimal", "Numeric") Then "("+ convert(nvarchar, numeric_precision)+"," + convert(nvarchar, numeric_scale)+ ")" Else "" -- pas de longueur spécifiable pour ce type End as lc , NullSPec from moreConvientUserTypesNameInfo ' Set @sql = replace(@sql, '', @dbName) Set @sql = replace(@sql, '"', '''') Exec yExecNLog.LogAndOrExec @jobNo = @JobNo , @context = 'yExport.ExportData' , @Info = 'Recording data type info. of columns of tables to migrate' , @sql = @sql , @raiseError = @stopOnError -- interesting trace ---select * from #TablesToExport ---select * from #ColsTablesAMigr ------------------------------ -- keep tables index info ------------------------------ Set @sql = ' Use [] truncate table #Indexes insert into #Indexes select T.sn , T.tn , Ix.name as IdxName , Ix.type_desc , Ix.is_unique , Ix.is_primary_key , Ix.is_unique_constraint , Ix.Object_id , Ix.Index_id , Case When Ix.data_space_id <= 2 Then "Primary" Else isnull(filegroup_name(Ix.data_space_id), "") End As FgDat , convert(int, objectpropertyex(object_id, "isView")) as IndexonView From #TablesToExport T join sys.indexes Ix ON Ix.object_id = T.Id And Ix.is_hypothetical = 0 And Ix.type_desc NOT IN ("HEAP", "XML") Order By T.Sn, T.Tn, Ix.name ' set @sql = replace (@sql, '', convert(sysname, Serverproperty('Collation'))) Set @sql = replace(@sql, '', @dbName) Set @sql = replace(@sql, '"', '''') Exec yExecNLog.LogAndOrExec @jobNo = @JobNo , @context = 'yExport.ExportData' , @Info = 'Recording index info.' , @sql = @sql , @raiseError = @stopOnError Set @sql = ' Use [] truncate table #IndexesCols insert into #IndexesCols (sn, tn, IdxName, cn, ko, ColIdxChar) select Ix.Sn, Ix.Tn, Ix.IdxName, c.name as nomCol, ixc.key_ordinal, Case When st.name in ("char", "nchar", "varchar", "nvarchar", "sysname", "Text") Then 1 Else 0 End From #Indexes Ix join sys.index_columns Ixc ON Ixc.object_id = Ix.object_id And Ixc.index_id = Ix.index_id join sys.columns C On c.object_id = Ixc.object_id And c.column_id = Ixc.column_id join master.sys.types st On st.system_type_id = C.system_type_id Order by sn, tn, IdxName, ixc.key_ordinal ' set @sql = replace (@sql, '', convert(sysname, Serverproperty('Collation'))) Set @sql = replace(@sql, '', @dbName) Set @sql = replace(@sql, '"', '''') Exec yExecNLog.LogAndOrExec @jobNo = @JobNo , @context = 'yExport.ExportData' , @Info = 'Recording columns'' indexes info.' , @sql = @sql , @raiseError = @stopOnError Declare @iType sysname Declare @fk int Declare @PremCol int -- ----------------------------------------------------------------------------------------------------- -- create schema -- ----------------------------------------------------------------------------------------------------- Set @sn = '' While (1=1) Begin Select top 1 @sn = sn -- next schema From #Schemas Where sn > @Sn Order by sn If @@rowcount = 0 Break -- no more exit Set @sql = ' use [_export] exec("Create Schema [] authorization dbo") ' Set @sql = replace(@sql, '"', '''') Set @sql = replace(@sql, '', @dbName) Set @sql = replace(@sql, '', @sn) Exec yExecNLog.LogAndOrExec @jobNo = @JobNo , @context = 'yExport.ExportData' , @Info = 'Create schema' , @sql = @sql , @raiseError = @stopOnError End -- ----------------------------------------------------------------------------------------------------- -- rebuild user datatypes -- ----------------------------------------------------------------------------------------------------- Set @seq = 0 While (1=1) Begin Select top 1 @sn = sn , @nouvTyp = un , @typ = typ , @lc = ISNULL(lc, '') , @nullSpec = ISNULL(nullSpec, '') , @seq = seq From #UserDefTypes Where seq > @seq Order by seq If @@rowcount = 0 Break -- no more, exit Set @sql = ' use [_export] exec("Create Type [].[] From ") ' Set @sql = replace(@sql, '"', '''') Set @sql = replace(@sql, '', @dbName) Set @sql = replace(@sql, '', @sn) Set @sql = replace(@sql, '', @nouvTyp) Set @sql = replace(@sql, '', @typ) Set @sql = replace(@sql, '', @lc) Set @sql = replace(@sql, '', @nullSpec) Exec yExecNLog.LogAndOrExec @jobNo = @JobNo , @context = 'yExport.ExportData' , @Info = 'Create data types' , @sql = @sql , @raiseError = @stopOnError End create table #defFunc ( seq int primary key , sn sysname , ModuleName sysname , def nvarchar(max) , anull int , qIden int ) Set @sql = ' use [] Truncate table #defFunc Insert into #defFunc Select ROW_NUMBER() Over (order by object_name(object_id)) , schema_name(convert(int, objectpropertyex(object_id, "schemaId"))) as Sn , object_name(object_id) , definition , uses_ansi_nulls as aNull , uses_quoted_identifier as qIden From Sys.sql_modules Where OBJECTPROPERTYEX (object_id, "IsScalarFunction") = 1 ' Set @sql = replace(@sql, '"', '''') Set @sql = replace(@sql, '', @dbName) Exec yExecNLog.LogAndOrExec @jobNo = @JobNo , @context = 'yExport.ExportData' , @Info = 'Recreate scalar function and/or views that may be recreated' , @sql = @sql , @raiseError = @stopOnError While (1=1) -- at least one scalar function view or table is created Begin -- --------------------------------------------------------------------------------------------- -- Recreate scalar udf that can be used as default -- try a blind recreate ignoring what can't be created -- only do the attempt for schema bound objects -- --------------------------------------------------------------------------------------------- Set @Created = 0 -- flag as if nothing was created for the loop below Set @seq = 0 Set @FunctionCreated = 0 -- to know if this pass has created at least a function While(1=1) Begin Select top 1 @seq = seq , @sn = sn , @mn = ModuleName , @def = def , @ANull = Anull , @qIden = qIden from #defFunc Where seq > @seq Order by seq If @@rowcount = 0 -- end of table If @Created = 1 -- at least one function could be created Begin Set @seq = 0 -- retry another pass in case some other fonction depends on one just created set @Created = 0 -- just to know if the next pass has created nothing continue End Else Break set @sql = ' Use [_export] set ansi_nulls ; Set quoted_identifier ; If object_id("[].[]") is null Begin begin try Execute sp_executeSql @def end try begin catch Print error_number() Print error_message() end catch End -- not all errors are caught If object_id("[].[]") is not null Set @created = 1 Else Set @created = 0 ' Print 'try create ['+@sn+'].['+@mn+']' print '------------------------------------------' Set @sql = replace(@sql, '"', '''') Set @sql = replace(@sql, '', @dbName) Set @sql = replace(@sql, '', @sn) Set @sql = replace(@sql, '', @mn) Set @Sql = replace(@Sql, '', case When @aNull = 1 Then 'On' Else 'Off' End) Set @Sql = replace(@Sql, '', case When @qIden = 1 Then 'On' Else 'Off' End) Exec sp_executeSql @Sql, N'@Def nvarchar(max), @created int output', @def, @created output If @created = 1 -- certains cas d'erreur ne sont pas capturés Begin Set @FunctionCreated = @FunctionCreated + 1 Print 'object '+ @sn+'.'+@mn+ ' created' print '------------------------------------------' Delete From #defFunc Where seq = @seq -- remove already created function End Else begin print @sql Exec yExecNLog.PrintSqlCode @sql = @def, @numberingRequired = 1 Print 'object '+ @sn+'.'+@mn+ ' not created' print '------------------------------------------' end End -- --------------------------------------------------------------------------------------------- -- Export data one table at the time -- --------------------------------------------------------------------------------------------- -- Select * from #TablesToExport Set @TableCreated = 0 -- to know if this pass has created at least a table Set @seqT = 0 While (1=1) -- process all tables Begin Select top 1 @sn = sn , @tn = tn , @seqT = seq , @iden = Iden , @fgLob = fgLob , @fgDat = fgDat , @fgDef = fgDef From #TablesToExport Where seq > @SeqT Order by seq If @@rowcount = 0 Break Set @Info = ' --Export to [_export].[].[] à partir de [].[].[] ' Set @sql = replace(@sql, '"', '''') Set @sql = replace(@sql, '', @dbName) Set @sql = replace(@sql, '', @sn) Set @sql = replace(@sql, '', @tn) Exec yExecNLog.LogAndOrExec @jobNo = @JobNo , @context = 'yExport.ExportData' , @Info = @Info , @raiseError = @stopOnError ----------------------------------------------------- -- build column list ----------------------------------------------------- Set @ColsSelect = '' Set @colsCreateTable = '' Set @colsInsertInto = '' Set @seqc = 0 While (1=1) Begin Select Top 1 @cn = cn , @typ = typ , @lc = lc , @defIden = defIden , @DefName = DefName , @def = Def , @nullSpec = nullSpec , @is_computed = is_computed , @computedColDef = computedColDef , @seqc = OrdCol From #ColsTablesAMigr Where sn = @Sn And tn = @Tn and ordCol > @seqc Order by ordCol If @@rowcount = 0 Break -- select list, remove data that can be copied If (@typ <> 'timestamp' And @is_computed = 0) Begin Set @ColsSelect = @ColsSelect + case when @ColsSelect = '' Then ' []\n' Else ' ,[]\n' End End Set @ColsSelect = Replace(@ColsSelect, '', @cn) Set @ColsSelect = Replace(@ColsSelect, '', @lc) -- liste de colonnes pour into du Insert, dans mode insert, on évite les colonnes timestamp, et les calculées If (@typ <> 'timestamp' And @is_computed <> 1) Begin Set @colsInsertInto = @colsInsertInto + case when @colsInsertInto = '' Then ' ' Else ' ,' End + '['+@cn +']\n' End -- liste de colonnes du create table -- Les champs n'ont pas tous un défaut, mais ils doivent tous avoir une spec NULL ou Not NULL Set @colsCreateTable = @colsCreateTable + case when @colsCreateTable = '' Then ' ' Else ' ,' End + '[] [] \n' -- si défaut pas spécifié, ôte repère de marqueur de la définition du défaut -- sinon ajouter la définition syntaxique If @Def = '' Set @colsCreateTable = Replace(@colsCreateTable, '', '') Else Set @colsCreateTable = Replace( @colsCreateTable , '' , 'CONSTRAINT [DF__] Default ') -- remplace tous les marqueurs Set @colsCreateTable = Replace(@colsCreateTable, '', @tn) Set @colsCreateTable = Replace(@colsCreateTable, '', @cn) If @is_computed <> 1 Begin Set @colsCreateTable = Replace(@colsCreateTable, '', @Typ) Set @colsCreateTable = Replace(@colsCreateTable, '', @lc) Set @colsCreateTable = Replace(@colsCreateTable, '', isnull(@defIden,'')) Set @colsCreateTable = Replace(@colsCreateTable, '', isnull(@def,'')) Set @colsCreateTable = Replace(@colsCreateTable, '', @nullSpec) End Else Begin Set @colsCreateTable = Replace(@colsCreateTable, '[]', 'as '+@computedColDef) Set @colsCreateTable = Replace(@colsCreateTable, '', '') Set @colsCreateTable = Replace(@colsCreateTable, '', '') Set @colsCreateTable = Replace(@colsCreateTable, '', '') Set @colsCreateTable = Replace(@colsCreateTable, '', '') End End -- While une colonne de la table ------------------------------------------------------------------------------------- -- Executer le create de la table ------------------------------------------------------------------------------------- Set @Sql = ' Use [_export] create Table [].[] ( ) ON [] TEXTIMAGE_ON [] ' Set @sql = replace(@sql, '', @dbName) Set @sql = replace(@sql, '', @sn) Set @sql = replace(@sql, '', @tn) Set @sql = replace(@sql, '', @colsCreateTable) If @FgDat = '' Set @sql = replace(@sql, 'ON [] ', '') Else Set @sql = replace(@sql, '', @FgDat) If @FgLob = '' Or (@fgLob = @fgDef) Set @sql = replace(@sql, 'TEXTIMAGE_ON []', '') Else Set @sql = replace(@sql, '', @FgLob) Set @sql = replace(@sql, '"', '''') Set @sql = Replace(@sql, '\n', nchar(10)) -- il y en a dans Begin Try Exec yExecNLog.LogAndOrExec @jobNo = @JobNo , @context = 'yExport.ExportData' , @Info = 'Table creation' , @sql = @Sql , @raiseError = 1 -- must catch the error Set @TableCreated = @TableCreated + 1 Delete From #TablesToExport Where seq = @SeqT End try Begin catch print error_message() Continue -- Jump to next table creation End catch -- decide if data is going to be pipelined through a view Set @sql = ' Use If exists ( select * from sys.views where name = "" And Schema_name(schema_id) = "yExport_" ) Set @schemaAlt = 1 Else Set @schemaAlt = 0 ' Set @sql = replace(@sql, '', @dbName) Set @sql = replace(@sql, '', @sn) Set @sql = replace(@sql, '', @tn) Set @sql = replace(@sql, '"', '''') Exec sp_executeSql @sql, N'@schemaAlt int output', @schemaAlt = @schemaAlt output ------------------------------------------------------------------------------------- -- Executer le insert / select ------------------------------------------------------------------------------------- Set @sql = ' declare @d nvarchar(25); set @d = convert(nvarchar(25), getdate(), 121) raiserror ("Start export to [_export].[].[] at %s",10,1, @d) with nowait -- force output no error ' Set @sql = replace(@sql, '', @dbName) Set @sql = replace(@sql, '', @sn) Set @sql = replace(@sql, '', @tn) Set @sql = replace(@sql, '"', '''') Exec sp_executeSql @sql -- progress report only Set @sql = -- prépare un insert /select complet ' Declare @nb Int ------------------------------------------------------------ Set identity_insert [_export].[].[] on Insert into [_export].[].[] with (tablock) ( ) Select from [].[].[] Set @nb = @@rowcount Set identity_insert [_export].[].[] off checkpoint -- Empty the log in simple recovery ------------------------------------------------------------ declare @d nvarchar(25); set @d = convert(nvarchar(25), getdate(), 121) declare @s nvarchar(25); set @s = convert(nvarchar(25), @nb) raiserror ("End export at %s. %s rows exported to [_export].[].[] ",10,1, @d, @s) with nowait -- force output no error ' -- pipeline data through a pre-defined view in a predefined schema If @schemaAlt = 1 Set @sql = REPLACE(@sql, '[].[].[]', '[].[yExport_].[]') If @iden = 0 -- si pas de définition de colonne identity enlève, mise là juste en mode Insert Select Begin -- ôte instructions relatives à la gestion de l'insertion de la clause identity Set @sql = replace(@sql, 'Set identity_insert [_export].[].[] on', '') Set @sql = replace(@sql, 'Set identity_insert [_export].[].[] off', '') End Set @sql = replace(@sql, '', @ColsInsertInto) Set @sql = replace(@sql, '', @ColsSelect) Set @sql = replace(@sql, '', @dbName) Set @sql = replace(@sql, '', @sn) Set @sql = replace(@sql, '', @tn) Set @sql = replace(@sql, '"', '''') Set @sql = Replace(@sql, '\n', nchar(10)) -- il y en a dans Exec yExecNLog.LogAndOrExec @jobNo = @JobNo , @context = 'yExport.ExportData' , @Info = 'Table load by insert/select' , @sql = @Sql , @raiseError = @stopOnError Set @typDesc = 'Clustered' -- traite en ordre clustered, puis après non clustered Set @in = '' Set @ColIdxChar = 0 While (1=1) -- un index de la table à recréer Begin Select Top 1 @in = IdxName, @iUniq = is_unique, @pk = Is_primary_key, @IUniqC = is_unique_constraint, @fgIdx=FgIdx, @IndexOnView = IndexOnView From #Indexes Where sn = @Sn And tn = @Tn and type_desc = @typDesc and IdxName > @in And IndexOnView = 0 Order by sn, tn, IdxName If @@rowcount = 0 Begin If @typDesc = 'Clustered' Begin Set @typDesc = 'NonClustered' -- traite ensuite nonclustered Set @in = '' -- recommence à parcourir les index en ordre continue End Else Break End -- détermine si l'index a des colonnes de type charactère pour éviter -- de vérifier l'unicité de l'index à cause de la cédille si elle n'a -- pas de champ texte Select top 1 @ColIdxChar = ColIdxChar from #IndexesCols Where sn = @Sn And tn = @Tn And IdxName = @In And ColIdxChar = 1 If @@rowcount = 0 Set @ColIdxChar = 0 -- fabriquer liste de colonnes de l'index Set @Cols = '' Set @LigCols = '' Set @seqc = 0 While (1=1) -- une colonne de l'index à attribuer Begin Select Top 1 @cn = cn, @seqc = Ko From #IndexesCols Where sn = @Sn And tn = @Tn And IdxName = @In and Ko > @seqc Order by ko If @@rowcount = 0 Break Set @Cols = @Cols + case when @Cols = '' Then '' Else ' ,' End + '[' + @cn + ']' Set @ligCols = @ligCols + case When @ligCols = '' Then '' Else ' ,' End+'[' + @cn + ']' End -- While une colonne Set @sql = ' Use [_export] ' + Case When @Pk = 1 Then ' Alter table [].[] add constraint [] primary key () With (FILLFACTOR = 90) ON [] ' When @iUniqC = 1 Then ' Alter table [].[] add constraint [] unique () With (FILLFACTOR = 90) ON [] ' Else ' Create Index [] On [].[] () With (FILLFACTOR = 90) ON [] ' End -- case Set @sql = replace(@sql, '', @dbName) Set @sql = replace(@sql, '', @sn) Set @sql = replace (@sql, '', @tn) Set @sql = replace (@sql, '', @In) Set @sql = replace (@sql, '', @TypDesc) Set @sql = replace (@sql, '', case When @iUniq = 1 Then 'Unique' Else '' End) Set @sql = replace (@sql, '', @Cols) Set @sql = replace (@sql, '', @LigCols) Set @sql = replace (@sql, '', Str(@pk,1)) Set @sql = replace (@sql, '', Str(@iUniqC,1)) If @FgIdx = '' Set @sql = replace(@sql, 'ON [] ', '') Else Set @sql = replace(@sql, '', @FgIdx) Set @sql = replace (@sql, '"', '''') Set @sql = @sql + NCHAR(10)+ 'checkpoint' Exec yExecNLog.LogAndOrExec @jobNo = @JobNo , @context = 'yExport.ExportData' , @Info = 'Recreate table indexes' , @sql = @Sql , @raiseError = @stopOnError End -- While un index End -- While Une table à traiter If exists(Select * from #TablesToExport) -- no table or scalar function could be created this -- must stop because this is not due to a cross dependencies problem between both Begin Select sn, tn from #TablesToExport raiserror ('Some tables/index could be exported',11,1) End Else Break -- no more tables End -- Creation d'une table et/ou au moins une fonction scalaire fonctionne ---------------------------------------------------------------------------------- -- recreate auto-generated stats for all tables ---------------------------------------------------------------------------------- Set @seq = 0 While (1=1) -- un index de la table à recréer Begin Select Top 1 @seq = seq, @sn = sn, @tn = tn, @cn = cn From #Stats Where seq > @seq Order by seq If @@ROWCOUNT = 0 break Set @sql = ' Use [_export] declare @c int Select @c = count(distinct []) From (Select [].[].[] From [].[] tablesample(10 percent)) as x ' Set @sql = Replace(@sql, '', @dbName) Set @sql = Replace(@sql, '', @Sn) Set @sql = Replace(@sql, '', @tn) Set @sql = Replace(@sql, '', @cn) Set @sql = Replace(@sql, '"', '''') Exec yExecNLog.LogAndOrExec @jobNo = @JobNo , @context = 'yExport.ExportData' , @Info = 'Optimizer stats recreate' , @sql = @Sql , @raiseError = @stopOnError End -- While ---------------------------------------------------------------------------------- -- rebatir les clés étrangères des tables s'il y a lieu ---------------------------------------------------------------------------------- Set @seqFk = 0 While (1=1) Begin Select Top 1 @Ks = Sn, @tn = Tn, @Kn = Kn, @seqFk = Seq, @FKOnClause = Case When UPDATE_RULE <> 'NO ACTION' Then ' ON UPDATE '+UPDATE_RULE ELSE '' END + Case When DELETE_RULE <> 'NO ACTION' Then ' ON DELETE '+DELETE_RULE ELSE '' END , @is_not_trusted = is_not_trusted From #RefConstraints Where seq > @seqFk order by seq If @@rowcount = 0 Break -- fabriquer liste de colonnes de la reference aux colonnes Set @Cols = '' Set @ucols = '' Set @seqc = 0 While (1=1) -- une colonne pour la reference de cle etrangere Begin Select Top 1 @cn = cn, @seqc = OrdCol, @Usn = Usn, @Utn = Utn, @Ucn = Ucn From #ColsRefConstraints Where sn = @Ks And tn = @Tn and @Kn=Kn and OrdCol > @seqC Order by sn, tn, ordCol If @@rowcount = 0 Break Set @Cols = @Cols + case when @Cols = '' Then ' ' Else ' , ' End + '['+ @cn + ']' Set @uCols = @uCols + case when @uCols = '' Then ' ' Else ' , ' End + '['+ @uCn + ']' End -- While une colonne Set @sql = ' Use [_export] Alter table [].[] add constraint [] FOREIGN KEY () REFERENCES [].[] () ; Alter table [].[] NoCheck Constraint []; Checkpoint ' If @is_not_trusted = 0 Begin Set @sql = replace (@sql, '', '') Set @sql = replace (@sql, 'Alter table [].[] NOCHECK Constraint [];', '') End Else Set @sql = replace (@sql, '', 'WITH NOCHECK') Set @sql = replace(@sql, '', @dbName) Set @sql = replace (@sql, '', @ks) Set @sql = replace (@sql, '', @tn) Set @sql = replace (@sql, '', @Kn) Set @sql = replace (@sql, '', @Cols) Set @sql = replace (@sql, '', @uSn) Set @sql = replace (@sql, '', @utn) Set @sql = replace (@sql, '', @uCols) Set @sql = replace (@sql, '', @FkOnClause) Exec yExecNLog.LogAndOrExec @jobNo = @JobNo , @context = 'yExport.ExportData' , @Info = 'Recreate referential constraints' , @sql = @Sql , @raiseError = @stopOnError End -- While une clé étrangère à traiter raiserror('Shrint the log',10,1) declare @logN sysname Set @sql = ' use [_Export] Select @logn = name from sys.database_files where type_desc = "LOGN" ' Set @sql = replace(@sql, '', @dbName) Set @sql = replace(@sql, '"', '''') Exec sp_executeSql @Sql, N'@logN sysname output', @logn = @logn output Set @sql = ' use [_Export] dbcc shrinkfile("") with NO_INFOMSGS ' Set @sql = replace(@sql, '', @dbName) Set @sql = replace(@sql, '"', '''') Set @sql = replace(@sql, '', @logn) Exec yExecNLog.LogAndOrExec @jobNo = @JobNo , @context = 'yExport.ExportData' , @Info = 'Reset log file' , @sql = @Sql , @raiseError = @stopOnError End try begin catch set @Info = ERROR_MESSAGE() + ' (ExportData)' raiserror(@Info, 11, 1) Exec yExecNLog.LogAndOrExec @jobNo = @JobNo , @context = 'yExport.ExportData' , @err = 'Failure to complete ExportData' end catch End -- Export.ExportData GO If objectpropertyEx(object_id('yExport.ExportCode'), 'isProcedure') = 1 Drop procedure yExport.ExportCode GO create proc yExport.ExportCode @dbName sysname , @stopOnError Int = 1 , @jobNo Int as Begin -- On boucle sur la création des objets car certains ne peuvent être crées avant que d'autres le soient -- ex: les vues ou fonctions peuvent dépendre de d'autres vues ou fonctions -- On crée ensuite les procédures qui bien qu'elles dépendent de d'autres procédures peuvent être créées -- mais la liste des dépendances n'est alors pas complète -- On repasse la création des procédures pour remédier à ce problème -- Le triggers n'ont qu'à être créés qu'une fois -- Le principe d'arrêt du traitement consiste à retirer de la table temporaire de copie de -- définition des objets, tous les objets crées avec succès set nocount on declare @seq int -- pour séquencer le traitement selon l'ordre voulu , @id int -- id de l'objet pour identifiant unique de l'objet , @n sysname -- nom sp ou fonction , @sc sysname -- nom du schema proprio , @typ_Desc sysname -- identification SQL du type de code, provient de sys.objetcs , @ModuleTyp sysname -- identifie si sp ou vue/fonction (en abrégé) , @anull bit -- mode uses_ansi_null , @qiden bit -- mode uses_quoted_identifier , @Def nvarchar(max) -- définition de la SP ou fonction , @sql nvarchar(max) , @sql2 nvarchar(max) , @ErreurNative int , @Info nvarchar(max) , @nbSqlOk int , @msgSql nvarchar(max) , @sqlMain nvarchar(max) --------------------------------------------------------------------------------------------------- -- preparer la BD pour la migration du code SQL, faire une copie du code dans Bd qui va être migrée --------------------------------------------------------------------------------------------------- create table #SqlCode -- list all proc and function ( seq int -- sequence voulue du traitement , id int -- id de l"objet pour relire dans même ordre , sc sysname -- schema de l"object , n sysname -- nom sp ou fonction , typ_Desc sysname -- vrai type d"origine , typ sysname -- identifie si sp ou fonction pour drop , anull Bit -- identifie si procédure créé avec ansi null on = 1 , qiden Bit -- identifie si procédure créé avec quote identifier on = 1 , msgSql nvarchar(1000) NULL -- conserver dernier message d"erreur , Def nvarchar(max) -- définition de la vue, trigger, SP ou fonction ) Create unique clustered index iPkSp on #SqlCode (Seq) declare @iTyp int; set @iTyp = 0 While (1=1) Begin ;With codeType (iTyp, ModuleTyp) as (Select 1, 'VUEF' Union all Select 2, 'PROC' Union all Select 3, 'TRIG') Select top 1 @iTyp = ityp, @Moduletyp = ModuleTyp From codeType Where iTyp > @iTyp Order by iTyp If @@rowcount = 0 break Set @sql = ' Use [] truncate table #SqlCode ;With SqlCode as ( Select M.object_id as id , isnull (SCHEMA_NAME (Ob.schema_id), "") as sc , object_name(M.object_id) as n , OB.type_desc as typ_desc , Case When TYPE_DESC Like "SQL%PROCEDURE" Then "Proc" When TYPE_DESC Like "SQL%TRIGGER" Then "Trig" Else "VueF" End as typ , M.definition as Def , M.uses_ansi_nulls as aNull , M.uses_quoted_identifier as qIden from sys.sql_modules M join sys.objects OB On OB.object_id = M.object_id ) Insert into #SqlCode (seq, id, sc, n, typ_desc, typ, def, anull, qiden) Select row_number() OVER (ORDER BY sc, n, id) as seq , id, sc, n, typ_desc, typ, def, anull, qiden From SqlCode where objectpropertyEx(id, "isMsShipped") = 0 and typ = "" Select seq, "[_export].["+sc+"].["+n+"]" from #sqlCode ' Set @sql = replace(@sql, '', @dbName) Set @sql = replace(@sql, '"', '''') Set @sql = replace(@sql, '', @ModuleTyp) Exec yExecNLog.LogAndOrExec @jobNo = @JobNo , @context = 'yExport.ExportCode' , @Info = 'Get SQL code' , @sql = @Sql , @raiseError = @stopOnError -- ------------------------------------------------------------------------------------------------ -- loop to recreate objects -- ------------------------------------------------------------------------------------------------ Set @nbSqlOk = 0 Set @seq = 0 Declare @pass int; set @pass = 1 Declare @created int; set @created = 0 while (1=1) -- there is a sp to create Begin -- read sql module definition select top 1 @seq = seq, @Id = id, @sc = sc, @n = n, @ModuleTyp = typ, @typ_desc = typ_desc , @aNull = aNull, @qIden = qIden, @def = def from #SqlCode Where seq > @seq Order by seq if @@rowcount = 0 -- reach list end Begin If @ModuleTyp= 'Proc' Begin If @pass > 1 Break Else Begin Set @seq = 0 -- redo a pass to have clean sp dependencies Set @pass = @pass + 1 continue End End If @ModuleTyp= 'VueF' Begin If @created = 0 -- nothing could be created, useless to continue Break Else Begin Set @created = 0 Set @seq = 0 -- redo a pass in attempt to get more dependent objects created continue End End If @ModuleTyp= 'Trig' -- trigger are created last, no worth keep trying again Break End set @sqlMain = ' Use [_export] set ansi_nulls ; Set quoted_identifier ; begin try exec YourSqldba.yUtl.DropObj "[_export].[].[]", @showdrop = 1 Execute sp_executeSql @def end try begin catch Print "Error: "+str(error_number()) + " " + error_message() end catch -- not all errors are caught If object_id("[].[]") is not null Set @created = 1 Else Set @created = 0 ' print 'try create: '+@dbName+'_export.'+@sc+'.'+@n Set @sqlMain = replace(@sqlMain, '"', '''') Set @sqlMain = replace(@sqlMain, '', case When @aNull = 1 Then 'On' Else 'Off' End) Set @sqlMain = replace(@sqlMain, '', case When @qIden = 1 Then 'On' Else 'Off' End) Set @sqlMain = REPLACE(@sqlMain, '', @dbName) Set @sqlMain = REPLACE(@sqlMain, '', @n) Set @sqlMain = REPLACE(@sqlMain, '', @sc) Exec sp_executeSql @Sqlmain, N'@Def nvarchar(max), @created int output', @def, @created output If @created = 1 -- certains cas d'erreur ne sont pas capturés Begin print 'create succeeded' If @pass = 2 Or @ModuleTyp in ('VUEF', 'TRIG') Delete From #SqlCode Where seq = @seq End Else begin Print 'Object '+@n + ' cannot be created yet ' Print @sqlMain Exec yExecNLog.PrintSqlCode @sql = @def, @numberingRequired =0 end End -- while End -- While there is a type of code to do -- TODO : Recreate indexes on view if any here End -- yExport.ExportCode go If Db_name() <> 'YourSqlDba' Use YourSqlDba GO -------------------------------------------------------------------------------------------------------- -- Procedure maitresse qui migre les code utilisateurs et les droits -------------------------------------------------------------------------------------------------------- if objectpropertyEx(object_id('yExport.ExportSecur'), 'isProcedure') = 1 Drop Procedure yExport.ExportSecur GO Create Procedure yExport.ExportSecur @dbName sysname , @stopOnError Int = 1 , @jobNo Int as Begin Set nocount on declare @etp nvarchar(4) Set @etp = 'Secu' -- simplifie appel de la proc de logExec et logErr declare @sql nvarchar(max) , @suffixe sysname -- var to recreate ysers , @Usr sysname , @Uid smallInt , @logN sysname , @default_schema sysname , @owning_principal_id int -- var to recreate perms to users and roles , @Seq int , @action nvarchar(50) , @perms nvarchar(256) , @TypObj Char(1) , @obj sysname , @col sysname , @SomeUsers nvarchar(max) -- var to create roles and roles members , @r sysname , @rM sysname , @seqM Int , @Info nvarchar(max) Begin try -- get actual users and corresponding login name Create Table #princ -- users list ( Usr sysname collate database_default Not NULL , uid int , logN sysname collate database_default NULL , default_schema sysname collate database_default null , owning_principal_id int null ) Set @sql = ' Use [] insert into #princ Select p.name collate LATIN1_GENERAL_CI_AI as UserName , p.principal_id , SUSER_SNAME(sid) , p.default_schema_name , p.owning_principal_id From [].sys.database_principals P Where p.type_desc = "SQL_USER" And p.default_schema_name is not null And not exists(Select * from [_export].sys.database_principals as E Where E.name = P.Name collate Latin1_general_ci_ai) ' Set @sql = replace(@sql,'', @dbName) Set @sql = replace(@sql,'"', '''') Exec yExecNLog.LogAndOrExec @jobNo = @JobNo , @context = 'yExport.ExportSecur' , @Info = 'Get users names' , @sql = @Sql , @raiseError = @stopOnError --------------------------------------------------------------------------------------------------------- -- enum database roles and their members --------------------------------------------------------------------------------------------------------- Create Table #Roles ( RoleName Sysname primary key clustered , Principal_id Int ) Create Table #RoleMembers ( Seq int primary key clustered , RoleName Sysname , RoleMember sysname ) Set @sql= ' Use [] Insert into #roles select PSrc.Name as RoleName, PSrc.principal_Id from sys.database_principals PSrc where type_desc = "database_role" And not exists(Select * from [_export].sys.database_principals as E Where E.name = PSrc.Name collate Latin1_general_ci_ai) Insert into #RoleMembers Select ROW_NUMBER() OVER(Order By R.RoleName, M.Name) as Seq , R.RoleName collate Latin1_general_ci_ai as RoleName , M.Name collate Latin1_general_ci_ai as Name From #roles R JOIN sys.database_role_members RM ON RM.Role_Principal_id = R.Principal_id JOIN sys.database_principals M ON M.Principal_id = RM.Member_Principal_id And M.type_desc <> "application_role" ' Set @sql = replace (@sql, '', @dbName) Set @sql = replace (@sql, '"', '''') Exec yExecNLog.LogAndOrExec @jobNo = @JobNo , @context = 'yExport.ExportSecur' , @Info = 'Keep roleMembership' , @sql = @Sql , @raiseError = @stopOnError ---------------------------------------------------------------------------------------------------------- -- Make a compressed list on rights to make less GRANT/DENY instructions ---------------------------------------------------------------------------------------------------------- Create Table #RightsToApply ( Seq int primary key clustered , action nvarchar(50) NOT NULL , perms nvarchar(256) NOT NULL , TypObj Char(1) , obj sysname NULL , col sysname NULL , SomeUsers nvarchar(max) NOT NULL ) Create Table #Privs ( Seq int primary key clustered , action nvarchar(50) NOT NULL , perm nvarchar(256) NOT NULL , TypObj Char(1) , obj sysname NULL , col sysname NULL , ToWho nvarchar(max) NOT NULL ) Set @sql= ' Use [] ;With ObjectIds (ObjId) as ( Select object_Id(name) as ObjId From sys.tables union all Select object_Id -- exclure les vues retournées aussi par information_schema.table From sys.sql_modules Where objectpropertyEx(object_id, "IsView") = 0 ) , AllPrivs as ( select -- lire les droits qui ne sont pas spécifique à la colonne state_desc collate LATIN1_GENERAL_CI_AI as Action , permission_name collate LATIN1_GENERAL_CI_AI as Perm , Case When objectpropertyex(major_Id, "isUserTable") =1 Or objectpropertyex(major_Id, "isView") =1 Then "Q" Else "M" End collate LATIN1_GENERAL_CI_AI as TypObj , object_name(major_Id) collate LATIN1_GENERAL_CI_AI as Obj , NULL as Col -- pas une colonne , user_name(grantee_principal_id) collate LATIN1_GENERAL_CI_AI as toWho from ObjectIds as Objs Join sys.database_permissions P ON P.major_id = Objs.ObjId Where minor_id = 0 And -- zéro if no column specific privileges class_desc = "OBJECT_OR_COLUMN" UNION ALL select -- add specific columns rights state_desc , permission_name , Case When objectpropertyex(major_Id, "isUserTable") =1 Or objectpropertyex(major_Id, "isView") =1 Then "Q" Else "M" End , object_name(major_Id) , COL_NAME (Object_id, Column_id) , user_name(grantee_principal_id) from sys.columns TC Join sys.database_permissions P ON P.major_id = Tc.Object_id And P.minor_id = Tc.Column_id ) Insert into #Privs (Seq, action, perm, TypObj, obj, col, toWho) Select Row_number() over (order by Obj) , Action , perm , typObj , obj , col , toWho From AllPrivs ' Set @sql = replace(@sql,'', @dbName) Set @sql = replace(@sql,'"', '''') Exec yExecNLog.LogAndOrExec @jobNo = @JobNo , @context = 'yExport.ExportSecur' , @Info = 'Keep user/role permissions' , @sql = @Sql , @raiseError = @stopOnError Set @Uid = 0 -- to get to #1 which is dbo and which must be processed first While (1=1) Begin Select -- read next user Top 1 @Usr = Usr , @logN = LogN , @Uid = Uid , @default_schema = default_schema , @owning_principal_id = owning_principal_id From #princ Where Uid > @Uid Order by Uid If @@rowcount = 0 Break -- no more to read If @usr = 'dbo' -- ordre de traitement des users fait que celui-ci est traité en premier Begin Set @sql = ' use [_export]; ALTER AUTHORIZATION ON Database::[_export] To []; ' Set @sql = replace(@sql,'', @dbName) Set @sql = replace(@sql,'', ISNULL(@LogN, 'YourSQLDba')) Set @sql = replace(@sql,'"', '''') Exec yExecNLog.LogAndOrExec @jobNo = @JobNo , @context = 'yExport.ExportSecur' , @Info = 'Set Db Owner' , @sql = @Sql , @raiseError = @stopOnError Continue End -- if here user is not dbo Set @sql = '' If @Usr <> 'Guest' Begin -- user not aliased to dbo If @logN <> '' Set @sql = ' use [_export]; Create user [] For Login [] with default_schema = ' Else Set @sql = ' -- user is orphaned or aliased to dbo use [_export]; Create user [] Without Login -- user is aliased to dbo recreate it without login ' End else Begin If exists(Select * from Sys.database_permissions where grantee_principal_id = user_id('guest') and type = 'co' and state = 'G') Begin Set @sql = ' use [_export]; Grant connect to guest ' End End Set @sql = replace(@sql,'', isnull(@dbName, '')) Set @sql = replace(@sql,'', isnull(@Usr, '')) Set @sql = replace(@sql,'', isnull(@logN, '')) If @default_schema is null Set @sql = replace (@sql, 'with default_schema = ', '') Else Set @sql = replace (@sql, '', @default_schema) Set @sql = replace(@sql,'"', '''') if @sql <> '' Exec yExecNLog.LogAndOrExec @jobNo = @JobNo , @context = 'yExport.ExportSecur' , @Info = 'create user ' , @sql = @Sql , @raiseError = @stopOnError End -- While user to create Set @r = '' -- read first role While (1=1) Begin Select top 1 @r = RoleName From #Roles Where RoleName > @r Order by RoleName If @@rowcount = 0 Break -- si plus rien quitter Set @sql = ' use [_export]; exec ("Create ROLE AUTHORIZATION dbo") ' Set @sql = replace (@sql, '', @r) Set @sql = replace (@sql, '', @dbName) Set @sql = replace (@sql, '"', '''') Exec yExecNLog.LogAndOrExec @jobNo = @JobNo , @context = 'yExport.ExportSecur' , @Info = 'create role' , @sql = @Sql , @raiseError = @stopOnError End -- while Set @SeqM = 0 -- amorce lecture des membres de roles While (1=1) Begin Select top 1 @r = RoleName, @rM = RoleMember, @SeqM = Seq From #RoleMembers Where Seq > @SeqM Order by Seq If @@rowcount = 0 Break Set @sql = ' use [_export]; If "" <> "dbo" Exec sp_addrolemember "", "" ' Set @sql = replace (@sql, '', @dbName) Set @sql = replace (@sql, '', @r) Set @sql = replace (@sql, '', @rM) Set @sql = replace(@sql,'"', '''') Exec yExecNLog.LogAndOrExec @jobNo = @JobNo , @context = 'yExport.ExportSecur' , @Info = 'Add role member' , @sql = @Sql , @raiseError = @stopOnError End -- While il y a un membre de role à ajouter à un role -- ***************************************************************** --declare @sql nvarchar(max) --declare @dbName sysname --set @dbName=db_name() --drop table #RightsToApply ---------------------------------------------------------------------------------------------------------- -- Réattribuer les droits, lister, compresser en moins d'instructions GRANT/DENY, ré-exécuter GRANT / DENY -- Droits lus de la Bd à migrer -- C'est un ensemble de requêtes avec tables temporaires assez compliqué -- On ne peut pas couper la batch en moins car les tables #temporaire sont créées par select into -- et cesseraient d'exister après ---------------------------------------------------------------------------------------------------------- Set @sql= ' use [] ;With TabAndProcPriv as ( Select Action , Convert ( nvarchar(128) , Stuff -- remove starting comma from the list ( -- put together perms by column, user Max(Case When Perm = "Select " Then ", Select " Else "" End) + Max(Case When Perm = "Insert " Then ", Insert " Else "" End) + Max(Case When Perm = "Update " Then ", Update " Else "" End) + Max(Case When Perm = "Delete " Then ", Delete " Else "" End) + Max(Case When Perm = "Execute " Then ", Execute " Else "" End) + Max(Case When Perm = "References " Then ", References " Else "" End) , 1 , 1 , "" ) ) as Perms , TypObj , Obj , Col , toWho From #Privs group by Action, TypObj, Obj, Col, toWho ) Select Action , Perms , TypObj , Obj , Col , toWho -- give unique sequence number group to every 15 users , ROW_NUMBER() OVER(partition By Action, perms, typObj, Obj, Col Order by toWho) / 15 AS "PermGroup" into #Pa From TabAndProcPriv create clustered index iPa on #Pa (action, perms, obj, permGroup) -- compact rights statement by keeping the same set of rights on one or more users -- use premGroup generated previously to do that Truncate table #RightsToApply Insert into #RightsToApply ( Seq , action , perms , TypObj , obj , col , SomeUsers ) Select -- order rights so that grants are performed before deny so action column order is set descending ROW_NUMBER() OVER(Order by Action Desc, perms, Obj, Col) , Action , Perms , TypObj , Obj , col -- put together users that receive the same set of rights on the same objects , stuff ( ( -- nom colonne interprétée par XPATH, -- ici text() spécifie que c"est le texte de l"élément et pas son nom ex: nomElem -- truc SQL2005 pour fusionner data de plusieurs lignes select ", ["+cast(D.toWho as varchar(max))+"]" as [text()] from #Pa D Where D.Action = Pa.Action And D.perms = Pa.Perms And D.Obj = Pa.Obj And ISNULL(D.col, "") = ISNULL(Pa.Col,"") And D.PermGroup = Pa.PermGroup ORDER By D.toWho FOR XML PATH("") ) , 1 , 2 , "" ) as SomeUsers From ( Select Distinct Action, Perms, TypObj, Obj, Col, PermGroup From #Pa ) as PA ' Set @sql = replace(@sql,'', @dbName) Set @sql = replace(@sql,'"', '''') Exec yExecNLog.LogAndOrExec @jobNo = @JobNo , @context = 'yExport.ExportSecur' , @Info = 'Get rights info' , @sql = @Sql , @raiseError = @stopOnError -- Select * from #RightsToApply Set @seq = 0 -- amorce pour lecture des attribution de droits While (1=1) Begin Select TOP 1 @seq = seq , @action = action , @perms = perms , @typObj = typObj , @obj = obj , @col = col , @SomeUsers = SomeUsers From #RightsToApply Where seq > @seq Order By seq if @@rowcount = 0 BreaK -- applique sur BD de destination les droits Set @sql = ' Use [_export]; If object_Id("[]") IS NOT NULL ON OBJECT::[] ([]) To ' Set @Sql = replace(@sql, '', case When @action <> 'GRANT_WITH_GRANT_OPTION' Then @action Else 'GRANT' End ) Set @Sql = replace(@sql, '', case When @action <> 'GRANT_WITH_GRANT_OPTION' Then '' -- efface tag option Else 'WITH GRANT OPTION' -- sinon la met End ) Set @Sql = replace(@sql, '"', '''') Set @Sql = replace(@sql, '', @perms) Set @Sql = replace(@sql, '', @obj) Set @Sql = replace(@sql, '', @SomeUsers) If @col is NULL Set @Sql = replace(@sql, '([])', '') Else Set @Sql = replace(@sql, '', @col) Set @sql = replace(@sql,'', @dbName) Exec yExecNLog.LogAndOrExec @jobNo = @JobNo , @context = 'yExport.ExportSecur' , @Info = 'Apply privileges' , @sql = @Sql , @raiseError = @stopOnError End -- tant que des droits à appliquer End Try begin catch set @Info = ERROR_MESSAGE() + ' (ExportSecur)' raiserror(@Info, 11, 1) end catch End -- yExport.ExportSecur GO if objectpropertyEx(object_id('Export.ExportDb'), 'isProcedure') = 1 Drop proc Export.ExportDb GO Create proc Export.ExportDb @dbName sysname , @collation sysname = NULL , @stopOnError Int = 1 , @jobName sysname as Begin Set nocount on declare @rc int declare @Info nvarchar(max) declare @jobNo Int Select 'Look at messages TAB, to see work progress messages' as ReadThisPlease Declare @sql nvarchar(max) Set @jobName = 'Export data from '+@dbName+' to '+@dbName+'_Export' Print '====================================================' Print @jobName Print '====================================================' Begin try Exec yExecNLog.AddJobEntry @jobName = @jobName , @jobNo = @jobNo output Exec @rc = yExport.CreateExportDatabase @dbname, @collation, @stopOnError, @jobNo If @rc = 0 Begin Exec yExport.ExportData @dbName, @stopOnError, @jobNo Exec yExport.ExportCode @dbName, @stopOnError, @jobNo Exec yExport.ExportSecur @dbName, @stopOnError, @jobNo End End try Begin Catch set @Info = error_message() raiserror (@Info ,11,1) End Catch end -- Export.ExportDb GO If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yUtl.SqlModuleCopy' GO Create procedure yUtl.SqlModuleCopy @SourceDb sysname , @TargetDb sysname = NULL , @ObjectPropertyEx sysname = NULL -- isExecuted, isProcedure, isFunction, isTrigger, ExecIsInsertTrigger, .... -- see T-SQL OBJECTPROPERTYEX function for all parameters , @SourceSchema sysname , @TargetSchema sysname = NULL , @SourceName sysname , @TargetName sysname = NULL As Begin Declare @ObjectDef nvarchar(max) Declare @sql nvarchar(max) Declare @Info nvarchar(max) Set @TargetDb = ISNULL(@targetDb, @SourceDb) Set @TargetSchema = ISNULL(@targetSchema, @SourceSchema) Set @TargetName = ISNULL(@TargetName, @SourceName) Set @sql = ' use []; Select @ObjectDef = M.[definition] From sys.sql_modules M Where Object_id = Object_id(@SourceSchema+"."+@SourceName) And (@ObjectPropertyEx is NULL Or Objectpropertyex(Object_id, @ObjectPropertyEx)=1) print @SourceSchema+"."+@Sourcename ' Set @sql = replace(@sql, '', @SourceDb) Set @sql = replace(@sql, '"', '''') Exec sp_executeSql @sql , N'@SourceDb sysname , @SourceSchema sysname , @SourceName sysname , @ObjectPropertyEx sysname , @ObjectDef nvarchar(max) Output ' , @SourceDb = @SourceDb , @SourceSchema = @SourceSchema , @Sourcename = @SourceName , @ObjectPropertyEx = @ObjectPropertyEx , @ObjectDef = @ObjectDef Output Set @sql = ' use []; Exec YourSqlDba.yUtl.DropObj "[].." If Schema_id("") is NULL exec("Create schema authorization dbo;") Exec Sp_ExecuteSql @ObjectDef ' Set @sql = replace(@sql, '', @TargetDb) Set @sql = replace(@sql, '', @TargetSchema) Set @sql = replace(@sql, '', @TargetName) Set @sql = replace(@sql, '"', '''') Exec sp_executeSql @sql, N'@ObjectDef nvarchar(max)', @ObjectDef End -- yUtl.SqlModuleCopy go --exec yUtl.SqlModuleCopy -- @SourceDb = 'yoursqldba' --, @TargetDb = 'achat' --, @SourceSchema = 'yUpgrade' --, @sourcename = 'UpgradeFulltextCatalogsFromSql2005' go If Db_name() <> 'YourSqlDba' Use YourSqlDba go If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yMirroring.DatabaseRecovery' GO Create procedure yMirroring.DatabaseRecovery @DbName sysname As Begin Declare @sql nvarchar(max) Set @sql = 'RESTORE DATABASE [] WITH RECOVERY, REPLACE' Set @sql = REPLACE(@sql, '', @DbName) print @sql Exec(@sql) End -- yMirroring.DatabaseRecovery GO If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'Mirroring.DoRecovery' GO Create procedure Mirroring.DoRecovery @IncDb nVARCHAR(max) = '' , @ExcDb nVARCHAR(max) = '' As Begin Declare @sql nvarchar(max) Declare @dbname sysname Declare @err nvarchar(max) Set @err = '' Set NOCOUNT ON -- The function udf_YourSQLDba_ApplyFilterDb apply filter parameters on this list Create table #Db ( DbName sysname primary key clustered , ErrorMsg nvarchar(max) default 'This is the database state before before putting it ''ONLINE''.' ) Insert into #Db (DbName) Select X.DbName from yUtl.YourSQLDba_ApplyFilterDb (@IncDb, @ExcDb) X Left Join master.sys.databases D On X.DbName = D.name Collate Latin1_general_ci_ai -- Exclude non-RESTORING databases Delete Db From #Db Db Where Exists( Select * From sys.databases d Where d.name = db.DbName and DatabasepropertyEx(d.name, 'Status') <> 'RESTORING' ) -- For each database to process Set @dbname = '' While 1=1 Begin Select Top 1 @DbName=DbName From #Db Where DbName > @dbname Order By DbName If @@rowcount = 0 break -- Switch the database from state "restoring" to available and recovered Set @sql = 'RESTORE DATABASE [] WITH RECOVERY' Set @sql = REPLACE(@sql, '', @DbName) Print '' Print '> ' + @sql Begin Try Exec sp_executeSql @sql End Try Begin Catch Set @err = ERROR_MESSAGE() Print '' Print 'Error. The database '''+ @DbName +''' has not changed to ''ONLINE''. Msg: ' + @err Update Db Set ErrorMsg = 'Msg: ' + @err From #Db Db Where Db.DbName = @DbName End Catch End --While 1=1 (DB list) -- Show results status for the selected databases Update Db Set ErrorMsg = Case When X.name Is Not Null Then 'The database is now ''ONLINE''.' Else 'Error. The database has not changed to ''ONLINE''. ' + ErrorMsg End From #Db Db Left Join master.sys.databases X On Db.DbName = X.name Collate Latin1_general_ci_ai And X.state_desc = 'ONLINE' Select DbName , ErrorMsg As N'Results ………………………………………………………………………………………………………………………………………………………………………………………………………………………………………………………………………………………………………………………………' From #Db End -- Mirroring.DoRecovery GO If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'yUpgrade.UpgradeFulltextCatalogsFromSql2005' GO Create Procedure yUpgrade.UpgradeFulltextCatalogsFromSql2005 As Begin declare @sql nvarchar(max) declare @colspec nvarchar(max) declare @object_id int declare @name sysname declare @CatalogName sysname declare @IndexName sysname declare @is_accent_sensitivity_on bit declare @Colname sysname declare @TypeColname sysname declare @language_id int declare @UniqueIndexName sysname declare @FileSize int declare @PhysicalPath nvarchar(max) Set NOCOUNT ON -- ************************************************************** -- Conserver les définition d'index pour les recréer plus tard -- ************************************************************** Select Case When c.name = 'eg_files_catalog' Then 'eg_files_catalog' -- EDU_GROUPE When c.name like '%FILES[_]CATALOG' Then 'GED_FILES_CATALOG' -- Clé de Voute When c.name like '%[_]CATALOG' Then 'GED_CATALOG' -- Clé de Voute Else c.name End as CatalogName , is_accent_sensitivity_on , FULLTEXTCATALOGPROPERTY(c.name,'IndexSize') as Size , ui.name as UniqueIndexName , object_name(i.object_id) as IndexName , c1.name As ColName , c2.name as TypeColName , ic.language_id Into #FulltextIndexes From sys.fulltext_catalogs c Join sys.fulltext_indexes i On i.fulltext_catalog_id = c.fulltext_catalog_id join sys.indexes ui On ui.object_id = i.object_id And ui.index_id = i.unique_index_id join sys.fulltext_index_columns ic On ic.object_id = i.object_id join sys.columns c1 On c1.object_id = ic.object_id And c1.column_id = ic.column_id left join sys.columns c2 On c2.object_id = ic.object_id And c2.column_id = ic.type_column_id -- ************************************************************ -- Si aucun index plein texte trouver on a plus rien à faire -- ************************************************************ If Not Exists( Select * From #FulltextIndexes) Begin Print 'Aucun index plein texte non-migré trouvé' return End -- ********************************************************** -- Supprimer tous ce qui se rapporte aux indexes Fulltext -- . Indexes -- . Catalogues -- . Fichiers *.ndf -- . FileGroup -- ********************************************************** -- *************************************** -- Supprimer tous les index plein texte -- *************************************** Set @object_id = 0 while 1=1 Begin Select Top 1 @object_id = object_id From sys.fulltext_indexes Where object_id > @object_id Order by object_id If @@ROWCOUNT = 0 break Set @sql = 'DROP FULLTEXT INDEX ON []' Set @sql = Replace(@sql, '', object_name(@object_id) ) Set @sql = Replace(@sql, '"', '''') Print @sql Exec(@sql) End -- ******************************* -- Supprimer tous les catalogue -- ******************************* Set @name = '' while 1=1 Begin Select Top 1 @name = name From sys.fulltext_catalogs Where name > @name Order by name If @@ROWCOUNT = 0 break Set @sql = 'DROP FULLTEXT CATALOG []' Set @sql = Replace(@sql, '', @name ) Set @sql = Replace(@sql, '"', '''') Print @sql Exec(@sql) End -- ****************************************************************************** -- Supprimer tous les fichiers de donnée qui contiennent des index plein texte -- ****************************************************************************** Set @name = '' while 1=1 Begin Select Top 1 @name = name From sys.database_files Where name like 'ftrow_%' And name > @name Order by name If @@ROWCOUNT = 0 break Set @sql = 'ALTER DATABASE [] REMOVE FILE []' Set @sql = Replace(@sql, '', db_name()) Set @sql = Replace(@sql, '', @name ) Set @sql = Replace(@sql, '"', '''') Print @sql Exec(@sql) End -- ********************************************************************************** -- Supprimer tous les FileGroup qui contenait des fichier d'indexation plein texte -- ********************************************************************************** Set @name = '' while 1=1 Begin Select Top 1 @name = name From sys.data_spaces Where name like 'ftfg_%' And name > @name Order by name If @@ROWCOUNT = 0 break Set @sql = 'ALTER DATABASE [] REMOVE FILEGROUP []' Set @sql = Replace(@sql, '', db_name()) Set @sql = Replace(@sql, '', @name ) Set @sql = Replace(@sql, '"', '''') Print @sql Exec(@sql) End -- ************************************************************** -- Créer un FileGroup pour le ou les catalogues s'il n'existe pas déjà -- ************************************************************** If Exists (Select * From #FulltextIndexes) And Not Exists (Select * From sys.filegroups where name = 'CATALOGS') Begin Set @sql = 'ALTER DATABASE [] ADD FILEGROUP [CATALOGS]' Set @sql = Replace(@sql, '', db_name()) Set @sql = Replace(@sql, '"', '''') Print @sql Exec(@sql) End -- ************************************************************** -- Ajouter un fichier de données dans le FILEGROUP Catalogs -- ************************************************************** If Not Exists (Select * From sys.filegroups fg join sys.database_files dbf On dbf.data_space_id = fg.data_space_id Where fg.name = 'CATALOGS' And dbf.state_desc = 'ONLINE') Begin Select @FileSize = SUM(Size) * 1.25 From ( Select Distinct CatalogName, Size From #FulltextIndexes ) X Set @FileSize = Case When @FileSize = 0 Then 50 Else @FileSize End Select @PhysicalPath = Left(physical_name, Len(physical_name) - CharIndex('\', Reverse(physical_name)) + 1) From sys.database_files Where file_id = 1 Set @sql = 'ALTER DATABASE [] ADD FILE (NAME="_CATALOGS", FILENAME="_CATALOGS.ndf", SIZE=, FILEGROWTH= 10 %) TO FILEGROUP [CATALOGS]' Set @sql = Replace(@sql, '', db_name()) Set @sql = Replace(@sql, '', @PhysicalPath) Set @sql = Replace(@sql, '', convert(nvarchar(25), @FileSize)) Set @sql = Replace(@sql, '"', '''') Print @sql Exec(@sql) End -- ************************************************************** -- Recréer les catalogues -- ************************************************************** Set @CatalogName = '' while 1=1 Begin Select Distinct Top 1 @CatalogName = CatalogName, @is_accent_sensitivity_on = is_accent_sensitivity_on From #FulltextIndexes Where CatalogName > @CatalogName Order by CatalogName If @@ROWCOUNT = 0 break Set @sql = 'CREATE FULLTEXT CATALOG [] WITH ACCENT_SENSITIVITY = ' Set @sql = Replace(@sql, '', @CatalogName ) Set @sql = Replace(@sql, '', Case @is_accent_sensitivity_on When 1 Then 'ON' Else 'OFF' End ) Set @sql = Replace(@sql, '"', '''') Print @sql Exec(@sql) End -- ************************************************************** -- Recréer les indexes fulltext -- ************************************************************** Set @IndexName = '' while 1=1 Begin Select Distinct Top 1 @IndexName = IndexName, @UniqueIndexName = UniqueIndexName, @CatalogName = CatalogName From #FulltextIndexes Where IndexName > @IndexName Order by IndexName If @@ROWCOUNT = 0 break Set @sql = ' CREATE FULLTEXT INDEX ON [] ( ) KEY INDEX [] ON ([], FILEGROUP CATALOGS) WITH CHANGE_TRACKING = AUTO ' Set @ColName = '' while 1=1 Begin Select Top 1 @ColName = ColName, @TypeColName = TypeColName, @language_id = language_id From #FulltextIndexes Where IndexName = @IndexName And ColName > @ColName Order by ColName If @@ROWCOUNT = 0 break Set @colspec = ' LANGUAGE ' Set @colspec = Replace(@colspec, '', @ColName) Set @colspec = Replace(@colspec, '', Case When @TypeColName Is Null Then '' Else 'TYPE COLUMN ' + @TypeColName End) Set @colspec = Replace(@colspec, '', @language_id) Set @colspec = @colspec + ',' Set @sql = Replace(@sql, '', @colspec) End Set @sql = Replace(@sql, ',', '') Set @sql = Replace(@sql, '', @IndexName ) Set @sql = Replace(@sql, '', @UniqueIndexName ) Set @sql = Replace(@sql, '', @CatalogName ) Set @sql = Replace(@sql, '"', '''') Print @sql Exec(@sql) End End -- yUpgrade.UpgradeFulltextCatalogsFromSql2005 GO If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'Upgrade.MakeDbCompatibleToTarget' GO Create procedure Upgrade.MakeDbCompatibleToTarget @DbName sysname As Begin Declare @sql nvarchar(max) -- Put the database in multi-user Set @sql = 'ALTER DATABASE [] SET MULTI_USER WITH ROLLBACK IMMEDIATE' Set @sql = REPLACE(@sql, '', @DbName) print @sql Exec(@sql) Declare @dbCompatLevel Int select @dbCompatLevel = compatibility_level From Sys.databases Where name = @DbName Select @sql = 'ALTER DATABASE[] SET COMPATIBILITY_LEVEL = ' + convert(nvarchar, yInstall.SqlVersionNumber ()) Set @sql = REPLACE(@sql, '', @DbName) print @sql Exec(@sql) -- the db is above SQL2005 or target server is SQL2005, no need to upgrade fulltext catalogs If @dbCompatLevel > 90 Or yInstall.SqlVersionNumber () = 90 Return -- Normalize full text catalogs Exec yUtl.SqlModuleCopy @SourceDb = 'yoursqldba' , @TargetDb = @DbName , @SourceSchema = 'yUpgrade' , @sourcename = 'UpgradeFulltextCatalogsFromSql2005' Set @sql = 'Exec [].yUpgrade.UpgradeFulltextCatalogsFromSql2005' Set @sql = REPLACE(@sql, '', @DbName) print @sql Exec(@sql) Set @sql = 'use [] Drop Procedure yUpgrade.UpgradeFulltextCatalogsFromSql2005' Set @sql = REPLACE(@sql, '', @DbName) print @sql Exec(@sql) Set @sql = 'use [] Drop Schema yUpgrade' Set @sql = REPLACE(@sql, '', @DbName) print @sql Exec(@sql) End -- Upgrade.MakeDbCompatibleToTarget GO -------------------------------------------------------------------------------------- If Db_name() <> 'YourSqlDba' Use YourSqlDba Exec yUtl.DropObj 'Mirroring.Failover' GO ------------------------------------------------------------------------------------------ If Db_name() <> 'YourSqlDba' Use YourSqlDba GO ------------------------------------------------------------------------------------------ CREATE procedure [Mirroring].[Failover] @IncDb nVARCHAR(max) = '' , @ExcDb nVARCHAR(max) = '' , @Simulation int = 0 , @LastDataSync Int = 1 -- for those who use other data sync solution like CommVault SQL Live Synce (similar to YourSqlDba Mirror) As Begin Declare @sql nvarchar(max) Declare @MirrorServer sysname Declare @dbname sysname Declare @dbOwner sysname Declare @FullRecoveryMode int Declare @lastLogBkpFile nvarchar(512) Declare @lastFullBkpFile nvarchar(512) Declare @lastDiffBkpFile nvarchar(512) Declare @fileName nvarchar(512) Declare @migrationTestMode Int Declare @bkpTyp nchar(1) Declare @OverwriteBackup int Declare @ListBDMigre nvarchar(max) Declare @TargetProductVersion Int Declare @ReplaceSrcBkpPathToMatchingMirrorPath nvarchar(max) Declare @ReplacePathsInDbFilenames nvarchar(max) Declare @maxSeverity int Declare @msgs Nvarchar(max) Declare @EncryptionAlgorithm nvarchar(10) Declare @EncryptionCertificate nvarchar(100) Set NOCOUNT ON -- The function udf_YourSQLDba_ApplyFilterDb apply filter parameters on this list Create table #Db ( DbName sysname primary key clustered , DbOwner sysname NULL -- because actual owner may be invalid after a restore , FullRecoveryMode int -- If = 1 log backup allowed , lastLogBkpFile nvarchar(512) null , lastFullBkpFile nvarchar(512) null , lastDiffBkpFile nvarchar(512) null , MirrorServer sysname null , ReplaceSrcBkpPathToMatchingMirrorPath nvarchar(max) , ReplacePathsInDbFilenames nvarchar(max) , ErrorMsg nvarchar(max) default 'Succès' , EncryptionAlgorithm nvarchar(10) , EncryptionCertificate nvarchar(100) , MigrationTestMode Int ) Insert into #Db ( DbName, DbOwner, FullRecoveryMode, lastLogBkpFile, lastFullBkpFile, lastDiffBkpFile, MirrorServer , ReplaceSrcBkpPathToMatchingMirrorPath, ReplacePathsInDbFilenames,EncryptionAlgorithm,EncryptionCertificate , MigrationTestMode) Select X.DbName , X.DbOwner , X.FullRecoveryMode , L.lastLogBkpFile , L.lastFullBkpFile , L.lastDiffBkpFile , L.MirrorServer , L.ReplaceSrcBkpPathToMatchingMirrorPath , L.ReplacePathsInDbFilenames , L.EncryptionAlgorithm , L.EncryptionCertificate , L.MigrationTestMode from yUtl.YourSQLDba_ApplyFilterDb (@IncDb, @ExcDb) X join Maint.JobLastBkpLocations L On L.dbName = X.DbName --And X.DbName Not IN ('master', 'model', 'msdb') -- to avoid messages about them -- Remove Snapshot databases Delete Db From #Db Db Where Exists(Select * From sys.databases d Where d.name = db.DbName and source_database_Id is not null ) If @Simulation = 0 Begin -- Synchroniser Logins on all «MirrorServer» Set @MirrorServer = '' While 1=1 Begin Select DISTINCT Top 1 @MirrorServer=MirrorServer From #Db Where MirrorServer > @MirrorServer Order by MirrorServer If @@rowcount = 0 break Print '' Print '' Print '-- *************************************************' Print '-- Synchronisation des logins sur ' + @MirrorServer Print '-- *************************************************' Exec yMirroring.LaunchLoginSync @MirrorServer = @MirrorServer End --for each BD to process Set @dbname = '' While 1=1 Begin declare @pathBkp nvarchar(512), @language sysname Select Top 1 @dbname=DbName , @dbOwner=DbOwner , @FullRecoveryMode=FullRecoveryMode , @lastLogBkpFile=lastLogBkpFile , @lastFullBkpFile=lastFullBkpFile , @lastDiffBkpFile=lastDiffBkpFile , @MirrorServer=MirrorServer , @migrationTestMode=migrationTestMode , @ReplaceSrcBkpPathToMatchingMirrorPath=Isnull(ReplaceSrcBkpPathToMatchingMirrorPath, '') , @ReplacePathsInDbFilenames=IsNull(ReplacePathsInDbFilenames, '') , @EncryptionAlgorithm=IsNull(EncryptionAlgorithm,'') , @EncryptionCertificate=IsNull(EncryptionCertificate,'') From #Db Where DbName > @dbname Order By DbName If @@rowcount = 0 break -- Assert that the database is online If @migrationTestMode=1 Begin Update #Db Set ErrorMsg = 'Failover won''t process database ['+@dbname+'] because it is in migrationTestMode=1' Where DbName = @dbname continue End -- Assert that the database is online If DatabasepropertyEx(@dbname, 'Status') <> 'Online' Begin Update #Db Set ErrorMsg = 'Database ['+@dbname+'] is not ONLINE and cannot be processed' Where DbName = @dbname continue End -- Assert that the Database is setup for mirroring If @MirrorServer = '' Begin Update #Db Set ErrorMsg = 'Database ['+@dbname+'] is not mirrored and won''t be failed over' Where DbName = @dbname continue End -- Assert that the database is in RESTORING state Declare @DbStatus sysname Set @sql = 'SELECT @DbStatus=DbStatus FROM openquery ([], "SELECT Convert(sysname, DatabasepropertyEx("""", ""Status"")) as DbStatus")' Set @sql = REPLACE(@sql, '', @MirrorServer) Set @sql = REPLACE(@sql, '', @DbName) Set @sql = REPLACE(@sql, '"', '''') Exec sp_executesql @sql, N'@DbStatus Sysname OUTPUT', @DbStatus=@DbStatus OUTPUT If @DbStatus IS NOT NULL And @DbStatus <> 'RESTORING' Begin Update #Db Set ErrorMsg = 'Database ['+@dbname+'] is not in "RESTORING" state and won''t be failed over' Where DbName = @dbname Continue End -- Assert that the mirror server is as least the same version or higher than the source server Set @sql = 'SELECT @TargetProductVersion=Version FROM openquery ([], "SELECT YourSqlDba.yInstall.SqlVersionNumber() AS [Version]")' Set @sql = REPLACE(@sql, '', @MirrorServer) Set @sql = REPLACE(@sql, '"', '''') Exec sp_executesql @sql, N'@TargetProductVersion Int OUTPUT', @TargetProductVersion=@TargetProductVersion OUTPUT If @TargetProductVersion < yInstall.SqlVersionNumber () Begin Update #Db Set ErrorMsg = 'The target server ['+@MirrorServer+'] must be a version equal or above the source server' Where DbName = @dbname continue End -- Signal that databases in simple recovery mode are going to backuped again, and that it will -- make maintenance longer If @FullRecoveryMode = 0 Begin Update #Db Set ErrorMsg = 'Database ['+@dbname+'] is in simple recovery. A differential backup will be performed making upgrade possibly a bit slower.' Where DbName = @dbname -- End If @Simulation = 0 Begin Print '' Print '-- *************************************************' Print '-- Processing database ' + @dbname Print '-- *************************************************' -- efficient kill for all connections Set @sql = ' ALTER DATABASE [] SET Single_user WITH ROLLBACK IMMEDIATE ALTER DATABASE [] SET Multi_User ' Set @sql = REPLACE(@sql, '', @dbname) Print '' print '> ' + @sql Exec(@sql) If @LastDataSync = 1 Begin -- If the database is in full recovery mode, proceed to a last log backup -- oterwise a differential backup will be necessary If @FullRecoveryMode=1 Begin -- Do the last log backup Set @bkpTyp = 'L' Set @fileName = @lastLogBkpFile Set @OverwriteBackup = 0 End Else Begin -- Do a differential backup Set @bkpTyp = 'D' If @lastDiffBkpFile IS NOT NULL Set @fileName = @lastFullBkpFile -- overwrite existing differential backup Else Begin -- extract backup location from last full backup location to build the new filename Set @fileName = reverse(@lastFullBkpFile) Set @pathBkp = Reverse(Stuff(@filename, 1, charindex('\', @filename), '')) Exec yInstall.InstallationLanguage @Language output -- with differential backup timestamp naming is not useful in a failover context Select @filename = YourSqlDba.yMaint.MakeBackupFileName (@dbname, 'D', @pathBkp, @Language, 'Bak', 0); End Set @OverwriteBackup = 1 End If ISNULL(@EncryptionAlgorithm, '') <> '' AND ISNULL(@EncryptionCertificate, '') <> '' Begin -- backups on the same file are not supported for encrypted backups -- extract backup location from last full backup location to build the new filename Set @fileName = reverse(@lastFullBkpFile) Set @pathBkp = Reverse(Stuff(@filename, 1, charindex('\', @filename), '')) Exec yInstall.InstallationLanguage @Language output -- with differential backup timestamp naming is not useful in a failover context Select @filename = YourSqlDba.yMaint.MakeBackupFileName (@dbname, 'D', @pathBkp, @Language, 'Bak', 0); End Set @sql = yMaint.MakeBackupCmd( @dbname, @bkpTyp, @fileName, @OverwriteBackup, Null, @EncryptionAlgorithm, @EncryptionCertificate) Print '' print '> ' + @sql Exec(@sql) -- Restore backup to mirroir Set @sql = ' Exec [].YourSqlDba.yMirroring.DoRestore @BackupType="" , @Filename="" , @DbName="" , @ReplaceSrcBkpPathToMatchingMirrorPath = "" , @ReplacePathsInDbFilenames = "" ' Set @sql = REPLACE(@sql, '', @bkpTyp) Set @sql = REPLACE(@sql, '', @fileName) Set @sql = REPLACE(@sql, '', @DbName) Set @sql = REPLACE(@sql, '', @MirrorServer) Set @sql = REPLACE(@sql, '', @ReplaceSrcBkpPathToMatchingMirrorPath) Set @sql = REPLACE(@sql, '', @ReplacePathsInDbFilenames) Set @sql = REPLACE(@sql, '"', '''') Exec yExecNLog.ExecWithProfilerTrace @sql, @MaxSeverity output, @Msgs output If @maxSeverity > 10 Begin Raiserror (N'Mirroring.Failover error %s: %s %s', 11, 1, @@SERVERNAME, @Sql, @Msgs) Return (1) End End -- Set BD in Multi-User before to go offline -- it is complicated to come back multi-user when we go from offline and single_user Set @sql = 'ALTER DATABASE [] SET MULTI_USER WITH ROLLBACK IMMEDIATE' Set @sql = REPLACE(@sql, '', @dbname) Print '' print '> ' + @sql Exec(@sql) -- Put the database Offline, so no more updates and reads are possible to the old Db Set @sql = 'ALTER DATABASE [] SET OFFLINE WITH ROLLBACK IMMEDIATE' Set @sql = REPLACE(@sql, '', @DbName) Print '' print '> ' + @sql Exec(@sql) -- Switch the database on remote server, from state "restoring" to available and recovered Set @sql = 'Exec [].YourSqlDba.yMirroring.DatabaseRecovery @DbName=""' Set @sql = REPLACE(@sql, '', @DbName) Set @sql = REPLACE(@sql, '', @MirrorServer) Set @sql = REPLACE(@sql, '"', '''') Print '' print '> ' + @sql Exec(@sql) -- set the database to the original owner now it is no more in restoring state If @DbOwner IS NOT NULL -- because actual owner may already be invalid after a previous restore Begin Set @sql = 'Exec ("Alter Authorization On database::[] To []") at []' Set @sql = REPLACE(@sql, '', @DbName) Set @sql = REPLACE(@sql, '', @DbOwner) Set @sql = REPLACE(@sql, '', @MirrorServer) Set @sql = REPLACE(@sql, '"', '''') End Exec yExecNLog.ExecWithProfilerTrace @sql, @MaxSeverity output, @Msgs output If @maxSeverity > 10 Begin Raiserror (N'Mirroring.Failover error %s: %s %s', 11, 1, @@SERVERNAME, @Sql, @Msgs) Return (1) End -- Finalize the migration Set @sql = 'Exec [].YourSqlDba.Upgrade.MakeDbCompatibleToTarget @DbName=""' Set @sql = REPLACE(@sql, '', @DbName) Set @sql = REPLACE(@sql, '', @MirrorServer) Set @sql = REPLACE(@sql, '"', '''') Print '' print '> ' + @sql Exec(@sql) Set @sql = ' Update Db Set ErrorMsg = Case When X.name Is Not Null Then "Success" Else "Unexpected error. Compatibility level should""ve been set to be equal to server version. Check ShowHistoryErrors to get some details about this problem" End From #Db Db Left Join [].master.sys.databases X On Db.DbName = X.name Collate Latin1_general_ci_ai And X.compatibility_level = And X.user_access_desc = "MULTI_USER" And X.state_desc = "ONLINE" Where Db.DbName = "" ' Set @sql = REPLACE(@sql, '', @DbName) Set @sql = REPLACE(@sql, '', @MirrorServer) Set @sql = REPLACE(@sql, '', convert(nvarchar, @TargetProductVersion) ) Set @sql = REPLACE(@sql, '"', '''') Print '' print '> ' + @sql Exec(@sql) End --If @Simulation = 0 End --While 1=1 (liste des BD) End --If @Simulation = 0 -- Show maintenance status for all databases Select DbName, ErrorMsg As Statut From #Db End -- Mirroring.Failover go If Db_name() <> 'YourSqlDba' Use YourSqlDba GO If Exists(select * from sys.symmetric_keys Where name = '##MS_DatabaseMasterKey##') Drop master Key IF NOT Exists (Select * From sys.databases Where name ='YourSQLDba' And is_master_key_encrypted_by_server=1) CREATE MASTER KEY ENCRYPTION BY PASSWORD = 'Aa$1YourSQLDba123456789012345678901234567890' GO ALTER DATABASE YourSQLDba SET ENABLE_BROKER WITH ROLLBACK IMMEDIATE; GO ALTER DATABASE YourSQLDba SET NEW_BROKER WITH ROLLBACK IMMEDIATE; GO IF EXISTS (SELECT * FROM sys.services WHERE name = N'//YourSQLDba/MirrorRestore/TargetService') DROP SERVICE [//YourSQLDba/MirrorRestore/TargetService]; GO IF EXISTS (SELECT * FROM sys.service_queues WHERE name = N'YourSQLDbaTargetQueueMirrorRestore') DROP QUEUE YourSQLDbaTargetQueueMirrorRestore; GO IF EXISTS (SELECT * FROM sys.services WHERE name = N'//YourSQLDba/MirrorRestore/InitiatorService') DROP SERVICE [//YourSQLDba/MirrorRestore/InitiatorService]; GO IF EXISTS (SELECT * FROM sys.service_queues WHERE name = N'YourSQLDbaInitiatorQueueMirrorRestore') DROP QUEUE YourSQLDbaInitiatorQueueMirrorRestore; GO IF EXISTS (SELECT * FROM sys.service_contracts WHERE name = N'//YourSQLDba/MirrorRestore/Contract') DROP CONTRACT [//YourSQLDba/MirrorRestore/Contract]; GO IF EXISTS (SELECT * FROM sys.service_message_types WHERE name = N'//YourSQLDba/MirrorRestore/Request') DROP MESSAGE TYPE [//YourSQLDba/MirrorRestore/Request]; GO IF EXISTS (SELECT * FROM sys.service_message_types WHERE name = N'//YourSQLDba/MirrorRestore/Reply') DROP MESSAGE TYPE [//YourSQLDba/MirrorRestore/Reply]; GO IF EXISTS (SELECT * FROM sys.service_message_types WHERE name = N'//YourSQLDba/MirrorRestore/End') DROP MESSAGE TYPE [//YourSQLDba/MirrorRestore/End]; GO CREATE MESSAGE TYPE [//YourSQLDba/MirrorRestore/Request] VALIDATION = WELL_FORMED_XML; GO CREATE MESSAGE TYPE [//YourSQLDba/MirrorRestore/Reply] VALIDATION = WELL_FORMED_XML; GO CREATE MESSAGE TYPE [//YourSQLDba/MirrorRestore/End] VALIDATION = NONE GO CREATE CONTRACT [//YourSQLDba/MirrorRestore/Contract] ([//YourSQLDba/MirrorRestore/Request] SENT BY INITIATOR, [//YourSQLDba/MirrorRestore/End] SENT BY INITIATOR, [//YourSQLDba/MirrorRestore/Reply] SENT BY TARGET ); GO CREATE QUEUE YourSQLDbaTargetQueueMirrorRestore WITH STATUS = ON , ACTIVATION ( PROCEDURE_NAME = yMirroring.Broker_AutoActivated_LaunchRestoreToMirrorCmd, MAX_QUEUE_READERS = 1, -- Very important to preserve the restore sequence of backups EXECUTE AS SELF ); GO CREATE QUEUE YourSQLDbaInitiatorQueueMirrorRestore WITH STATUS = ON GO CREATE SERVICE [//YourSQLDba/MirrorRestore/TargetService] ON QUEUE YourSQLDbaTargetQueueMirrorRestore ([//YourSQLDba/MirrorRestore/Contract]); GO CREATE SERVICE [//YourSQLDba/MirrorRestore/InitiatorService] ON QUEUE YourSQLDbaInitiatorQueueMirrorRestore; GO -- the sole purpose of these synonyms is to avoid -- breaking scripts that could used the previous name with dbo. schema -- Ia also ease calling of procedures not prefixed by the schema maint. If OBJECT_ID ('dbo.DiagDbMail') IS NULL create synonym dbo.DiagDbMail For Maint.DiagDbMail If OBJECT_ID ('dbo.BringBackOnlineAllOfflineDb') IS NULL create synonym dbo.BringBackOnlineAllOfflineDb For Maint.BringBackOnlineAllOfflineDb If OBJECT_ID ('dbo.DeleteOldBackups') IS NULL create synonym dbo.DeleteOldBackups For Maint.DeleteOldBackups If OBJECT_ID ('dbo.YourSqlDba_DoMaint') IS NULL create synonym dbo.YourSqlDba_DoMaint For Maint.YourSqlDba_DoMaint If OBJECT_ID ('dbo.SaveDbOnNewFileSet') IS NULL create synonym dbo.SaveDbOnNewFileSet For Maint.SaveDbOnNewFileSet If OBJECT_ID ('dbo.SaveDbCopyOnly') IS NULL create synonym dbo.SaveDbCopyOnly For Maint.SaveDbCopyOnly If OBJECT_ID ('dbo.DuplicateDb') IS NULL create synonym dbo.DuplicateDb For Maint.DuplicateDb If OBJECT_ID ('dbo.DuplicateDbFromBackupHistory') IS NULL create synonym dbo.DuplicateDbFromBackupHistory For Maint.DuplicateDbFromBackupHistory If OBJECT_ID ('dbo.RestoreDb') IS NULL create synonym dbo.RestoreDb For Maint.RestoreDb If OBJECT_ID ('dbo.ShowHistory') IS NULL create synonym dbo.ShowHistory For Maint.ShowHistory If OBJECT_ID ('dbo.CreateNetworkDrives') IS NULL create synonym dbo.CreateNetworkDrives For Maint.CreateNetworkDrives If OBJECT_ID ('dbo.DisconnectNetworkDrive') IS NULL create synonym dbo.DisconnectNetworkDrive For Maint.DisconnectNetworkDrive If OBJECT_ID ('dbo.ListNetworkDrives') IS NULL create synonym dbo.ListNetworkDrives For Maint.ListNetworkDrives If OBJECT_ID ('dbo.PrepDbForMaintenanceMode') IS NULL create synonym dbo.PrepDbForMaintenanceMode For Maint.PrepDbForMaintenanceMode If OBJECT_ID ('dbo.RestoreDbAtStartOfMaintenanceMode') IS NULL create synonym dbo.RestoreDbAtStartOfMaintenanceMode For Maint.RestoreDbAtStartOfMaintenanceMode If OBJECT_ID ('dbo.ReturnDbToNormalUseFromMaintenanceMode') IS NULL create synonym dbo.ReturnDbToNormalUseFromMaintenanceMode For Maint.ReturnDbToNormalUseFromMaintenanceMode go grant execute on dbo.SaveDbOnNewFileSet to guest GO grant execute on dbo.SaveDbCopyOnly to guest GO grant execute on dbo.DuplicateDb to guest GO grant execute on dbo.DuplicateDbFromBackupHistory to guest GO grant execute on dbo.RestoreDb to guest GO -- check YourSqlDba account access through mirror server, and correct it if necessary. If failure to do it send a e-mail Exec yMirroring.CleanMirrorServerForMissingServerAndCheckServerAccessAsYourSqlDbaAccount GO -- changing parameter name ConsecutiveDaysOfFailedBackupsToPutDbOffline to ConsecutiveFailedbackupsDaysToPutDbOffline -- ================================================================================== -- ** SAMPLE** SAMPLE** SAMPLE** SAMPLE** SAMPLE** SAMPLE** SAMPLE -- ** CONFIG of MAINTENANCE -- ================================================================================== --If Db_name() <> 'YourSqlDba' Use YourSqlDba --Exec Install.InitialSetupOfYourSqlDba -- @FullBackupPath = 'c:\iSql2005Backups' -- full backup directory --, @LogBackupPath = 'c:\iSql2005Backups' -- log backup directory --, @email = 'me@myDomain' -- log maintenance --, @SmtpMailServer = 'myEmailServer' -- email server which allow incoming smtp request from SQL Server --, @ConsecutiveDaysOfFailedBackupsToPutDbOffline = 9999 -- ================================================================================== -- ** End Of SAMPLE** ** End Of SAMPLE** ** End Of SAMPLE** -- ================================================================================== GO If Schema_id('utl') is NOT NULL drop schema utl GO Exec Install.PrintVersionInfo