├── .gitattributes ├── .gitignore ├── DataWarehousing └── DateTime │ ├── fn_DateTable.sql │ ├── fn_TimeTable.sql │ └── usp_TimeTable.sql ├── LICENSE ├── README.md ├── RightsManagement ├── sp_CloneRights.sql └── sp_HelpRights.sql ├── SSISDB ├── SSISDB.Export │ ├── SSISDB.Export.sln │ ├── SSISDB.Export │ │ ├── Properties │ │ │ ├── AssemblyInfo.cs │ │ │ ├── Resources.Designer.cs │ │ │ └── Resources.resx │ │ ├── SSISDB.Export.ExportProjectClr.sql │ │ ├── SSISDB.Export.csproj │ │ ├── SSISDB.Export.snk │ │ ├── SSISDB.Export.sql │ │ ├── SSISDBExport.cs │ │ └── sp_SSISExportProject.sql │ └── TestApp │ │ ├── App.config │ │ ├── Program.cs │ │ ├── Properties │ │ └── AssemblyInfo.cs │ │ └── TestApp.csproj ├── SSISDB_Indexes.sql ├── sp_SSISCloneConfiguration.sql ├── sp_SSISCloneEnvironment.sql ├── sp_SSISClonePermissions.sql ├── sp_SSISCloneProject.sql ├── sp_SSISExportProject.sql ├── sp_SSISListEnvironment.sql ├── sp_SSISMapEnvironment.sql ├── sp_SSISResetConfiguraion.sql ├── sp_ssisdb.sql ├── sp_ssisstat.sql ├── usp_CheckConstraints.sql ├── usp_cleanup_key_certificates.sql └── usp_cleanup_server_retention_window.sql ├── Samples └── DateTime │ ├── DayOfWeek.sql │ └── StartAndEndOfPeriods.sql ├── Searching └── sp_find.sql ├── TablesManagement ├── Partitioning │ ├── sp_HelpPartitionFunction.sql │ ├── sp_HelpPartitionScheme.sql │ ├── sp_tblCheckAndCreatePartitions.sql │ ├── sp_tblCleanupRetentionWindow.sql │ ├── sp_tblCreatePartitionFunction.sql │ ├── sp_tblDropPartition.sql │ └── sp_tblSwitchPartition.sql └── Scripting │ ├── 01-sp_tblScriptIndexes.sql │ └── 02-sp_tblScriptTable.sql └── msdb ├── sp_ScheduleStatus.sql └── sp_jobstatus.sql /.gitattributes: -------------------------------------------------------------------------------- 1 | ############################################################################### 2 | # Set default behavior to automatically normalize line endings. 3 | ############################################################################### 4 | * text=auto 5 | 6 | ############################################################################### 7 | # Set default behavior for command prompt diff. 8 | # 9 | # This is need for earlier builds of msysgit that does not have it on by 10 | # default for csharp files. 11 | # Note: This is only used by command line 12 | ############################################################################### 13 | #*.cs diff=csharp 14 | 15 | ############################################################################### 16 | # Set the merge driver for project and solution files 17 | # 18 | # Merging from the command prompt will add diff markers to the files if there 19 | # are conflicts (Merging from VS is not affected by the settings below, in VS 20 | # the diff markers are never inserted). Diff markers may cause the following 21 | # file extensions to fail to load in VS. An alternative would be to treat 22 | # these files as binary and thus will always conflict and require user 23 | # intervention with every merge. To do so, just uncomment the entries below 24 | ############################################################################### 25 | #*.sln merge=binary 26 | #*.csproj merge=binary 27 | #*.vbproj merge=binary 28 | #*.vcxproj merge=binary 29 | #*.vcproj merge=binary 30 | #*.dbproj merge=binary 31 | #*.fsproj merge=binary 32 | #*.lsproj merge=binary 33 | #*.wixproj merge=binary 34 | #*.modelproj merge=binary 35 | #*.sqlproj merge=binary 36 | #*.wwaproj merge=binary 37 | 38 | ############################################################################### 39 | # behavior for image files 40 | # 41 | # image files are treated as binary by default. 42 | ############################################################################### 43 | #*.jpg binary 44 | #*.png binary 45 | #*.gif binary 46 | 47 | ############################################################################### 48 | # diff behavior for common document formats 49 | # 50 | # Convert binary document formats to text before diffing them. This feature 51 | # is only available from the command line. Turn it on by uncommenting the 52 | # entries below. 53 | ############################################################################### 54 | #*.doc diff=astextplain 55 | #*.DOC diff=astextplain 56 | #*.docx diff=astextplain 57 | #*.DOCX diff=astextplain 58 | #*.dot diff=astextplain 59 | #*.DOT diff=astextplain 60 | #*.pdf diff=astextplain 61 | #*.PDF diff=astextplain 62 | #*.rtf diff=astextplain 63 | #*.RTF diff=astextplain 64 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | ## Ignore Visual Studio temporary files, build results, and 2 | ## files generated by popular Visual Studio add-ons. 3 | 4 | # User-specific files 5 | *.suo 6 | *.user 7 | *.userosscache 8 | *.sln.docstates 9 | 10 | # User-specific files (MonoDevelop/Xamarin Studio) 11 | *.userprefs 12 | 13 | # Build results 14 | [Dd]ebug/ 15 | [Dd]ebugPublic/ 16 | [Rr]elease/ 17 | [Rr]eleases/ 18 | x64/ 19 | x86/ 20 | bld/ 21 | [Bb]in/ 22 | [Oo]bj/ 23 | [Ll]og/ 24 | 25 | # Visual Studio 2015 cache/options directory 26 | .vs/ 27 | # Uncomment if you have tasks that create the project's static files in wwwroot 28 | #wwwroot/ 29 | 30 | # MSTest test Results 31 | [Tt]est[Rr]esult*/ 32 | [Bb]uild[Ll]og.* 33 | 34 | # NUNIT 35 | *.VisualState.xml 36 | TestResult.xml 37 | 38 | # Build Results of an ATL Project 39 | [Dd]ebugPS/ 40 | [Rr]eleasePS/ 41 | dlldata.c 42 | 43 | # DNX 44 | project.lock.json 45 | artifacts/ 46 | 47 | *_i.c 48 | *_p.c 49 | *_i.h 50 | *.ilk 51 | *.meta 52 | *.obj 53 | *.pch 54 | *.pdb 55 | *.pgc 56 | *.pgd 57 | *.rsp 58 | *.sbr 59 | *.tlb 60 | *.tli 61 | *.tlh 62 | *.tmp 63 | *.tmp_proj 64 | *.log 65 | *.vspscc 66 | *.vssscc 67 | .builds 68 | *.pidb 69 | *.svclog 70 | *.scc 71 | 72 | # Chutzpah Test files 73 | _Chutzpah* 74 | 75 | # Visual C++ cache files 76 | ipch/ 77 | *.aps 78 | *.ncb 79 | *.opendb 80 | *.opensdf 81 | *.sdf 82 | *.cachefile 83 | *.VC.db 84 | *.VC.VC.opendb 85 | 86 | # Visual Studio profiler 87 | *.psess 88 | *.vsp 89 | *.vspx 90 | *.sap 91 | 92 | # TFS 2012 Local Workspace 93 | $tf/ 94 | 95 | # Guidance Automation Toolkit 96 | *.gpState 97 | 98 | # ReSharper is a .NET coding add-in 99 | _ReSharper*/ 100 | *.[Rr]e[Ss]harper 101 | *.DotSettings.user 102 | 103 | # JustCode is a .NET coding add-in 104 | .JustCode 105 | 106 | # TeamCity is a build add-in 107 | _TeamCity* 108 | 109 | # DotCover is a Code Coverage Tool 110 | *.dotCover 111 | 112 | # NCrunch 113 | _NCrunch_* 114 | .*crunch*.local.xml 115 | nCrunchTemp_* 116 | 117 | # MightyMoose 118 | *.mm.* 119 | AutoTest.Net/ 120 | 121 | # Web workbench (sass) 122 | .sass-cache/ 123 | 124 | # Installshield output folder 125 | [Ee]xpress/ 126 | 127 | # DocProject is a documentation generator add-in 128 | DocProject/buildhelp/ 129 | DocProject/Help/*.HxT 130 | DocProject/Help/*.HxC 131 | DocProject/Help/*.hhc 132 | DocProject/Help/*.hhk 133 | DocProject/Help/*.hhp 134 | DocProject/Help/Html2 135 | DocProject/Help/html 136 | 137 | # Click-Once directory 138 | publish/ 139 | 140 | # Publish Web Output 141 | *.[Pp]ublish.xml 142 | *.azurePubxml 143 | # TODO: Comment the next line if you want to checkin your web deploy settings 144 | # but database connection strings (with potential passwords) will be unencrypted 145 | *.pubxml 146 | *.publishproj 147 | 148 | # Microsoft Azure Web App publish settings. Comment the next line if you want to 149 | # checkin your Azure Web App publish settings, but sensitive information contained 150 | # in these scripts will be unencrypted 151 | PublishScripts/ 152 | 153 | # NuGet Packages 154 | *.nupkg 155 | # The packages folder can be ignored because of Package Restore 156 | **/packages/* 157 | # except build/, which is used as an MSBuild target. 158 | !**/packages/build/ 159 | # Uncomment if necessary however generally it will be regenerated when needed 160 | #!**/packages/repositories.config 161 | # NuGet v3's project.json files produces more ignoreable files 162 | *.nuget.props 163 | *.nuget.targets 164 | 165 | # Microsoft Azure Build Output 166 | csx/ 167 | *.build.csdef 168 | 169 | # Microsoft Azure Emulator 170 | ecf/ 171 | rcf/ 172 | 173 | # Windows Store app package directories and files 174 | AppPackages/ 175 | BundleArtifacts/ 176 | Package.StoreAssociation.xml 177 | _pkginfo.txt 178 | 179 | # Visual Studio cache files 180 | # files ending in .cache can be ignored 181 | *.[Cc]ache 182 | # but keep track of directories ending in .cache 183 | !*.[Cc]ache/ 184 | 185 | # Others 186 | ClientBin/ 187 | ~$* 188 | *~ 189 | *.dbmdl 190 | *.dbproj.schemaview 191 | *.pfx 192 | *.publishsettings 193 | node_modules/ 194 | orleans.codegen.cs 195 | 196 | # Since there are multiple workflows, uncomment next line to ignore bower_components 197 | # (https://github.com/github/gitignore/pull/1529#issuecomment-104372622) 198 | #bower_components/ 199 | 200 | # RIA/Silverlight projects 201 | Generated_Code/ 202 | 203 | # Backup & report files from converting an old project file 204 | # to a newer Visual Studio version. Backup files are not needed, 205 | # because we have git ;-) 206 | _UpgradeReport_Files/ 207 | Backup*/ 208 | UpgradeLog*.XML 209 | UpgradeLog*.htm 210 | 211 | # SQL Server files 212 | *.mdf 213 | *.ldf 214 | 215 | # Business Intelligence projects 216 | *.rdl.data 217 | *.bim.layout 218 | *.bim_*.settings 219 | 220 | # Microsoft Fakes 221 | FakesAssemblies/ 222 | 223 | # GhostDoc plugin setting file 224 | *.GhostDoc.xml 225 | 226 | # Node.js Tools for Visual Studio 227 | .ntvs_analysis.dat 228 | 229 | # Visual Studio 6 build log 230 | *.plg 231 | 232 | # Visual Studio 6 workspace options file 233 | *.opt 234 | 235 | # Visual Studio LightSwitch build output 236 | **/*.HTMLClient/GeneratedArtifacts 237 | **/*.DesktopClient/GeneratedArtifacts 238 | **/*.DesktopClient/ModelManifest.xml 239 | **/*.Server/GeneratedArtifacts 240 | **/*.Server/ModelManifest.xml 241 | _Pvt_Extensions 242 | 243 | # Paket dependency manager 244 | .paket/paket.exe 245 | paket-files/ 246 | 247 | # FAKE - F# Make 248 | .fake/ 249 | 250 | # JetBrains Rider 251 | .idea/ 252 | *.sln.iml 253 | 254 | .DS_Store 255 | -------------------------------------------------------------------------------- /DataWarehousing/DateTime/fn_TimeTable.sql: -------------------------------------------------------------------------------- 1 | IF NOT EXISTS (SELECT 1 FROM sys.objects WHERE object_id = OBJECT_ID('[dbo].[fn_TimeTable]') AND TYPE = 'IF') 2 | EXECUTE ('CREATE FUNCTION [dbo].[fn_TimeTable]() RETURNS TABLE AS RETURN(SELECT ''Container for fn_TimeTable() (C) Pavel Pawlowski'' AS DateTable)'); 3 | GO 4 | /* **************************************************** 5 | fn_TimeTable v 1.0 (C) 2015 - 2018 Pavel Pawlowski 6 | 7 | Feedback: mailto:pavel.pawlowski@hotmail.cz 8 | 9 | MIT License 10 | 11 | Copyright (c) 2018 Pavel Pawlowski 12 | 13 | Permission is hereby granted, free of charge, to any person obtaining a copy 14 | of this software and associated documentation files (the "Software"), to deal 15 | in the Software without restriction, including without limitation the rights 16 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 17 | copies of the Software, and to permit persons to whom the Software is 18 | furnished to do so, subject to the following conditions: 19 | 20 | The above copyright notice and this permission notice shall be included in all 21 | copies or substantial portions of the Software. 22 | 23 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 24 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 25 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 26 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 27 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 28 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 29 | 30 | Description: 31 | Generates a TimeTable for Kimball's based Time Dimensions. Works on SQL Server 2012 and above. 32 | 33 | Parameters: 34 | @culture nvarchar(10) = N'en-US' -- Culture to be used for names generation 35 | ,@timeNameFormatString nvarchar(30) = N'T' -- Format string for time name 36 | ,@timeName12FormatString nvarchar(30) = N'hh:mm:ss tt' -- Format string for 12h time name 37 | ,@hourNameFormatString nvarchar(30) = N'H ' -- Format string for nour name 38 | ,@hour12NameFormatString nvarchar(30) = N'h tt' -- Format string for 12h hour name 39 | ,@hourMinuteNameFormatString nvarchar(30) = N't' -- Format string for hour minute name 40 | ,@minuteNameFormatString nvarchar(30) = N'MM' -- Format string for minute name 41 | ,@minuteSecondNameFormatString nvarchar(30) = N'mm:ss' -- Format string for minute second name 42 | ,@secondNameFormatString nvarchar(30) = N'ss' -- Format string for second name 43 | ,@hourOfNameFormatString nvarchar(30) = N'# ##0\. h' -- Format string for hour of ... name 44 | ,@minuteOfNameFormatString nvarchar(30) = N'# ##0\. min' -- Format string for minute of ... name 45 | ,@secondOfNameFormatString nvarchar(30) = N'# ##0\. sec' -- Format string for second of ... name 46 | ,@amPmIndicatorFormatString nvarchar(30) = N'tt' -- Format string for AM/PM indicator 47 | 48 | For details on Format Strings, review MSDN - FORMAT(Transact-SQL): https://msdn.microsoft.com/en-us/library/hh213505.aspx 49 | For details on cultures see MDSDN - National Language Support (NLS) API Reference: https://msdn.microsoft.com/en-us/goglobal/bb896001.aspx 50 | Usage: 51 | To provide multiple translations of the names, you can INNER JOIN two calls to the function 52 | 53 | **************************************************** */ 54 | ALTER FUNCTION [dbo].[fn_TimeTable] ( 55 | @culture nvarchar(10) = N'en-US' -- Culture to be used for names generation 56 | ,@timeNameFormatString nvarchar(30) = N'T' -- Format string for time name 57 | ,@timeName12FormatString nvarchar(30) = N'hh:mm:ss tt' -- Format string for 12h time name 58 | ,@hourNameFormatString nvarchar(30) = N'H ' -- Format string for nour name 59 | ,@hour12NameFormatString nvarchar(30) = N'h tt' -- Format string for 12h hour name 60 | ,@hourMinuteNameFormatString nvarchar(30) = N't' -- Format string for hour minute name 61 | ,@minuteNameFormatString nvarchar(30) = N'MM' -- Format string for minute name 62 | ,@minuteSecondNameFormatString nvarchar(30) = N'mm:ss' -- Format string for minute second name 63 | ,@secondNameFormatString nvarchar(30) = N'ss' -- Format string for second name 64 | ,@hourOfNameFormatString nvarchar(30) = N'# ##0\. h' -- Format string for hour of ... name 65 | ,@minuteOfNameFormatString nvarchar(30) = N'# ##0\. min' -- Format string for minute of ... name 66 | ,@secondOfNameFormatString nvarchar(30) = N'# ##0\. sec' -- Format string for second of ... name 67 | ,@amPmIndicatorFormatString nvarchar(30) = N'tt' -- Format string for AM/PM indicator 68 | ) 69 | RETURNS TABLE 70 | AS 71 | RETURN ( 72 | WITH NumTable AS ( --Numbers Table 73 | SELECT N FROM(VALUES (1), (1), (1), (1), (1), (1), (1), (1), (1), (1)) T(N) 74 | ), 75 | Times AS ( --Generate Times as time of 1900-01-01 76 | SELECT TOP (86400) --Take only TOP 86400 rows, which represents number of seconds in a day 77 | CONVERT(datetime2(0), DATEADD(SECOND, ROW_NUMBER() OVER(ORDER BY (SELECT NULL)) - 1, 0)) AS [DateTime] 78 | FROM 79 | NumTable N10 80 | ,NumTable N100 81 | ,NumTable N1000 82 | ,NumTable N10000 83 | ,NumTable N100000 84 | ), 85 | TimeTable AS ( --Generate a TimeTable 86 | SELECT 87 | T.[DateTime] AS [DateTime] 88 | ,DATEPART(HOUR, T.[DateTime]) * 10000 + DATEPART(MINUTE, T.[DateTime]) * 100 + DATEPART(SECOND, T.[DateTime]) AS [TimeKey] 89 | ,CONVERT(time(0), T.[DateTime]) AS [Time] 90 | ,CONVERT(tinyint, DATEPART(HOUR, T.[DateTime])) AS [Hour] 91 | ,CONVERT(tinyint, FORMAT(T.[DateTime], N'hh', N'en-US')) AS [Hour12] 92 | ,CONVERT(tinyint, DATEPART(MINUTE, T.[DateTime])) AS [Minute] 93 | ,CONVERT(tinyint, DATEPART(SECOND, T.[DateTime])) AS [Second] 94 | ,CONVERT(tinyint, DATEPART(HOUR, T.[DateTime]) + 1) AS [HourOfDay] 95 | ,CONVERT(smallint, DATEPART(HOUR, T.[DateTime]) * 100 + DATEPART(MINUTE, T.[DateTime])) AS [HourMinute] 96 | ,CONVERT(smallint, DATEDIFF(MINUTE, 0, T.[DateTime]) + 1) AS [MinuteOfDay] 97 | ,CONVERT(tinyint, DATEPART(MINUTE, T.[DateTime]) + 1 ) AS [MinuteOfHour] 98 | ,CONVERT(smallint, DATEPART(MINUTE, T.[DateTime]) * 100 + DATEPART(SECOND, T.[DateTime])) AS [MinuteSecond] 99 | ,CONVERT(int, DATEDIFF(SECOND, 0, T.[DateTime]) + 1) AS [SecondOfDay] 100 | ,CONVERT(smallint, DATEPART(MINUTE, T.[DateTime]) * 60 + DATEPART(SECOND, T.[DateTime]) + 1) AS [SecondOfHour] 101 | ,CONVERT(tinyint, DATEPART(SECOND, T.[DateTime]) + 1) AS [SecondOfMinute] 102 | FROM [Times] T 103 | ) 104 | SELECT 105 | [TimeKey] AS [TimeKey] 106 | ,[Time] AS [Time] 107 | ,LTRIM(RTRIM(CONVERT(nvarchar(30), FORMAT(T.[DateTime], @timeNameFormatString, @culture)))) AS [TimeName] 108 | ,LTRIM(RTRIM(CONVERT(nvarchar(30), FORMAT(T.[DateTime], @timeName12FormatString, @culture)))) AS [TimeName12] 109 | 110 | ,[Hour] AS [Hour] 111 | ,LTRIM(RTRIM(CONVERT(nvarchar(30), FORMAT(T.[DateTime], @hourNameFormatString, @culture)))) AS [HourName] 112 | ,[Hour12] AS [Hour12] 113 | ,LTRIM(RTRIM(CONVERT(nvarchar(30), FORMAT(T.[DateTime], @hour12NameFormatString, @culture)))) AS [Hour12Name] 114 | ,[Minute] AS [Minute] 115 | ,LTRIM(RTRIM(CONVERT(nvarchar(30), FORMAT(T.[DateTime], @minuteNameFormatString, @culture)))) AS [MinuteName] 116 | ,[Second] AS [Second] 117 | ,LTRIM(RTRIM(CONVERT(nvarchar(30), FORMAT(T.[DateTime], @secondNameFormatString, @culture)))) AS [SecondName] 118 | 119 | ,[HourOfDay] AS [HourOfDay] 120 | ,LTRIM(RTRIM(CONVERT(nvarchar(30), FORMAT([HourOfDay], @hourOfNameFormatString, @culture)))) AS [HourOfDayName] 121 | 122 | ,[HourMinute] AS [HourMinute] 123 | ,LTRIM(RTRIM(CONVERT(nvarchar(30), FORMAT(T.[DateTime], @hourMinuteNameFormatString, @culture)))) AS [HourMinuteName] 124 | ,[MinuteOfDay] AS [MinuteOfDay] 125 | ,LTRIM(RTRIM(CONVERT(nvarchar(30), FORMAT([MinuteOfDay], @minuteOfNameFormatString, @culture)))) AS [MinuteOfDayName] 126 | ,[MinuteOfHour] AS [MinuteOfHour] 127 | ,LTRIM(RTRIM(CONVERT(nvarchar(30), FORMAT([MinuteOfHour], @minuteOfNameFormatString, @culture)))) AS [MinuteOfHourName] 128 | 129 | ,[MinuteSecond] AS [MinuteSecond] 130 | ,LTRIM(RTRIM(CONVERT(nvarchar(30), FORMAT(T.[DateTime], @minuteSecondNameFormatString, @culture)))) AS [MinuteSecondName] 131 | ,[SecondOfDay] AS [SecondOfDay] 132 | ,LTRIM(RTRIM(CONVERT(nvarchar(30), FORMAT([SecondOfDay], @secondOfNameFormatString, @culture)))) AS [SecondOfDayName] 133 | ,[SecondOfHour] AS [SecondOfHour] 134 | ,LTRIM(RTRIM(CONVERT(nvarchar(30), FORMAT([SecondOfHour], @secondOfNameFormatString, @culture)))) AS [SecondOfHourName] 135 | ,[SecondOfMinute] AS [SecondOfMinute] 136 | ,LTRIM(RTRIM(CONVERT(nvarchar(30), FORMAT([SecondOfMinute], @secondOfNameFormatString, @culture)))) AS [SecondOfMinuteName] 137 | 138 | ,LTRIM(RTRIM(CONVERT(nvarchar(30), FORMAT(T.[DateTime], @amPmIndicatorFormatString, @culture)))) AS [AmPmName] 139 | FROM TimeTable T 140 | ) -------------------------------------------------------------------------------- /DataWarehousing/DateTime/usp_TimeTable.sql: -------------------------------------------------------------------------------- 1 | IF NOT EXISTS (SELECT 1 FROM sys.all_objects WHERE object_id = OBJECT_ID('[dbo].[usp_TimeTable]') AND TYPE = 'P') 2 | EXECUTE ('CREATE PROCEDURE [dbo].[usp_TimeTable] AS BEGIN PRINT ''Container for usp_TimeTable (C) Pavel Pawlowski'' END'); 3 | GO 4 | /* **************************************************** 5 | usp_TimeTable v 1.0 6 | (C) 2015 Pavel Pawlowski 7 | 8 | Feedback: mailto:pavel.pawlowski@hotmail.cz 9 | 10 | License: 11 | usp_TimeTable is free to download and use for personal, educational, and internal 12 | corporate purposes, provided that this header is preserved. Redistribution or sale 13 | of usp_TimeTable, in whole or in part, is prohibited without the author's express 14 | written consent. 15 | 16 | Description: 17 | Generates a TimeTable for Kimball's based Time Dimensions. Works on SQL Server 2012 and above. 18 | Encapsulates call to fn_TimeTable. 19 | 20 | Parameters: 21 | @culture nvarchar(10) = N'en-US' -- Culture to be used for names generation 22 | ,@timeNameFormatString nvarchar(30) = N'T' -- Format string for time name 23 | ,@timeName12FormatString nvarchar(30) = N'hh:mm:ss tt' -- Format string for 12h time name 24 | ,@hourNameFormatString nvarchar(30) = N'H ' -- Format string for nour name 25 | ,@hour12NameFormatString nvarchar(30) = N'h tt' -- Format string for 12h hour name 26 | ,@hourMinuteNameFormatString nvarchar(30) = N't' -- Format string for hour minute name 27 | ,@minuteNameFormatString nvarchar(30) = N'MM' -- Format string for minute name 28 | ,@minuteSecondNameFormatString nvarchar(30) = N'mm:ss' -- Format string for minute second name 29 | ,@secondNameFormatString nvarchar(30) = N'ss' -- Format string for second name 30 | ,@hourOfNameFormatString nvarchar(30) = N'# ##0\. h' -- Format string for hour of ... name 31 | ,@minuteOfNameFormatString nvarchar(30) = N'# ##0\. min' -- Format string for minute of ... name 32 | ,@secondOfNameFormatString nvarchar(30) = N'# ##0\. sec' -- Format string for second of ... name 33 | ,@amPmIndicatorFormatString nvarchar(30) = N'tt' -- Format string for AM/PM indicator 34 | 35 | For details on Format Strings, review MSDN - FORMAT(Transact-SQL): https://msdn.microsoft.com/en-us/library/hh213505.aspx 36 | For details on cultures see MDSDN - National Language Support (NLS) API Reference: https://msdn.microsoft.com/en-us/goglobal/bb896001.aspx 37 | 38 | **************************************************** */ 39 | ALTER PROCEDURE [dbo].[usp_TimeTable] 40 | @culture nvarchar(10) = N'en-US' -- Culture to be used for names generation 41 | ,@timeNameFormatString nvarchar(30) = N'T' -- Format string for time name 42 | ,@timeName12FormatString nvarchar(30) = N'hh:mm:ss tt' -- Format string for 12h time name 43 | ,@hourNameFormatString nvarchar(30) = N'H ' -- Format string for nour name 44 | ,@hour12NameFormatString nvarchar(30) = N'h tt' -- Format string for 12h hour name 45 | ,@hourMinuteNameFormatString nvarchar(30) = N't' -- Format string for hour minute name 46 | ,@minuteNameFormatString nvarchar(30) = N'MM' -- Format string for minute name 47 | ,@minuteSecondNameFormatString nvarchar(30) = N'mm:ss' -- Format string for minute second name 48 | ,@secondNameFormatString nvarchar(30) = N'ss' -- Format string for second name 49 | ,@hourOfNameFormatString nvarchar(30) = N'# ##0\. h' -- Format string for hour of ... name 50 | ,@minuteOfNameFormatString nvarchar(30) = N'# ##0\. min' -- Format string for minute of ... name 51 | ,@secondOfNameFormatString nvarchar(30) = N'# ##0\. sec' -- Format string for second of ... name 52 | ,@amPmIndicatorFormatString nvarchar(30) = N'tt' -- Format string for AM/PM indicator 53 | AS 54 | BEGIN 55 | SELECT 56 | [TimeKey] 57 | ,[Time] 58 | ,[TimeName] 59 | ,[TimeName12] 60 | ,[Hour] 61 | ,[HourName] 62 | ,[Hour12] 63 | ,[Hour12Name] 64 | ,[Minute] 65 | ,[MinuteName] 66 | ,[Second] 67 | ,[SecondName] 68 | ,[HourOfDay] 69 | ,[HourOfDayName] 70 | ,[HourMinute] 71 | ,[HourMinuteName] 72 | ,[MinuteOfDay] 73 | ,[MinuteOfDayName] 74 | ,[MinuteOfHour] 75 | ,[MinuteOfHourName] 76 | ,[MinuteSecond] 77 | ,[MinuteSecondName] 78 | ,[SecondOfDay] 79 | ,[SecondOfDayName] 80 | ,[SecondOfHour] 81 | ,[SecondOfHourName] 82 | ,[SecondOfMinute] 83 | ,[SecondOfMinuteName] 84 | ,[AmPmName] 85 | FROM dbo.fn_TimeTable( 86 | @culture 87 | ,@timeNameFormatString 88 | ,@timeName12FormatString 89 | ,@hourNameFormatString 90 | ,@hour12NameFormatString 91 | ,@hourMinuteNameFormatString 92 | ,@minuteNameFormatString 93 | ,@minuteSecondNameFormatString 94 | ,@secondNameFormatString 95 | ,@hourOfNameFormatString 96 | ,@minuteOfNameFormatString 97 | ,@secondOfNameFormatString 98 | ,@amPmIndicatorFormatString 99 | ) 100 | END -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2017 Pavel Pawlowski 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # SQL-Scripts 2 | 3 | This project contain scripts for SQL Server in different Areas. 4 | 5 | ## Searching 6 | 7 | Scripts for simplifying searching of objects on SQL Server. 8 | 9 | ### sp_find 10 | 11 | Powerful stored procedure for searching objects on SQL Server. Searching by name or by object definition. Allows Searching Database scope objects, Server Scoped objects as well as searching SSIS packages stored in both SSISDB and msdb. 12 | 13 | ## Rights Management 14 | 15 | Righs management folder contains script usable for managing user rights. 16 | 17 | ### sp_CloneRights 18 | 19 | Stored procedure for scripting database objects rights granted to a database principal or to clone the database objects rights among principals. 20 | 21 | ### sp_HelpRights 22 | 23 | Stored procedure provides overview about rights assignments in database. 24 | 25 | ## SSISDB 26 | 27 | SSISDB folder contains scripts related to SSIS. 28 | 29 | ### sp_ssisdb 30 | 31 | Stored procedure provides information about operations in ssisdb. 32 | It tool for easy (and advanced) analysis of what is going on on SSIS Server. 33 | Use `sp_ssisdb '?'` for detailed help. 34 | 35 | ### sp_SSISCloneEnvironment 36 | 37 | Stored procedure for cloning SSIS server variables from one environment to another. It supports generation of easily reusable scripts for replication of the SSIS Server variables among environments. 38 | 39 | ### sp_SSISCloneConfiguration 40 | 41 | Stored procedure cones SSIS project configuration from one project to another. 42 | Allows simple scripting of existing configuration for easy transfer among environments or backup purposes. 43 | 44 | ### sp_SSISClonePermissions 45 | 46 | Stored procedure clones permissions on objects in SSISDB catalog. 47 | Allows easy scripting of existing granular permissions on Folders, Project and Environments. 48 | 49 | ### sp_SSISCloneProject 50 | 51 | Stored procedure for cloning SSIS project(s) among folders and servers. 52 | Allows simple deployment of projects among servers through linked servers. 53 | 54 | ### sp_SSISMapEnvironment 55 | 56 | Stored procedure maps Project/Object configuration parameters to corresponding Environment variables. 57 | Mapping is done on parameter and variable name as well as data type. 58 | 59 | ### sp_SSISListEnvironment 60 | 61 | Stored procedure allows easy listing of environment variables and their values. 62 | Allows decryption of encrypted variable values. 63 | 64 | ### sp_SSISResetConfiguration 65 | 66 | Stored procedure allows easy reset of Project/Object/Parameter configuration values. 67 | 68 | ### usp_cleanup_server_retention_window 69 | 70 | Cleanups SSISDB catalog from all kind of log mesasges belonging to operations past specified data or retention window 71 | 72 | ### usp_cleanup_key_certificates 73 | 74 | Cleanups SSISDB catalog from left over certificates and symmetric keys 75 | 76 | ## msdb 77 | 78 | Stored procedures for stuff related to msdb. 79 | 80 | ### sp_jobStatus 81 | Stored procedure allows easy generation of scripts for setting status of agent jobs. 82 | Useful during maintenance breaks to generate script for disabling all active jobs and their easy re-enabling by simple parameter change. 83 | 84 | ## Tables Management 85 | 86 | Contains stored procedures for managing tables. 87 | 88 | ### Partitioning 89 | 90 | Contains stored procedure for managing partitioned tables. 91 | 92 | #### sp_tblCreatePartitionFunction 93 | 94 | Generates Partition function for specified range of dates in specified format. 95 | 96 | #### sp_HelpPartitionFunction 97 | 98 | Provides information about the partition function including partitions it will generate and their boundary values. 99 | Procedure also lists depended partition schemes and tables/indexed views/indexes using that partition function. 100 | 101 | #### sp_HelpPartitionScheme 102 | 103 | Provides information about the partition scheme including the partition function it is based on and partition boundary values. 104 | Procedure also lists depended tables and indexes using the partition scheme. 105 | 106 | #### sp_tblCleanupRetentionWindow 107 | 108 | Cleans retention window for all tables associated with partition function. 109 | It Truncates any partition prior the partition containing retention window and then merges all those partitions into the first (leftmost) one. 110 | -------------------------------------------------------------------------------- /SSISDB/SSISDB.Export/SSISDB.Export.sln: -------------------------------------------------------------------------------- 1 |  2 | Microsoft Visual Studio Solution File, Format Version 12.00 3 | # Visual Studio 15 4 | VisualStudioVersion = 15.0.28307.645 5 | MinimumVisualStudioVersion = 10.0.40219.1 6 | Project("{FAE04EC0-301F-11D3-BF4B-00C04F79EFBC}") = "SSISDB.Export", "SSISDB.Export\SSISDB.Export.csproj", "{987FD3E8-0C65-46F9-AD9D-26CA2A5D065B}" 7 | EndProject 8 | Project("{FAE04EC0-301F-11D3-BF4B-00C04F79EFBC}") = "TestApp", "TestApp\TestApp.csproj", "{2D6990A8-A13F-4E2D-B73A-6EBB17676BE1}" 9 | EndProject 10 | Global 11 | GlobalSection(SolutionConfigurationPlatforms) = preSolution 12 | Debug|Any CPU = Debug|Any CPU 13 | Release|Any CPU = Release|Any CPU 14 | EndGlobalSection 15 | GlobalSection(ProjectConfigurationPlatforms) = postSolution 16 | {987FD3E8-0C65-46F9-AD9D-26CA2A5D065B}.Debug|Any CPU.ActiveCfg = Debug|Any CPU 17 | {987FD3E8-0C65-46F9-AD9D-26CA2A5D065B}.Debug|Any CPU.Build.0 = Debug|Any CPU 18 | {987FD3E8-0C65-46F9-AD9D-26CA2A5D065B}.Release|Any CPU.ActiveCfg = Release|Any CPU 19 | {987FD3E8-0C65-46F9-AD9D-26CA2A5D065B}.Release|Any CPU.Build.0 = Release|Any CPU 20 | {2D6990A8-A13F-4E2D-B73A-6EBB17676BE1}.Debug|Any CPU.ActiveCfg = Debug|Any CPU 21 | {2D6990A8-A13F-4E2D-B73A-6EBB17676BE1}.Debug|Any CPU.Build.0 = Debug|Any CPU 22 | {2D6990A8-A13F-4E2D-B73A-6EBB17676BE1}.Release|Any CPU.ActiveCfg = Release|Any CPU 23 | {2D6990A8-A13F-4E2D-B73A-6EBB17676BE1}.Release|Any CPU.Build.0 = Release|Any CPU 24 | EndGlobalSection 25 | GlobalSection(SolutionProperties) = preSolution 26 | HideSolutionNode = FALSE 27 | EndGlobalSection 28 | GlobalSection(ExtensibilityGlobals) = postSolution 29 | SolutionGuid = {3380EDD5-F387-4D69-B3D9-A21494430026} 30 | EndGlobalSection 31 | EndGlobal 32 | -------------------------------------------------------------------------------- /SSISDB/SSISDB.Export/SSISDB.Export/Properties/AssemblyInfo.cs: -------------------------------------------------------------------------------- 1 | using System.Reflection; 2 | using System.Runtime.CompilerServices; 3 | using System.Runtime.InteropServices; 4 | 5 | // General Information about an assembly is controlled through the following 6 | // set of attributes. Change these attribute values to modify the information 7 | // associated with an assembly. 8 | [assembly: AssemblyTitle("SSISDB.Export")] 9 | [assembly: AssemblyDescription("Allows export of SSISDB project versions to .ispac files")] 10 | [assembly: AssemblyConfiguration("")] 11 | [assembly: AssemblyCompany("Pavel Pawlowski")] 12 | [assembly: AssemblyProduct("SSISDB.Export")] 13 | [assembly: AssemblyCopyright("Copyright © 2019Pavel Pawlowski")] 14 | [assembly: AssemblyTrademark("")] 15 | [assembly: AssemblyCulture("")] 16 | 17 | // Setting ComVisible to false makes the types in this assembly not visible 18 | // to COM components. If you need to access a type in this assembly from 19 | // COM, set the ComVisible attribute to true on that type. 20 | [assembly: ComVisible(false)] 21 | 22 | // The following GUID is for the ID of the typelib if this project is exposed to COM 23 | [assembly: Guid("987fd3e8-0c65-46f9-ad9d-26ca2a5d065b")] 24 | 25 | // Version information for an assembly consists of the following four values: 26 | // 27 | // Major Version 28 | // Minor Version 29 | // Build Number 30 | // Revision 31 | // 32 | // You can specify all the values or you can default the Build and Revision Numbers 33 | // by using the '*' as shown below: 34 | // [assembly: AssemblyVersion("1.0.*")] 35 | [assembly: AssemblyVersion("1.0.0.0")] 36 | [assembly: AssemblyFileVersion("1.0.0.0")] 37 | -------------------------------------------------------------------------------- /SSISDB/SSISDB.Export/SSISDB.Export/Properties/Resources.Designer.cs: -------------------------------------------------------------------------------- 1 | //------------------------------------------------------------------------------ 2 | // 3 | // This code was generated by a tool. 4 | // Runtime Version:4.0.30319.42000 5 | // 6 | // Changes to this file may cause incorrect behavior and will be lost if 7 | // the code is regenerated. 8 | // 9 | //------------------------------------------------------------------------------ 10 | 11 | namespace SSISDB.Export.Properties { 12 | using System; 13 | 14 | 15 | /// 16 | /// A strongly-typed resource class, for looking up localized strings, etc. 17 | /// 18 | // This class was auto-generated by the StronglyTypedResourceBuilder 19 | // class via a tool like ResGen or Visual Studio. 20 | // To add or remove a member, edit your .ResX file then rerun ResGen 21 | // with the /str option, or rebuild your VS project. 22 | [global::System.CodeDom.Compiler.GeneratedCodeAttribute("System.Resources.Tools.StronglyTypedResourceBuilder", "15.0.0.0")] 23 | [global::System.Diagnostics.DebuggerNonUserCodeAttribute()] 24 | [global::System.Runtime.CompilerServices.CompilerGeneratedAttribute()] 25 | internal class Resources { 26 | 27 | private static global::System.Resources.ResourceManager resourceMan; 28 | 29 | private static global::System.Globalization.CultureInfo resourceCulture; 30 | 31 | [global::System.Diagnostics.CodeAnalysis.SuppressMessageAttribute("Microsoft.Performance", "CA1811:AvoidUncalledPrivateCode")] 32 | internal Resources() { 33 | } 34 | 35 | /// 36 | /// Returns the cached ResourceManager instance used by this class. 37 | /// 38 | [global::System.ComponentModel.EditorBrowsableAttribute(global::System.ComponentModel.EditorBrowsableState.Advanced)] 39 | internal static global::System.Resources.ResourceManager ResourceManager { 40 | get { 41 | if (object.ReferenceEquals(resourceMan, null)) { 42 | global::System.Resources.ResourceManager temp = new global::System.Resources.ResourceManager("SSISDB.Export.Properties.Resources", typeof(Resources).Assembly); 43 | resourceMan = temp; 44 | } 45 | return resourceMan; 46 | } 47 | } 48 | 49 | /// 50 | /// Overrides the current thread's CurrentUICulture property for all 51 | /// resource lookups using this strongly typed resource class. 52 | /// 53 | [global::System.ComponentModel.EditorBrowsableAttribute(global::System.ComponentModel.EditorBrowsableState.Advanced)] 54 | internal static global::System.Globalization.CultureInfo Culture { 55 | get { 56 | return resourceCulture; 57 | } 58 | set { 59 | resourceCulture = value; 60 | } 61 | } 62 | 63 | /// 64 | /// Looks up a localized string similar to EXEC [internal].[get_project_internal] 65 | /// @project_version_lsn = @project_version_lsn, 66 | /// @project_id = @project_id, 67 | /// @project_name = @project_name. 68 | /// 69 | internal static string ExportProject { 70 | get { 71 | return ResourceManager.GetString("ExportProject", resourceCulture); 72 | } 73 | } 74 | } 75 | } 76 | -------------------------------------------------------------------------------- /SSISDB/SSISDB.Export/SSISDB.Export/Properties/Resources.resx: -------------------------------------------------------------------------------- 1 |  2 | 3 | 62 | 63 | 64 | 65 | 66 | 67 | 68 | 69 | 70 | 71 | 72 | 73 | 74 | 75 | 76 | 77 | 78 | 79 | 80 | 81 | 82 | 83 | 84 | 85 | 86 | 87 | 88 | 89 | 90 | 91 | 92 | 93 | 94 | 95 | 96 | 97 | 98 | 99 | 100 | 101 | 102 | 103 | 104 | 105 | 106 | 107 | 108 | 109 | text/microsoft-resx 110 | 111 | 112 | 2.0 113 | 114 | 115 | System.Resources.ResXResourceReader, System.Windows.Forms, Version=4.0.0.0, Culture=neutral, PublicKeyToken=b77a5c561934e089 116 | 117 | 118 | System.Resources.ResXResourceWriter, System.Windows.Forms, Version=4.0.0.0, Culture=neutral, PublicKeyToken=b77a5c561934e089 119 | 120 | 121 | EXEC [internal].[get_project_internal] 122 | @project_version_lsn = @project_version_lsn, 123 | @project_id = @project_id, 124 | @project_name = @project_name 125 | 126 | -------------------------------------------------------------------------------- /SSISDB/SSISDB.Export/SSISDB.Export/SSISDB.Export.ExportProjectClr.sql: -------------------------------------------------------------------------------- 1 | USE [SSISDB] 2 | GO 3 | IF (OBJECT_ID('[dbo].[usp_ExportProjectClr]') IS NOT NULL) 4 | BEGIN 5 | RAISERROR(N'-Dropping [dbo].[usp_ExportProjectClr]', 0, 0) WITH NOWAIT; 6 | DROP PROCEDURE [dbo].[usp_ExportProjectClr] 7 | END 8 | 9 | PRINT '+Creating [dbo].[usp_ExportProjectClr]' 10 | GO 11 | /* ========================================================================== 12 | [dbo].[usp_ExportProjectClr] 13 | 14 | Exports SSIS Project to an .ispac file 15 | 16 | Parameters: 17 | 18 | @project_name nvarchar(128) --name of the SSIS project 19 | ,@project_id bigint --Id of the SSIS project 20 | ,@project_version bigint --version id of the SSIS project 21 | ,@destination_file nvarchar(4000) --Destination file name 22 | ,@create_path bit --Specifies whether the path portion of the destination file should be automatically created 23 | ========================================================================== */ 24 | CREATE PROCEDURE [dbo].[usp_ExportProjectClr] 25 | @project_name nvarchar(128) --name of the SSIS project 26 | ,@project_id bigint --Id of the SSIS project 27 | ,@project_version bigint --version id of the SSIS project 28 | ,@destination_file nvarchar(4000) --Destination file name 29 | ,@create_path bit --Specifies whether the path portion of the destination file should be automatically created 30 | AS 31 | EXTERNAL NAME [SSISDB.Export].[SSISDBExport].[ExportProject] 32 | GO 33 | GRANT EXECUTE TO [ssis_admin]; 34 | GRANT EXECUTE TO [AllSchemaOwner] -------------------------------------------------------------------------------- /SSISDB/SSISDB.Export/SSISDB.Export/SSISDB.Export.csproj: -------------------------------------------------------------------------------- 1 |  2 | 3 | 4 | 5 | Debug 6 | AnyCPU 7 | {987FD3E8-0C65-46F9-AD9D-26CA2A5D065B} 8 | Library 9 | Properties 10 | SSISDB.Export 11 | SSISDB.Export 12 | v4.0 13 | 512 14 | true 15 | 16 | 17 | true 18 | full 19 | false 20 | bin\Debug\ 21 | DEBUG;TRACE 22 | prompt 23 | 4 24 | 25 | 26 | pdbonly 27 | true 28 | bin\Release\ 29 | TRACE 30 | prompt 31 | 4 32 | 33 | 34 | true 35 | 36 | 37 | SSISDB.Export.snk 38 | 39 | 40 | 41 | 42 | 43 | 44 | 45 | 46 | 47 | 48 | 49 | 50 | True 51 | True 52 | Resources.resx 53 | 54 | 55 | 56 | 57 | 58 | 59 | ResXFileCodeGenerator 60 | Resources.Designer.cs 61 | 62 | 63 | 64 | 65 | 66 | 67 | 68 | 69 | 70 | 71 | 72 | xcopy "$(TargetDir)*$(TargetExt)" C:\SQLCLR /Y /R /I 73 | 74 | -------------------------------------------------------------------------------- /SSISDB/SSISDB.Export/SSISDB.Export/SSISDB.Export.snk: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/PavelPawlowski/SQL-Scripts/362077f8fd4a3722fdd14baffa2f96ae1ac34146/SSISDB/SSISDB.Export/SSISDB.Export/SSISDB.Export.snk -------------------------------------------------------------------------------- /SSISDB/SSISDB.Export/SSISDB.Export/SSISDB.Export.sql: -------------------------------------------------------------------------------- 1 | USE [master] 2 | GO 3 | /* 4 | Create Asymmetric Key from the CLR to enable Unsafe assmebly execution 5 | Further we create login based on that asymmetric key to enable creation of unsafe assembly 6 | */ 7 | IF NOT EXISTS(SELECT 1 FROM sys.asymmetric_keys WHERE name = 'SSISDB.Export.dll') 8 | BEGIN 9 | RAISERROR( N'+ Creating [SSISDB.Export.dll] asymmetric key form SSISDB.Export.dll', 0, 0) WITH NOWAIT; 10 | CREATE ASYMMETRIC KEY [SSISDB.Export.dll] FROM EXECUTABLE FILE = N'C:\SQLCLR\SSISDB.Export.dll'; 11 | END 12 | GO 13 | 14 | /* 15 | Create login from the Assembly asymmetric key. Futher we grant unsafe assembly to that login to enable unsafe assembly creation 16 | */ 17 | IF NOT EXISTS(SELECT 1 FROM sys.server_principals WHERE name = 'SSISDB.Export.dll' AND type = 'K') 18 | BEGIN 19 | RAISERROR( N'+ Creating Login [SSISDB.Export.dll] from asymmetric key [SSISDB.Export.dll]', 0, 0) WITH NOWAIT; 20 | CREATE LOGIN [SSISDB.Export.dll] FROM ASYMMETRIC KEY [SSISDB.Export.dll]; 21 | END 22 | GO 23 | 24 | /* 25 | Grant unsafe aseembly to the [SSISDB.Export.dll] login based on the assembly asymmetric key. 26 | This ensures, that we can create an ussafe asembly in the SSISDB database even without setting 27 | database as trustworthy. 28 | */ 29 | RAISERROR( N'+ Granting UNSAFE ASSEMBLY TO [SSISDB.Export.dll]', 0, 0) WITH NOWAIT; 30 | GO 31 | GRANT UNSAFE ASSEMBLY TO [SSISDB.Export.dll]; 32 | GO 33 | 34 | 35 | 36 | USE [SSISDB] 37 | GO 38 | 39 | IF EXISTS(SELECT 1 FROM sys.assemblies WHERE name = 'SSISDB.Export') 40 | BEGIN 41 | RAISERROR(N'+Updating [SSISDB.Export] Assembly... 42 | 43 | If the assmebly does not differs form existing one in SSISDB, an exception will follow. 44 | 45 | ', 0, 0) WITH NOWAIT; 46 | ALTER ASSEMBLY [SSISDB.Export] 47 | DROP FILE ALL 48 | 49 | ALTER ASSEMBLY [SSISDB.Export] 50 | FROM 'C:\SQLCLR\SSISDB.Export.dll' 51 | 52 | ALTER ASSEMBLY [SSISDB.Export] 53 | ADD FILE FROM 'C:\SQLCLR\SSISDB.Export.dll' 54 | END 55 | ELSE 56 | BEGIN 57 | RAISERROR(N'+Creating [SSISDB.Export] Assembly', 0,0) WITH NOWAIT; 58 | CREATE ASSEMBLY [SSISDB.Export] 59 | AUTHORIZATION [dbo] 60 | FROM 'C:\SQLCLR\SSISDB.Export.dll' 61 | WITH PERMISSION_SET = UNSAFE 62 | END -------------------------------------------------------------------------------- /SSISDB/SSISDB.Export/SSISDB.Export/SSISDBExport.cs: -------------------------------------------------------------------------------- 1 | using SSISDB.Export.Properties; 2 | using System; 3 | using System.Collections.Generic; 4 | using System.Data.SqlClient; 5 | using System.IO; 6 | using System.Linq; 7 | using System.Text; 8 | 9 | public class SSISDBExport 10 | { 11 | /// 12 | /// Context connection string 13 | /// 14 | public const string ContextConnectionString = "context connection=true"; 15 | 16 | /// 17 | /// Exports a version of SSISDB projet to .ispac file 18 | /// 19 | /// Name of the project to export 20 | /// project_id of project to export 21 | /// object_version_lsn of the project to export 22 | /// path to destination .ispac file 23 | /// connection string to the SSISDB 24 | private static void ExportProjectInternal(string project_name, long project_id, long project_version, string destination_file, string connectionString, bool createPath) 25 | { 26 | byte[] buffer = new byte[65536]; 27 | long bytesRead = 0; 28 | long dataIndex = 0; 29 | 30 | using (SqlConnection con = new SqlConnection(connectionString)) 31 | { 32 | //Command to execute the [internal].[get_project_internal] to get the decrypted data stream with project content 33 | SqlCommand cmd = new SqlCommand(Resources.ExportProject, con); 34 | cmd.Parameters.AddWithValue("@project_version_lsn", project_version); 35 | cmd.Parameters.AddWithValue("@project_id", project_id); 36 | cmd.Parameters.AddWithValue("@project_name", project_name); 37 | 38 | con.Open(); 39 | 40 | //get the decrypted project data stream 41 | using (var reader = cmd.ExecuteReader(System.Data.CommandBehavior.SingleRow | System.Data.CommandBehavior.SequentialAccess)) 42 | { 43 | if (reader.Read()) 44 | { 45 | if (createPath) 46 | { 47 | var path = Path.GetDirectoryName(destination_file); 48 | Directory.CreateDirectory(path); 49 | } 50 | 51 | //Create the ouptu .ispac file 52 | using (FileStream fs = File.Open(destination_file, FileMode.Create)) 53 | { 54 | //Read the project data in 64kB chunks and write to the output .ispac file 55 | do 56 | { 57 | bytesRead = reader.GetBytes(0, dataIndex, buffer, 0, buffer.Length); 58 | dataIndex += bytesRead; 59 | 60 | fs.Write(buffer, 0, (int)bytesRead); 61 | 62 | } while (bytesRead == buffer.LongLength); 63 | 64 | fs.Close(); 65 | } 66 | 67 | } 68 | } 69 | 70 | con.Close(); 71 | } 72 | } 73 | 74 | /// 75 | /// Procedure to test exports 76 | /// 77 | /// data source (instance) to connect 78 | /// Name of the project to export 79 | /// project_id of project to export 80 | /// object_version_lsn of the project to export 81 | /// path to destination .ispac file 82 | public static void ExportProjectTest(string dataSource, string project_name, long project_id, long project_version, string destination_file, bool createPath) 83 | { 84 | 85 | SqlConnectionStringBuilder builder = new SqlConnectionStringBuilder(); 86 | builder.InitialCatalog = "SSISDB"; 87 | builder.IntegratedSecurity = true; 88 | builder.DataSource = dataSource; 89 | 90 | ExportProjectInternal(project_name, project_id, project_version, destination_file, builder.ToString(), createPath); 91 | } 92 | 93 | /// 94 | /// SQL Stored procedure to export SSISDB proejct version to .ispac file 95 | /// 96 | /// Name of the project to export 97 | /// project_id of project to export 98 | /// object_version_lsn of the project to export 99 | /// path to destination .ispac file 100 | [Microsoft.SqlServer.Server.SqlProcedure] 101 | public static void ExportProject(string project_name, long project_id, long project_version, string destination_file, bool createPath) 102 | { 103 | 104 | ExportProjectInternal(project_name, project_id, project_version, destination_file, ContextConnectionString, createPath); 105 | 106 | } 107 | } -------------------------------------------------------------------------------- /SSISDB/SSISDB.Export/SSISDB.Export/sp_SSISExportProject.sql: -------------------------------------------------------------------------------- 1 | IF NOT EXISTS(SELECT 1 FROM sys.databases where name = 'SSISDB') 2 | BEGIN 3 | RAISERROR(N'SSIS Database Does not Exists', 15, 0) 4 | SET NOEXEC ON; 5 | END 6 | GO 7 | USE [SSISDB] 8 | GO 9 | IF NOT EXISTS(SELECT * FROM sys.procedures WHERE object_id = OBJECT_ID('[dbo].[sp_SSISExportProject]')) 10 | EXEC (N'CREATE PROCEDURE [dbo].[sp_SSISExportProject] AS PRINT ''Placeholder for [dbo].[sp_SSISExportProject]''') 11 | GO 12 | -------------------------------------------------------------------------------- /SSISDB/SSISDB.Export/TestApp/App.config: -------------------------------------------------------------------------------- 1 |  2 | 3 | 4 | 5 | 6 | -------------------------------------------------------------------------------- /SSISDB/SSISDB.Export/TestApp/Program.cs: -------------------------------------------------------------------------------- 1 | using System; 2 | using System.Collections.Generic; 3 | using System.Linq; 4 | using System.Text; 5 | using System.Threading.Tasks; 6 | 7 | namespace TestApp 8 | { 9 | class Program 10 | { 11 | static void Main(string[] args) 12 | { 13 | 14 | SSISDBExport.ExportProjectTest("L00SRV2122,5001", "TestProject", 145, 2398, @"FC:\temp\test.ispac", true); 15 | } 16 | 17 | 18 | } 19 | } 20 | -------------------------------------------------------------------------------- /SSISDB/SSISDB.Export/TestApp/Properties/AssemblyInfo.cs: -------------------------------------------------------------------------------- 1 | using System.Reflection; 2 | using System.Runtime.CompilerServices; 3 | using System.Runtime.InteropServices; 4 | 5 | // General Information about an assembly is controlled through the following 6 | // set of attributes. Change these attribute values to modify the information 7 | // associated with an assembly. 8 | [assembly: AssemblyTitle("TestApp")] 9 | [assembly: AssemblyDescription("")] 10 | [assembly: AssemblyConfiguration("")] 11 | [assembly: AssemblyCompany("")] 12 | [assembly: AssemblyProduct("TestApp")] 13 | [assembly: AssemblyCopyright("Copyright © 2019")] 14 | [assembly: AssemblyTrademark("")] 15 | [assembly: AssemblyCulture("")] 16 | 17 | // Setting ComVisible to false makes the types in this assembly not visible 18 | // to COM components. If you need to access a type in this assembly from 19 | // COM, set the ComVisible attribute to true on that type. 20 | [assembly: ComVisible(false)] 21 | 22 | // The following GUID is for the ID of the typelib if this project is exposed to COM 23 | [assembly: Guid("2d6990a8-a13f-4e2d-b73a-6ebb17676be1")] 24 | 25 | // Version information for an assembly consists of the following four values: 26 | // 27 | // Major Version 28 | // Minor Version 29 | // Build Number 30 | // Revision 31 | // 32 | // You can specify all the values or you can default the Build and Revision Numbers 33 | // by using the '*' as shown below: 34 | // [assembly: AssemblyVersion("1.0.*")] 35 | [assembly: AssemblyVersion("1.0.0.0")] 36 | [assembly: AssemblyFileVersion("1.0.0.0")] 37 | -------------------------------------------------------------------------------- /SSISDB/SSISDB.Export/TestApp/TestApp.csproj: -------------------------------------------------------------------------------- 1 |  2 | 3 | 4 | 5 | Debug 6 | AnyCPU 7 | {2D6990A8-A13F-4E2D-B73A-6EBB17676BE1} 8 | Exe 9 | TestApp 10 | TestApp 11 | v4.6.1 12 | 512 13 | true 14 | true 15 | 16 | 17 | AnyCPU 18 | true 19 | full 20 | false 21 | bin\Debug\ 22 | DEBUG;TRACE 23 | prompt 24 | 4 25 | 26 | 27 | AnyCPU 28 | pdbonly 29 | true 30 | bin\Release\ 31 | TRACE 32 | prompt 33 | 4 34 | 35 | 36 | 37 | 38 | 39 | 40 | 41 | 42 | 43 | 44 | 45 | 46 | 47 | 48 | 49 | 50 | 51 | 52 | 53 | 54 | {987fd3e8-0c65-46f9-ad9d-26ca2a5d065b} 55 | SSISDB.Export 56 | 57 | 58 | 59 | -------------------------------------------------------------------------------- /SSISDB/SSISDB_Indexes.sql: -------------------------------------------------------------------------------- 1 | USE [SSISDB] 2 | GO 3 | 4 | /* 5 | EXECUTION SPEAD-UP 6 | 7 | This Index speeds up the SSIS Packages execution extremely. 8 | It speedups lookups of every executed executable in the SSIS package . 9 | In case large number of packages or large number of executables inside a package being executed the time reduction is extreme. 10 | */ 11 | IF NOT EXISTS( 12 | SELECT 13 | ic.index_id 14 | ,COUNT(index_id) 15 | FROM ( 16 | SELECT 17 | ic.object_id 18 | ,ic.index_id 19 | ,c.name 20 | ,ic.index_column_id 21 | ,ic.key_ordinal 22 | ,is_included_column 23 | FROM sys.index_columns ic 24 | INNER JOIN sys.columns c ON c.column_id = ic.column_id AND c.object_id = ic.object_id 25 | WHERE 26 | ic.object_id = OBJECT_ID('[internal].[executables]') 27 | AND 28 | ( 29 | (c.name = 'project_id' AND ic.key_ordinal = 1) 30 | OR 31 | (c.name = 'project_version_lsn' AND ic.key_ordinal = 2) 32 | OR 33 | (c.name = 'package_name' AND ic.key_ordinal = 3) 34 | 35 | ) 36 | ) ic 37 | GROUP BY 38 | ic.index_id 39 | HAVING COUNT(index_id) = 3 40 | ) 41 | BEGIN 42 | CREATE NONCLUSTERED INDEX [IX_PP_Executables_project_id_project_version_lsn_package_name] ON [internal].[executables] 43 | ( 44 | [project_id] ASC, 45 | [project_version_lsn] ASC, 46 | [package_name] ASC 47 | ) 48 | END 49 | GO 50 | 51 | 52 | 53 | IF NOT EXISTS( 54 | SELECT 55 | ic.index_id 56 | ,COUNT(index_id) 57 | FROM ( 58 | SELECT 59 | ic.object_id 60 | ,ic.index_id 61 | ,c.name 62 | ,ic.index_column_id 63 | ,ic.key_ordinal 64 | ,is_included_column 65 | FROM sys.index_columns ic 66 | INNER JOIN sys.columns c ON c.column_id = ic.column_id AND c.object_id = ic.object_id 67 | WHERE 68 | ic.object_id = OBJECT_ID('[internal].[executables]') 69 | AND 70 | ( 71 | (c.name = 'package_name' AND ic.key_ordinal = 1) 72 | OR 73 | (c.name = 'project_version_lsn' AND ic.key_ordinal = 2) 74 | OR 75 | (c.name = 'executable_name' AND (ic.key_ordinal > 2 OR ic.is_included_column = 1)) 76 | OR 77 | (c.name = 'package_path' AND (ic.key_ordinal > 2 OR ic.is_included_column = 1)) 78 | 79 | ) 80 | ) ic 81 | GROUP BY 82 | ic.index_id 83 | HAVING COUNT(index_id) = 4 84 | ) 85 | BEGIN 86 | CREATE NONCLUSTERED INDEX [IX_PP_executable_project_package_name_project_version_lsn_Filtered] ON [internal].[executables] 87 | ( 88 | [package_name] ASC, 89 | [project_version_lsn] ASC 90 | ) 91 | INCLUDE([executable_name],[package_path]) 92 | WHERE ([package_path]='\Package') 93 | END 94 | 95 | /* 96 | DEPLOYMENT ISSUES RESOLVING 97 | 98 | When deploying a large project with lots of packages, after some time deployment timeout will start occurring. 99 | This is caused by call to below stored procedure which will start executing longer than 30 seconds and causing large amounts of reads. 100 | 101 | exec [internal].[sync_parameter_versions] @project_id=xxx,@object_version_lsn=xxx 102 | 103 | To resolve the issue, the below indexes needs to be created in the SSISDB. 104 | */ 105 | 106 | IF NOT EXISTS( 107 | SELECT 108 | ic.index_id 109 | ,COUNT(index_id) 110 | FROM ( 111 | SELECT 112 | ic.object_id 113 | ,ic.index_id 114 | ,c.name 115 | ,ic.index_column_id 116 | ,ic.key_ordinal 117 | ,is_included_column 118 | FROM sys.index_columns ic 119 | INNER JOIN sys.columns c ON c.column_id = ic.column_id AND c.object_id = ic.object_id 120 | WHERE 121 | ic.object_id = OBJECT_ID('[internal].[object_parameters]') 122 | AND 123 | ( 124 | (c.name = 'project_id' AND ic.key_ordinal = 1) 125 | OR 126 | (c.name = 'project_version_lsn' AND ic.key_ordinal = 2) 127 | 128 | ) 129 | ) ic 130 | GROUP BY 131 | ic.index_id 132 | HAVING COUNT(index_id) = 2 133 | ) 134 | BEGIN 135 | CREATE NONCLUSTERED INDEX [IX_PP_object_parameters_DeployIssue] 136 | ON [internal].[object_parameters] ( 137 | [project_id], 138 | [project_version_lsn] 139 | ) 140 | INCLUDE ( 141 | [parameter_id],[object_type],[object_name],[parameter_name],[parameter_data_type],[required],[sensitive] 142 | ) 143 | END 144 | GO 145 | 146 | IF NOT EXISTS( 147 | SELECT 148 | ic.index_id 149 | ,COUNT(index_id) 150 | FROM ( 151 | SELECT 152 | ic.object_id 153 | ,ic.index_id 154 | ,c.name 155 | ,ic.index_column_id 156 | ,ic.key_ordinal 157 | ,is_included_column 158 | FROM sys.index_columns ic 159 | INNER JOIN sys.columns c ON c.column_id = ic.column_id AND c.object_id = ic.object_id 160 | WHERE 161 | ic.object_id = OBJECT_ID('[internal].[object_parameters]') 162 | AND 163 | ( 164 | (c.name = 'project_id' AND ic.key_ordinal = 1) 165 | OR 166 | (c.name = 'project_version_lsn' AND ic.key_ordinal = 2) 167 | OR 168 | (c.name = 'object_type' AND ic.key_ordinal = 3) 169 | OR 170 | (c.name = 'object_name' AND ic.key_ordinal = 4) 171 | OR 172 | (c.name = 'parameter_data_type' AND ic.key_ordinal = 5) 173 | OR 174 | (c.name = 'required' AND ic.key_ordinal = 6) 175 | OR 176 | (c.name = 'sensitive' AND ic.key_ordinal = 7) 177 | 178 | ) 179 | ) ic 180 | GROUP BY 181 | ic.index_id 182 | HAVING COUNT(index_id) = 7 183 | ) 184 | BEGIN 185 | CREATE NONCLUSTERED INDEX [IX_PP_object_parameters_DeployIssue2] 186 | ON [internal].[object_parameters] ( 187 | [project_id], 188 | [project_version_lsn], 189 | [object_type], 190 | [object_name], 191 | [parameter_data_type], 192 | [required], 193 | [sensitive] 194 | ) 195 | INCLUDE ([parameter_name],[default_value],[sensitive_default_value],[value_type],[value_set],[referenced_variable_name]) 196 | END 197 | GO 198 | 199 | 200 | 201 | --Additional Supporting indexes 202 | IF NOT EXISTS( 203 | SELECT 204 | ic.object_id 205 | ,ic.index_id 206 | ,c.name 207 | ,ic.index_column_id 208 | ,ic.key_ordinal 209 | ,is_included_column 210 | FROM sys.index_columns ic 211 | INNER JOIN sys.columns c ON c.column_id = ic.column_id AND c.object_id = ic.object_id 212 | WHERE 213 | ic.object_id = OBJECT_ID('[internal].[event_messages]') 214 | AND 215 | c.name = 'operation_id' 216 | AND 217 | ic.key_ordinal = 1 218 | ) 219 | BEGIN 220 | CREATE NONCLUSTERED INDEX [IX_PP_event_messages_operation_id] ON [internal].[event_messages] 221 | ( 222 | [operation_id] ASC 223 | ) 224 | END; 225 | 226 | 227 | 228 | IF NOT EXISTS ( 229 | SELECT 230 | ic.index_id 231 | ,COUNT(index_id) 232 | FROM ( 233 | SELECT 234 | ic.object_id 235 | ,ic.index_id 236 | ,c.name 237 | ,ic.index_column_id 238 | ,ic.key_ordinal 239 | ,is_included_column 240 | FROM sys.index_columns ic 241 | INNER JOIN sys.columns c ON c.column_id = ic.column_id AND c.object_id = ic.object_id 242 | WHERE 243 | ic.object_id = OBJECT_ID('[internal].[executable_statistics]') 244 | AND 245 | ( 246 | (c.name = 'execution_id' AND ic.key_ordinal = 1) 247 | OR 248 | (c.name = 'statistics_id' AND (ic.key_ordinal > 1 OR ic.is_included_column = 1)) 249 | 250 | ) 251 | ) ic 252 | GROUP BY 253 | ic.index_id 254 | HAVING COUNT(index_id) = 2 255 | ) 256 | BEGIN 257 | CREATE NONCLUSTERED INDEX [IX_PP_executable_statistics_execution_id] ON [internal].[executable_statistics] 258 | ( 259 | [execution_id] ASC 260 | ) 261 | INCLUDE([statistics_id]) 262 | END 263 | GO 264 | 265 | 266 | IF NOT EXISTS ( 267 | SELECT 268 | ic.index_id 269 | ,COUNT(index_id) 270 | FROM ( 271 | SELECT 272 | ic.object_id 273 | ,ic.index_id 274 | ,c.name 275 | ,ic.index_column_id 276 | ,ic.key_ordinal 277 | ,is_included_column 278 | FROM sys.index_columns ic 279 | INNER JOIN sys.columns c ON c.column_id = ic.column_id AND c.object_id = ic.object_id 280 | WHERE 281 | ic.object_id = OBJECT_ID('[internal].[execution_component_phases]') 282 | AND 283 | ( 284 | (c.name = 'execution_id' AND ic.key_ordinal = 1) 285 | OR 286 | (c.name = 'sequence_id' AND ic.key_ordinal = 2) 287 | 288 | ) 289 | ) ic 290 | GROUP BY 291 | ic.index_id 292 | HAVING COUNT(index_id) = 2 293 | ) 294 | BEGIN 295 | CREATE NONCLUSTERED INDEX [IX_PP_execution_component_phases_execution_id_sequence_id] ON [internal].[execution_component_phases] 296 | ( 297 | [execution_id] ASC, 298 | [sequence_id] ASC 299 | ) 300 | END 301 | GO 302 | 303 | 304 | IF NOT EXISTS ( 305 | SELECT 306 | ic.index_id 307 | ,COUNT(index_id) 308 | FROM ( 309 | SELECT 310 | ic.object_id 311 | ,ic.index_id 312 | ,c.name 313 | ,ic.index_column_id 314 | ,ic.key_ordinal 315 | ,is_included_column 316 | FROM sys.index_columns ic 317 | INNER JOIN sys.columns c ON c.column_id = ic.column_id AND c.object_id = ic.object_id 318 | WHERE 319 | ic.object_id = OBJECT_ID('[internal].[operation_messages]') 320 | AND 321 | ( 322 | (c.name = 'operation_id' AND ic.key_ordinal = 1) 323 | OR 324 | (c.name = 'operation_message_id' AND (ic.key_ordinal > 1 OR ic.is_included_column = 1)) 325 | 326 | ) 327 | ) ic 328 | GROUP BY 329 | ic.index_id 330 | HAVING COUNT(index_id) = 2 331 | ) 332 | BEGIN 333 | CREATE NONCLUSTERED INDEX [IX_PP_operation_messages_operation_id] ON [internal].[operation_messages] 334 | ( 335 | [operation_id] ASC 336 | ) 337 | INCLUDE([operation_message_id]) 338 | END 339 | GO 340 | 341 | IF NOT EXISTS ( 342 | SELECT 343 | ic.index_id 344 | ,COUNT(index_id) 345 | FROM ( 346 | SELECT 347 | ic.object_id 348 | ,ic.index_id 349 | ,c.name 350 | ,ic.index_column_id 351 | ,ic.key_ordinal 352 | ,is_included_column 353 | FROM sys.index_columns ic 354 | INNER JOIN sys.columns c ON c.column_id = ic.column_id AND c.object_id = ic.object_id 355 | WHERE 356 | ic.object_id = OBJECT_ID('[internal].[event_message_context]') 357 | AND 358 | ( 359 | (c.name = 'operation_id' AND ic.key_ordinal = 1) 360 | OR 361 | (c.name = 'event_message_id' AND ic.key_ordinal = 2) 362 | OR 363 | (c.name = 'context_id' AND (ic.key_ordinal > 2 OR ic.is_included_column = 1)) 364 | 365 | ) 366 | ) ic 367 | GROUP BY 368 | ic.index_id 369 | HAVING COUNT(index_id) = 3 370 | ) 371 | BEGIN 372 | CREATE NONCLUSTERED INDEX [IX_PP_event_message_context_operation_id_event_message_id] ON [internal].[event_message_context] 373 | ( 374 | [operation_id] ASC, 375 | [event_message_id] ASC 376 | ) 377 | INCLUDE([context_id]) 378 | END 379 | 380 | 381 | 382 | IF NOT EXISTS ( 383 | SELECT 384 | ic.index_id 385 | ,COUNT(index_id) 386 | FROM ( 387 | SELECT 388 | ic.object_id 389 | ,ic.index_id 390 | ,c.name 391 | ,ic.index_column_id 392 | ,ic.key_ordinal 393 | ,is_included_column 394 | FROM sys.index_columns ic 395 | INNER JOIN sys.columns c ON c.column_id = ic.column_id AND c.object_id = ic.object_id 396 | WHERE 397 | ic.object_id = OBJECT_ID('[internal].[event_message_context]') 398 | AND 399 | ( 400 | (c.name = 'event_message_id' AND ic.key_ordinal = 1) 401 | ) 402 | ) ic 403 | GROUP BY 404 | ic.index_id 405 | HAVING COUNT(index_id) = 1 406 | ) 407 | BEGIN 408 | CREATE NONCLUSTERED INDEX [IX_PP_event_message_context_event_message_id] ON [internal].[event_message_context] 409 | ( 410 | [event_message_id] ASC 411 | ) 412 | END 413 | -------------------------------------------------------------------------------- /SSISDB/sp_SSISListEnvironment.sql: -------------------------------------------------------------------------------- 1 | IF NOT EXISTS(SELECT 1 FROM sys.databases where name = 'SSISDB') 2 | BEGIN 3 | RAISERROR(N'SSIS Database Does not Exists', 15, 0) 4 | SET NOEXEC ON; 5 | END 6 | GO 7 | USE [SSISDB] 8 | GO 9 | RAISERROR('Creating procedure [dbo].[sp_SSISListEnvironment]', 0, 0) WITH NOWAIT; 10 | IF NOT EXISTS(SELECT * FROM sys.procedures WHERE object_id = OBJECT_ID('[dbo].[sp_SSISListEnvironment]')) 11 | EXEC (N'CREATE PROCEDURE [dbo].[sp_SSISListEnvironment] AS PRINT ''Placeholder for [dbo].[sp_SSISListEnvironment]''') 12 | GO 13 | /* **************************************************** 14 | sp_SSISListEnvironment v 0.40 (2017-10-31) 15 | 16 | Feedback: mailto:pavel.pawlowski@hotmail.cz 17 | 18 | MIT License 19 | 20 | Copyright (c) 2017 Pavel Pawlowski 21 | 22 | Permission is hereby granted, free of charge, to any person obtaining a copy 23 | of this software and associated documentation files (the "Software"), to deal 24 | in the Software without restriction, including without limitation the rights 25 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 26 | copies of the Software, and to permit persons to whom the Software is 27 | furnished to do so, subject to the following conditions: 28 | 29 | The above copyright notice and this permission notice shall be included in all 30 | copies or substantial portions of the Software. 31 | 32 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 33 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 34 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 35 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 36 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 37 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 38 | SOFTWARE. 39 | 40 | Description: 41 | List Environment variables and their values for environments specified by parameters. 42 | Allows decryption of encrypted variable values 43 | 44 | Parameters: 45 | @folder nvarchar(max) = NULL --comma separated list of environment folder. Supports wildcards. 46 | ,@environment nvarchar(max) = '%' --comma separated lists of environments. Supports wildcards. 47 | ,@variables nvarchar(max) = NULL --Comma separated lists of environment variables to list. Supports wildcards. 48 | ,@value nvarchar(max) = NULL --Comma separated list of environment variable values. Supports wildcards. 49 | ,@exactValue nvarchar(max) = NULL --Exact value of variables to be matched. Have priority above value. 50 | ,@decryptSensitive bit = 0 --Specifies whether sensitive data should be decrypted. 51 | ******************************************************* */ 52 | ALTER PROCEDURE [dbo].[sp_SSISListEnvironment] 53 | @folder nvarchar(max) = NULL --comma separated list of environment folder. Supports wildcards. 54 | ,@environment nvarchar(max) = '%' --comma separated lists of environments. Supports wildcards. 55 | ,@variables nvarchar(max) = NULL --Comma separated lists of environment variables to list. Supports wildcards. 56 | ,@value nvarchar(max) = NULL --Comma separated list of environment variable values. Supports wildcards. 57 | ,@exactValue nvarchar(max) = NULL --Exact value of variables to be matched. Have priority above value. 58 | ,@decryptSensitive bit = 0 --Specifies whether sensitive data should be decrypted. 59 | WITH EXECUTE AS 'AllSchemaOwner' 60 | AS 61 | BEGIN 62 | SET NOCOUNT ON; 63 | SET XACT_ABORT ON; 64 | 65 | DECLARE 66 | @src_folder_id bigint --ID of the source folder 67 | ,@src_Environment_id bigint --ID of the source Environment 68 | ,@msg nvarchar(max) --General purpose message variable (used for printing output) 69 | ,@printHelp bit = 0 --Identifies whether Help should be printed (in case of no parameters provided or error) 70 | ,@name sysname --Name of the variable 71 | ,@description nvarchar(1024) --Description of the variable 72 | ,@type nvarchar(128) --DataType of the variable 73 | ,@sensitive bit --Identifies sensitive variable 74 | ,@valueInternal sql_variant --Non sensitive value of the variable 75 | ,@sensitive_value varbinary(max) --Sensitive value of the variable 76 | ,@base_data_type nvarchar(128) --Base data type of the variable 77 | ,@sql nvarchar(max) --Variable for storing dynamic SQL statements 78 | ,@src_keyName nvarchar(256) --Name of the symmetric key for decryption of the source sensitive values from the source environment 79 | ,@src_certificateName nvarchar(256) --Name of the certificate for decryption of the source symmetric key 80 | ,@decrypted_value varbinary(max) --Variable to store decrypted sensitive value 81 | ,@stringval nvarchar(max) --String representation of the value 82 | ,@xml xml --Xml variable for parsing input parameters 83 | ,@src_environment_name nvarchar(128) 84 | ,@src_folder_name nvarchar(128) 85 | ,@variable_id bigint 86 | ,@sensitiveAccess bit = 0 --Indicates whether caller have access to senstive infomration 87 | 88 | EXECUTE AS CALLER; 89 | IF IS_MEMBER('ssis_sensitive_access') = 1 OR IS_MEMBER('db_owner') = 1 OR IS_SRVROLEMEMBER('sysadmin') = 1 90 | SET @sensitiveAccess = 1 91 | REVERT; 92 | 93 | --Table variable for holding parsed folder names list 94 | DECLARE @folders TABLE ( 95 | folder_id bigint 96 | ,folder_name nvarchar(128) 97 | ) 98 | 99 | --Table variable for holding parsed variable names list 100 | DECLARE @variableNames TABLE ( 101 | name nvarchar(128) 102 | ) 103 | 104 | --Table variable for holding parsed variable values list 105 | DECLARE @values TABLE ( 106 | Value nvarchar(4000) 107 | ) 108 | 109 | --Table variable fo holding intermediate environment list 110 | DECLARE @environments TABLE ( 111 | FolderID bigint 112 | ,EnvironmentID bigint 113 | ,FolderName nvarchar(128) 114 | ,EnvironmentName nvarchar(128) 115 | ) 116 | 117 | --If the needed input parameters are null, print help 118 | IF @folder IS NULL OR @environment IS NULL 119 | SET @printHelp = 1 120 | 121 | RAISERROR(N'sp_SSISListEnvironment v0.40 (2017-10-31) (C) 2017 Pavel Pawlowski', 0, 0) WITH NOWAIT; 122 | RAISERROR(N'==================================================================' , 0, 0) WITH NOWAIT; 123 | 124 | --Check @value and @exactValue 125 | IF @value IS NOT NULL AND @exactValue IS NOT NULL 126 | BEGIN 127 | RAISERROR(N'Only @value or @exactValue can be specified at a time', 11, 0) WITH NOWAIT; 128 | SET @printHelp = 1 129 | END 130 | 131 | --PRINT HELP 132 | IF @printHelp = 1 133 | BEGIN 134 | RAISERROR(N'', 0, 0) WITH NOWAIT; 135 | RAISERROR(N'Lists SSIS environment variables and allows seeing encrypted information', 0, 0) WITH NOWAIT; 136 | RAISERROR(N'', 0, 0) WITH NOWAIT; 137 | RAISERROR(N'Usage:', 0, 0) WITH NOWAIT; 138 | RAISERROR(N'[sp_SSISListEnvironment] parameters', 0, 0) WITH NOWAIT; 139 | RAISERROR(N'', 0, 0) WITH NOWAIT; 140 | RAISERROR(N'Parameters: 141 | @folder nvarchar(max) = NULL - Comma separated list of environment folders. Supports wildcards. 142 | Only variables from environment belonging to matched folder are listed 143 | ,@environment nvarchar(max) = ''%%'' - Comma separated lists of environments. Support wildcards. 144 | Only variables from environments matching provided list are returned. 145 | ,@variables nvarchar(max) = NULL - Comma separated lists of environment variables to list. Supports wildcards. 146 | Only variables matching provided pattern are returned 147 | ,@value nvarchar(max) = NULL - Comma separated list of environment variable values. Supports wildcards. 148 | Only variables which value in string representation matches provided pattern are listed. 149 | Ideal when need to find all environments and variables using particular value. 150 | Eg. Updating to new password. 151 | ,@exactValue nvarchar(max) = NULL - Exact value of variables to be matched. Only one of @exactValue and @value can be specified at a time 152 | ,@decryptSensitive bit = 0 - Specifies whether sensitive data should be decrypted. 153 | Caller must be member of [db_owner] or [ssis_sensitive_access] database role or member of [sysadmin] server role 154 | to be able to decrypt sensitive information 155 | ', 0, 0) WITH NOWAIT; 156 | RAISERROR(N' 157 | Wildcards: 158 | Wildcards are standard wildcards for the LIKE statement 159 | Entries prefixed with [-] (minus) symbol are excluded form results and have priority over the non excluding 160 | 161 | Samples: 162 | sp_SSISListEnvironment @folder = N''TEST%%,DEV%%,-%%Backup'' = List all environment variables from folders starting with ''TEST'' or ''DEV'' but exclude all folder names ending with ''Backup'' 163 | 164 | List varibles from all folders and environments starting with OLEDB_ and ending with _Password and containing value "AAA" or "BBB" 165 | sp_SSISListEnvironment 166 | @folder = ''%%'' 167 | ,@environment = ''%%'' 168 | ,@variables = ''OLEDB_%%_Password'' 169 | ,@value = ''AAA,BBB'' 170 | ', 0, 0) WITH NOWAIT; 171 | 172 | RAISERROR(N' 173 | Table for output resultset: 174 | --------------------------- 175 | CREATE TABLE #outputTable ( 176 | [FolderID] bigint 177 | ,[EnvironmentID] bigint 178 | ,[VariableID] bigint 179 | ,[FolderName] nvarchar(128) 180 | ,[EnvironmentName] nvarchar(128) 181 | ,[VariableName] nvarchar(128) 182 | ,[Value] sql_variant 183 | ,[VariableDescription] nvarchar(1024) 184 | ,[VariableType] nvarchar(128) 185 | ,[BaseDataType] nvarchar(128) 186 | ,[IsSensitive] bit 187 | ) 188 | ', 0, 0) WITH NOWAIT; 189 | 190 | RAISERROR(N'',0, 0) WITH NOWAIT; 191 | 192 | RETURN; 193 | END 194 | 195 | 196 | --Get list of folders 197 | SET @xml = N'' + REPLACE(@folder, ',', '') + N''; 198 | 199 | WITH FolderNames AS ( 200 | SELECT DISTINCT 201 | LTRIM(RTRIM(F.value('.', 'nvarchar(128)'))) AS FolderName 202 | FROM @xml.nodes(N'/i') T(F) 203 | ) 204 | INSERT INTO @folders (folder_id, folder_name) 205 | SELECT DISTINCT 206 | folder_id 207 | ,name 208 | FROM internal.folders F 209 | INNER JOIN FolderNames FN ON F.name LIKE FN.FolderName AND LEFT(FN.FolderName, 1) <> '-' 210 | EXCEPT 211 | SELECT 212 | folder_id 213 | ,name 214 | FROM internal.folders F 215 | INNER JOIN FolderNames FN ON F.name LIKE RIGHT(FN.FolderName, LEN(FN.FolderName) - 1) AND LEFT(FN.FolderName, 1) = '-' 216 | 217 | IF NOT EXISTS(SELECT 1 FROM @folders) 218 | BEGIN 219 | RAISERROR(N'No Folder matching [%s] exists.', 15, 1, @folder) WITH NOWAIT; 220 | RETURN; 221 | END 222 | 223 | --Get list of environments 224 | SET @xml = N'' + REPLACE(@environment, ',', '') + N''; 225 | 226 | WITH EnvironmentNames AS ( 227 | SELECT DISTINCT 228 | LTRIM(RTRIM(F.value('.', 'nvarchar(128)'))) AS EnvName 229 | FROM @xml.nodes(N'/i') T(F) 230 | ) 231 | INSERT INTO @environments ( 232 | FolderID 233 | ,EnvironmentID 234 | ,FolderName 235 | ,EnvironmentName 236 | ) 237 | SELECT DISTINCT 238 | E.folder_id 239 | ,E.environment_id 240 | ,F.folder_name 241 | ,E.environment_name 242 | FROM internal.environments E 243 | INNER JOIN @folders F ON E.folder_id = F.folder_id 244 | INNER JOIN EnvironmentNames EN ON E.environment_name LIKE EN.EnvName AND LEFT(EN.EnvName, 1) <> '-' 245 | EXCEPT 246 | SELECT 247 | E.folder_id 248 | ,E.environment_id 249 | ,F.folder_name 250 | ,E.environment_name 251 | FROM internal.environments E 252 | INNER JOIN @folders F ON E.folder_id = F.folder_id 253 | INNER JOIN EnvironmentNames EN ON E.environment_name LIKE RIGHT(EN.EnvName, LEN(EN.EnvName) -1) AND LEFT(EN.EnvName, 1) = '-' 254 | 255 | IF NOT EXISTS(SELECT 1 FROM @environments) 256 | BEGIN 257 | RAISERROR(N'No Environments matching [%s] exists in folders matching [%s]', 15, 2, @environment, @folder) WITH NOWAIT; 258 | RETURN; 259 | END 260 | 261 | --Get variable values list 262 | SET @xml = N'' + REPLACE(@value, ',', '') + N''; 263 | 264 | INSERT INTO @values (Value) 265 | SELECT DISTINCT 266 | LTRIM(RTRIM(V.value(N'.', N'nvarchar(4000)'))) AS Value 267 | FROM @xml.nodes(N'/i') T(V) 268 | 269 | --Get variable names list 270 | SET @xml = N'' + REPLACE(ISNULL(@variables, N'%'), ',', '') + N''; 271 | INSERT INTO @variableNames ( 272 | Name 273 | ) 274 | SELECT DISTINCT 275 | LTRIM(RTRIM(V.value(N'.', N'nvarchar(128)'))) AS VariableName 276 | FROM @xml.nodes(N'/i') T(V); 277 | 278 | --Output the result 279 | WITH Variables AS ( 280 | SELECT DISTINCT 281 | ev.variable_id 282 | FROM [internal].[environment_variables] ev 283 | INNER JOIN @environments e ON e.EnvironmentID = ev.environment_id 284 | INNER JOIN @variableNames vn ON ev.name LIKE vn.name AND LEFT(vn.name, 1) <> '-' 285 | 286 | EXCEPT 287 | 288 | SELECT DISTINCT 289 | ev.variable_id 290 | FROM [internal].[environment_variables] ev 291 | INNER JOIN @environments e ON e.EnvironmentID = ev.environment_id 292 | INNER JOIN @variableNames vn ON ev.name LIKE RIGHT(vn.name, LEN(vn.name) -1) AND LEFT(vn.name, 1) = '-' 293 | ), VariableValues AS ( 294 | SELECT 295 | e.FolderID 296 | ,e.EnvironmentID 297 | ,ev.variable_id AS VariableID 298 | ,e.FolderName 299 | ,e.EnvironmentName 300 | ,ev.[name] AS VariableName 301 | ,ev.[value] AS v 302 | ,ev.[sensitive_value] 303 | ,CASE 304 | WHEN ev.[sensitive] = 0 THEN [value] 305 | WHEN ev.[sensitive] = 1 AND @decryptSensitive = 1 AND @sensitiveAccess = 1 THEN [internal].[get_value_by_data_type](DECRYPTBYKEYAUTOCERT(CERT_ID(N'MS_Cert_Env_' + CONVERT(nvarchar(20), ev.environment_id)), NULL, ev.[sensitive_value]), ev.[type]) 306 | ELSE NULL 307 | END AS Value 308 | ,ev.[description] AS VariableDescription 309 | ,ev.[type] AS VariableType 310 | ,ev.[base_data_type] AS BaseDataType 311 | ,ev.[sensitive] AS IsSensitive 312 | FROM [internal].[environment_variables] ev 313 | INNER JOIN Variables v ON v.variable_id = ev.variable_id 314 | INNER JOIN @environments e ON e.EnvironmentID = ev.environment_id 315 | ), VariableValuesString AS ( 316 | SELECT 317 | FolderID 318 | ,EnvironmentID 319 | ,VariableID 320 | ,FolderName 321 | ,EnvironmentName 322 | ,VariableName 323 | ,Value 324 | ,CASE 325 | WHEN LOWER(vv.VariableType) = 'datetime' THEN CONVERT(nvarchar(50), Value, 126) 326 | ELSE CONVERT(nvarchar(4000), Value) 327 | END AS StringValue 328 | ,VariableDescription 329 | ,VariableType 330 | ,BaseDataType 331 | ,IsSensitive 332 | FROM VariableValues vv 333 | ) 334 | SELECT 335 | FolderID 336 | ,EnvironmentID 337 | ,VariableID 338 | ,FolderName 339 | ,EnvironmentName 340 | ,VariableName 341 | ,Value 342 | ,VariableDescription 343 | ,VariableType 344 | ,BaseDataType 345 | ,IsSensitive 346 | FROM VariableValuesString 347 | WHERE 348 | ((@value IS NULL OR @value = N'%') AND @exactValue IS NULL) OR (@exactValue IS NOT NULL AND StringValue = @exactValue) 349 | OR 350 | EXISTS ( 351 | SELECT 352 | StringValue 353 | FROM @values v 354 | WHERE 355 | @exactValue IS NULL 356 | AND 357 | LEFT(v.Value, 1) <> '-' 358 | AND 359 | StringValue LIKE v.Value 360 | EXCEPT 361 | SELECT 362 | StringValue 363 | FROM @values v 364 | WHERE 365 | @exactValue IS NULL 366 | AND 367 | LEFT(v.Value, 1) = '-' 368 | AND 369 | StringValue LIKE RIGHT(v.Value, LEN(v.Value) - 1) 370 | ) 371 | ORDER BY FolderName, EnvironmentName, VariableName 372 | END 373 | 374 | GO 375 | IF NOT EXISTS(SELECT 1 FROM sys.database_principals WHERE TYPE = 'R' AND name = 'ssis_sensitive_access') 376 | BEGIN 377 | RAISERROR(N'Creating database role [ssis_sensitive_access]...', 0, 0) WITH NOWAIT; 378 | CREATE ROLE [ssis_sensitive_access] 379 | END 380 | ELSE 381 | BEGIN 382 | RAISERROR(N'Database role [ssis_sensitive_access] exists.', 0, 0) WITH NOWAIT; 383 | END 384 | GO 385 | RAISERROR('[ssis_sensitive_access] database role allows using @decryptSensitive paramter to decrypt sensitive information', 0, 0) WITH NOWAIT; 386 | GO 387 | -- 388 | RAISERROR(N'Adding [ssis_admin] to [ssis_sensitive_access]', 0, 0) WITH NOWAIT; 389 | ALTER ROLE [ssis_sensitive_access] ADD MEMBER [ssis_admin] 390 | GO 391 | 392 | --GRANT EXECUTE permission on the stored procedure to [ssis_admin] role 393 | RAISERROR(N'Granting EXECUTE permission to [ssis_admin]', 0, 0) WITH NOWAIT; 394 | GRANT EXECUTE ON [dbo].[sp_SSISListEnvironment] TO [ssis_admin] 395 | GO 396 | -------------------------------------------------------------------------------- /SSISDB/sp_SSISMapEnvironment.sql: -------------------------------------------------------------------------------- 1 | IF NOT EXISTS(SELECT 1 FROM sys.databases where name = 'SSISDB') 2 | BEGIN 3 | RAISERROR(N'SSIS Database Does not Exists', 15, 0) 4 | SET NOEXEC ON; 5 | END 6 | GO 7 | USE [SSISDB] 8 | GO 9 | IF NOT EXISTS(SELECT * FROM sys.procedures WHERE object_id = OBJECT_ID('[dbo].[sp_SSISMapEnvironment]')) 10 | EXEC (N'CREATE PROCEDURE [dbo].[sp_SSISMapEnvironment] AS PRINT ''Placeholder for [dbo].[sp_SSISMapEnvironment]''') 11 | GO 12 | /* **************************************************** 13 | sp_SSISMapEnvironment v 0.11 (2017-10-30) 14 | 15 | Feedback: mailto:pavel.pawlowski@hotmail.cz 16 | 17 | MIT License 18 | 19 | Copyright (c) 2017 Pavel Pawlowski 20 | 21 | Permission is hereby granted, free of charge, to any person obtaining a copy 22 | of this software and associated documentation files (the "Software"), to deal 23 | in the Software without restriction, including without limitation the rights 24 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 25 | copies of the Software, and to permit persons to whom the Software is 26 | furnished to do so, subject to the following conditions: 27 | 28 | The above copyright notice and this permission notice shall be included in all 29 | copies or substantial portions of the Software. 30 | 31 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 32 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 33 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 34 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 35 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 36 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 37 | SOFTWARE. 38 | 39 | Description: 40 | Stored procedure maps Project/Object configuration parameters to corresponding Environment variables 41 | Mapping is done on parameter and variable name as well as data type. 42 | 43 | Parameters: 44 | @folder nvarchar(128) = NULL --Name of the Folder of the project to reset configurations 45 | ,@project nvarchar(128) = NULL --Name of the Project to reset configuration 46 | ,@environment nvarchar(128) = NULL --Name of the environment to be mapped 47 | ,@object nvarchar(260) = NULL --Comma separated list of objects which parameters should be mapped. Supports LIKE wildcards. NULL Means all objects 48 | ,@parameter nvarchar(max) = NULL --Comma separated list of parameters to be mapped. Supports LIKE wildcards. NULL Means all parameters. 49 | ,@environmentFolder nvarchar(128) = NULL --Name of the environment folder to be mapped. When null, then the project folder is being used 50 | ,@setupReference bit = 1 --Specifies whether reference to the Environment should be setup on the Project 51 | ,@PrintOnly bit = 1 --Indicates whether the script will be printed only or executed 52 | ******************************************************* */ 53 | ALTER PROCEDURE [dbo].[sp_SSISMapEnvironment] 54 | @folder nvarchar(128) = NULL --Name of the Folder of the project to reset configurations 55 | ,@project nvarchar(128) = NULL --Name of the Project to reset configuration 56 | ,@environment nvarchar(128) = NULL --Name of the environment to be mapped 57 | ,@object nvarchar(260) = NULL --Comma separated list of objects which parameters should be cleared. Supports LIKE wildcards 58 | ,@parameter nvarchar(max) = NULL --Comma separated list of parameters to be cleared. Supports LIKE wildcards 59 | ,@environmentFolder nvarchar(128) = NULL --Name of the environment folder to be mapped. When null, then the project folder is being used 60 | ,@setupReference bit = 1 --Specifies whether reference to the Environment should be setup on the Project 61 | ,@PrintOnly bit = 1 --Indicates whether the script will be printed only or executed 62 | WITH EXECUTE AS 'AllSchemaOwner' 63 | AS 64 | BEGIN 65 | SET NOCOUNT ON; 66 | SET XACT_ABORT ON; 67 | 68 | DECLARE 69 | @src_folder_id bigint --ID of the source folder 70 | ,@src_project_id bigint --ID of the source project 71 | ,@src_project_lsn bigint --current source project lsn 72 | ,@env_folder_id bigint --ID of the environment folder 73 | ,@env_id bigint --ID of the environment 74 | ,@env_folder_name nvarchar(128) --name of the environment folder 75 | ,@maxLen int --max len of names for printing purposes 76 | ,@printHelp bit = 0 --Identifies whether Help should be printed (in case of no parameters provided or error) 77 | ,@msg nvarchar(max) --Variable to hold messages 78 | ,@sql nvarchar(max) --Variable to hold dynamic SQL statements 79 | ,@object_name nvarchar(260) --name of the object being reset 80 | ,@object_type smallint --Object type for the purpose of scripting 81 | ,@parameter_name nvarchar(128) --name of the parameter being reset 82 | ,@xmlObj xml --variable for holding xml for parsing input parameters 83 | ,@xmlPar xml --variable for holding xml for parsing input parameters 84 | ,@headerPrefix nvarchar(20) = N'RAISERROR(N''' 85 | ,@headerSuffix nvarchar(20) = N''', 0, 0) WITH NOWAIT' 86 | 87 | --Table for holding list of parameters to be dropped 88 | CREATE TABLE #parametersToMap ( 89 | parameter_id bigint NOT NULL PRIMARY KEY CLUSTERED 90 | ,object_name nvarchar(128) 91 | ,object_type smallint 92 | ,parameter_name nvarchar(128) 93 | ,parameter_data_type nvarchar(128) 94 | ,sensitive bit 95 | ,variable_name nvarchar(128) 96 | ) 97 | 98 | SET @env_folder_name = ISNULL(@environmentFolder, @folder); 99 | 100 | --If the required input parameters are null, print help 101 | IF @folder IS NULL OR @project IS NULL OR @environment IS NULL 102 | BEGIN 103 | SELECT 104 | @printHelp = 1 105 | ,@headerPrefix = N'' 106 | ,@headerSuffix = N'' 107 | END 108 | 109 | 110 | RAISERROR(N'%ssp_SSISMapEnvironment v0.11 (2017-10-30) (C) 2016 Pavel Pawlowski%s', 0, 0, @headerPrefix, @headerSuffix) WITH NOWAIT; 111 | RAISERROR(N'%s=================================================================%s', 0, 0, @headerPrefix, @headerSuffix) WITH NOWAIT; 112 | 113 | --PRINT HELP 114 | IF @printHelp = 1 115 | BEGIN 116 | RAISERROR(N'Maps Project/Object configuration parameters to corresponding Environment variables', 0, 0) WITH NOWAIT; 117 | RAISERROR(N'Mapping is done on parameter and variable name as well as data type.', 0, 0) WITH NOWAIT; 118 | RAISERROR(N'', 0, 0) WITH NOWAIT; 119 | RAISERROR(N'Usage:', 0, 0) WITH NOWAIT; 120 | RAISERROR(N'[sp_SSISMapEnvironment] parameters', 0, 0) WITH NOWAIT; 121 | RAISERROR(N'', 0, 0) WITH NOWAIT; 122 | SET @msg = N'Parameters: 123 | @folder nvarchar(128) = - Name of the Folder of the project to reset configurations. 124 | Folder is required and must exist. 125 | ,@project nvarchar(128) = - Name of the Project to reset configuration. 126 | Project is required and must exists. 127 | ,@environment nvarchar(128) = NULL - Name of the environment to be mapped 128 | ,@object nvarchar(260) = NULL - Comma separated list of object names within project to include in matching. Supports LIKE wildcards 129 | Object is optional and if provided then only matching for that particular objects will be done. 130 | ,@parameter nvarchar(128) = NULL - Comma separated list of parameter names within project to include in matching. Supports LIKE wildcards 131 | Parameter is optional and if provided then only matching for that parameters will be done 132 | When @parameter is provided and @object not, then all parameters with that particular name 133 | are are include in matching. 134 | ,@environmentFolder nvarchar(128) = NULL - Name of the environment folder to be mapped. When null, then the project folder is being used 135 | Also when NULL then eventual Reference is created as reference to local environment. 136 | If Provided then the reference to a 137 | ,@setupReference bit = 1 - Specifies whether reference to the Environment should be setup on the Project 138 | ,@PrintOnly bit = 1 - Indicates whether the script will be printed only or printed and executed 139 | ' 140 | 141 | RAISERROR(@msg, 0, 0) WITH NOWAIT; 142 | 143 | RAISERROR(N'',0, 0) WITH NOWAIT; 144 | 145 | RETURN; 146 | END 147 | 148 | --get source folder_id 149 | SELECT 150 | @src_folder_id = folder_id 151 | FROM internal.folders f 152 | WHERE f.name = @folder; 153 | 154 | --check source folder 155 | IF @src_folder_id IS NULL 156 | BEGIN 157 | RAISERROR(N'Source folder [%s] does not exists.', 15, 1, @folder) WITH NOWAIT; 158 | RETURN; 159 | END 160 | 161 | --get source project_id 162 | SELECT 163 | @src_project_id = p.project_id 164 | ,@src_project_lsn = p.object_version_lsn 165 | FROM [catalog].projects p 166 | WHERE 167 | p.folder_id = @src_folder_id 168 | AND 169 | p.name = @project; 170 | 171 | 172 | --chek source project 173 | IF @src_project_id IS NULL 174 | BEGIN 175 | RAISERROR(N'Project [%s]\[%s] does not exists.', 15, 2, @folder, @project) WITH NOWAIT; 176 | RETURN; 177 | END 178 | 179 | --get environment folder 180 | SELECT 181 | @env_folder_id = folder_id 182 | FROM internal.folders f 183 | WHERE f.name = @env_folder_name; 184 | 185 | --check source folder 186 | IF @env_folder_id IS NULL 187 | BEGIN 188 | RAISERROR(N'Environment folder [%s] does not exists.', 15, 1, @env_folder_name) WITH NOWAIT; 189 | RETURN; 190 | END 191 | 192 | --get environment id 193 | SELECT 194 | @env_id = environment_id 195 | FROM internal.environments e 196 | WHERE 197 | e.folder_id = @env_folder_id 198 | AND 199 | e.environment_name = @environment 200 | 201 | 202 | IF @env_id IS NULL 203 | BEGIN 204 | RAISERROR(N'Environment [%s]\[%s] does not exists.', 15, 1, @env_folder_name, @environment) WITH NOWAIT; 205 | RETURN; 206 | END 207 | 208 | 209 | SET @xmlObj = N'' + REPLACE(ISNULL(@object, N'%'), N',', N'') + N''; 210 | SET @xmlPar = N'' + REPLACE(ISNULL(@parameter, N'%'), N',', N'') + N''; 211 | 212 | WITH ObjNames AS ( 213 | SELECT DISTINCT 214 | LTRIM(RTRIM(n.value(N'.', N'nvarchar(128)'))) AS ObjectName 215 | FROM @xmlObj.nodes(N'i') T(N) 216 | ), 217 | ParamNames AS ( 218 | SELECT DISTINCT 219 | LTRIM(RTRIM(n.value(N'.', N'nvarchar(128)'))) AS ParamName 220 | FROM @xmlPar.nodes(N'i') T(N) 221 | ) 222 | INSERT INTO #parametersToMap ( 223 | parameter_id 224 | ,object_name 225 | ,object_type 226 | ,parameter_name 227 | ,parameter_data_type 228 | ,sensitive 229 | ) 230 | SELECT DISTINCT 231 | parameter_id 232 | ,object_name 233 | ,object_type 234 | ,parameter_name 235 | ,parameter_data_type 236 | ,sensitive 237 | FROM [internal].[object_parameters] op 238 | INNER JOIN ObjNames o ON op.object_name LIKE o.ObjectName 239 | INNER JOIN ParamNames p ON op.parameter_name LIKE p.ParamName 240 | WHERE 241 | op.project_id = @src_project_id 242 | AND 243 | op.project_version_lsn = @src_project_lsn 244 | 245 | 246 | IF NOT EXISTS(SELECT 1 FROM #parametersToMap) 247 | BEGIN 248 | RAISERROR(N'--No parameters for mapping matching input criteria...', 0, 0) WITH NOWAIT; 249 | RETURN; 250 | END 251 | 252 | UPDATE pm SET 253 | variable_name = ev.name 254 | FROM #parametersToMap pm 255 | INNER JOIN internal.environment_variables ev ON 256 | pm.parameter_name COLLATE database_default = ev.name COLLATE database_default 257 | AND 258 | pm.parameter_data_type COLLATE database_default = ev.type COLLATE database_default 259 | AND 260 | pm.sensitive = ev.sensitive 261 | WHERE 262 | ev.environment_id = @env_id 263 | 264 | 265 | IF NOT EXISTS(SELECT 1 FROM #parametersToMap WHERE variable_name IS NOT NULL) 266 | BEGIN 267 | RAISERROR(N'Environment [%s]\[%s] does not contain any variable matching parameters specified by input criteria.', 0, 0, @env_folder_name, @environment) WITH NOWAIT; 268 | RETURN; 269 | END 270 | 271 | SET @maxLen = LEN(@folder); 272 | IF LEN(@project) > @maxLen 273 | SET @maxLen = LEN(@project); 274 | IF LEN(@environment) > @maxLen 275 | SET @maxLen = LEN(@environment); 276 | IF LEN(@environmentFolder) > @maxLen 277 | SET @maxLen = LEN(@environmentFolder); 278 | 279 | SET @maxLen = @maxLen + 2 280 | 281 | 282 | RAISERROR(N'', 0, 0) WITH NOWAIT; 283 | SET @msg = N'DECLARE @folder nvarchar(128) = N''%s''' + SPACE(@maxLen - LEN(@folder)) + N'--Update for appropriate folder name' 284 | RAISERROR(@msg, 0, 0, @folder) WITH NOWAIT; 285 | SET @msg = N'DECLARE @project nvarchar(128) = N''%s''' + SPACE(@maxLen - LEN(@project)) + N'--Update for appropriate project name' 286 | RAISERROR(@msg, 0, 0, @project) WITH NOWAIT; 287 | 288 | IF @setupReference = 1 289 | BEGIN 290 | IF @environmentFolder IS NULL 291 | BEGIN 292 | SET @msg = N'DECLARE @environmentFolder nvarchar(128) = NULL' + SPACE(@maxLen - 1) + N'--Update for appropriate folder name'; 293 | RAISERROR(@msg, 0, 0) WITH NOWAIT; 294 | END 295 | ELSE 296 | BEGIN 297 | SET @msg = N'DECLARE @environmentFolder nvarchar(128) = N''%s''' + SPACE(@maxLen - LEN(@environmentFolder)) + N'--Update for appropriate folder name' 298 | RAISERROR(@msg, 0, 0, @environmentFolder) WITH NOWAIT; 299 | END 300 | SET @msg = N'DECLARE @environment nvarchar(128) = N''%s''' + SPACE(@maxLen - LEN(@environment)) + N'--Update for appropriate environment name' 301 | RAISERROR(@msg, 0, 0, @environment) WITH NOWAIT; 302 | END 303 | 304 | 305 | RAISERROR(N'', 0, 0) WITH NOWAIT; 306 | RAISERROR(N'', 0, 0) WITH NOWAIT; 307 | RAISERROR( N'RAISERROR(N''Setting Environment and Parameter references for project [%%s]\[%%s]'', 0, 0, @folder, @project) WITH NOWAIT', 0, 0) WITH NOWAIT; 308 | SET @msg = N'RAISERROR(N''--------------------------------------------------------------' + REPLICATE('-', LEN(@folder) + LEN(@project)) + N''', 0, 0) WITH NOWAIT' ; 309 | RAISERROR(@msg, 0, 0) WITH NOWAIT; 310 | 311 | IF @setupReference = 1 312 | BEGIN 313 | RAISERROR(N'', 0, 0) WITH NOWAIT; 314 | 315 | RAISERROR( N'RAISERROR(N''Setting Environment reference...'', 0, 0) WITH NOWAIT', 0, 0) WITH NOWAIT; 316 | 317 | RAISERROR(N'DECLARE @reference_id bigint', 0, 0) WITH NOWAIT; 318 | RAISERROR(N'IF @environmentFolder IS NULL AND NOT EXISTS(SELECT 1 FROM [SSISDB].[catalog].[environment_references] WHERE environment_folder_name IS NULL AND environment_name = @environment)', 0, 0) WITH NOWAIT; 319 | RAISERROR(N' EXEC [SSISDB].[catalog].[create_environment_reference] @environment_name=@environment, @reference_id=@reference_id OUTPUT, @project_name=@project, @folder_name=@folder, @reference_type=''R''', 0, 0) WITH NOWAIT; 320 | RAISERROR(N'ELSE IF @environmentFolder IS NOT NULL AND NOT EXISTS(SELECT 1 FROM [SSISDB].[catalog].[environment_references] WHERE environment_folder_name=@environmentFolder AND environment_name = @environment)', 0, 0) WITH NOWAIT; 321 | RAISERROR(N' EXEC [SSISDB].[catalog].[create_environment_reference] @environment_name=@environment, @environment_folder_name=@environmentFolder, @reference_id=@reference_id OUTPUT, @project_name=@project, @folder_name=@folder, @reference_type=''A''', 0, 0) WITH NOWAIT; 322 | END 323 | 324 | RAISERROR(N'', 0, 0) WITH NOWAIT; 325 | 326 | DECLARE cr CURSOR FAST_FORWARD FOR 327 | SELECT 328 | object_name 329 | ,object_type 330 | ,parameter_name 331 | FROM #parametersToMap 332 | WHERE variable_name IS NOT NULL 333 | 334 | OPEN cr; 335 | 336 | FETCH NEXT FROM cr INTO @object_name, @object_type, @parameter_name 337 | 338 | WHILE @@FETCH_STATUS = 0 339 | BEGIN 340 | IF @object_name = @project 341 | RAISERROR(N'RAISERROR(N''Setting mapping for Parameter [%%s]\[%%s]\[%%s]\[%s]'', 0, 0, @folder, @project, @project) WITH NOWAIT', 0, 0, @parameter_name) WITH NOWAIT; 342 | ELSE 343 | RAISERROR(N'RAISERROR(N''Setting mapping for Parameter [%%s]\[%%s]\[%s]\[%s]'', 0, 0, @folder, @project) WITH NOWAIT', 0, 0, @object_name, @parameter_name) WITH NOWAIT; 344 | 345 | IF @object_name = @project 346 | BEGIN 347 | SET @msg = 'EXEC [SSISDB].[catalog].[set_object_parameter_value] @object_type=' + CONVERT(nvarchar(10), @object_type) + N', @parameter_name=N''' + @parameter_name + N'''' + 348 | N', @object_name=@project, @folder_name=@folder, @project_name=@project' + N', @value_type=N''R'', @parameter_value=N''' + @parameter_name + N'''' 349 | END 350 | ELSE 351 | BEGIN 352 | SET @msg = 'EXEC [SSISDB].[catalog].[set_object_parameter_value] @object_type=' + CONVERT(nvarchar(10), @object_type) + N', @parameter_name=N''' + @parameter_name + N'''' + 353 | N', @object_name=N''' + @object_name + N'''' + N', @folder_name=@folder, @project_name=@project' + N', @value_type=N''R'', @parameter_value=N''' + @parameter_name + N'''' 354 | END 355 | 356 | RAISERROR(@msg, 0, 0) WITH NOWAIT; 357 | 358 | IF @PrintOnly = 0 359 | BEGIN 360 | 361 | SET @sql = 'EXEC [SSISDB].[catalog].[set_object_parameter_value] @object_type=' + CONVERT(nvarchar(10), @object_type) + N', @parameter_name=N''' + @parameter_name + N'''' + 362 | N', @object_name=N''' + @object_name + N'''' + N', @folder_name=N''' + @folder + N'''' + N', @project_name=N''' + @project + N'''' + N', @value_type=N''R'', @parameter_value=N''' + @parameter_name + N'''' 363 | EXECUTE AS CALLER; 364 | EXEC(@sql); 365 | REVERT; 366 | END 367 | 368 | RAISERROR(N'', 0, 0) WITH NOWAIT; 369 | 370 | FETCH NEXT FROM cr INTO @object_name, @object_type, @parameter_name 371 | END 372 | 373 | IF @PrintOnly = 0 374 | BEGIN 375 | RAISERROR(N'--*******************************', 0, 0) WITH NOWAIT; 376 | RAISERROR(N'--Script was executed and applied', 0, 0) WITH NOWAIT; 377 | END 378 | 379 | CLOSE cr; 380 | DEALLOCATE cr; 381 | END 382 | GO 383 | --GRANT EXECUTE permission on the stored procedure to [ssis_admin] role 384 | GRANT EXECUTE ON [dbo].[sp_SSISMapEnvironment] TO [ssis_admin] 385 | GO 386 | -------------------------------------------------------------------------------- /SSISDB/sp_SSISResetConfiguraion.sql: -------------------------------------------------------------------------------- 1 | IF NOT EXISTS(SELECT 1 FROM sys.databases where name = 'SSISDB') 2 | BEGIN 3 | RAISERROR(N'SSIS Database Does not Exists', 15, 0) 4 | SET NOEXEC ON; 5 | END 6 | GO 7 | USE [SSISDB] 8 | GO 9 | IF NOT EXISTS(SELECT * FROM sys.procedures WHERE object_id = OBJECT_ID('[dbo].[sp_SSISResetConfiguration]')) 10 | EXEC (N'CREATE PROCEDURE [dbo].[sp_SSISResetConfiguration] AS PRINT ''Placeholder for [dbo].[sp_SSISResetConfiguration]''') 11 | GO 12 | /* **************************************************** 13 | sp_SSISResetConfiguration v 0.21 (2017-10-30) 14 | 15 | Feedback: mailto:pavel.pawlowski@hotmail.cz 16 | 17 | MIT License 18 | 19 | Copyright (c) 2017 Pavel Pawlowski 20 | 21 | Permission is hereby granted, free of charge, to any person obtaining a copy 22 | of this software and associated documentation files (the "Software"), to deal 23 | in the Software without restriction, including without limitation the rights 24 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 25 | copies of the Software, and to permit persons to whom the Software is 26 | furnished to do so, subject to the following conditions: 27 | 28 | The above copyright notice and this permission notice shall be included in all 29 | copies or substantial portions of the Software. 30 | 31 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 32 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 33 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 34 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 35 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 36 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 37 | SOFTWARE. 38 | 39 | Description: 40 | Resets configured value for project, object or individual parameter in the project configuration 41 | 42 | Parameters: 43 | @folder nvarchar(128) = --Name of the Folder of the project to reset configurations 44 | ,@project nvarchar(128) = --Name of the Project to reset configuration 45 | ,@object nvarchar(260) = NULL --Comma separated list of objects which parameters should be cleared. Supports LIKE wildcards 46 | ,@parameter nvarchar(max) = NULL --Comma separated list of parameters to be cleared. Supports LIKE wildcards 47 | ,@listOnly bit = 0 --specifies whether only list of parameters to be reset will be printed. No actual reset will happen 48 | ******************************************************* */ 49 | ALTER PROCEDURE [dbo].[sp_SSISResetConfiguration] 50 | @folder nvarchar(128) = NULL --Name of the Folder of the project to reset configurations 51 | ,@project nvarchar(128) = NULL --Name of the Project to reset configuration 52 | ,@object nvarchar(260) = NULL --Comma separated list of objects which parameters should be cleared. Supports LIKE wildcards 53 | ,@parameter nvarchar(max) = NULL --Comma separated list of parameters to be cleared. Supports LIKE wildcards 54 | ,@listOnly bit = 0 --specifies whether only list of parameters to be reset will be printed. No actual reset will happen 55 | WITH EXECUTE AS 'AllSchemaOwner' 56 | AS 57 | BEGIN 58 | SET NOCOUNT ON; 59 | SET XACT_ABORT ON; 60 | 61 | DECLARE 62 | @src_folder_id bigint --ID of the source folder 63 | ,@src_project_id bigint --ID of the source project 64 | ,@src_project_lsn bigint --current source project lsn 65 | 66 | ,@printHelp bit = 0 --Identifies whether Help should be printed (in case of no parameters provided or error) 67 | ,@msg nvarchar(max) --Variable to hold messages 68 | ,@parameter_id bigint --ID of the parameter to reset 69 | ,@object_name nvarchar(260) --name of the object being reset 70 | ,@parameter_name nvarchar(128) --name of the parameter being reset 71 | ,@preview nvarchar(128) --variable to hold preview message 72 | ,@cnt int = 0 --count of parameters which were reset 73 | ,@xmlObj xml --variable for holding xml for parsing input parameters 74 | ,@xmlPar xml --variable for holding xml for parsing input parameters 75 | 76 | 77 | --Table for holding list of parameters to be dropped 78 | CREATE TABLE #parametersToClear ( 79 | parameter_id bigint NOT NULL PRIMARY KEY CLUSTERED 80 | ,object_name nvarchar(128) 81 | ,parameter_name nvarchar(128) 82 | ) 83 | 84 | --If the required input parameters are null, print help 85 | IF @folder IS NULL OR @project IS NULL 86 | SET @printHelp = 1 87 | 88 | 89 | RAISERROR(N'sp_SSISResetConfiguration v0.21 (2017-10-30) (C) 2016 Pavel Pawlowski', 0, 0) WITH NOWAIT; 90 | RAISERROR(N'=====================================================================', 0, 0) WITH NOWAIT; 91 | 92 | --PRINT HELP 93 | IF @printHelp = 1 94 | BEGIN 95 | RAISERROR(N'Resets configuration of a Project/ObjectName/Parameter', 0, 0) WITH NOWAIT; 96 | RAISERROR(N'', 0, 0) WITH NOWAIT; 97 | RAISERROR(N'Usage:', 0, 0) WITH NOWAIT; 98 | RAISERROR(N'[sp_SSISResetConfiguration] parameters', 0, 0) WITH NOWAIT; 99 | RAISERROR(N'', 0, 0) WITH NOWAIT; 100 | SET @msg = N'Parameters: 101 | @folder nvarchar(128) = - Name of the Folder of the project to reset configurations. 102 | Folder is required and must exist. 103 | ,@project nvarchar(128) = - Name of the Project to reset configuration. 104 | Project is required and must exists. 105 | ,@object nvarchar(260) = NULL - Comma separated list of object names within project to reset configuration. Support LIKE wildcards 106 | Object is optional and if provided then only configuration for that particular objects will be reset. 107 | ,@parameter nvarchar(128) = NULL - Comma separated list of parameter names within project to reset configuration. Support LIKE wildcards 108 | Parameter is optional and if provided then only configuration for that parameter are reset 109 | When @parameter is provided and @object not, then all parameters with that particular name 110 | are reset within the project configurations. 111 | ,@listOnly bit = 0 - Specifies whether only list of parameters to be reset will be printed. 112 | No actual reset will happen. 113 | ' 114 | RAISERROR(@msg, 0, 0) WITH NOWAIT; 115 | 116 | RAISERROR(N'',0, 0) WITH NOWAIT; 117 | 118 | RETURN; 119 | END 120 | 121 | --get source folder_id 122 | SELECT 123 | @src_folder_id = folder_id 124 | FROM internal.folders f 125 | WHERE f.name = @folder; 126 | 127 | --check source folder 128 | IF @src_folder_id IS NULL 129 | BEGIN 130 | RAISERROR(N'Source folder [%s] does not exists.', 15, 1, @folder) WITH NOWAIT; 131 | RETURN; 132 | END 133 | 134 | --get source project_id 135 | SELECT 136 | @src_project_id = p.project_id 137 | ,@src_project_lsn = p.object_version_lsn 138 | FROM [catalog].projects p 139 | WHERE 140 | p.folder_id = @src_folder_id 141 | AND 142 | p.name = @project; 143 | 144 | 145 | --chek source project 146 | IF @src_project_id IS NULL 147 | BEGIN 148 | RAISERROR(N'Project [%s]\[%s] does not exists.', 15, 2, @folder, @project) WITH NOWAIT; 149 | RETURN; 150 | END 151 | 152 | SET @xmlObj = N'' + REPLACE(ISNULL(@object, N'%'), N',', N'') + N''; 153 | SET @xmlPar = N'' + REPLACE(ISNULL(@parameter, N'%'), N',', N'') + N''; 154 | 155 | WITH ObjNames AS ( 156 | SELECT DISTINCT 157 | LTRIM(RTRIM(n.value(N'.', N'nvarchar(128)'))) AS ObjectName 158 | FROM @xmlObj.nodes(N'i') T(N) 159 | ), 160 | ParamNames AS ( 161 | SELECT DISTINCT 162 | LTRIM(RTRIM(n.value(N'.', N'nvarchar(128)'))) AS ParamName 163 | FROM @xmlPar.nodes(N'i') T(N) 164 | ) 165 | INSERT INTO #parametersToClear ( 166 | parameter_id 167 | ,object_name 168 | ,parameter_name 169 | ) 170 | SELECT DISTINCT 171 | parameter_id 172 | ,object_name 173 | ,parameter_name 174 | FROM [internal].[object_parameters] op 175 | INNER JOIN ObjNames o ON op.object_name LIKE o.ObjectName 176 | INNER JOIN ParamNames p ON op.parameter_name LIKE p.ParamName 177 | WHERE 178 | op.project_id = @src_project_id 179 | AND 180 | op.project_version_lsn = @src_project_lsn 181 | AND 182 | op.value_set = 1 183 | 184 | IF NOT EXISTS(SELECT 1 FROM #parametersToClear) 185 | BEGIN 186 | RAISERROR(N'No parameters configuration exists for input parameters provided...', 0, 0) WITH NOWAIT; 187 | RETURN; 188 | END 189 | 190 | 191 | RAISERROR(N'', 0, 0) WITH NOWAIT; 192 | RAISERROR( N'Resetting configurations for project [%s]\[%s]', 0, 0, @folder, @project) WITH NOWAIT; 193 | SET @msg = N'-----------------------------------------' + REPLICATE('-', LEN(@folder) + LEN(@project)); 194 | RAISERROR(@msg, 0, 0) WITH NOWAIT; 195 | RAISERROR(N'', 0, 0) WITH NOWAIT; 196 | 197 | IF (@listOnly = 0) 198 | SET @preview = N'' 199 | ELSE 200 | SET @preview = N'PREVIEW ONLY: ' 201 | 202 | SET TRANSACTION ISOLATION LEVEL SERIALIZABLE; 203 | BEGIN TRAN 204 | 205 | DECLARE cr CURSOR FAST_FORWARD FOR 206 | SELECT 207 | parameter_id 208 | ,object_name 209 | ,parameter_name 210 | FROM #parametersToClear 211 | 212 | OPEN cr; 213 | 214 | FETCH NEXT FROM cr INTO @parameter_id, @object_name, @parameter_name 215 | 216 | WHILE @@FETCH_STATUS = 0 217 | BEGIN 218 | RAISERROR ('%sResetting configuration of parameter [SSISDB]\[%s]\[%s]\[%s]\[%s]', 0, 0, @preview, @folder, @project, @object_name, @parameter_name) WITH NOWAIT; 219 | 220 | IF @listOnly = 0 221 | BEGIN 222 | UPDATE [internal].[object_parameters] SET 223 | referenced_variable_name = NULL 224 | ,value_set = 0 225 | ,sensitive_default_value = NULL 226 | ,default_value = NULL 227 | ,base_data_type = NULL 228 | ,value_type = 'V' 229 | WHERE 230 | parameter_id = @parameter_id 231 | END 232 | 233 | SET @cnt = @cnt + 1 234 | FETCH NEXT FROM cr INTO @parameter_id, @object_name, @parameter_name 235 | END 236 | 237 | IF @cnt = 0 238 | BEGIN 239 | RAISERROR(N'Nothing to RESET. There is no parameter matching criteria passed.', 0, 0) WITH NOWAIT; 240 | END 241 | 242 | CLOSE cr; 243 | DEALLOCATE cr; 244 | 245 | COMMIT TRAN; 246 | END 247 | GO 248 | --GRANT EXECUTE permission on the stored procedure to [ssis_admin] role 249 | GRANT EXECUTE ON [dbo].[sp_SSISResetConfiguration] TO [ssis_admin] 250 | GO 251 | -------------------------------------------------------------------------------- /SSISDB/usp_CheckConstraints.sql: -------------------------------------------------------------------------------- 1 | USE [SSISDB] 2 | GO 3 | IF NOT EXISTS(SELECT * FROM sys.procedures WHERE object_id = OBJECT_ID('[dbo].[usp_CheckConstraints]')) 4 | EXEC (N'CREATE PROCEDURE [dbo].[usp_CheckConstraints] AS PRINT ''Placeholder for [dbo].[usp_CheckConstraints]''') 5 | GO 6 | IF NOT EXISTS (SELECT 1 FROM sys.database_principals WHERE name = 'AllSchemaMaintenance') 7 | BEGIN 8 | CREATE USER [AllSchemaMaintenance] WITHOUT LOGIN WITH DEFAULT_SCHEMA=[dbo] 9 | GRANT ALTER, DELETE, INSERT, SELECT, UPDATE ON SCHEMA::[internal] TO [AllSchemaMaintenance] 10 | END 11 | GO 12 | /* **************************************************** 13 | usp_CheckConstraints v 1.0 (2019-10-01) 14 | Feedback: mailto:pavel.pawlowski@hotmail.cz 15 | 16 | MIT License 17 | 18 | Copyright (c) 2019 Pavel Pawlowski 19 | 20 | Permission is hereby granted, free of charge, to any person obtaining a copy 21 | of this software and associated documentation files (the "Software"), to deal 22 | in the Software without restriction, including without limitation the rights 23 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 24 | copies of the Software, and to permit persons to whom the Software is 25 | furnished to do so, subject to the following conditions: 26 | 27 | The above copyright notice and this permission notice shall be included in all 28 | copies or substantial portions of the Software. 29 | 30 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 31 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 32 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 33 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 34 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 35 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 36 | SOFTWARE. 37 | 38 | Description: 39 | Enables or disables check constraints betwen among the log tables to allow fast cleanup of log records. 40 | Paramters: 41 | @enable bit = 1 --Specifies whether the constraints should be enabled or disabled 42 | ******************************************************* */ 43 | ALTER PROCEDURE [dbo].[usp_CheckConstraints] 44 | @enable bit = 1 --Specifies whether the constraints should be enabled or disabled 45 | WITH EXECUTE AS 'AllSchemaMaintenance' 46 | AS 47 | BEGIN 48 | SET NOCOUNT ON 49 | 50 | RAISERROR(N'[dbo].[usp_CheckConstraints]', 0, 0) WITH NOWAIT; 51 | RAISERROR(N'=============================', 0, 0) WITH NOWAIT; 52 | 53 | IF @enable = 0 54 | BEGIN 55 | RAISERROR(N'Disabling [SSISDB] Constraints to [internal].[operations]', 0, 0) WITH NOWAIT; 56 | ALTER TABLE [internal].[event_message_context] 57 | NOCHECK CONSTRAINT [FK_EventMessagecontext_Operations] 58 | 59 | ALTER TABLE [internal].[event_messages] 60 | NOCHECK CONSTRAINT [FK_EventMessage_Operations] 61 | 62 | ALTER TABLE [internal].[operation_messages] 63 | NOCHECK CONSTRAINT [FK_OperationMessages_OperationId_Operations] 64 | 65 | ALTER TABLE [internal].[executions] 66 | NOCHECK CONSTRAINT [FK_Executions_ExecutionId_Operations] 67 | 68 | 69 | ALTER TABLE [internal].[validations] 70 | NOCHECK CONSTRAINT [FK_Validations_ValidationId_Operations] 71 | 72 | 73 | ALTER TABLE [internal].[operation_permissions] 74 | NOCHECK CONSTRAINT [FK_OperationPermissions_ObjectId_Operations] 75 | 76 | ALTER TABLE [internal].[extended_operation_info] 77 | NOCHECK CONSTRAINT [FK_OperationInfo_Operations] 78 | 79 | ALTER TABLE [internal].[operation_os_sys_info] 80 | NOCHECK CONSTRAINT [FK_OssysInfo_Operations] 81 | END 82 | ELSE 83 | BEGIN 84 | RAISERROR(N'Enabling [SSISDB] Constraints to [internal].[operations]', 0, 0) WITH NOWAIT; 85 | 86 | DELETE FROM [internal].[event_messages] 87 | WHERE operation_id NOT IN (SELECT operation_id FROM [internal].[operations]) 88 | 89 | ALTER TABLE [internal].[event_message_context] 90 | NOCHECK CONSTRAINT [FK_EventMessagecontext_Operations] 91 | 92 | ALTER TABLE [internal].[event_messages] 93 | CHECK CONSTRAINT [FK_EventMessage_Operations] 94 | 95 | --============================= 96 | DELETE FROM [internal].[operation_messages] 97 | WHERE operation_id NOT IN (SELECT operation_id FROM [internal].[operations]) 98 | 99 | ALTER TABLE [internal].[operation_messages] 100 | CHECK CONSTRAINT [FK_OperationMessages_OperationId_Operations] 101 | 102 | --============================= 103 | DELETE FROM [internal].[executions] 104 | WHERE execution_id NOT IN (SELECT operation_id FROM [internal].[operations]) 105 | 106 | ALTER TABLE [internal].[executions] 107 | CHECK CONSTRAINT [FK_Executions_ExecutionId_Operations] 108 | 109 | 110 | --============================= 111 | DELETE FROM [internal].[validations] 112 | WHERE validation_id NOT IN (SELECT operation_id FROM [internal].[operations]) 113 | 114 | ALTER TABLE [internal].[validations] 115 | CHECK CONSTRAINT [FK_Validations_ValidationId_Operations] 116 | 117 | 118 | --============================= 119 | DELETE FROM [internal].[operation_permissions] 120 | WHERE [object_id] NOT IN (SELECT operation_id FROM [internal].[operations]) 121 | 122 | ALTER TABLE [internal].[operation_permissions] 123 | CHECK CONSTRAINT [FK_OperationPermissions_ObjectId_Operations] 124 | 125 | --============================= 126 | DELETE FROM [internal].[extended_operation_info] 127 | WHERE operation_id NOT IN (SELECT operation_id FROM [internal].[operations]) 128 | 129 | ALTER TABLE [internal].[extended_operation_info] 130 | CHECK CONSTRAINT [FK_OperationInfo_Operations] 131 | 132 | --============================= 133 | DELETE FROM [internal].[operation_os_sys_info] 134 | WHERE operation_id NOT IN (SELECT operation_id FROM [internal].[operations]) 135 | 136 | ALTER TABLE [internal].[operation_os_sys_info] 137 | CHECK CONSTRAINT [FK_OssysInfo_Operations] 138 | END 139 | END 140 | GO 141 | 142 | GRANT EXECUTE ON [dbo].[usp_CheckConstraints] TO [##MS_SSISServerCleanupJobUser##] 143 | GO 144 | -------------------------------------------------------------------------------- /SSISDB/usp_cleanup_key_certificates.sql: -------------------------------------------------------------------------------- 1 | USE [SSISDB] 2 | GO 3 | IF NOT EXISTS(SELECT * FROM sys.procedures WHERE object_id = OBJECT_ID('[dbo].[usp_cleanup_key_certificates]')) 4 | EXEC (N'CREATE PROCEDURE [dbo].[usp_cleanup_key_certificates] AS PRINT ''Placeholder for [dbo].[usp_cleanup_key_certificates]''') 5 | GO 6 | /* **************************************************** 7 | usp_cleanup_key_certificates v 1.01 (2019-08-19) 8 | Feedback: mailto:pavel.pawlowski@hotmail.cz 9 | 10 | MIT License 11 | 12 | Copyright (c) 2019 Pavel Pawlowski 13 | 14 | Permission is hereby granted, free of charge, to any person obtaining a copy 15 | of this software and associated documentation files (the "Software"), to deal 16 | in the Software without restriction, including without limitation the rights 17 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 18 | copies of the Software, and to permit persons to whom the Software is 19 | furnished to do so, subject to the following conditions: 20 | 21 | The above copyright notice and this permission notice shall be included in all 22 | copies or substantial portions of the Software. 23 | 24 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 25 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 26 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 27 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 28 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 29 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 30 | SOFTWARE. 31 | 32 | Description: 33 | Cleanups SSISDB catalog from left over certificates and symmetric keys. 34 | 35 | The regular SSISDB cleanup job is dropping operations behind the retention window in batches. During the deletion it stores 36 | the deleted operation_ids in temporary table and and then deletes keys and certificates for such deleted operation_ids. 37 | In case the delete operation fails for whatever reason, then it happens that there are left over keys and certificates which 38 | will be never deleted. 39 | 40 | This procedure compares the existing execution IDs with the certificates and drops such left over certificates 41 | and symmetric keys. 42 | 43 | This procedure should be added as last step to the SSIS Server Maintenance Job 44 | 45 | Paramters: 46 | @do_cleanup bit = NULL --Specifies whether information about left over certificates will be printed instead of actual cleanup 47 | ******************************************************* */ 48 | ALTER PROCEDURE [dbo].[usp_cleanup_key_certificates] 49 | @do_cleanup bit = NULL --Specifies whether information about left over certificates will be printed instead of actual cleanup 50 | --WITH EXECUTE AS 'AllSchemaOwner' 51 | WITH EXECUTE AS OWNER 52 | AS 53 | SET NOCOUNT ON; 54 | 55 | RAISERROR(N'usp_cleanup_key_certificates v1.01 (2019-08-19) (c) 2019 Pavel Pawlowski', 0, 0) WITH NOWAIT; 56 | RAISERROR(N'========================================================================', 0, 0) WITH NOWAIT; 57 | RAISERROR(N'usp_cleanup_key_certificates cleanups SSISDB for left over certificates.', 0, 0) WITH NOWAIT; 58 | RAISERROR(N'and symmetric key caused by regular cleanup job failures', 0, 0) WITH NOWAIT; 59 | RAISERROR(N'https://github.com/PavelPawlowski/SQL-Scripts', 0, 0) WITH NOWAIT; 60 | 61 | RAISERROR(N'', 0, 0) WITH NOWAIT; 62 | 63 | IF @do_cleanup IS NULL 64 | BEGIN 65 | RAISERROR(N' 66 | Usage: 67 | [dbo].[usp_cleanup_key_certificates] [params] 68 | 69 | Parameters: 70 | @do_cleanup bit = NULL --Specifies whetehr actual cleanup should be done or only information about the cleanup should be printed. 71 | --0 = print only the left-over certificates and keys. 72 | --1 = delete left-over certificates and keys 73 | ', 0, 0) WITH NOWAIT; 74 | 75 | 76 | RETURN; 77 | END 78 | ELSE IF @do_cleanup = 0 79 | BEGIN 80 | RAISERROR(N'<<-- NO DELETE MODE - information is printed only -->>', 0, 0); 81 | END 82 | 83 | RAISERROR(N'', 0, 0) WITH NOWAIT; 84 | RAISERROR(N'Retrieving information about left-over certificates and symmetric keys....', 0, 0) WITH NOWAIT; 85 | 86 | 87 | DECLARE 88 | @name_to_delete nvarchar(128) 89 | ,@is_cert bit 90 | ,@msg nvarchar(max) 91 | ,@sql nvarchar(max) 92 | ,@cntCerts int 93 | ,@cntKeys int 94 | 95 | 96 | CREATE TABLE #certkeys ( 97 | operation_id bigint NOT NULL 98 | ,is_cert bit NOT NULL 99 | ,name nvarchar(128) 100 | ,PRIMARY KEY CLUSTERED(operation_id, is_cert) 101 | ) 102 | 103 | --Get redundant certificates 104 | INSERT INTO #certkeys(operation_id, is_cert, name) 105 | SELECT 106 | CONVERT(bigint, RIGHT(name, LEN(name) - LEN('MS_Cert_Exec_'))) AS operation_id 107 | ,CONVERT(bit, 1) AS is_cert 108 | ,name 109 | FROM sys.certificates 110 | WHERE 111 | name LIKE 'MS_Cert_Exec_%' 112 | 113 | INSERT INTO #certkeys(operation_id, is_cert, name) 114 | SELECT 115 | CONVERT(bigint, RIGHT(name, LEN(name) - LEN('MS_Enckey_Exec_'))) AS operation_id 116 | ,CONVERT(bit, 0) as is_cert 117 | ,name 118 | FROM sys.symmetric_keys 119 | WHERE name LIKE 'MS_Enckey_Exec_%' 120 | 121 | 122 | SELECT 123 | @cntCerts = ISNULL(SUM(CASE WHEN is_cert = 1 THEN 1 ELSE 0 END), 0) 124 | ,@cntKeys = ISNULL(SUM(CASE WHEN is_cert = 1 THEN 0 ELSE 1 END), 0) 125 | FROM #certkeys c 126 | LEFT JOIN internal.operations o ON c.operation_id = o.operation_id 127 | WHERE 128 | o.operation_id IS NULL 129 | 130 | RAISERROR(N'Number of Certificates to Cleanup: %d', 0, 0, @cntCerts) WITH NOWAIT; 131 | RAISERROR(N'Number of symmetric keys to Cleanup: %d', 0, 0, @cntKeys) WITH NOWAIT; 132 | RAISERROR(N'------------------------------------------------------------------', 0, 0) WITH NOWAIT; 133 | WAITFOR DELAY '00:00:00.5'; 134 | 135 | DECLARE rk CURSOR LOCAL FAST_FORWARD FOR 136 | SELECT 137 | c.name 138 | ,c.is_cert 139 | FROM #certkeys c 140 | LEFT JOIN internal.operations o ON c.operation_id = o.operation_id 141 | WHERE 142 | o.operation_id IS NULL 143 | ORDER BY c.operation_id 144 | 145 | OPEN rk; 146 | 147 | FETCH NEXT FROM rk INTO @name_to_delete, @is_cert 148 | 149 | WHILE @@FETCH_STATUS = 0 150 | BEGIN 151 | if @is_cert = 1 152 | BEGIN 153 | SET @msg = 'Deleting left-over certificate: ' + @name_to_delete; 154 | SET @sql = 'DROP CERTIFICATE ' + QUOTENAME(@name_to_delete); 155 | END 156 | ELSE 157 | BEGIN 158 | SET @msg = 'Deleting left-over symmetric key: ' + @name_to_delete; 159 | SET @sql = 'DROP SYMMETRIC KEY ' + QUOTENAME(@name_to_delete); 160 | END 161 | 162 | 163 | IF @do_cleanup = 1 164 | BEGIN 165 | RAISERROR(@msg, 0, 0) WITH NOWAIT; 166 | EXECUTE sp_executesql @sql; 167 | END 168 | ELSE 169 | BEGIN 170 | SET @msg = N'NOT ' + @msg + N' (' + @sql + N')' 171 | RAISERROR(@msg, 0, 0) WITH NOWAIT; 172 | END 173 | 174 | FETCH NEXT FROM rk INTO @name_to_delete, @is_cert 175 | END 176 | 177 | CLOSE rk; 178 | DEALLOCATE rk; 179 | 180 | GO 181 | 182 | GRANT EXECUTE ON [dbo].[usp_cleanup_key_certificates] TO [##MS_SSISServerCleanupJobUser##] 183 | GO 184 | -------------------------------------------------------------------------------- /Samples/DateTime/DayOfWeek.sql: -------------------------------------------------------------------------------- 1 | /* **************************************************** 2 | SQL Server Samples 3 | 4 | (C) 2008 - 2021 Pavel Pawlowski 5 | 6 | Feedback: mailto:pavel.pawlowski@hotmail.cz 7 | 8 | Description: 9 | 10 | Samples of Day of week calculations 11 | 12 | **************************************************** */ 13 | 14 | 15 | /* Selecting First Day of a Week based on date */ 16 | 17 | DECLARE @date datetime = GETDATE() 18 | 19 | SELECT 20 | DATEADD(WEEK, DATEDIFF(WEEK, 0, GETDATE()), 0) AS [FirstDayOfWeekMonday] /*Difference in weeks between date and 0 = (1900-01-01 was Monday) for weeks starting Monday*/ 21 | ,DATEADD(WEEK, DATEDIFF(WEEK, -1, GETDATE()), 0) AS [FirstDayOfWeekSunday] /*Difference in weeks between date and -1 = (1899-12-31 was Sunday) for weeks starting Sunday*/ 22 | GO 23 | 24 | 25 | 26 | /* 27 | Getting Number of a day might be tricky, because it depends on the SET DATEFIRST 28 | 29 | https://docs.microsoft.com/en-us/sql/t-sql/functions/datepart-transact-sql?view=sql-server-ver15 30 | 31 | If we want to have the week of day independed on the system setting, we can calculate it easily 32 | 33 | 34 | DATEDIFF(DAY, @firstDayOfWeek - 8, [WeekDay]) % 7 + 1 AS [WeekDay Independed on DATEFIRST] 35 | 36 | 1. We know that 1900-01-01 was Monday 37 | 2. @firsrDayOfWeek we use as starting day. 0 = 1900-01-01. But we are setting it in range 1 - 7 this meens between 1900-01-02 - 1900-01-08 38 | 3. Then we substract 8 from that date. This ensures that for 1 Monday we receive 1899-12-25 (Monday) and for 7 Sunday we receive 1899-12-31 Sunday 39 | 4. Then we caculate the difference between such caclulated starting day and current date in days: DATEDIFF(DAY, @firstDayOfWeek - 8, [WeekDay]) 40 | 5. Then we divide the number by 7 and take the residual (% operator). Residual will be between 0 (monday) - 6 (Sunday): DATEDIFF(DAY, @firstDayOfWeek - 8, [WeekDay]) % 7 41 | 6. We add 1 to that residual to have range from 1 Monday to 7 Sunday: DATEDIFF(DAY, @firstDayOfWeek - 8, [WeekDay]) % 7 + 1 42 | 43 | */ 44 | 45 | 46 | DECLARE 47 | @firstDayOfWeek tinyint = 1 --Defines the first day of week we want to have 1 = Monday - 7 = Sunday 48 | 49 | 50 | 51 | SET DATEFIRST 7 52 | 53 | /*Get dates for current week*/ 54 | ;WITH CurrentWeek AS ( 55 | SELECT 56 | DATEADD(WEEK, DATEDIFF(WEEK, 0, GETDATE()) + N, 0) AS [WeekDay] /* Utilizes the first example First Day of Week */ 57 | FROM (VALUES (0),(1),(2),(3),(4), (5),(6)) T (N) 58 | ) 59 | SELECT 60 | cw.[WeekDay] 61 | ,DATEPART(WEEKDAY, cw.[WeekDay]) AS [WeekDay Depended On DATEFIRST=7] --DATEPART is depended on DATEFIRST 62 | ,DATEDIFF(DAY, @firstDayOfWeek - 8, [WeekDay]) % 7 + 1 AS [WeekDay Independed on DATEFIRST] 63 | FROM CurrentWeek cw 64 | 65 | 66 | SET DATEFIRST 1 67 | 68 | /*Get dates for current week*/ 69 | ;WITH CurrentWeek AS ( 70 | SELECT 71 | DATEADD(WEEK, DATEDIFF(WEEK, 0, GETDATE()) + N, 0) AS [WeekDay] /* Utilizes the first example First Day of Week */ 72 | FROM (VALUES (0),(1),(2),(3),(4), (5),(6)) T (N) 73 | ) 74 | SELECT 75 | cw.[WeekDay] 76 | ,DATEPART(WEEKDAY, cw.[WeekDay]) AS [WeekDay Depended On DATEFIRST=1] 77 | ,DATEDIFF(DAY, @firstDayOfWeek - 8, [WeekDay]) % 7 + 1 AS [WeekDay Independed on DATEFIRST] 78 | FROM CurrentWeek cw -------------------------------------------------------------------------------- /Samples/DateTime/StartAndEndOfPeriods.sql: -------------------------------------------------------------------------------- 1 | /* **************************************************** 2 | SQL Server Samples 3 | 4 | (C) 2008 - 2021 Pavel Pawlowski 5 | 6 | Feedback: mailto:pavel.pawlowski@hotmail.cz 7 | 8 | Description: 9 | 10 | Samples calculations of beginning and end of DateTime Periods 11 | 12 | **************************************************** */ 13 | 14 | 15 | 16 | /* The easiest way to calculate the beginning and/or end of particular period 17 | is by using the DATEADD and DATEDIFF function and do the calculations 18 | from some known point in time in past 19 | 20 | */ 21 | 22 | 23 | DECLARE 24 | @date datetime = GETDATE() 25 | 26 | 27 | SELECT 28 | @date AS [Selected Date] 29 | ,DATEADD(YEAR, DATEDIFF(YEAR, 0, @date), 0) AS [Beginning of Year] --We count number of years from 0 = 1900-01-01 and add them back to the 0. 30 | --we receive beginning of the year of selected date 31 | ,DATEADD(DAY, -1, DATEADD(YEAR, DATEDIFF(YEAR, 0, @date) + 1, 0)) AS [End of Year] --We count the beginning of the year, but add 1 additional year and subtract 1 day. 32 | ,DATEADD(MONTH, DATEDIFF(MONTH, 0, @date), 0) AS [Beginning of Month] --We count the number of months from 0 = 1900-01-010 and add them back to the 0. 33 | --we receive beginning of the month of selected date 34 | ,DATEADD(DAY, -1, DATEADD(MONTH, DATEDIFF(MONTH, 0, @date) + 1, 0)) AS [End of Month] --We count the beginning of the month but add 1 additional month and subtract 1 day 35 | ,DATEADD(WEEK, DATEDIFF(WEEK, 0, @date), 0) AS [Beginning of Week - Monday] --We count the number of weeks from 0 = 1900-01-01 and add them back to the 0 36 | --We receive Monday as beginning of the year as we know 1900-01-01 was Monday 37 | ,DATEADD(WEEK, DATEDIFF(WEEK, -1, @date), -1) AS [Beginning of Week - Sunday] --We count the number of weeks from -1 = 1899-12-31 and add them back to the -1 38 | --We receive Sunday as beginning of the year as we know 1-01-01 was Monday 39 | ,DATEADD(DAY, -1, DATEADD(WEEK, DATEDIFF(WEEK, 0, @date) + 1, 0)) AS [End of Week - Sunday] --We count the beginning of the week, but add 1 additional week and subtract 1 day. 40 | ,DATEADD(DAY, -1, DATEADD(WEEK, DATEDIFF(WEEK, -1, @date) + 1, -1)) AS [End of Week - Saturday] --We count the beginning of the week, but add 1 additional week and subtract 1 day. 41 | 42 | SELECT 43 | @date AS [Selected Date] 44 | ,DATEADD(HOUR, DATEDIFF(HOUR, 0, @date), 0) AS [Start of Hour] --We count the number of hours from 0 = 1900-01-01 midnight and add them back to 0. 45 | ,DATEADD(MINUTE, DATEDIFF(MINUTE, 0, @date), 0) AS [Start of Minute] --We count the number of minutes from 0 = 1900-01-01 midnight and add them back to 0. 46 | ,CONVERT(datetime, CONVERT(datetime2(0), @date)) AS [Start of Second] --For seconds the easies is to convert the to datetime2(0) which has zero precison 47 | --so time is truncated to whole seconds and conver back to original data type. 48 | --DATEADD and DATEDIFF would be possible to utilize as well 49 | --but we we would need to choose a closer starting date (not 0 as it would result in overflow 50 | --too much seconds from 1900-01-01) 51 | ,CONVERT(datetime, CONVERT(datetime2(1), @date)) AS [Start of Millisecond] --For seconds the easies is to convert the to datetime2(1) which has millisecond precison and convert back to original data type 52 | -------------------------------------------------------------------------------- /TablesManagement/Partitioning/sp_HelpPartitionFunction.sql: -------------------------------------------------------------------------------- 1 | /* ***************************************************************************************** 2 | AZURE SQL DB Notice 3 | 4 | Comment-out the unsupported USE [master] when running in Azure SQL DB/Synapse Analytics 5 | or ignore error caused by unsupported USE statement 6 | ******************************************************************************************** */ 7 | 8 | USE [master] 9 | GO 10 | IF NOT EXISTS (SELECT 1 FROM sys.all_objects WHERE object_id = OBJECT_ID('[dbo].[sp_HelpPartitionFunction]') AND TYPE = 'P') 11 | EXECUTE ('CREATE PROCEDURE [dbo].[sp_HelpPartitionFunction] AS BEGIN PRINT ''Container for [dbo].[sp_HelpPartitionFunction] (C) Pavel Pawlowski'' END') 12 | GO 13 | /* ******************************************************* 14 | sp_HelpPartitionFunction v 0.53 (2018-03-20) 15 | 16 | Feedback: mailto:pavel.pawlowski@hotmail.cz 17 | 18 | MIT License 19 | 20 | Copyright (c) 2017 Pavel Pawlowski 21 | 22 | Permission is hereby granted, free of charge, to any person obtaining a copy 23 | of this software and associated documentation files (the "Software"), to deal 24 | in the Software without restriction, including without limitation the rights 25 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 26 | copies of the Software, and to permit persons to whom the Software is 27 | furnished to do so, subject to the following conditions: 28 | 29 | The above copyright notice and this permission notice shall be included in all 30 | copies or substantial portions of the Software. 31 | 32 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 33 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 34 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 35 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 36 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 37 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 38 | SOFTWARE. 39 | 40 | Description: 41 | Provides information about the partition function including partitions it will generate and their boundary values 42 | Procedure also lists depended partition schemes and tables/indexed views/indexes using that partition function 43 | 44 | 45 | Parameters: 46 | @pfName nvarchar(128) = NULL --Name of the partition function 47 | ,@listDependencies bit = 0 --Specifies whether list dependencies of the partition function 48 | ,@noInfoMsg bit = 0 --Disbles printing of header and informationals messages 49 | 50 | Result table schema: 51 | CREATE TABLE #Results( 52 | [PartitionFunctionName] sysname NOT NULL --Partition function name 53 | ,[PartitionFunctionID] int NOT NULL --Partition function id 54 | ,[Created] datetime NOT NULL --Date/Time when the partition function was created 55 | ,[Modified] datetime NOT NULL --Date/Time when the partition function was last modified 56 | ,[ParameterDataType] sysname NOT NULL --data type of the partition function parameter 57 | ,[BoundaryType] nvarchar(5) NOT NULL --Boundary type of the partition function LEFT/RIGHT 58 | ,[PartitionID] bigint NULL --ID of the partition which will be generated by the partition function 59 | ,[LeftBoundaryIncluded] char(1) NOT NULL --Specifies whether left boundary value is included in the partition 60 | ,[RightBoundaryIncluded] char(1) NOT NULL --Specifies whether right boundary value is included in the partition 61 | ,[LeftBoundary] sql_variant NULL --Left boundary value 62 | ,[RightBoundary] [ sql_variant NULL --Right boundary value 63 | ,[PartitionRange] nvarchar(4000) NULL --Partition range in human readable form 64 | ); 65 | */ 66 | ALTER PROCEDURE [dbo].[sp_HelpPartitionFunction] 67 | @pfName nvarchar(128) = NULL --Name of the partition function 68 | ,@listDependencies bit = 0 --Specifies whether list dependencies of the partition function 69 | ,@noInfoMsg bit = 0 --Disbles printing of header and informational messages 70 | AS 71 | BEGIN 72 | SET NOCOUNT ON; 73 | DECLARE 74 | @caption nvarchar(max) --Procedure caption 75 | ,@msg nvarchar(max) --message 76 | ,@pfID int --ID of partition Function 77 | ,@partitionsCount int --count of boundary values 78 | 79 | IF @noInfoMsg = 0 80 | BEGIN 81 | SET @caption = N'sp_HelpPartitionFunction v 0.53 (2018-03-20) (C) 2014 - 2018 Pavel Pawlowski' + NCHAR(13) + NCHAR(10) + 82 | N'============================================================================'; 83 | RAISERROR(@caption, 0, 0) WITH NOWAIT; 84 | END 85 | 86 | --if partition function name is not provided, print Help 87 | IF @pfName IS NULL 88 | BEGIN 89 | RAISERROR(N'', 0, 0) WITH NOWAIT; 90 | RAISERROR(N'Provides detailed information about the partition function including partitions and their boundary values it will generate as well as dependencies.', 0, 0) WITH NOWAIT; 91 | RAISERROR(N'', 0, 0); 92 | RAISERROR(N'Usage:', 0, 0); 93 | RAISERROR(N'[sp_HelpPartitionFunction] {@pfName = ''partition_function_name''} [,@listDependencies]', 0, 0); 94 | RAISERROR(N'', 0, 0); 95 | SET @msg = N'Parameters: 96 | @pfName nvarchar(128) = NULL - Name of the partition function for which the information should be returned 97 | ,@listDependencies bit = 1 - Specifies whether list dependencies of the partition function'; 98 | RAISERROR(@msg, 0, 0); 99 | 100 | SET @msg = N' 101 | Table schema to hold results for partition information 102 | ------------------------------------------------------ 103 | CREATE TABLE #Results( 104 | [PartitionFunctionName] sysname NOT NULL --Partition function name 105 | ,[PartitionFunctionID] int NOT NULL --Partition function id 106 | ,[Created] datetime NOT NULL --Date/Time when the partition function was created 107 | ,[Modified] datetime NOT NULL --Date/Time when the partition function was last modified 108 | ,[ParameterDataType] sysname NOT NULL --data type of the partition function parameter 109 | ,[BoundaryType] nvarchar(5) NOT NULL --Boundary type of the partition function LEFT/RIGHT 110 | ,[PartitionID] bigint NULL --ID of the partition which will be generated by the partition function 111 | ,[LeftBoundaryIncluded] char(1) NOT NULL --Specifies whether left boundary value is included in the partition 112 | ,[RightBoundaryIncluded] char(1) NOT NULL --Specifies whether right boundary value is included in the partition 113 | ,[LeftBoundary] sql_variant NULL --Left boundary value 114 | ,[RightBoundary] [ sql_variant NULL --Right boundary value 115 | ,[PartitionRange] nvarchar(4000) NULL --Partition range in human readable form 116 | );'; 117 | RAISERROR(@msg, 0, 0); 118 | 119 | RETURN 120 | END 121 | 122 | --Get the partition function ID and count of partitions it will generate 123 | SELECT 124 | @pfID = pf.function_id 125 | ,@partitionsCount = pf.fanout 126 | FROM sys.partition_functions pf 127 | WHERE pf.[name] = @pfName 128 | 129 | IF @pfID IS NULL 130 | BEGIN 131 | RAISERROR(N'Partition Function [%s] does not exists', 15, 0, @pfname) WITH NOWAIT; 132 | RETURN; 133 | END; 134 | 135 | IF @noInfoMsg = 0 136 | RAISERROR(N'Retrieving information for partition function [%s]', 0, 0, @pfName) WITH NOWAIT; 137 | 138 | --Get partition information 139 | WITH TallyBase AS ( --Bae Tally table for generating partition IDs 140 | SELECT 141 | N 142 | FROM (VALUES (1), (1), (1), (1), (1), (1), (1), (1), (1), (1)) T(N) --10 rows 143 | ), 144 | [Partitions] AS ( --Generate partitions for the partition function 145 | SELECT TOP (@partitionsCount) -- Get Only @boundariesCount +1 as this is the number of partitions 146 | ROW_NUMBER() OVER(ORDER BY (SELECT NULL)) AS PartitionID 147 | FROM 148 | TallyBase T10 --10 149 | ,TallyBase T100 --100 150 | ,TallyBase T1000 --1000 151 | ,TallyBase T10000 --10000 152 | ,TallyBase T100000 --100000 --Enough for maximum number of partitions 153 | ), 154 | PartitionBaseData AS ( --Get partition data 155 | SELECT 156 | pf.[name] AS PartitionFunctionName 157 | ,pf.function_id AS PartitionFunctionID 158 | ,CASE WHEN boundary_value_on_right = 0 THEN N'LEFT' ELSE 'RIGHT' END AS BoundaryType 159 | ,pf.create_date AS Created 160 | ,pf.modify_date AS Modified 161 | ,p.PartitionID AS PartitionID 162 | ,prv.[value] AS LeftBoundary 163 | ,LEAD(prv.[value]) OVER(ORDER BY p.PartitionID) AS RightBoundary 164 | ,ISNULL ( 165 | CASE ppt.[name] --Format the value for displaying 166 | WHEN N'date' THEN LEFT(CONVERT(varchar(30), CONVERT(date, prv.[value] ), 120), 10) 167 | WHEN N'datetime' THEN CONVERT(varchar(30), CONVERT(datetime, prv.[value] ), 121) 168 | WHEN N'datetime2' THEN CONVERT(varchar(30), CONVERT(datetime2, prv.[value] ), 121) 169 | ELSE CONVERT(varchar(30), prv.[value] ) 170 | END 171 | , N'' 172 | ) AS LeftBoundaryStr 173 | ,ISNULL ( 174 | CASE ppt.[name] --Format the value for displaying 175 | WHEN N'date' THEN CONVERT(varchar(30), LEFT(CONVERT(date, LEAD(prv.[value]) OVER(ORDER BY p.PartitionID)), 121), 10) 176 | WHEN N'datetime' THEN CONVERT(varchar(30), CONVERT(datetime, LEAD(prv.[value]) OVER(ORDER BY p.PartitionID)), 121) 177 | WHEN N'datetime2' THEN CONVERT(varchar(30), CONVERT(datetime2, LEAD(prv.[value]) OVER(ORDER BY p.PartitionID)), 121) 178 | ELSE CONVERT(varchar(30), LEAD(prv.[value]) OVER(ORDER BY p.PartitionID)) 179 | END 180 | , N'' 181 | ) AS RightBoundaryStr 182 | ,ppt.[name] AS ParameterDataType 183 | 184 | FROM sys.partition_functions pf --information about partition function 185 | INNER JOIN sys.partition_parameters pp ON pp.function_id = pf.function_id AND pp.parameter_id = 1 --information about partition function parameter 186 | INNER JOIN sys.types ppt ON ppt.system_type_id = pp.system_type_id --information about the parameter data type 187 | CROSS APPLY [Partitions] p 188 | LEFT JOIN sys.partition_range_values prv ON prv.function_id = pf.function_id AND prv.boundary_id = p.PartitionID - 1 AND prv.parameter_id = 1 189 | WHERE 190 | pf.function_id = @pfID 191 | ) 192 | SELECT 193 | pbd.PartitionFunctionName AS PartitionFunctionName 194 | ,pbd.PartitionFunctionID AS PartitionFunctionID 195 | ,pbd.Created AS Created 196 | ,pbd.Modified AS Modified 197 | ,pbd.ParameterDataType AS ParameterDataType 198 | ,pbd.BoundaryType AS BoundaryType 199 | ,pbd.PartitionID AS PartitionID 200 | ,CASE 201 | WHEN LeftBoundary IS NULL THEN NULL 202 | WHEN BoundaryType = 'RIGHT' THEN 'Y' 203 | ELSE 'N' 204 | END AS LeftBoundaryIncluded 205 | ,CASE 206 | WHEN RightBoundary IS NULL THEN NULL 207 | WHEN BoundaryType = 'RIGHT' THEN N'N' 208 | ELSE N'Y' 209 | END AS RightBoundaryIncluded 210 | ,pbd.LeftBoundary AS LeftBoundary 211 | ,pbd.RightBoundary AS RightBoundary 212 | ,RIGHT(REPLICATE(' ', MAX(LEN(LeftBoundaryStr)) OVER()) 213 | + LeftBoundaryStr, MAX(LEN(LeftBoundaryStr)) OVER()) 214 | + 215 | CASE 216 | WHEN LeftBoundary IS NULL THEN N' ' 217 | WHEN BoundaryType = 'RIGHT' THEN N' <= ' 218 | ELSE N' < ' 219 | END 220 | + N' [x] ' 221 | + 222 | CASE 223 | WHEN RightBoundary IS NULL THEN N' ' 224 | WHEN BoundaryType = 'RIGHT' THEN N' < ' 225 | ELSE N' <= ' 226 | END 227 | + 228 | ISNULL(RightBoundaryStr, N'') AS PartitionRange 229 | FROM PartitionBaseData pbd 230 | ORDER BY pbd.PartitionID 231 | 232 | IF @listDependencies = 1 233 | BEGIN 234 | RAISERROR(N'Retrieving information about depended partition schemes', 0, 0) WITH NOWAIT; 235 | --list depended partition schemes 236 | SELECT 237 | pf.[name] AS PartitionFunctionName 238 | ,ps.[name] AS PartitionSchemeName 239 | ,ps.data_space_id AS PartitionScheme_data_space_id 240 | ,ps.function_id AS PartitionFunctionID 241 | into #PS 242 | FROM sys.partition_schemes ps 243 | INNER JOIN sys.partition_functions pf ON pf.function_id = ps.function_id 244 | WHERE 245 | ps.function_id = @pfID 246 | 247 | IF EXISTS(SELECT 1 FROM #PS) 248 | SELECT * FROM #PS ORDER BY PartitionSchemeName 249 | 250 | RAISERROR(N'Retrieving information about depended objects (Tables and/or Indexed Views)', 0, 0) WITH NOWAIT; 251 | --list depended partitioned tables and partitioned views 252 | SELECT 253 | pf.[name] AS PartitionFunctionName 254 | ,SCHEMA_NAME(o.schema_id) AS SchemaName 255 | ,o.[name] AS ObjectName 256 | ,o.object_id AS ObjectID 257 | ,o.[type] AS ObjectType 258 | ,o.[type_desc] AS ObjectTypeName 259 | ,o.create_date AS Created 260 | ,o.modify_date AS Modified 261 | ,i.[type_desc] AS StorageType 262 | ,ps.[name] AS PartitionSchemeName 263 | ,ps.data_space_id AS PartitionScheme_data_space_id 264 | ,ps.function_id AS PartitionFunctionID 265 | INTO #PT 266 | FROM sys.objects o 267 | INNER JOIN sys.indexes i ON i.object_id = o.object_id AND i.index_id <= 1 268 | INNER JOIN sys.data_spaces ds on ds.data_space_id = i.data_space_id 269 | INNER JOIN sys.partition_schemes ps ON ds.data_space_id = ps.data_space_id 270 | INNER JOIN sys.partition_functions pf ON pf.function_id = ps.function_id 271 | WHERE ps.function_id = @pfID 272 | 273 | IF EXISTS(SELECT 1 FROM #PT) 274 | SELECT * FROM #PT ORDER BY SchemaName, ObjectName 275 | 276 | RAISERROR(N'Retrieving information about depended non clustered indexes', 0, 0) WITH NOWAIT; 277 | --list all nonclustered indexes 278 | SELECT 279 | pf.[name] AS PartitionFunctionName 280 | ,SCHEMA_NAME(o.schema_id) AS SchemaName 281 | ,o.[name] AS ObjectName 282 | ,i.[name] AS IndexName 283 | ,o.object_id AS ObjectID 284 | ,i.index_id AS IndexID 285 | ,i.[type] AS IndexType 286 | ,i.[type_desc] AS IndexTypeName 287 | ,o.[type] AS ObjectType 288 | ,o.[type_desc] AS ObjectTypeName 289 | ,ps.[name] AS PartitionSchemeName 290 | ,ps.data_space_id AS PartitionScheme_data_space_id 291 | ,ps.function_id AS PartitionFunctionID 292 | INTO #PI 293 | FROM sys.objects o 294 | INNER JOIN sys.indexes i ON i.object_id = o.object_id AND i.index_id > 1 295 | INNER JOIN sys.data_spaces ds on ds.data_space_id = i.data_space_id 296 | INNER JOIN sys.partition_schemes ps ON ds.data_space_id = ps.data_space_id 297 | INNER JOIN sys.partition_functions pf ON pf.function_id = ps.function_id 298 | WHERE ps.function_id = @pfID 299 | 300 | IF EXISTS(SELECT 1 FROM #PI) 301 | SELECT * FROM #PI ORDER BY SchemaName, ObjectName, IndexName 302 | 303 | DROP TABLE #PS; 304 | DROP TABLE #PT; 305 | DROP TABLE #PI; 306 | END 307 | RAISERROR(N'', 0, 0) WITH NOWAIT; 308 | END 309 | GO 310 | 311 | --Mark Stored Procedure as system object, so it executes in the context of current database. 312 | IF SERVERPROPERTY('EngineEdition') IN (1, 2, 3, 4, 8) 313 | EXEC(N'EXECUTE sp_ms_marksystemobject ''dbo.sp_HelpPartitionFunction'''); 314 | GO 315 | GO -------------------------------------------------------------------------------- /TablesManagement/Partitioning/sp_HelpPartitionScheme.sql: -------------------------------------------------------------------------------- 1 | /* ***************************************************************************************** 2 | AZURE SQL DB Notice 3 | 4 | Comment-out the unsupported USE [master] when running in Azure SQL DB/Synapse Analytics 5 | or ignore error caused by unsupported USE statement 6 | ******************************************************************************************** */ 7 | USE [master] 8 | GO 9 | 10 | IF NOT EXISTS (SELECT 1 FROM sys.all_objects WHERE object_id = OBJECT_ID('[dbo].[sp_HelpPartitionScheme]') AND TYPE = 'P') 11 | EXECUTE ('CREATE PROCEDURE [dbo].[sp_HelpPartitionScheme] AS BEGIN PRINT ''Container for [dbo].[sp_HelpPartitionScheme] (C) Pavel Pawlowski'' END') 12 | GO 13 | /* ******************************************************* 14 | sp_HelpPartitionScheme v 0.54 (2019-02-19) 15 | 16 | Feedback: mailto:pavel.pawlowski@hotmail.cz 17 | 18 | MIT License 19 | 20 | Copyright (c) 2017 Pavel Pawlowski 21 | 22 | Permission is hereby granted, free of charge, to any person obtaining a copy 23 | of this software and associated documentation files (the "Software"), to deal 24 | in the Software without restriction, including without limitation the rights 25 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 26 | copies of the Software, and to permit persons to whom the Software is 27 | furnished to do so, subject to the following conditions: 28 | 29 | The above copyright notice and this permission notice shall be included in all 30 | copies or substantial portions of the Software. 31 | 32 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 33 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 34 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 35 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 36 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 37 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 38 | SOFTWARE. 39 | 40 | Description: 41 | Provides information about the partition scheme including the partition function it is based on and partition boundary values 42 | Procedure also lists depended tables and indexes using the partition scheme 43 | 44 | 45 | Parameters: 46 | @psName nvarchar(261) = NULL --Name of the partition scheme or partitioned table 47 | ,@listDependencies bit = 0 --Specifies whether list dependencies of the partition scheme 48 | ,@noInfoMsg bit = 0 --Disbles printing of header and informationals messages 49 | 50 | Result table schema: 51 | CREATE TABLE #Results( 52 | [TableName] nvarchar(261) NULL --Name of partitioned table in case table name was provided 53 | ,[TableID] int NULL --ID of the partitioned table in case table name was provided 54 | ,[PartitionColumn] nvarchar(max) NULL --List of partition columns used 55 | ,[PartitionSchemeName] sysname NOT NULL --Partition scheme name 56 | ,[PartitionSchemeID] int NOT NULL --Partition scheme ID 57 | ,[PartitionFunctionName] sysname NOT NULL --Associated partition function name 58 | ,[PartitionFunctionID] int NOT NULL --Associated partition function ID 59 | ,[ParameterDataType] sysname NOT NULL --PF parameter data type 60 | ,[BoundaryType] nvarchar(5) NOT NULL --Partition function boundary type 61 | ,[PartitionID] int NOT NULL --ID of the partition defined by partition function 62 | ,[DestinationFileGroup] sysname NOT NULL --Destination file group of the partition 63 | ,[LeftBoundaryIncluded] char(1) NULL --Specifies whether left boundary value is included in the partition 64 | ,[RightBoundaryIncluded] char(1) NULL --Specifies whether right boundary value is included in the partition 65 | ,[LeftBoundary] sql_variant NULL --Left boundary value 66 | ,[RightBoundary] sql_variant NULL --Right boundary value 67 | ,[PartitionRange] nvarchar(4000) NULL --Partition range in human readable form [NEXT_USED] for next file group used during partition function split 68 | ); 69 | */ 70 | ALTER PROCEDURE [dbo].[sp_HelpPartitionScheme] 71 | @psName nvarchar(261) = NULL --Name of the partition scheme or partitioned table 72 | ,@listDependencies bit = 0 --Specifies whether list dependencies of the partition scheme 73 | ,@noInfoMsg bit = 0 --Disbles printing of header and informationals messages 74 | AS 75 | BEGIN 76 | SET NOCOUNT ON; 77 | DECLARE 78 | @caption nvarchar(max) --Procedure caption 79 | ,@msg nvarchar(max) --message 80 | ,@psID int --ID of partition Scheme 81 | ,@partitionsCount int --count of boundary values 82 | ,@tableObjectID int --ID of the Table Specified 83 | ,@tableName nvarchar(261) --name of the partitioned table 84 | ,@partitionColumnn nvarchar(max) --list of patition columns 85 | 86 | IF @noInfoMsg = 0 87 | BEGIN 88 | SET @caption = N'sp_HelpPartitionScheme v 0.55 (2020-12-03) (C) 2014 - 2020 Pavel Pawlowski' + NCHAR(13) + NCHAR(10) + 89 | N'=========================================================================='; 90 | RAISERROR(@caption, 0, 0) WITH NOWAIT; 91 | END 92 | 93 | --if partition function name is not provided, print Help 94 | IF @psName IS NULL 95 | BEGIN 96 | RAISERROR(N'', 0, 0) WITH NOWAIT; 97 | RAISERROR(N'Provides detailed information about the partition scheme including partitions and their boundary values defined by related partition function..', 0, 0) WITH NOWAIT; 98 | RAISERROR(N'Provides information about depended objects like tables/indexed views/indexes utilizing the partition scheme', 0, 0) WITH NOWAIT; 99 | RAISERROR(N'', 0, 0); 100 | RAISERROR(N'Usage:', 0, 0); 101 | RAISERROR(N'[sp_HelpPartitionScheme] {@psName = ''partition_scheme_name | partitioned_table_name''} [,@listDependencies]', 0, 0); 102 | RAISERROR(N'', 0, 0); 103 | SET @msg = N'Parameters: 104 | @psName nvarchar(261) = NULL - name of the partition scheme or patitioned table for which the information should be returned 105 | ,@listDependencies bit = 1 - Specifies whether list dependencies of the partition scheme'; 106 | RAISERROR(N'', 0, 0); 107 | RAISERROR(N'When partitioned_table_name is provided, then also information about partition columns is returned for the table as firt recordset', 0, 0); 108 | RAISERROR(@msg, 0, 0); 109 | 110 | SET @msg = N' 111 | Table schema to hold results for partition scheme information 112 | ------------------------------------------------------------- 113 | CREATE TABLE #Results( 114 | [TableName] nvarchar(261) NULL --Name of partitioned table in case table name was provided 115 | ,[TableID] int NULL --ID of the partitioned table in case table name was provided 116 | ,[PartitionColumn] nvarchar(max) NULL --List of partition columns used 117 | ,[PartitionSchemeName] sysname NOT NULL --Partition scheme name 118 | ,[PartitionSchemeID] int NOT NULL --Partition scheme ID 119 | ,[PartitionFunctionName] sysname NOT NULL --Associated partition function name 120 | ,[PartitionFunctionID] int NOT NULL --Associated partition function ID 121 | ,[ParameterDataType] sysname NOT NULL --PF parameter data type 122 | ,[BoundaryType] nvarchar(5) NOT NULL --Partition function boundary type 123 | ,[PartitionID] int NOT NULL --ID of the partition defined by partition function 124 | ,[DestinationFileGroup] sysname NOT NULL --Destination file group of the partition 125 | ,[LeftBoundaryIncluded] char(1) NULL --Specifies whether left boundary value is included in the partition 126 | ,[RightBoundaryIncluded] char(1) NULL --Specifies whether right boundary value is included in the partition 127 | ,[LeftBoundary] sql_variant NULL --Left boundary value 128 | ,[RightBoundary] sql_variant NULL --Right boundary value 129 | ,[PartitionRange] nvarchar(4000) NULL --Partition range in human readable form [NEXT_USED] for next file group used during partition function split 130 | );'; 131 | RAISERROR(@msg, 0, 0); 132 | 133 | RETURN 134 | END 135 | 136 | --Try to get ID of the table (in case table name was provided in the @psName) 137 | SELECT 138 | @tableObjectID = object_id 139 | ,@tableName = QUOTENAME(SCHEMA_NAME(t.schema_id)) + N'.' + QUOTENAME(t.name) 140 | FROM sys.tables t 141 | WHERE t.object_id = OBJECT_ID(@psName) 142 | 143 | --Table name was provided in the @psName 144 | IF @tableObjectID IS NOT NULL 145 | BEGIN 146 | --Get table data Space Information (Partition scheme) 147 | SELECT 148 | @psID = ds.data_space_id 149 | ,@psName = ds.name 150 | FROM sys.indexes i 151 | INNER JOIN sys.data_spaces ds ON i.data_space_id = ds.data_space_id 152 | WHERE 153 | i.object_id = @tableObjectID 154 | AND 155 | i.index_id <= 1 156 | AND 157 | ds.type = 'PS' 158 | 159 | IF @psID IS NULL 160 | BEGIN 161 | RAISERROR(N'Table %s is not partitioned', 15, 0, @tableName) WITH NOWAIT; 162 | RETURN; 163 | END 164 | 165 | --Get partition column information 166 | SET @partitionColumnn = 167 | STUFF(( 168 | SELECT 169 | N', ' + QUOTENAME(c.name) 170 | FROM sys.index_columns ic 171 | INNER JOIN sys.columns c ON c.object_id = ic.object_id AND c.column_id = ic.column_id 172 | WHERE 173 | ic.object_id = @tableObjectID 174 | AND 175 | ic.index_id <= 1 176 | AND 177 | ic.partition_ordinal > 0 178 | ORDER BY ic.partition_ordinal 179 | FOR XML PATH(N'')), 1, 2, N'') 180 | 181 | IF @noInfoMsg = 0 182 | RAISERROR(N'Retrieving information for partitioned table "%s"', 0, 0, @psName) WITH NOWAIT; 183 | END 184 | ELSE 185 | BEGIN 186 | --Get ID of partition scheme. 187 | SELECT 188 | @psID = ps.data_space_id 189 | FROM sys.partition_schemes ps 190 | WHERE ps.[name] = @psName 191 | 192 | IF @psID IS NULL 193 | BEGIN 194 | RAISERROR(N'Partition scheme [%s] does not exists', 15, 0, @psName) WITH NOWAIT; 195 | RETURN; 196 | END; 197 | END 198 | 199 | IF @noInfoMsg = 0 200 | RAISERROR(N'Retrieving information for partition scheme [%s]', 0, 0, @psName) WITH NOWAIT; 201 | 202 | --Get partition information 203 | WITH PartitionBaseData AS ( --Get partition data 204 | SELECT 205 | ps.[name] AS PartitionSchemeName 206 | ,pf.[name] AS PartitionFunctionName 207 | ,pf.function_id AS PartitionFunctionID 208 | ,CASE WHEN boundary_value_on_right = 0 THEN N'LEFT' ELSE 'RIGHT' END AS BoundaryType 209 | ,dds.destination_id AS PartitionID 210 | ,prv.[value] AS LeftBoundary 211 | ,LEAD(prv.[value]) OVER(ORDER BY dds.destination_id) AS RightBoundary 212 | ,ISNULL ( 213 | CASE ppt.[name] --Format the value for displaying 214 | WHEN N'date' THEN LEFT(CONVERT(varchar(30), CONVERT(date, prv.[value] ), 120), 10) 215 | WHEN N'datetime' THEN CONVERT(varchar(30), CONVERT(datetime, prv.[value] ), 121) 216 | WHEN N'datetime2' THEN CONVERT(varchar(30), CONVERT(datetime2, prv.[value] ), 121) 217 | ELSE CONVERT(varchar(30), prv.[value] ) 218 | END 219 | , N'' 220 | ) AS LeftBoundaryStr 221 | ,ISNULL ( 222 | CASE ppt.[name] --Format the value for displaying 223 | WHEN N'date' THEN CONVERT(varchar(30), LEFT(CONVERT(date, LEAD(prv.[value]) OVER(ORDER BY dds.destination_id)), 121), 10) 224 | WHEN N'datetime' THEN CONVERT(varchar(30), CONVERT(datetime, LEAD(prv.[value]) OVER(ORDER BY dds.destination_id)), 121) 225 | WHEN N'datetime2' THEN CONVERT(varchar(30), CONVERT(datetime2, LEAD(prv.[value]) OVER(ORDER BY dds.destination_id)), 121) 226 | ELSE CONVERT(varchar(30), LEAD(prv.[value]) OVER(ORDER BY dds.destination_id)) 227 | END 228 | , N'' 229 | ) AS RightBoundaryStr 230 | ,ppt.[name] AS ParameterDataType 231 | ,fg.[name] AS FileGroupName 232 | FROM sys.partition_schemes ps --information about partition scheme 233 | INNER JOIN sys.partition_functions pf ON pf.function_id = ps.function_id --information about partition function 234 | INNER JOIN sys.partition_parameters pp ON pp.function_id = pf.function_id AND pp.parameter_id = 1 --information about partition function parameter 235 | INNER JOIN sys.types ppt ON ppt.system_type_id = pp.system_type_id --information about the parameter data type 236 | INNER JOIN sys.destination_data_spaces dds ON dds.partition_scheme_id = ps.data_space_id --get destination data spaces to get partitions and destination file groups 237 | INNER JOIN sys.filegroups fg on dds.data_space_id = fg.data_space_id --FileGroups to get file group name for the destination data space 238 | LEFT JOIN sys.partition_range_values prv ON prv.function_id = pf.function_id AND prv.boundary_id = dds.destination_id - 1 AND prv.parameter_id = 1 239 | WHERE 240 | ps.data_space_id = @psID 241 | ) 242 | SELECT 243 | @tableName AS TableName 244 | ,@tableObjectID AS TableID 245 | ,@partitionColumnn AS PartitionColumn 246 | ,pbd.PartitionSchemeName AS PartitionSchemeName 247 | ,@psID AS PartitionSchemeID 248 | ,pbd.PartitionFunctionName AS PartitionFunctionName 249 | ,pbd.PartitionFunctionID AS PartitionFunctionID 250 | ,pbd.ParameterDataType AS ParameterDataType 251 | ,pbd.BoundaryType AS BoundaryType 252 | ,pbd.PartitionID AS PartitionID 253 | ,pbd.FileGroupName AS DestinationFileGroup 254 | ,CASE 255 | WHEN LeftBoundary IS NULL THEN NULL 256 | WHEN BoundaryType = 'RIGHT' THEN 'Y' 257 | ELSE 'N' 258 | END AS LeftBoundaryIncluded 259 | ,CASE 260 | WHEN RightBoundary IS NULL THEN NULL 261 | WHEN BoundaryType = 'RIGHT' THEN N'N' 262 | ELSE N'Y' 263 | END AS RightBoundaryIncluded 264 | ,pbd.LeftBoundary AS LeftBoundary 265 | ,pbd.RightBoundary AS RightBoundary 266 | 267 | ,CASE 268 | WHEN pbd.LeftBoundary IS NULL AND pbd.RightBoundary IS NULL THEN '[NEXT_USED]' 269 | ELSE 270 | RIGHT(REPLICATE(' ', MAX(LEN(LeftBoundaryStr)) OVER()) 271 | + LeftBoundaryStr, MAX(LEN(LeftBoundaryStr)) OVER() 272 | ) 273 | + 274 | CASE 275 | WHEN LeftBoundary IS NULL THEN N' ' 276 | WHEN BoundaryType = 'RIGHT' THEN N' <= ' 277 | ELSE N' < ' 278 | END 279 | + N' [x] ' 280 | + 281 | CASE 282 | WHEN RightBoundary IS NULL THEN N' ' 283 | WHEN BoundaryType = 'RIGHT' THEN N' < ' 284 | ELSE N' <= ' 285 | END 286 | + 287 | ISNULL(RightBoundaryStr, N'') 288 | END AS PartitionRange 289 | FROM PartitionBaseData pbd 290 | ORDER BY pbd.PartitionID 291 | 292 | IF @listDependencies = 1 293 | BEGIN 294 | RAISERROR(N'Retrieving information about depended objects (Tables and/or Indexed Views)', 0, 0) WITH NOWAIT; 295 | --list depended partitioned tables and partitioned views 296 | SELECT 297 | ps.name AS PartitionSchemeName 298 | ,SCHEMA_NAME(o.schema_id) AS SchemaName 299 | ,o.[name] AS ObjectName 300 | ,o.object_id AS ObjectID 301 | ,o.[type] AS ObjectType 302 | ,o.[type_desc] AS ObjectTypeName 303 | ,o.create_date AS Created 304 | ,o.modify_date AS Modified 305 | ,i.[type_desc] AS StorageType 306 | INTO #PT 307 | FROM sys.objects o 308 | INNER JOIN sys.indexes i ON i.object_id = o.object_id AND i.index_id <= 1 309 | INNER JOIN sys.data_spaces ds on ds.data_space_id = i.data_space_id 310 | INNER JOIN sys.partition_schemes ps ON ds.data_space_id = ps.data_space_id 311 | WHERE ps.data_space_id = @psID 312 | 313 | IF EXISTS(SELECT 1 FROM #PT) 314 | SELECT * FROM #PT ORDER BY SchemaName, ObjectName 315 | 316 | RAISERROR(N'Retrieving information about depended non clustered indexes', 0, 0) WITH NOWAIT; 317 | --list all non clustered indexes 318 | SELECT 319 | ps.[name] AS PartitionSchemeName 320 | ,SCHEMA_NAME(o.schema_id) AS SchemaName 321 | ,o.[name] AS ObjectName 322 | ,i.[name] AS IndexName 323 | ,o.object_id AS ObjectID 324 | ,i.index_id AS IndexID 325 | ,i.[type] AS IndexType 326 | ,i.[type_desc] AS IndexTypeName 327 | ,o.[type] AS ObjectType 328 | ,o.[type_desc] AS ObjectTypeName 329 | ,ps.data_space_id AS PartitionScheme_data_space_id 330 | INTO #PI 331 | FROM sys.objects o 332 | INNER JOIN sys.indexes i ON i.object_id = o.object_id AND i.index_id > 1 333 | INNER JOIN sys.data_spaces ds on ds.data_space_id = i.data_space_id 334 | INNER JOIN sys.partition_schemes ps ON ds.data_space_id = ps.data_space_id 335 | WHERE ps.data_space_id = @psID 336 | 337 | IF EXISTS(SELECT 1 FROM #PI) 338 | SELECT * FROM #PI ORDER BY SchemaName, ObjectName, IndexName 339 | 340 | DROP TABLE #PT; 341 | DROP TABLE #PI; 342 | END 343 | RAISERROR(N'', 0, 0) WITH NOWAIT; 344 | END 345 | GO 346 | 347 | --Mark Stored Procedure as system object, so it executes in the context of current database. 348 | IF SERVERPROPERTY('EngineEdition') IN (1, 2, 3, 4, 8) 349 | EXEC(N'EXECUTE sp_ms_marksystemobject ''dbo.sp_HelpPartitionScheme'''); 350 | GO 351 | -------------------------------------------------------------------------------- /TablesManagement/Partitioning/sp_tblDropPartition.sql: -------------------------------------------------------------------------------- 1 | /* ***************************************************************************************** 2 | AZURE SQL DB Notice 3 | 4 | Comment-out the unsupported USE [master] when running in Azure SQL DB/Synapse Analytics 5 | or ignore error caused by unsupported USE statement 6 | ******************************************************************************************** */ 7 | --USE [master] 8 | --GO 9 | 10 | --Detection of correct sp_tblSwitchPartition 11 | DECLARE 12 | @minVersion nvarchar(5) = N'0.52' --Defines minimum required version of sp_tblScriptIndexes 13 | ,@definition nvarchar(max) 14 | ,@versionPos int 15 | ,@foundVersion int 16 | ,@minVersionInt int 17 | ,@productVersion nvarchar(128) = CONVERT(nvarchar(128), SERVERPROPERTY ('productversion')) 18 | ,@version nvarchar(5) 19 | ,@msg nvarchar(max) = NULL 20 | 21 | SELECT 22 | @definition = m.definition 23 | FROM sys.procedures p 24 | INNER JOIN .sys.sql_modules m ON m.object_id = p.object_id 25 | WHERE name = 'sp_tblSwitchPartition' 26 | 27 | SELECT 28 | @versionPos = PATINDEX('%sp_tblSwitchPartition v __.__ (%', @definition) 29 | 30 | IF @versionPos IS NOT NULL 31 | BEGIN 32 | BEGIN TRY 33 | SET @minVersionInt = CONVERT(int, REPLACE(@minVersion, N'.', N'')); 34 | SET @version = SUBSTRING(@definition, @versionPos + 24, 5); 35 | SET @foundVersion = CONVERT(int, REPLACE(@version, N'.', N'')); 36 | END TRY 37 | BEGIN CATCH 38 | END CATCH 39 | END 40 | 41 | 42 | IF @definition IS NULL 43 | BEGIN 44 | SET @msg = N'Could not locate [sp_tblSwitchPartition] which is required for [sp_tblDropPartition].'; 45 | END 46 | ELSE IF @versionPos = 0 OR @foundVersion IS NULL 47 | BEGIN 48 | SET @msg = N'Could not determine version of [sp_tblSwitchPartition] which is required for [sp_tblDropPartition].'; 49 | END 50 | ELSE IF @foundVersion < @minVersionInt 51 | BEGIN 52 | SET @msg = N'Minimum required version of [sp_tblSwitchPartition]: %s 53 | Detected version %s' 54 | END 55 | 56 | IF @msg IS NOT NULL 57 | BEGIN 58 | IF CONVERT(int, LEFT(@productVersion, CHARINDEX('.', @productVersion) - 1)) < 13 59 | BEGIN 60 | SET @msg = @msg + N' Please run [sp_tblSwitchPartition] script first. 61 | To get latest version visit: https://github.com/PavelPawlowski/SQL-Scripts/tree/master/TablesManagement/Partitioning' 62 | RAISERROR(@msg, 16, 0, @minVersion, @version) WITH NOWAIT; 63 | RETURN 64 | END 65 | ELSE 66 | BEGIN 67 | SET @msg = @msg + N' 68 | Without [sp_tblSwitchPartition] it will not be possible to use partition switching only default and preffered TRUNCATE. Please run [sp_tblSwitchPartition] script first. 69 | To get latest version visit: https://github.com/PavelPawlowski/SQL-Scripts/tree/master/TablesManagement/Partitioning'; 70 | RAISERROR(@msg, 10, 0, @minVersion, @version) WITH NOWAIT; 71 | END 72 | END 73 | ELSE 74 | BEGIN 75 | RAISERROR(N'Detected version of [sp_tblSwitchPartition]: %s', 0, 0, @version) WITH NOWAIT; 76 | END 77 | 78 | RAISERROR(N'Creating [sp_tblDropPartition]', 0, 0) WITH NOWAIT; 79 | 80 | 81 | IF NOT EXISTS (SELECT 1 FROM sys.all_objects WHERE object_id = OBJECT_ID('[dbo].[sp_tblDropPartition]') AND TYPE = 'P') 82 | EXECUTE ('CREATE PROCEDURE [dbo].[sp_tblDropPartition] AS BEGIN PRINT ''Container'' END') 83 | GO 84 | /* **************************************************** 85 | sp_tblDropPartition v 0.4 (2020-12-04) 86 | 87 | Feedback: mailto:pavel.pawlowski@hotmail.cz 88 | 89 | MIT License 90 | 91 | Copyright (c) 2014-2020 Pavel Pawlowski 92 | 93 | Permission is hereby granted, free of charge, to any person obtaining a copy 94 | of this software and associated documentation files (the "Software"), to deal 95 | in the Software without restriction, including without limitation the rights 96 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 97 | copies of the Software, and to permit persons to whom the Software is 98 | furnished to do so, subject to the following conditions: 99 | 100 | The above copyright notice and this permission notice shall be included in all 101 | copies or substantial portions of the Software. 102 | 103 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 104 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 105 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 106 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 107 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 108 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 109 | SOFTWARE. 110 | 111 | Description: 112 | Drops specified partition by clearting it and merging into adjacent one. 113 | 114 | Parameters: 115 | @tableName nvarchar(261) = NULL --Partitioned table name for partition switching 116 | ,@partitionID int = NULL --Partition to be Switched 117 | ,@partitionValue sql_variant = NULL --Value to be used to determine PartitionID. Can be used instead of @partitionID 118 | ,@stagingTableName nvarchar(261) = NULL --Staging Table Name. If NULL, Staging table name is generated based on the partition number. 119 | --Used for partition switchout. Not needed for SQL Server 2016 and above 120 | ,@useTruncateWhenPossible bit = 1 --Specifies whether on SQL Server 2016 and above to use TRUNCATE WITH PARTITION instead of partition switching 121 | ,@dropStagingTable bit = 1 --Specifies whether drop staging table after partition switching. 122 | * ***************************************************** */ 123 | ALTER PROCEDURE [dbo].[sp_tblDropPartition] 124 | @tableName nvarchar(261) = NULL --Partitioned table name for partition switching 125 | ,@partitionID int = NULL --Partition to be Switched 126 | ,@partitionValue sql_variant = NULL --Value to be used to determine PartitionID. Can be used instead of @partitionID 127 | ,@stagingTableName nvarchar(261) = NULL --Staging Table Name. If NULL, Staging table name is generated based on the partition number. 128 | --Used for partition switchout. Not needed for SQL Server 2016 and above 129 | ,@useTruncateWhenPossible bit = 1 --Specifies whether on SQL Server 2016 and above to use TRUNCATE WITH PARTITION instead of partition switching 130 | ,@dropStagingTable bit = 1 --Specifies whether drop staging table after partition switching. 131 | AS 132 | BEGIN 133 | SET NOCOUNT ON; 134 | SET XACT_ABORT ON; 135 | 136 | RAISERROR(N'sp_tblDropPartition v 0.4 (2020-12-04) (C) 2014 - 2020 Pavel Pawlowski', 0, 0) WITH NOWAIT; 137 | RAISERROR(N'=======================================================================', 0, 0) WITH NOWAIT; 138 | RAISERROR(N'Deletes a parttion from partitioned table by truncating/switching out partition and merging.', 0, 0) WITH NOWAIT; 139 | RAISERROR(N'', 0, 0) WITH NOWAIT; 140 | 141 | DECLARE 142 | @psName nvarchar(128) 143 | ,@productVersion nvarchar(128) = CONVERT(nvarchar(128), SERVERPROPERTY ('productversion')) 144 | ,@tblName nvarchar(261) 145 | ,@boundaryType nvarchar(5) 146 | ,@boundaryValue sql_variant 147 | ,@pfName nvarchar(128) 148 | ,@dataType nvarchar(128) 149 | ,@sql nvarchar(max) 150 | ,@sourcePartitionRange nvarchar(4000) 151 | ,@destinationPartitionRange nvarchar(4000) 152 | ,@destinationPartitionID int 153 | ,@destinationBoundaryValue sql_variant 154 | ,@newPartitionRange nvarchar(4000) 155 | ,@newPartitionID int 156 | ,@printHelp bit = 0 157 | 158 | 159 | --Table To hold partitions information 160 | DECLARE @psInfo TABLE( 161 | [TableName] nvarchar(261) NULL --Name of partitioned table in case table name was provided 162 | ,[TableID] int NULL --ID of the partitioned table in case table name was provided 163 | ,[PartitionColumn] nvarchar(max) NULL --List of partition columns used 164 | ,[PartitionSchemeName] sysname NOT NULL --Partition scheme name 165 | ,[PartitionSchemeID] int NOT NULL --Partition scheme ID 166 | ,[PartitionFunctionName] sysname NOT NULL --Associated partition function name 167 | ,[PartitionFunctionID] int NOT NULL --Associated partition function ID 168 | ,[ParameterDataType] sysname NOT NULL --PF parameter data type 169 | ,[BoundaryType] nvarchar(5) NOT NULL --Partition function boundary type 170 | ,[PartitionID] int NOT NULL --ID of the partition defined by partition function 171 | ,[DestinationFileGroup] sysname NOT NULL --Destination file group of the partition 172 | ,[LeftBoundaryIncluded] char(1) NULL --Specifies whether left boundary value is included in the partition 173 | ,[RightBoundaryIncluded] char(1) NULL --Specifies whether right boundary value is included in the partition 174 | ,[LeftBoundary] sql_variant NULL --Left boundary value 175 | ,[RightBoundary] sql_variant NULL --Right boundary value 176 | ,[PartitionRange] nvarchar(4000) NULL --Partition range in human readable form [NEXT_USED] for next file group used during partition function split 177 | ) 178 | 179 | DECLARE @switchedTable TABLE ( 180 | TableName nvarchar(261) 181 | ,StagingTableName nvarchar(261) 182 | ,PartitionID int 183 | ,SwithOperation char(3) 184 | ) 185 | 186 | IF @tableName IS NULL 187 | BEGIN 188 | SET @printHelp = 1 189 | END 190 | ELSE IF NOT EXISTS (SELECT 1 FROM sys.tables WHERE object_id = OBJECT_ID(@tableName) AND type = 'U') 191 | BEGIN 192 | RAISERROR(N'The user table %s does not exists', 16, 0, @tableName) 193 | SET @printHelp = 1 194 | END 195 | 196 | IF @printHelp = 0 AND (@partitionID IS NULL AND @partitionValue IS NULL) 197 | BEGIN 198 | RAISERROR(N'Either @partitionID or @partitionValue has to be specified', 16, 1) 199 | SET @printHelp = 1 200 | END 201 | 202 | IF @printHelp = 0 AND (@partitionID IS NOT NULL AND @partitionValue IS NOT NULL) 203 | BEGIN 204 | RAISERROR(N'Only one from @partitionID or @partitionValue can be specified', 16, 2) 205 | SET @printHelp = 1 206 | END 207 | 208 | IF @printHelp = 1 209 | BEGIN 210 | RAISERROR(N'Usage:', 0, 0); 211 | RAISERROR(N'[sp_tblDropPartition] <> 212 | ', 0, 0) WITH NOWAIT; 213 | 214 | RAISERROR(N'!!! WARNING !!! !!! WARNING !!! !!! WARNING !!! !!! WARNING !!! !!! WARNING !!!', 0, 0) WITH NOWAIT; 215 | RAISERROR(N'Even the procedure is using @tableName for partition dropping, it merges partitions in Partition Function,', 0, 0) WITH NOWAIT; 216 | RAISERROR(N'thuss affecting all parition schemes and table using corresponding partition function', 0, 0) WITH NOWAIT; 217 | RAISERROR(N'If partition function is used by multiple tables, all tables are affected but', 0, 0) WITH NOWAIT; 218 | RAISERROR(N'partition truncation or switching is done only on the table specified thus on other tables it is very costly operation', 0, 0) WITH NOWAIT; 219 | RAISERROR(N'', 0, 0) WITH NOWAIT; 220 | RAISERROR(N'It is recomended that the partition function is used by single table.', 0, 0) WITH NOWAIT; 221 | 222 | 223 | RAISERROR(N'', 0, 0) WITH NOWAIT; 224 | RAISERROR(N'Parameters: 225 | @tableName nvarchar(261) --Partitioned table name for partition dropping 226 | @partitionID int = NULL --Partition to be dropped 227 | @partitionValue sql_variant = NULL --Value to be used to determine PartitionID. Can be used instead of @partitionID 228 | @stagingTableName nvarchar(261) = NULL --Staging Table Name. If NULL, Staging table name is generated based on the partition number. 229 | --Used for partition switchout. Not needed for SQL Server 2016 and above 230 | @useTruncateWhenPossible bit = 1 --Specifies whether on SQL Server 2016 and above to use TRUNCATE WITH PARTITION instead of partition switching 231 | @dropStagingTable bit = 1 --Specifies whether drop staging table after partition switching. 232 | ', 0, 0) WITH NOWAIT; 233 | 234 | RETURN 235 | END 236 | 237 | SELECT --Get Partition Scheme of the table 238 | @psName = ds.name 239 | ,@tblName = QUOTENAME(SCHEMA_NAME(t.schema_id)) + N'.' + QUOTENAME(t.name) 240 | FROM sys.tables t 241 | INNER JOIN sys.indexes i ON i.object_id = t.object_id AND i.index_id <= 1 242 | INNER JOIN sys.data_spaces ds ON i.data_space_id = ds.data_space_id 243 | WHERE 244 | t.object_id = OBJECT_ID(@tableName) 245 | AND 246 | ds.type = 'PS' 247 | 248 | IF @psName IS NULL --Check whether table is partitioned 249 | BEGIN 250 | RAISERROR(N'Table %s is not partitioned table. Dropping partitions is only possible on partitioned tables', 16, 4, @tableName) 251 | RETURN 252 | END 253 | 254 | --Get scheme paritions and boundaries 255 | INSERT INTO @psInfo 256 | EXEC sp_HelpPartitionScheme 257 | @psName = @psName 258 | ,@noInfoMsg = 1 259 | 260 | IF @partitionID IS NULL 261 | BEGIN 262 | SELECT 263 | @partitionID = psi.PartitionID 264 | FROM @psInfo psi 265 | WHERE 266 | (psi.BoundaryType = N'RIGHT' AND (psi.LeftBoundary IS NULL OR psi.LeftBoundary <= @partitionValue) AND (psi.RightBoundary IS NULL OR psi.RightBoundary > @partitionValue)) 267 | OR 268 | (psi.BoundaryType = N'LEFT' AND (psi.LeftBoundary IS NULL OR psi.LeftBoundary < @partitionValue) AND (psi.RightBoundary IS NULL OR psi.RightBoundary >= @partitionValue)) 269 | 270 | IF @partitionID IS NULL 271 | BEGIN 272 | RAISERROR(N'Could not determine PartitionID based on @partitionValue', 16, 5); 273 | RETURN; 274 | END 275 | END 276 | 277 | --Get Partition Function name and Boundary information 278 | SELECT 279 | @pfName = p.PartitionFunctionName 280 | ,@boundaryValue = CASE WHEN p.BoundaryType = 'RIGHT' THEN p.LeftBoundary ELSE p.RightBoundary END 281 | ,@dataType = p.ParameterDataType 282 | ,@sourcePartitionRange = LTRIM(RTRIM(p.PartitionRange)) 283 | ,@boundaryType = BoundaryType 284 | FROM @psInfo p 285 | WHERE 286 | p.PartitionID = @partitionID 287 | 288 | IF @boundaryValue IS NULL 289 | BEGIN 290 | IF @boundaryType = 'RIGHT' 291 | RAISERROR(N'Partition boundary type is RIGHT and left most partition was selected. Could not merge partition', 16, 6); 292 | ELSE 293 | RAISERROR(N'Partition boundary type is LEFT and right most partition was selected. Could not merge partition', 16, 6); 294 | RETURN; 295 | END 296 | 297 | SET @destinationPartitionID = @partitionID + CASE WHEN @boundaryType = 'RIGHT' THEN -1 ELSE 1 END; 298 | 299 | SELECT 300 | @destinationBoundaryValue = CASE WHEN p.BoundaryType = 'RIGHT' THEN p.LeftBoundary ELSE p.RightBoundary END 301 | ,@destinationPartitionRange = LTRIM(RTRIM(p.PartitionRange)) 302 | FROM @psInfo p 303 | WHERE 304 | PartitionID = @destinationPartitionID 305 | 306 | 307 | --If Partition truncation should be used, use it on SQL Sever 2016 and above 308 | IF CONVERT(int, LEFT(@productVersion, CHARINDEX('.', @productVersion) - 1)) >= 13 AND @useTruncateWhenPossible = 1 309 | BEGIN 310 | RAISERROR(N'Truncating partition (%d) in table %s', 0, 0, @partitionID, @tblName) WITH NOWAIT; 311 | SET @sql = 'TRUNCATE TABLE ' + @tblName + N'WITH (PARTITIONS (' + CONVERT(nvarchar(10), @partitionID) + N'))'; 312 | EXEC (@sql) 313 | END 314 | ELSE --Utilize partition switching to empty partition 315 | BEGIN 316 | EXEC [sp_tblSwitchPartition] 317 | @tableName = @tblName 318 | ,@partitionID = @partitionID 319 | ,@switchOperation = 'OUT' 320 | ,@stagingTableName = @stagingTableName OUTPUT 321 | ,@outputScriptOnly = 0 322 | ,@noInfoMsg = 1 323 | 324 | --Drop staging table if we should drop it 325 | IF @dropStagingTable = 1 326 | BEGIN 327 | RAISERROR(N'Dropping staging table %s', 0, 0, @stagingTableName) WITH NOWAIT; 328 | SET @sql = N'DROP TABLE ' + @stagingTableName; 329 | EXEC (@sql) 330 | END 331 | END 332 | 333 | RAISERROR(N'Merging partition [%d] with range (%s) into partition [%d] with original range (%s)', 0, 0, @partitionID, @sourcePartitionRange, @destinationPartitionID, @destinationPartitionRange) WITH NOWAIT; 334 | 335 | SET @sql = N'DECLARE @rangeTyped ' + QUOTENAME(@dataType) + N' = CONVERT(' + QUOTENAME(@dataType) + N', @range); ALTER PARTITION FUNCTION ' + QUOTENAME(@pfName) + N' () MERGE RANGE (@rangeTyped)'; 336 | 337 | --PRINT @sql; 338 | EXEC sp_executesql @sql, N'@range sql_variant', @range = @boundaryValue 339 | 340 | DELETE FROM @psInfo; 341 | 342 | INSERT INTO @psInfo 343 | EXEC sp_HelpPartitionScheme 344 | @psName = @psName 345 | ,@noInfoMsg = 1 346 | 347 | SET @newPartitionID = @partitionID + CASE WHEN @boundaryType = 'RIGHT' THEN -1 ELSE 0 END; 348 | 349 | SELECT 350 | @newPartitionRange = LTRIM(RTRIM(PartitionRange)) 351 | FROM @psInfo 352 | WHERE 353 | PartitionID = @newPartitionID 354 | 355 | RAISERROR(N'Partition [%d] successfully merged into partition [%d]. New PartitionID = [%d] with new Range: (%s)', 0, 0, @partitionID, @destinationPartitionID, @newPartitionID, @newPartitionRange) WITH NOWAIT; 356 | 357 | END 358 | GO 359 | 360 | --Mark Stored Procedure as system object, so it executes in the context of current database. 361 | IF SERVERPROPERTY('EngineEdition') IN (1, 2, 3, 4, 8) 362 | EXEC(N'EXECUTE sp_ms_marksystemobject ''dbo.sp_tblDropPartition'''); 363 | GO 364 | -------------------------------------------------------------------------------- /msdb/sp_ScheduleStatus.sql: -------------------------------------------------------------------------------- 1 | USE [msdb] 2 | IF NOT EXISTS(SELECT * FROM sys.procedures WHERE object_id = OBJECT_ID('[dbo].[sp_ScheduleStatus]')) 3 | EXEC (N'CREATE PROCEDURE [dbo].[sp_ScheduleStatus] AS PRINT ''Placeholder for [dbo].[sp_ScheduleStatus]''') 4 | GO 5 | /* **************************************************** 6 | sp_ScheduleStatus v 0.20 (2019-07-23) 7 | 8 | Feedback: mailto:pavel.pawlowski@hotmail.cz 9 | 10 | MIT License 11 | 12 | Copyright (c) 2017 Pavel Pawlowski 13 | 14 | Permission is hereby granted, free of charge, to any person obtaining a copy 15 | of this software and associated documentation files (the "Software"), to deal 16 | in the Software without restriction, including without limitation the rights 17 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 18 | copies of the Software, and to permit persons to whom the Software is 19 | furnished to do so, subject to the following conditions: 20 | 21 | The above copyright notice and this permission notice shall be included in all 22 | copies or substantial portions of the Software. 23 | 24 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 25 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 26 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 27 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 28 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 29 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 30 | SOFTWARE. 31 | 32 | Description: 33 | Generates script for enabling or disabling job schedules 34 | 35 | Parameters: 36 | @filter nvarchar(max) = NULL --Comma separated list of LIKE filter to limit schedules. When not provided all schedules are scripted 37 | ,@status bit = 1 --Status of the schedule to be printed. 1 = Enabled, 0 - Disabled, NULL = both disable and enabled 38 | ,@job nvarchar(max) = NULL --Comma separated list of LIKE filter to limit schedules by job names 39 | ,@category nvarchar(max) = NULL --Comma separated list of LIKE filter to limit schedules by job categories 40 | ,@scriptName bit = 0 --Specifes whether Name should be scripted instead of schedule_id. Default 0 = schedule_id is used 41 | ******************************************************* */ 42 | ALTER PROCEDURE [dbo].[sp_ScheduleStatus] 43 | @filter nvarchar(max) = NULL --Comma separated list of LIKE filter to limit schedules. When not provided all schedules are scripted 44 | ,@status bit = 1 --Status of the schedule to be printed. 1 = Enabled, 0 - Disabled, NULL = both disable and enabled 45 | ,@job nvarchar(max) = NULL --Comma separated list of LIKE filter to limit schedules by job names 46 | ,@category nvarchar(max) = NULL --Comma separated list of LIKE filter to limit schedules by job categories 47 | ,@scriptName bit = 0 --Specifes whether Name should be scripted instead of schedule_id. Default 0 = schedule_id is used 48 | AS 49 | SET NOCOUNT ON; 50 | DECLARE 51 | @schedule_id int 52 | ,@name nvarchar(128) 53 | ,@msg nvarchar(max) 54 | ,@xml xml 55 | 56 | 57 | DECLARE @categories TABLE ( 58 | category_id INT NOT NULL PRIMARY KEY CLUSTERED 59 | ) 60 | 61 | DECLARE @jobSchedules TABLE ( 62 | schedule_id int NOT NULL PRIMARY KEY CLUSTERED 63 | ); 64 | 65 | DECLARE @schedules TABLE ( 66 | schedule_id int NOT NULL PRIMARY KEY CLUSTERED 67 | ,name nvarchar(128) 68 | ) 69 | 70 | RAISERROR(N'--sp_ScheduleStatus v0.20 (2019-07-23) (c) 2017-2019 Pavel Pawlowski', 0, 0) WITH NOWAIT; 71 | RAISERROR(N'--==================================================================', 0, 0) WITH NOWAIT; 72 | RAISERROR(N'--sp_ScheduleStatus Generates script for enabling or disabling job schedules', 0, 0) WITH NOWAIT; 73 | RAISERROR(N'', 0, 0) WITH NOWAIT; 74 | 75 | IF @filter = N'?' 76 | BEGIN 77 | RAISERROR(N' 78 | Usage: sp_ScheduleStatus [parameters] 79 | 80 | Params: 81 | @filter nvarchar(max) = NULL - Comma separated list of LIKE filter to limit schedules. When not provided all schedules are printed. 82 | filter prefixed by [-] removes schedules from selection 83 | ,@status bit = 1 - Status of the schedules to be printed. 1 = Enabled, 0 - Disabled, NULL = both disabled and enabled 84 | ,@job nvarchar(max) = NULL - Comma separated list of LIKE filter to limit schedules by job names. 85 | If provided then only schedules for jobs with matching names are scripted 86 | ,@category nvarchar(max) = NULL - Comma separated list of LIKE filter to limit schedules by job categories. 87 | If provided then only schedules for jobs from matching job categories are scripted 88 | ,@scriptName bit = 0 - Specifes whether Name should be scripted instead of schedule_id. Default 0 = schedule_id is used 89 | 90 | @filter, @status, @job and @category are combined with AND when provided together. 91 | ', 0, 0) WITH NOWAIT; 92 | RETURN; 93 | END 94 | ELSE 95 | BEGIN 96 | RAISERROR(N'--sp_ScheduleStatus ''?'' for help 97 | ', 0, 0) WITH NOWAIT; 98 | END 99 | 100 | IF @job IS NOT NULL OR @category IS NOT NULL 101 | BEGIN 102 | IF @category IS NOT NULL 103 | BEGIN 104 | SET @xml = N'' + REPLACE(ISNULL(@category, N'%'), N',', N'') + N''; 105 | WITH CategoryNames AS ( 106 | SELECT DISTINCT 107 | LTRIM(RTRIM(n.value('.', 'nvarchar(128)'))) AS Categoryname 108 | FROM @xml.nodes('/i') T(n) 109 | ) 110 | INSERT INTO @categories(category_id) 111 | SELECT DISTINCT 112 | c.category_id 113 | FROM msdb.dbo.syscategories c 114 | INNER JOIN CategoryNames cn ON c.name LIKE cn.Categoryname AND LEFT(cn.Categoryname, 1) <> '-' 115 | EXCEPT 116 | SELECT DISTINCT 117 | c.category_id 118 | FROM msdb.dbo.syscategories c 119 | INNER JOIN CategoryNames cn ON c.name LIKE RIGHT(cn.Categoryname, LEN(cn.Categoryname) - 1) AND LEFT(cn.Categoryname, 1) = '-' 120 | END 121 | 122 | SET @xml = N'' + REPLACE(ISNULL(@job, N'%'), N',', N'') + N''; 123 | 124 | WITH JobNames AS ( 125 | SELECT DISTINCT 126 | LTRIM(RTRIM(n.value('.', 'nvarchar(128)'))) AS JobName 127 | FROM @xml.nodes('/i') T(n) 128 | ),JobsBase AS ( 129 | SELECT DISTINCT 130 | job_id 131 | ,category_id 132 | FROM msdb.dbo.sysjobs j 133 | INNER JOIN JobNames jn ON j.name LIKE jn.JobName AND LEFT(jn.JobName, 1) <> '-' 134 | EXCEPT 135 | SELECT DISTINCT 136 | job_id 137 | ,category_id 138 | FROM msdb.dbo.sysjobs j 139 | INNER JOIN JobNames jn ON j.name LIKE RIGHT(jn.JobName, LEN(jn.JobName) - 1) AND LEFT(jn.JobName, 1) = '-' 140 | ), Jobs AS( 141 | SELECT 142 | job_id 143 | FROM JobsBase j 144 | WHERE 145 | @category IS NULL OR EXISTS(SELECT 1 FROM @categories c WHERE c.category_id = j.category_id) 146 | ) 147 | INSERT INTO @jobSchedules(schedule_id) 148 | SELECT DISTINCT 149 | js.schedule_id 150 | FROM msdb.dbo.sysjobschedules js 151 | INNER JOIN jobs j ON j.job_id = js.job_id 152 | END 153 | 154 | 155 | SET @filter = ISNULL(NULLIF(@filter, N''), N'%'); 156 | SET @xml = N'' + REPLACE(@filter, N',', N'') + N''; 157 | 158 | 159 | WITH Schedules AS ( 160 | SELECT DISTINCT 161 | schedule_id 162 | ,name 163 | FROM msdb.dbo.sysschedules s 164 | INNER JOIN (SELECT LTRIM(RTRIM(n.value('.', 'nvarchar(128)'))) FROM @xml.nodes('/i') T(n)) F(n) ON s.name LIKE F.n 165 | WHERE 166 | enabled = @status OR @status IS NULL 167 | AND 168 | LEFT(F.n, 1) <> '-' 169 | EXCEPT 170 | SELECT 171 | schedule_id 172 | ,name 173 | FROM msdb.dbo.sysschedules s 174 | INNER JOIN (SELECT LTRIM(RTRIM(n.value('.', 'nvarchar(128)'))) FROM @xml.nodes('/i') T(n)) F(n) ON s.name LIKE RIGHT(F.n, LEN(F.n) - 1) AND LEFT(F.n, 1) = '-' 175 | WHERE 176 | enabled = @status OR @status IS NULL 177 | AND 178 | LEFT(F.n, 1) = '-' 179 | ) 180 | INSERT INTO @schedules(schedule_id, name) 181 | SELECT 182 | schedule_id 183 | ,name 184 | FROM Schedules s 185 | WHERE 186 | (@job IS NULL AND @category IS NULL) OR EXISTS(SELECT 1 FROM @jobSchedules js WHERE js.schedule_id = s.schedule_id) 187 | 188 | 189 | IF NOT EXISTS(SELECT 1 FROM @schedules) 190 | BEGIN 191 | RAISERROR(N'No job schedules matching provided criteria exists', 15, 0) WITH NOWAIT; 192 | RETURN; 193 | END 194 | 195 | SET @msg ='DECLARE @enabled bit = ' + CASE WHEN @status = 0 THEN N'0' ELSE N'1' END + N' --Specify status to set: 1 = Enabled, 0 = Disabled' 196 | RAISERROR(@msg, 0, 0) WITH NOWAIT; 197 | 198 | RAISERROR(N'', 0,0) WITH NOWAIT; 199 | RAISERROR(N'DECLARE @status nvarchar(10) = CASE WHEN @enabled = 0 THEN N''Disabling'' ELSE N''Enabling'' END', 0,0) WITH NOWAIT; 200 | 201 | 202 | DECLARE cr CURSOR FAST_FORWARD FOR 203 | SELECT 204 | schedule_id 205 | ,name 206 | FROM @schedules 207 | 208 | OPEN cr; 209 | 210 | RAISERROR(N'', 0,0) WITH NOWAIT; 211 | 212 | FETCH NEXT FROM cr INTO @schedule_id, @name 213 | 214 | WHILE @@FETCH_STATUS = 0 215 | BEGIN 216 | RAISERROR(N'-- [%s] (%d)', 0, 0, @name, @schedule_id) WITH NOWAIT; 217 | RAISERROR(N'RAISERROR(N''%%s schedule [%s] (%d)'', 0, 0, @status) WITH NOWAIT;', 0, 0, @name, @schedule_id) WITH NOWAIT; 218 | IF @scriptName = 1 219 | RAISERROR(N'EXEC msdb.dbo.sp_update_schedule @name=''%s'', @enabled = @enabled', 0, 0, @name) WITH NOWAIT; 220 | ELSE 221 | RAISERROR(N'EXEC msdb.dbo.sp_update_schedule @schedule_id=%d, @enabled = @enabled', 0, 0, @schedule_id) WITH NOWAIT; 222 | FETCH NEXT FROM cr INTO @schedule_id, @name 223 | END 224 | 225 | 226 | CLOSE cr; 227 | DEALLOCATE cr; 228 | GO -------------------------------------------------------------------------------- /msdb/sp_jobstatus.sql: -------------------------------------------------------------------------------- 1 | USE [msdb] 2 | IF NOT EXISTS(SELECT * FROM sys.procedures WHERE object_id = OBJECT_ID('[dbo].[sp_JobStatus]')) 3 | EXEC (N'CREATE PROCEDURE [dbo].[sp_JobStatus] AS PRINT ''Placeholder for [dbo].[sp_JobStatus]''') 4 | GO 5 | /* **************************************************** 6 | sp_JobStatus v 0.30 (2019-07-23) 7 | 8 | Feedback: mailto:pavel.pawlowski@hotmail.cz 9 | 10 | MIT License 11 | 12 | Copyright (c) 2017 Pavel Pawlowski 13 | 14 | Permission is hereby granted, free of charge, to any person obtaining a copy 15 | of this software and associated documentation files (the "Software"), to deal 16 | in the Software without restriction, including without limitation the rights 17 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 18 | copies of the Software, and to permit persons to whom the Software is 19 | furnished to do so, subject to the following conditions: 20 | 21 | The above copyright notice and this permission notice shall be included in all 22 | copies or substantial portions of the Software. 23 | 24 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 25 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 26 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 27 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 28 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 29 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 30 | SOFTWARE. 31 | 32 | Description: 33 | Generates script for enabling or disabling jbos 34 | 35 | Parameters: 36 | @filter nvarchar(max) = NULL --Comma separated list of LIKE filter to limit jobs. When not provided all jobs are printed 37 | ,@status bit = 1 --Status of the jobs to be printed. 1 = Enabled, 0 - Disabled, NULL = both disable and enabled 38 | ,@category nvarchar(max) = NULL --Comma separated list of LIKE filter to limit schedules by job categories 39 | ,@scriptName bit = 0 --Specifes whether Name should be scripted instead of job_id. Default 0 = job_id is used 40 | ******************************************************* */ 41 | ALTER PROCEDURE [dbo].[sp_JobStatus] 42 | @filter nvarchar(max) = NULL --Comma separated list of LIKE filter to limit jobs. When not provided all jobs are printed 43 | ,@status bit = 1 --Status of the jobs to be printed. 1 = Enabled, 0 - Disabled, NULL = both disable and enabled 44 | ,@category nvarchar(max) = NULL --Comma separated list of LIKE filter to limit schedules by job categories 45 | ,@scriptName bit = 0 --Specifes whether Name should be scripted instead of job_id. Default 0 = job_id is used 46 | AS 47 | SET NOCOUNT ON; 48 | DECLARE 49 | @job_id uniqueidentifier 50 | ,@name nvarchar(128) 51 | ,@msg nvarchar(max) 52 | ,@job_id_str nvarchar(50) 53 | ,@xml xml 54 | 55 | DECLARE @categories TABLE ( 56 | category_id INT NOT NULL PRIMARY KEY CLUSTERED 57 | ) 58 | 59 | DECLARE @jobs TABLE ( 60 | job_id uniqueidentifier NOT NULL PRIMARY KEY CLUSTERED 61 | ,name nvarchar(128) 62 | ) 63 | 64 | RAISERROR(N'--sp_JobStatus v0.30 (2019-07-23) (c) 2017-2019 Pavel Pawlowski', 0, 0) WITH NOWAIT; 65 | RAISERROR(N'--=============================================================', 0, 0) WITH NOWAIT; 66 | RAISERROR(N'--sp_JobStatus Generates script for enabling or disabling jobs', 0, 0) WITH NOWAIT; 67 | RAISERROR(N'', 0, 0) WITH NOWAIT; 68 | 69 | IF @filter = N'?' 70 | BEGIN 71 | RAISERROR(N' 72 | Usage: sp_JobStatus [parameters] 73 | 74 | Params: 75 | @filter nvarchar(max) = NULL - Comma separated list of LIKE filter to limit jobs. When not provided all jobs are printed. 76 | filter prefixed by [-] removes jobs from selection 77 | ,@status bit = 1 - Status of the jobs to be printed. 1 = Enabled, 0 - Disabled, NULL = both disable and enabled 78 | ,@category nvarchar(max) = NULL - Comma separated list of LIKE filter to limit schedules by job categories. 79 | If provided then only jobs from matching job categories are scripted. 80 | ,@scriptName bit = 0 - Specifes whether Name should be scripted instead of job_id. Default 0 = job_id is used 81 | 82 | @filter, @status and @category are combined with AND when provided together. 83 | 84 | ', 0, 0) WITH NOWAIT; 85 | RETURN; 86 | END 87 | ELSE 88 | BEGIN 89 | RAISERROR(N'--sp_jobstatus ''?'' for help 90 | ', 0, 0) WITH NOWAIT; 91 | END 92 | 93 | IF @category IS NOT NULL 94 | BEGIN 95 | IF @category IS NOT NULL 96 | BEGIN 97 | SET @xml = N'' + REPLACE(ISNULL(@category, N'%'), N',', N'') + N''; 98 | WITH CategoryNames AS ( 99 | SELECT DISTINCT 100 | LTRIM(RTRIM(n.value('.', 'nvarchar(128)'))) AS Categoryname 101 | FROM @xml.nodes('/i') T(n) 102 | ) 103 | INSERT INTO @categories(category_id) 104 | SELECT DISTINCT 105 | c.category_id 106 | FROM msdb.dbo.syscategories c 107 | INNER JOIN CategoryNames cn ON c.name LIKE cn.Categoryname AND LEFT(cn.Categoryname, 1) <> '-' 108 | EXCEPT 109 | SELECT DISTINCT 110 | c.category_id 111 | FROM msdb.dbo.syscategories c 112 | INNER JOIN CategoryNames cn ON c.name LIKE RIGHT(cn.Categoryname, LEN(cn.Categoryname) - 1) AND LEFT(cn.Categoryname, 1) = '-' 113 | END 114 | END 115 | 116 | SET @filter = ISNULL(NULLIF(@filter, N''), N'%'); 117 | SET @xml = N'' + REPLACE(@filter, N',', N'') + N''; 118 | 119 | WITH Jobs AS ( 120 | SELECT DISTINCT 121 | job_id 122 | ,name 123 | ,category_id 124 | FROM msdb.dbo.sysjobs j 125 | INNER JOIN (SELECT LTRIM(RTRIM(n.value('.', 'nvarchar(128)'))) FROM @xml.nodes('/i') T(n)) F(n) ON j.name LIKE F.n 126 | WHERE 127 | enabled = @status OR @status IS NULL 128 | AND 129 | LEFT(F.n, 1) <> '-' 130 | EXCEPT 131 | SELECT 132 | job_id 133 | ,name 134 | ,category_id 135 | FROM msdb.dbo.sysjobs j 136 | INNER JOIN (SELECT LTRIM(RTRIM(n.value('.', 'nvarchar(128)'))) FROM @xml.nodes('/i') T(n)) F(n) ON j.name LIKE RIGHT(F.n, LEN(F.n) - 1) AND LEFT(F.n, 1) = '-' 137 | WHERE 138 | enabled = @status OR @status IS NULL 139 | AND 140 | LEFT(F.n, 1) = '-' 141 | ) 142 | INSERT INTO @jobs(job_id, name) 143 | SELECT 144 | job_id 145 | ,name 146 | FROM Jobs j 147 | WHERE 148 | @category IS NULL OR EXISTS(SELECT 1 FROM @categories c WHERE c.category_id = j.category_id) 149 | 150 | 151 | IF NOT EXISTS(SELECT 1 FROM @jobs) 152 | BEGIN 153 | RAISERROR(N'No jobs matching provided criteria exists', 15, 0) WITH NOWAIT; 154 | RETURN; 155 | END 156 | 157 | SET @msg ='DECLARE @enabled bit = ' + CASE WHEN @status = 0 THEN N'0' ELSE N'1' END + N' --Specify status to set: 1 = Enabled, 0 = Disabled' 158 | RAISERROR(@msg, 0, 0) WITH NOWAIT; 159 | 160 | RAISERROR(N'', 0,0) WITH NOWAIT; 161 | RAISERROR(N'DECLARE @status nvarchar(10) = CASE WHEN @enabled = 0 THEN N''Disabling'' ELSE N''Enabling'' END', 0,0) WITH NOWAIT; 162 | 163 | 164 | DECLARE cr CURSOR FAST_FORWARD FOR 165 | SELECT 166 | job_id 167 | ,name 168 | FROM @jobs 169 | 170 | OPEN cr; 171 | 172 | RAISERROR(N'', 0,0) WITH NOWAIT; 173 | 174 | FETCH NEXT FROM cr INTO @job_id, @name 175 | 176 | WHILE @@FETCH_STATUS = 0 177 | BEGIN 178 | SET @job_id_str = CONVERT(nvarchar(50), @job_id); 179 | RAISERROR(N'RAISERROR(N''%%s job [%s] (%s)'', 0, 0, @status) WITH NOWAIT;', 0, 0, @name, @job_id_str) WITH NOWAIT; 180 | IF @scriptName = 1 181 | RAISERROR(N'EXEC msdb.dbo.sp_update_job @job_name=N''%s'', @enabled = @enabled', 0, 0, @name) WITH NOWAIT; 182 | ELSE 183 | RAISERROR(N'EXEC msdb.dbo.sp_update_job @job_id=N''%s'', @enabled = @enabled', 0, 0, @job_id_str) WITH NOWAIT; 184 | FETCH NEXT FROM cr INTO @job_id, @name 185 | END 186 | 187 | 188 | CLOSE cr; 189 | DEALLOCATE cr; 190 | GO 191 | --------------------------------------------------------------------------------