├── FindTableColumnDataMatches.sql ├── README.markdown ├── TSQLUnitHelpers.sql ├── TSQLUnitIntroductionTests.sql ├── Timings.sql ├── spu_compareprocedures.sql ├── spu_generateInsert.sql └── spu_scriptprocedures.sql /FindTableColumnDataMatches.sql: -------------------------------------------------------------------------------- 1 | IF EXISTS (SELECT * FROM sysobjects WHERE type = 'P' AND name = 'FindTableColumnDataMatches') 2 | BEGIN 3 | DROP Procedure FindTableColumnDataMatches 4 | END 5 | 6 | GO 7 | 8 | SET ANSI_NULLS ON 9 | GO 10 | SET QUOTED_IDENTIFIER ON 11 | GO 12 | 13 | CREATE PROCEDURE [dbo].[FindTableColumnDataMatches] 14 | ( @strSearchTerm AS VARCHAR(1000) ) 15 | AS 16 | 17 | /******************************************************************* 18 | Author: Jane Dallaway 19 | Updates at: https://github.com/janedallaway/SQL-Server-Helper-Scripts 20 | Documentation at: https://github.com/janedallaway/SQL-Server-Helper-Scripts 21 | Date Created: January 24th 2008 22 | Description: This procedure searches for @strSearchTerm amongst all text, ntext, 23 | varchar, nvarchar, char and nchar columns in all tables. If this is run against 24 | a large database it will take a long time to complete 25 | 26 | Modified: add a comment here (date, who, comment) 27 | 28 | Date Author Description 29 | ~~~~~~~ ~~~~~ ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~ 30 | 31 | Usage: 32 | exec FindTableColumnDataMatches @strSearchTerm ='users' 33 | 34 | 35 | *******************************************************************/ 36 | 37 | SET NOCOUNT ON 38 | 39 | -- Variables 40 | DECLARE @tabSearchableColumns TABLE (TableName VARCHAR(100), ColumnName VARCHAR(100), Matches int) 41 | DECLARE @intCount INT 42 | DECLARE @intDataCount INT 43 | DECLARE @strTableName VARCHAR(100) 44 | DECLARE @strColumnName VARCHAR(100) 45 | DECLARE @strSQL NVARCHAR(1000) -- This must be an nvarchar to allow the sql to be passed in to sp_executesql 46 | 47 | -- Produce a list of columns (with their tablenames) 48 | INSERT INTO @tabSearchableColumns 49 | SELECT TABLE_NAME,COLUMN_NAME, NULL 50 | FROM INFORMATION_SCHEMA.COLUMNS 51 | WHERE DATA_TYPE IN ('varchar', 'nvarchar', 'text', 'ntext', 'char', 'nchar') 52 | 53 | -- Get the number of possible places 54 | SELECT @intCount = COUNT(*) 55 | FROM @tabSearchableColumns 56 | WHERE Matches IS NULL 57 | 58 | -- Whilst there is still data to complete 59 | WHILE @intCount > 0 60 | BEGIN 61 | 62 | -- Get the top entry to work on now 63 | SELECT TOP 1 @strTableName = TableName, @strColumnName = ColumnName 64 | FROM @tabSearchableColumns 65 | WHERE Matches IS NULL 66 | ORDER BY TableName, ColumnName 67 | 68 | -- Build up the dynamic SQL statement 69 | SET @strSQL = 'SELECT @intDataCount = COUNT(*) FROM ' + @strTableName + ' WHERE ' + @strColumnName + ' LIKE ''%' + @strSearchTerm + '%''' 70 | 71 | -- Use sp_executesql to allow the variable to be returned out from the dynamic sql 72 | EXEC sp_executesql @strSQL, N'@intDataCount INT OUTPUT', @intDataCount OUTPUT 73 | 74 | -- Update the working set, to store the matches returned from the dynamic SQL 75 | UPDATE @tabSearchableColumns 76 | SET Matches = @intDataCount 77 | WHERE TableName = @strTableName 78 | AND ColumnName = @strColumnName 79 | 80 | -- Reset the counter 81 | SELECT @intCount = COUNT(*) 82 | FROM @tabSearchableColumns 83 | WHERE Matches IS NULL 84 | 85 | END 86 | 87 | -- Display the results 88 | SELECT TableName, ColumnName, Matches 89 | FROM @tabSearchableColumns 90 | WHERE Matches > 0 91 | 92 | RETURN(0) 93 | GO 94 | -------------------------------------------------------------------------------- /README.markdown: -------------------------------------------------------------------------------- 1 | # SQL Server Helper Scripts 2 | 3 | These are a collection of SQL Scripts that I've written over the years, and have offered via blog posts, or google docs to anyone who was interested. It seemed to make sense to finally move them to a proper repository so that anyone who wishes to make use of them, can. 4 | 5 | The scripts are: 6 | 7 | 1. spu_generateInsert.sql - a stored procedure to generate insert statements out of data in a table. The history of this procedure can be found via [my blog posts about it](http://jane.dallaway.com/?sort=&search=spu_generateInsert.sql). 8 | 9 | 2. spu_scriptprocedures.sql - a simple stored procedure which builds up a defensive SQL script for one or many stored procedures. Notes can be found [at this blog post](http://jane.dallaway.com/scripting-stored-procedures) 10 | 11 | 3. spu_compareprocedures.sql - a stored procedure which compares the code for stored procedures based on a list of procedures. Accompanying notes can be found [at this blog post](http://jane.dallaway.com/stored-procedure-comparison) 12 | 13 | 4. timings.sql - some simple code to determine how long a set of SQL operations will take. Again, notes can be found [on this blog post](http://jane.dallaway.com/tsql-timings) 14 | 15 | 5. FindTableColumnDataMatches.sql - some code to effectively look for a term throughout all the text based columns of all tables. Notes [at this blog post](http://jane.dallaway.com/?sort=&search=FindTableColumnDataMatches) 16 | 17 | 6. TSQLUnitHelpers.sql - Some extension functions to the original [TSQLUnit](http://tsqlunit.sourceforge.net/) code. See [this blog post](http://jane.dallaway.com/tsqlunit-updates-helper-functions) for more information 18 | 19 | 7. TSQLUnitIntroductionTests.sql - Some sample, simple, introductory tests used to introduce colleagues to [TSQLUnit](http://tsqlunit.sourceforge.net/). See [this blog post](http://jane.dallaway.com/tsqlunit-updates-helper-functions) for more information 20 | -------------------------------------------------------------------------------- /TSQLUnitHelpers.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/janedallaway/SQL-Server-Helper-Scripts/c66bdf789c2a04eccf888a76bb8758190992fe43/TSQLUnitHelpers.sql -------------------------------------------------------------------------------- /TSQLUnitIntroductionTests.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/janedallaway/SQL-Server-Helper-Scripts/c66bdf789c2a04eccf888a76bb8758190992fe43/TSQLUnitIntroductionTests.sql -------------------------------------------------------------------------------- /Timings.sql: -------------------------------------------------------------------------------- 1 | -- Set up Tables/Procedures for Timing Audits 2 | 3 | IF NOT EXISTS (SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = 'Timings') 4 | BEGIN 5 | 6 | CREATE TABLE [dbo].[Timings] 7 | ( 8 | [Code] NVARCHAR(10) NOT NULL, 9 | [Description] NVARCHAR(100), 10 | [ActionTime] DATETIME NOT NULL, 11 | [IsComplete] BIT DEFAULT(0) 12 | CONSTRAINT [PK_Timings] PRIMARY KEY CLUSTERED 13 | ( 14 | [Code] ASC, 15 | [IsComplete] ASC 16 | ) ON [PRIMARY] 17 | ) ON [PRIMARY] 18 | END 19 | GO 20 | 21 | IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.ROUTINES WHERE ROUTINE_NAME = 'up_RecordStart') 22 | BEGIN 23 | 24 | DROP PROCEDURE [dbo].[up_RecordStart] 25 | END 26 | GO 27 | 28 | CREATE PROCEDURE [dbo].[up_RecordStart] 29 | ( @Code NVARCHAR(10), 30 | @Description NVARCHAR(100) = '') 31 | -- @Code - Parameter used to uniquely identify this action 32 | -- @Description - Parameter used to record a description for this action 33 | -- ActionTime is auto-populated with GETDATE() 34 | -- IsComplete is auto-populated with 0 to indicate this is not a completion 35 | AS 36 | 37 | SET NOCOUNT ON 38 | SET XACT_ABORT ON 39 | 40 | BEGIN TRAN 41 | 42 | BEGIN TRY 43 | INSERT INTO [dbo].[Timings] 44 | ( [Code], [Description], [ActionTime], [IsComplete]) 45 | VALUES 46 | ( @Code, @Description, GETDATE(), 0) 47 | 48 | COMMIT TRAN 49 | END TRY 50 | BEGIN CATCH 51 | IF ERROR_NUMBER() = 2627 52 | PRINT 'ERROR: You hve already used the code ' + @Code + ' for timing purposes. Please choose a different code and try again.' 53 | ELSE 54 | PRINT 'ERROR: ' + CAST(ERROR_NUMBER() AS VARCHAR(10)) + ' - ' + ERROR_MESSAGE() 55 | ROLLBACK TRAN 56 | END CATCH 57 | GO 58 | 59 | IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.ROUTINES WHERE ROUTINE_NAME = 'up_RecordEnd') 60 | BEGIN 61 | 62 | DROP PROCEDURE [dbo].[up_RecordEnd] 63 | END 64 | GO 65 | 66 | CREATE PROCEDURE [dbo].[up_RecordEnd] 67 | ( @Code NVARCHAR(10)) 68 | -- @Code - Parameter used to uniquely identify this action 69 | -- @Description is only populated at the start point, not at end point 70 | -- ActionTime is auto-populated with GETDATE() 71 | -- IsComplete is auto-populated with 1 to indicate this is completion 72 | AS 73 | 74 | SET NOCOUNT ON 75 | SET XACT_ABORT ON 76 | 77 | BEGIN TRAN 78 | 79 | BEGIN TRY 80 | INSERT INTO [dbo].[Timings] 81 | ( [Code], [ActionTime], [IsComplete]) 82 | VALUES 83 | ( @Code, GETDATE(), 1) 84 | COMMIT TRAN 85 | END TRY 86 | BEGIN CATCH 87 | IF ERROR_NUMBER() = 2627 88 | PRINT 'ERROR: You hve already used the code ' + @Code + ' for timing purposes. Please choose a different code and try again.' 89 | ELSE 90 | PRINT 'ERROR: ' + CAST(ERROR_NUMBER() AS VARCHAR(10)) + ' - ' + ERROR_MESSAGE() 91 | 92 | ROLLBACK TRAN 93 | END CATCH 94 | 95 | GO 96 | 97 | IF EXISTS (SELECT * FROM INFORMATION_SCHEMA.ROUTINES WHERE ROUTINE_NAME = 'up_GetTimings') 98 | BEGIN 99 | 100 | DROP PROCEDURE [dbo].[up_GetTimings] 101 | END 102 | GO 103 | 104 | CREATE PROCEDURE [dbo].[up_GetTimings] 105 | ( @Code NVARCHAR(10) ) 106 | -- @Code - Parameter used to identify this action uniquely 107 | -- Returns Code, Description, and Length of time in ms between the start and end actions 108 | -- If no start or end action is found then TimeInMS will be -1 109 | -- Description is taken from the Start Action 110 | AS 111 | 112 | SET NOCOUNT ON 113 | SET XACT_ABORT ON 114 | 115 | DECLARE @StartTime AS DATETIME 116 | DECLARE @EndTime AS DATETIME 117 | DECLARE @Length AS INT 118 | SET @Length = 0 119 | 120 | SELECT @StartTime = ActionTime 121 | FROM Timings 122 | WHERE Code = @Code 123 | AND IsComplete = 0 124 | 125 | SELECT @EndTime = ActionTime 126 | FROM Timings 127 | WHERE Code = @Code 128 | AND IsComplete = 1 129 | 130 | IF ISNULL(CAST(@StartTime AS VARCHAR(12)),'NULL') = 'NULL' 131 | SET @Length = -1 132 | 133 | IF ISNULL(CAST(@EndTime AS VARCHAR(12)),'NULL') = 'NULL' 134 | SET @Length = -1 135 | 136 | IF @Length >= 0 137 | SET @Length = DATEDIFF(ms,@StartTime,@EndTime) 138 | 139 | SELECT Code, Description, @Length AS TimeInMS 140 | FROM [dbo].[Timings] 141 | WHERE [Code] = @Code 142 | AND IsComplete = 0 143 | 144 | GO -------------------------------------------------------------------------------- /spu_compareprocedures.sql: -------------------------------------------------------------------------------- 1 | USE [master] 2 | GO 3 | IF EXISTS (SELECT 1 FROM INFORMATION_SCHEMA.ROUTINES WHERE ROUTINE_NAME = 'spu_compareprocedures') 4 | BEGIN 5 | DROP PROCEDURE spu_compareprocedures 6 | END 7 | GO 8 | 9 | SET ANSI_NULLS ON 10 | GO 11 | SET QUOTED_IDENTIFIER ON 12 | GO 13 | -------------------------------------------------------------------------------------------- 14 | -- Name: spu_compareprocedures 15 | -- 16 | -- Author: Jane Dallaway 17 | -- 18 | -- Created: 15th April 2009 19 | -- 20 | -- This file available at : https://github.com/janedallaway/SQL-Server-Helper-Scripts 21 | -- 22 | -- Documentation and updates at: https://github.com/janedallaway/SQL-Server-Helper-Scripts 23 | -- 24 | -------------------------------------------------------------------------------------------- 25 | -- Modification History: 26 | -- -------------------- 27 | -- 20090416 Jane Added checking for procedure's existance 28 | -- 20090417 Jane Reworked the comma checking. When no stored procedures specified, report 29 | -- on all 30 | -- 20090417 Jane The INFORMATION_SCHEMA.ROUTINES.ROUTINE_DEFINITON column is limited to 31 | -- 4000 characters, so only the first 4000 characters were being checked. 32 | -- Updated to use syscomments instead to check the entire procedure 33 | -- 34 | -------------------------------------------------------------------------------------------- 35 | -- Usage: 36 | -- @db1 - must specify the name of the 1st database to use 37 | -- @db2 - must specify the name of the 2nd database to use 38 | -- @proceduresToCompare - used to restrict the objects being compared - 39 | -- should be a comma separated list. If not supplied checks 40 | -- all procedures and functions in both databases 41 | -- @displayOnlyDifferent - show only different stored procedures/functions - defaults to this, to 42 | -- display the same ones as well set this to 0. 43 | -- Always shows any errors regardless of this setting 44 | -- @debug - can be used to get extra information from the stored procedure - mainly SQL used 45 | -- internally to allow for debugging of this procedure 46 | -- 47 | -- Example: 48 | -- spu_compareprocedures @db1 = 'MyMasterDatabase', @db2 = 'MyOtherDatabase', @proceduresToCompare='spu_generateinsert,spu_compareprocedures', @displayOnlyDifferent=1, @debug=0 49 | -- 50 | -- Output: 51 | -- is produced as text in the Messages window of Management Studio/Query analyser 52 | -- 53 | -- Testing: 54 | -- tested on SQL Server 2005 only 55 | -- 56 | -------------------------------------------------------------------------------------------- 57 | CREATE PROC [dbo].[spu_compareprocedures] 58 | ( 59 | @db1 VARCHAR(128), 60 | @db2 VARCHAR(128), 61 | @proceduresToCompare VARCHAR(8000) = '', 62 | @displayOnlyDifferent BIT = 1, 63 | @debug BIT = 0 64 | ) 65 | AS 66 | BEGIN 67 | 68 | SET NOCOUNT ON 69 | SET ANSI_WARNINGS ON 70 | SET ANSI_NULLS ON 71 | 72 | -- Variable declarations 73 | DECLARE @sql VARCHAR(8000) 74 | DECLARE @loop INT 75 | DECLARE @name SYSNAME 76 | DECLARE @Comment VARCHAR(255) 77 | DECLARE @NextCommaPos INT 78 | DECLARE @database SYSNAME 79 | 80 | -- Set up constants - used for the comment fields 81 | DECLARE @c_ProcedureMissing VARCHAR(50) 82 | SET @c_ProcedureMissing = 'missing' 83 | DECLARE @c_ProcedureDifferent VARCHAR(50) 84 | SET @c_ProcedureDifferent = 'different' 85 | DECLARE @c_ProcedureSame VARCHAR(50) 86 | SET @c_ProcedureSame = 'same' 87 | 88 | -- Set up tables to store comparison objects and outputs 89 | IF EXISTS (SELECT 1 FROM tempdb.dbo.sysobjects WHERE name LIKE '#proceduresToCompare%') 90 | BEGIN 91 | DROP TABLE #proceduresToCompare 92 | END 93 | 94 | CREATE TABLE #proceduresToCompare (ObjectName sysname) 95 | 96 | IF EXISTS (SELECT 1 FROM tempdb.dbo.sysobjects WHERE name LIKE '#Results%') 97 | BEGIN 98 | DROP TABLE #Results 99 | END 100 | 101 | CREATE TABLE #Results (ObjectName sysname, Comment VARCHAR(255), DatabaseName SYSNAME NULL) 102 | 103 | -- Tidy up the input parameters 104 | SET @db1 = Rtrim(Ltrim(@db1)) 105 | SET @db2 = Rtrim(Ltrim(@db2)) 106 | IF LEN(@proceduresToCompare) > 0 107 | BEGIN 108 | SET @proceduresToCompare = REPLACE(@proceduresToCompare,', ',',') 109 | SET @proceduresToCompare = REPLACE(@proceduresToCompare,' ,',' ,') 110 | END 111 | 112 | PRINT REPLICATE ('*', DATALENGTH(@db1) + DATALENGTH(@db2) + 35) 113 | PRINT ' Comparing databases ' + @db1 + ' and ' + @db2 114 | PRINT ' Objects: ' 115 | PRINT REPLICATE(' ',5) + CASE WHEN DATALENGTH(@proceduresToCompare) = 0 THEN ' ALL stored procedures in both databases - MAY TAKE A WHILE' ELSE REPLACE(@proceduresToCompare,',',CHAR(10)+REPLICATE(' ',5)) END 116 | PRINT REPLICATE ('*', DATALENGTH(@db1) + DATALENGTH(@db2) + 35) 117 | 118 | IF @debug = 1 119 | PRINT 'DEBUG: Populating #proceduresToCompare' 120 | 121 | IF @proceduresToCompare <> '' 122 | BEGIN 123 | 124 | SET @NextCommaPos = Charindex(',',@proceduresToCompare) 125 | WHILE @NextCommaPos > 0 126 | BEGIN 127 | 128 | INSERT INTO #proceduresToCompare VALUES(LEFT(@proceduresToCompare,@NextCommaPos - 1)) 129 | 130 | SET @proceduresToCompare = RIGHT(@proceduresToCompare,LEN(@proceduresToCompare) - @NextCommaPos) 131 | 132 | SET @NextCommaPos = Charindex(',',@proceduresToCompare) 133 | 134 | END 135 | INSERT INTO #proceduresToCompare VALUES(@proceduresToCompare) 136 | END 137 | ELSE 138 | BEGIN 139 | -- Check all stored procedures in either database 140 | -- Populate with @db1 procedures 141 | SET @sql = 'INSERT INTO #proceduresToCompare (ObjectName) SELECT ROUTINE_NAME FROM ' + @db1 + '.INFORMATION_SCHEMA.ROUTINES' 142 | 143 | IF @debug = 1 144 | PRINT 'DEBUG: SQL is - ' + @sql 145 | 146 | EXEC (@sql) 147 | 148 | -- Populate with @db2 procedures which aren't already in #proceduresToCompare 149 | SET @sql = 'INSERT INTO #proceduresToCompare (ObjectName) SELECT ROUTINE_NAME FROM ' + @db2 + '.INFORMATION_SCHEMA.ROUTINES WHERE ROUTINE_NAME NOT IN (SELECT ROUTINE_NAME FROM #proceduresToCompare)' 150 | 151 | IF @debug = 1 152 | PRINT 'DEBUG: SQL is - ' + @sql 153 | 154 | EXEC (@sql) 155 | 156 | END 157 | 158 | IF EXISTS (SELECT 1 FROM #proceduresToCompare) 159 | BEGIN 160 | 161 | SET @Loop = 1 162 | SET @Name = '' 163 | 164 | WHILE @Loop = 1 165 | BEGIN 166 | 167 | SELECT TOP 1 @Name = ObjectName 168 | FROM #proceduresToCompare 169 | WHERE ObjectName > @Name 170 | ORDER BY ObjectName 171 | 172 | SET @Loop = @@ROWCOUNT 173 | 174 | IF @Loop = 0 175 | BREAK 176 | 177 | SET @sql = 'IF NOT EXISTS (SELECT 1 FROM ' + @db1 + '.INFORMATION_SCHEMA.ROUTINES WHERE ROUTINE_NAME = ''' + @Name + ''') BEGIN INSERT INTO #Results (ObjectName, Comment, DatabaseName) VALUES (''' + @name + ''',''' + @c_ProcedureMissing + ''',''' + @db1 + ''') END' 178 | 179 | IF @debug = 1 180 | PRINT 'DEBUG: SQL is - ' + @sql 181 | 182 | EXEC (@sql) 183 | 184 | SET @sql = 'IF NOT EXISTS (SELECT 1 FROM ' + @db2 + '.INFORMATION_SCHEMA.ROUTINES WHERE ROUTINE_NAME = ''' + @Name + ''') BEGIN INSERT INTO #Results (ObjectName, Comment, DatabaseName) VALUES (''' + @name + ''',''' + @c_ProcedureMissing + ''',''' + @db2 + ''') END' 185 | 186 | IF @debug = 1 187 | PRINT 'DEBUG: SQL is - ' + @sql 188 | 189 | EXEC (@sql) 190 | 191 | -- INFORMATION_SCHEMA.ROUTINES only stores first 4000 characters of the routine, so use the old syscomments 192 | -- table to get the contents to ensure true comparison 193 | SET @sql = 'DECLARE @contents1 VARCHAR(MAX) ' 194 | + 'DECLARE @contents2 VARCHAR(MAX) ' 195 | + 'DECLARE @contentsloop INT ' 196 | + 'DECLARE @currentcontents VARCHAR(Max) ' 197 | + 'DECLARE @contentsrow INT ' 198 | + 'SET @contentsloop = 1 ' 199 | + 'SET @currentcontents = ''''' 200 | + 'SET @contents1 = ''''' 201 | + 'SET @contentsrow = 0' 202 | + 'WHILE @contentsloop = 1' 203 | + 'BEGIN' 204 | + ' SELECT TOP 1 @currentcontents = sc.text, @contentsrow = sc.colid ' 205 | + ' FROM ' + @db1 + '.dbo.sysobjects so ' 206 | + ' INNER JOIN ' + @db1 + '.dbo.syscomments sc ' 207 | + ' ON so.id = sc.id ' 208 | + ' WHERE so.xtype = ''P''' 209 | + ' AND so.name = ''' + @name + '''' 210 | + ' AND sc.colid > @contentsrow' 211 | + ' ORDER BY sc.colid ' 212 | + ' SET @contentsloop = @@ROWCOUNT ' 213 | + ' IF @contentsloop = 0 ' 214 | + ' BREAK ' 215 | + ' SET @contents1 = @contents1 + @currentcontents ' 216 | + 'END ' 217 | + 'SET @contentsloop = 1 ' 218 | + 'SET @currentcontents = ''''' 219 | + 'SET @contents2 = ''''' 220 | + 'SET @contentsrow = 0' 221 | + 'WHILE @contentsloop = 1' 222 | + 'BEGIN' 223 | + ' SELECT TOP 1 @currentcontents = sc.text, @contentsrow = sc.colid ' 224 | + ' FROM ' + @db2 + '.dbo.sysobjects so ' 225 | + ' INNER JOIN ' + @db2 + '.dbo.syscomments sc ' 226 | + ' ON so.id = sc.id ' 227 | + ' WHERE so.xtype = ''P''' 228 | + ' AND so.name = ''' + @name + '''' 229 | + ' AND sc.colid > @contentsrow' 230 | + ' ORDER BY sc.colid ' 231 | + ' SET @contentsloop = @@ROWCOUNT ' 232 | + ' IF @contentsloop = 0 ' 233 | + ' BREAK ' 234 | + ' SET @contents2 = @contents2 + @currentcontents ' 235 | + 'END ' 236 | + 'INSERT INTO #Results (ObjectName, Comment) SELECT ''' + @Name + ''', CASE WHEN @contents1 = @contents2 THEN ''' + @c_ProcedureSame + ''' ELSE ''' + @c_ProcedureDifferent + ''' END ' 237 | 238 | IF @debug = 1 239 | PRINT 'DEBUG: SQL is - ' + @sql 240 | 241 | EXEC (@sql) 242 | END 243 | END 244 | ELSE 245 | BEGIN 246 | 247 | IF @proceduresToCompare = '1=1' 248 | BEGIN 249 | PRINT 'No objects specified, please provide a parameter for @proceduresToCompare in the form of a comma separated list of procedure names' 250 | END 251 | ELSE 252 | BEGIN 253 | PRINT 'No objects found' 254 | END 255 | END 256 | 257 | -------------------------------------------------------------------------------------------- 258 | -- Output errors 259 | -------------------------------------------------------------------------------------------- 260 | 261 | IF EXISTS (SELECT 1 FROM #Results WHERE Comment = @c_ProcedureMissing) 262 | BEGIN 263 | 264 | PRINT '' 265 | PRINT REPLICATE('*',17) 266 | PRINT '** ERRORS **' 267 | PRINT REPLICATE('*',17) 268 | PRINT '' 269 | 270 | SET @Loop = 1 271 | SET @Name = '' 272 | SET @Comment = '' 273 | 274 | SELECT @Loop = COUNT(*) 275 | FROM #Results 276 | WHERE Comment = @c_ProcedureMissing 277 | 278 | WHILE @Loop > 0 279 | BEGIN 280 | 281 | SELECT TOP 1 @Name = ObjectName, @Comment = Comment, @database = DatabaseName 282 | FROM #Results 283 | WHERE Comment = @c_ProcedureMissing 284 | ORDER BY ObjectName 285 | 286 | IF @Debug = 1 287 | PRINT 'DEBUG : Outputting error information for ' + @name 288 | 289 | PRINT @Name + ' is ' + @comment + ' for ' + @database 290 | 291 | DELETE FROM #Results 292 | WHERE ObjectName = @Name 293 | AND Comment = @Comment 294 | AND DatabaseName = @database 295 | 296 | SELECT @Loop = COUNT(*) 297 | FROM #Results 298 | WHERE Comment = @c_ProcedureMissing 299 | 300 | END 301 | END 302 | 303 | -------------------------------------------------------------------------------------------- 304 | -- Output comparisons 305 | -------------------------------------------------------------------------------------------- 306 | 307 | IF EXISTS (SELECT 1 FROM #Results) 308 | BEGIN 309 | 310 | PRINT '' 311 | PRINT REPLICATE('*',17) 312 | PRINT '** COMPARISONS **' 313 | PRINT REPLICATE('*',17) 314 | PRINT '' 315 | 316 | IF EXISTS (SELECT 1 FROM #Results WHERE Comment = CASE WHEN @displayOnlyDifferent = 1 THEN @c_ProcedureDifferent ELSE Comment END) 317 | BEGIN 318 | 319 | SET @Loop = 1 320 | SET @Name = '' 321 | SET @Comment = '' 322 | 323 | SELECT @Loop = COUNT(*) 324 | FROM #Results 325 | 326 | WHILE @Loop > 0 327 | BEGIN 328 | 329 | SELECT TOP 1 @Name = ObjectName, @Comment = Comment 330 | FROM #Results 331 | ORDER BY ObjectName 332 | 333 | IF @Debug = 1 334 | PRINT 'DEBUG : Outputting information for ' + @name 335 | 336 | IF @displayOnlyDifferent = 0 OR @Comment = @c_ProcedureDifferent 337 | PRINT @Name + ' on ' + @db1 + ' and ' + @db2 + ' are ' + @Comment 338 | 339 | DELETE FROM #Results 340 | WHERE ObjectName = @Name 341 | AND Comment = @Comment 342 | 343 | SELECT @Loop = COUNT(*) 344 | FROM #Results 345 | END 346 | END 347 | ELSE 348 | BEGIN 349 | PRINT 'No differences found' 350 | END 351 | END 352 | -------------------------------------------------------------------------------------------- 353 | -- Clean up temporary tables 354 | -------------------------------------------------------------------------------------------- 355 | IF EXISTS (SELECT 1 FROM tempdb.dbo.sysobjects WHERE name LIKE '#proceduresToCompare%') 356 | BEGIN 357 | DROP TABLE #proceduresToCompare 358 | END 359 | 360 | IF EXISTS (SELECT 1 FROM tempdb.dbo.sysobjects WHERE name LIKE '#Results%') 361 | BEGIN 362 | DROP TABLE #Results 363 | END 364 | 365 | RETURN 366 | END -------------------------------------------------------------------------------- /spu_generateInsert.sql: -------------------------------------------------------------------------------- 1 | IF EXISTS (SELECT * FROM sysobjects WHERE xtype = 'P' AND name = 'spu_GenerateInsert') 2 | BEGIN 3 | DROP PROCEDURE spu_GenerateInsert 4 | END 5 | GO 6 | 7 | CREATE PROCEDURE [dbo].[spu_GenerateInsert] 8 | @tableSchema varchar(128) = 'dbo', -- used to specify the tableschema, if null or empty string defaults to dbo 9 | @table varchar(128), -- used to specify the table to generate data for 10 | @generateGo bit = 0, -- used to allow GO statements to separate the insert statements 11 | @restriction varchar(1000) = '', -- used to allow the data set to be restricted, no need for the where clause but can use syntax as 'columna = 1' 12 | @producesingleinsert bit = 0, -- used to switch the ability to produce multiple insert statements (default) or one statement using UNION SELECT 13 | @debug bit = 0, -- used to allow debugging to be turned on to the stored procedure - in case of queries 14 | @GenerateOneLinePerColumn bit = 0, -- used to display the columns and data on separate lines 15 | @GenerateIdentityColumn bit = 1 -- used to prevent the identity columns from being scripted 16 | AS 17 | /******************************************************************************* 18 | Original Author: Keith E Kratochvil 19 | 20 | This version: Jane Dallaway 21 | 22 | Available from: https://github.com/janedallaway/SQL-Server-Helper-Scripts 23 | 24 | Documentation at: https://github.com/janedallaway/SQL-Server-Helper-Scripts 25 | 26 | Date Created: March 16, 2000 27 | 28 | Description: This procedure takes the data from a table and turns it into 29 | an insert statement. 30 | 31 | CAUTION!!! If you run this on a large table be prepared to wait a while! 32 | 33 | Modified: add a comment here (date, who, comment) 34 | 35 | Date Name Description 36 | ~~~~~~~ ~~~~~ ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~ 37 | 07/11/03 Jane Added a @generateGO parameter to allow selection 38 | 07/11/03 Jane This procedure has an issue with NULLs.... 39 | 07/11/03 Jane Deal with Identities 40 | 07/11/03 Jane Wrap all tablenames and columns with [ and ] 41 | 15/12/03 Jane For DateTimes covert as style 1 - to allow for mm/dd/yyy 42 | 16/12/03 Jane Get rid of rowcount 43 | 18/12/03 Jane Prevent single field tables having that field displayed twice 44 | 06/07/04 Jane Large money values get separeted with a comma - so specify convert 45 | with 0 rather than 1 46 | 31/05/05 Jane Added default for GenerateGo and added ability to generate 47 | Inserts for selected records based on the restriction 48 | 03/01/08 Jane Updated to cope with text and ntext. It converts to VARCHAR(8000) to allow quote escaping 49 | Also copes with Nulls much better now. 50 | 07/01/08 Jane Now handles guids 51 | 07/01/08 Jane Forced collation to use database_default as was causing an error in some circumstances 52 | 15/01/08 Jane Dave reported issue with image column types as a comment on my blog 53 | http://jane.dallaway.com/blog/2007/11/generate-sql-insert-statement-from.html#c9038036788352783369 54 | So, ensured that all column types either work, or replace with NULL and add warning 55 | 23/01/08 Jane Ignore calculated columns. Can't migrate the data, so remove from the INSERT 56 | Implemented a suggestion from Jon Green - 4R Systems Inc left on my blog post at 57 | http://jane.dallaway.com/blog/2007/11/generate-sql-insert-statement-from.html#c2055936172890486440 58 | to allow a choice of separate insert statements or a single statement using the UNION SELECT syntax. 59 | New parameter @producesingleinsert used. When this is set to 0 it produces separate INSERT statements. 60 | When set to 1 it produces a single statment using UNION SELECT 61 | 20/08/08 Jane New parameter @GenerateOneLinePerColumn added as suggested by Christian via comment on my blog post at 62 | http://jane.dallaway.com/blog/2007/11/generate-sql-insert-statement-from.html?showComment=1219174920000#c6992035307857457643 63 | Also made all string variables varchar(max). This means it no longer works on SQL 2000 - but to make it do so is just a case of 64 | putting all varchar(max) to varchar(8000) 65 | 07/01/09 Jane New parameter @GenerateIdentityColumns added as suggestion by James Bradshaw to enable identity columns to not be scripted 66 | and therefore rely on the database to populate the identities from scratch 67 | 16/02/09 Jane Continuation of work started on 20/08/08 - all remaining VARCHAR(8000)s removed and replaced with VARCHAR(max). So, no longer 68 | an issue with text columns unless it is SQL Server 2000, in which case this stored procedure will need to have been updated. 69 | 16/04/09 Jane Add checking to see if the table specified actually exists - user error on my case when using the procedure 70 | 17/04/09 Jane Changed @tabledata to be nvarchar rather than varchar to allow for unicode 71 | Added checking for data exceeding 8000 bytes and split the data based on CHAR(13) if this situation is seen. 72 | This won't resolve it in all cases, and if it doesn't then a warning is displayed at the bottom of the generated code 73 | 08/06/09 Jane All strings are now output as N'«data»' rather than '«data»' to cope with extended character sets 74 | 24/09/10 James Added support to specify the db schema. 75 | 24/09/10 Jane Cope with . in the table name, forced the default for schema to be dbo via parameter 76 | 77 | Known Issues: 78 | 1) BLOBs can't be output 79 | 80 | Usage: 81 | exec spu_GenerateInsert @tableSchema='dbo', @table ='users', @generateGo=0, @restriction='columna = x', @producesingleinsert=0, @debug=0, @GenerateOneLinePerColumn=0, @GenerateIdentityColumn=0 82 | 83 | 84 | Version: 85 | This version has been tested on SQL Server 2005. To make this work on SQL Server 2000, replace all instances of VARCHAR(max) with VARCHAR(8000). This will limit 86 | the ability of export of text and XML columns to 8000 characters 87 | 88 | *******************************************************************************/ 89 | --Variable declarations 90 | DECLARE @InsertStmt varchar(max) -- change this to be (8000) for SQL Server 2000 91 | DECLARE @Fields varchar(max) -- change this to be (8000) for SQL Server 2000 92 | DECLARE @SelList varchar(max) -- change this to be (8000) for SQL Server 2000 93 | DECLARE @Data varchar(max) -- change this to be (8000) for SQL Server 2000 94 | DECLARE @ColName varchar(128) 95 | DECLARE @IsChar tinyint 96 | DECLARE @FldCounter int 97 | DECLARE @TableData nvarchar(max) -- change this to be (8000) for SQL Server 2000 98 | 99 | -- added by Jane - 07/11/03 100 | DECLARE @bitIdentity BIT 101 | 102 | -- added by Jane 03/01/08 103 | DECLARE @bitHasEncounteredText BIT 104 | SET @bitHasEncounteredText = 0 105 | 106 | -- added by Jane 15/01/08 107 | DECLARE @bitHasEncounteredImage BIT 108 | SET @bitHasEncounteredImage = 0 109 | DECLARE @bitHasEncounteredBinary BIT 110 | SET @bitHasEncounteredBinary = 0 111 | DECLARE @bitHasEncounteredXML BIT 112 | SET @bitHasEncounteredXML = 0 113 | 114 | -- added by Jane - 23/01/08 115 | DECLARE @bitInsertStatementPrinted BIT 116 | SET @bitInsertStatementPrinted = 0 117 | 118 | -- added by Jane - 17/04/09 - To try and cope with bits of data which are greater than 8000 bytes 119 | DECLARE @bitDataExceedMaxPrintLength BIT 120 | SET @bitDataExceedMaxPrintLength = 0 121 | DECLARE @cintMaximumSupportedPrintByteCount INT 122 | SET @cintMaximumSupportedPrintByteCount = 8000 -- based on SQL Server 2005 123 | DECLARE @statementToOutput NVARCHAR(max) -- change this to be (8000) for SQL Server 2000 124 | DECLARE @NextCR INT -- used to split the output up into smaller chunks - look for carriage returns/line feeds and break into separate print statements 125 | DECLARE @statementsToOutput TABLE (Id INT IDENTITY(1,1), singleStatement NVARCHAR (max) ) -- change this to be (8000) for SQL Server 2000 126 | DECLARE @id INT 127 | DECLARE @singleStatement NVARCHAR(max) -- change this to be (8000) for SQL Server 2000 128 | DECLARE @loop INT 129 | 130 | -- added by Jane - 16/12/03 131 | SET NOCOUNT OFF 132 | 133 | -- added by Jane - 16/04/09 - check for table existance 134 | -- AND TABLE_SCHEMA = @tableSchema added by James - 24/09/2010 135 | IF EXISTS(SELECT 1 FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_NAME = @table AND TABLE_SCHEMA = @tableSchema) 136 | BEGIN 137 | -- added by Jane - 16/04/2009 - Show details of table being generated, and date/time 138 | PRINT REPLICATE('-', 37 + LEN(@table) + LEN(CONVERT(VARCHAR,GETDATE(),120))) 139 | PRINT '-- Script generated for table [' +@TableSchema +'].[' + @table + '] on ' + CONVERT(VARCHAR,GETDATE(),120) + ' --' 140 | PRINT REPLICATE('-', 37 + LEN(@table) + LEN(CONVERT(VARCHAR,GETDATE(),120))) 141 | 142 | -- added by Jane - 07/11/03 143 | SELECT @bitIdentity = OBJECTPROPERTY(OBJECT_ID(TABLE_SCHEMA+'.'+TABLE_NAME), 'TableHasIdentity') 144 | FROM INFORMATION_SCHEMA.TABLES 145 | WHERE TABLE_Name = @table 146 | AND TABLE_SCHEMA = @tableSchema --added by James - 24/09/2010 147 | 148 | -- added by Jane - 03/01/08 149 | PRINT '-- ** Start of Inserts ** --' 150 | PRINT '' 151 | 152 | -- added by Jane - 07/11/03 153 | -- AND @GenerateIdentityColumn = 1 added by Jane - 07/01/09 154 | IF @bitIdentity = 1 AND @GenerateIdentityColumn = 1 155 | BEGIN 156 | PRINT 'SET IDENTITY_INSERT ['+@tableSchema +'].[' + @table + '] ON ' 157 | END 158 | 159 | --initialize some of the variables 160 | -- updated by Jane 20/08/08 added one line per column functionality as per Christian's suggestion 161 | -- updated by James 24/09/2010 tableschema 162 | SELECT @InsertStmt = 'INSERT INTO ['+@tableSchema +'].[' + @Table + '] '+ CASE WHEN @GenerateOneLinePerColumn = 1 THEN CHAR(13) ELSE '' END + '(' + CASE WHEN @GenerateOneLinePerColumn = 1 THEN CHAR(13) ELSE '' END, 163 | @Fields = '', 164 | @Data = '', 165 | @SelList = 'SELECT ', 166 | @FldCounter = 0 167 | 168 | --create a cursor that loops through the fields in the table 169 | --and retrieves the column names and determines the delimiter type that the 170 | --field needs 171 | DECLARE CR_Table CURSOR FAST_FORWARD FOR 172 | 173 | SELECT COLUMN_NAME, 174 | 'IsChar' = CASE 175 | WHEN DATA_TYPE in ('int', 'money', 'decimal', 'tinyint', 'smallint' ,'numeric', 'bit', 'bigint', 'smallmoney', 'float','timestamp') THEN 0 176 | WHEN DATA_TYPE in ('char', 'varchar', 'nvarchar','uniqueidentifier', 'nchar') THEN 1 177 | WHEN DATA_TYPE in ('datetime', 'smalldatetime') THEN 2 178 | WHEN DATA_TYPE in ('text', 'ntext') THEN 3 179 | WHEN DATA_TYPE in ('image') THEN 4 -- added by Jane - 15/01/08 180 | WHEN DATA_TYPE in ('binary', 'varbinary') THEN 5 -- added by Jane - 15/01/08 181 | WHEN DATA_TYPE in ('sql_variant') THEN 6 -- added by Jane - 15/01/08 - Force to be converted as varchars 182 | WHEN DATA_TYPE in ('xml') THEN 7 -- added by Jane - 15/01/08 183 | ELSE 9 184 | END 185 | FROM INFORMATION_SCHEMA.COLUMNS c WITH (NOLOCK) 186 | INNER JOIN syscolumns sc WITH (NOLOCK) 187 | ON c.COLUMN_NAME = sc.name 188 | INNER JOIN sysobjects so WITH (NOLOCK) 189 | ON sc.id = so.id 190 | AND so.name = c.TABLE_NAME 191 | WHERE table_name = @table 192 | AND TABLE_SCHEMA = @tableSchema -- added by James - 24/09/2010 193 | AND DATA_TYPE <> 'timestamp' 194 | AND sc.IsComputed = 0 195 | AND 1 = 196 | CASE @GenerateIdentityColumn 197 | WHEN 1 -- When we want the identity columns to be generated, then always include the column 198 | THEN 1 199 | ELSE 200 | CASE COLUMNPROPERTY(object_id(TABLE_SCHEMA+'.'+TABLE_NAME), COLUMN_NAME, 'IsIdentity') -- Check if the column has the property IsIdentity 201 | WHEN 1 -- If it does 202 | THEN 0 -- don't include this column 203 | ELSE 1 -- otherwise include this column 204 | END 205 | END 206 | ORDER BY ORDINAL_POSITION 207 | FOR READ ONLY 208 | OPEN CR_Table 209 | 210 | FETCH NEXT FROM CR_Table INTO @ColName, @IsChar 211 | 212 | WHILE (@@fetch_status <> -1) 213 | BEGIN 214 | 215 | IF @IsChar = 3 216 | SET @bitHasEncounteredText = 1 217 | 218 | -- added by Jane - 15/01/08 219 | IF @IsChar = 4 220 | SET @bitHasEncounteredImage = 1 221 | IF @IsChar = 5 222 | SET @bitHasEncounteredBinary = 1 223 | 224 | IF (@@fetch_status <> -2) 225 | BEGIN 226 | 227 | -- Updated by Jane - 15/01/08 - cope with xml, image, binary, varbinary etc 228 | -- Updated by Jane - 03/01/08 to cope with text and ntext - converts to VARCHAR(8000) to allow quote escaping 229 | -- Special case for first field 230 | IF @FldCounter = 0 231 | BEGIN 232 | SELECT @Fields = @Fields + '[' + @ColName + ']' + ', ' 233 | -- Updated by Jane - 08/06/09 - prefix string with N to cope with extended character sets 234 | SELECT @SelList = CASE @IsChar 235 | WHEN 1 THEN @SelList + ' ISNULL(''N'''''' + REPLACE(['+ @ColName + '],'''''''', '''''''''''') + '''''''' ,''NULL'') ' + ' COLLATE database_default + ' 236 | WHEN 2 THEN @SelList + ' ISNULL(''N'''''' + CONVERT(varchar(20),[' + @ColName + ']) + '''''''',''NULL'') ' + ' COLLATE database_default + ' 237 | WHEN 3 THEN @SelList + ' ISNULL(''N'''''' + REPLACE(CONVERT(VARCHAR(max),['+ @ColName + ']),'''''''', '''''''''''')+ '''''''' ,''NULL'') '+ ' COLLATE database_default + ' 238 | WHEN 4 THEN @SelList + '''NULL''' + ' COLLATE database_default + ' 239 | WHEN 5 THEN @SelList + '''NULL''' + ' COLLATE database_default + ' 240 | WHEN 6 THEN @SelList + ' ISNULL(''N'''''' + REPLACE(CONVERT(VARCHAR(max),['+ @ColName + ']),'''''''', '''''''''''')+ '''''''' ,''NULL'') '+ ' COLLATE database_default + ' 241 | WHEN 7 THEN @SelList + ' ISNULL(''N'''''' + REPLACE(CONVERT(VARCHAR(max),['+ @ColName + ']),'''''''', '''''''''''')+ '''''''' ,''NULL'') '+ ' COLLATE database_default + ' 242 | ELSE @SelList + 'ISNULL(CONVERT(varchar(2000),['+@ColName + '],0),''NULL'')' + ' COLLATE database_default + ' 243 | END 244 | SELECT @FldCounter = @FldCounter + 1 245 | SET @SelList = @Sellist 246 | FETCH NEXT FROM CR_Table INTO @ColName, @IsChar 247 | END 248 | 249 | -- Updated by Jane - 15/01/08 - cope with xml, image, binary, varbinary etc 250 | -- Updated by Jane - 03/01/08 to cope with NULL replacements 251 | -- Updated by Jane - 03/01/08 to cope with text and ntext - converts to VARCHAR(8000) to allow quote escaping 252 | -- Updated by Jane - 18/12/03 to prevent single field tables having that field displayed twice 253 | -- Updated by Jane - 20/08/08 to incorporate the @GenerateOneLinePerColumn parameter suggested by Christian 254 | IF @@fetch_status <> -1 255 | BEGIN 256 | SELECT @Fields = @Fields + '[' + @ColName + ']' + ', ' 257 | -- Updated by Jane - 08/06/09 - prefix string with N to cope with extended character sets 258 | SELECT @SelList = CASE @IsChar 259 | WHEN 1 THEN @SelList + ''',''' + CASE WHEN @GenerateOneLinePerColumn = 1 THEN ' + CHAR(13) ' ELSE '' END + ' + ' + ' ISNULL(''N'''''' + REPLACE(['+ @ColName + '],'''''''', '''''''''''' ) + '''''''',''NULL'') ' + ' COLLATE database_default + ' 260 | WHEN 2 THEN @SelList + ''',''' + CASE WHEN @GenerateOneLinePerColumn = 1 THEN ' + CHAR(13) ' ELSE '' END + ' + ' + 'ISNULL(''N'''''' + CONVERT(varchar(20),['+ @ColName + '])+ '''''''',''NULL'') ' + ' COLLATE database_default + ' 261 | WHEN 3 THEN @SelList + ''',''' + CASE WHEN @GenerateOneLinePerColumn = 1 THEN ' + CHAR(13) ' ELSE '' END + ' + ' + ' ISNULL(''N'''''' + REPLACE(CONVERT(VARCHAR(max),['+ @ColName + ']),'''''''', '''''''''''' )+ '''''''',''NULL'') ' + ' COLLATE database_default + ' 262 | WHEN 4 THEN @SelList + ''',''' + CASE WHEN @GenerateOneLinePerColumn = 1 THEN ' + CHAR(13) ' ELSE '' END + ' + ' + '''NULL''' + ' COLLATE database_default + ' 263 | WHEN 5 THEN @SelList + ''',''' + CASE WHEN @GenerateOneLinePerColumn = 1 THEN ' + CHAR(13) ' ELSE '' END + ' + ' + '''NULL''' + ' COLLATE database_default + ' 264 | WHEN 6 THEN @SelList + ''',''' + CASE WHEN @GenerateOneLinePerColumn = 1 THEN ' + CHAR(13) ' ELSE '' END + ' + ' + ' ISNULL(''N'''''' + REPLACE(CONVERT(VARCHAR(max),['+ @ColName + ']),'''''''', '''''''''''')+ '''''''' ,''NULL'') '+ ' COLLATE database_default + ' 265 | WHEN 7 THEN @SelList + ''',''' + CASE WHEN @GenerateOneLinePerColumn = 1 THEN ' + CHAR(13) ' ELSE '' END + ' + ' + ' ISNULL(''N'''''' + REPLACE(CONVERT(VARCHAR(max),['+ @ColName + ']),'''''''', '''''''''''')+ '''''''' ,''NULL'') '+ ' COLLATE database_default + ' 266 | ELSE @SelList + ''',''' + CASE WHEN @GenerateOneLinePerColumn = 1 THEN ' + CHAR(13) ' ELSE '' END + ' + ' + ' ISNULL(CONVERT(varchar(2000),['+@ColName + '],0),''NULL'')' + ' COLLATE database_default + ' 267 | END 268 | END 269 | END 270 | 271 | FETCH NEXT FROM CR_Table INTO @ColName, @IsChar 272 | END 273 | 274 | CLOSE CR_Table 275 | DEALLOCATE CR_Table 276 | 277 | SELECT @Fields = SUBSTRING(@Fields, 1,(len(@Fields)-1)) 278 | 279 | SELECT @SelList = SUBSTRING(@SelList, 1,(len(@SelList)-1)) 280 | SELECT @SelList = @SelList + ' FROM ' +@TableSchema +'.[' + @table + ']' 281 | 282 | IF LEN(@restriction) > 0 283 | BEGIN 284 | SELECT @SelList = @SelList + ' WHERE ' + @restriction 285 | END 286 | 287 | -- updated by Jane 20/08/08 added one line per column functionality as per Christian's suggestion 288 | SELECT @InsertStmt = @InsertStmt + CASE WHEN @GenerateOneLinePerColumn = 1 THEN REPLACE(@Fields,', ',',' + CHAR(13)) ELSE @Fields END + CASE WHEN @GenerateOneLinePerColumn = 1 THEN CHAR(13) ELSE '' END + ')' 289 | 290 | --for debugging purposes... 291 | IF @Debug = 1 292 | BEGIN 293 | PRINT '*** DEBUG INFORMATION - THIS IS THE SELECT STATEMENT BEING RUN *** ' 294 | PRINT @sellist 295 | PRINT '*** END DEBUG ***' 296 | END 297 | 298 | -- added by Jane - 16/12/03 299 | SET NOCOUNT ON 300 | 301 | --now we need to create and load the temp table that will hold the data 302 | --that we are going to generate into an insert statement 303 | 304 | CREATE TABLE #TheData (TableData VARCHAR(max)) -- change this to be (8000) for SQL Server 2000 305 | INSERT INTO #TheData (TableData) EXEC (@SelList) 306 | 307 | --Cursor through the data to generate the INSERT statement / VALUES/SELECT/UNION SELECT clause 308 | DECLARE CR_Data CURSOR FAST_FORWARD FOR SELECT TableData FROM #TheData FOR 309 | READ ONLY 310 | OPEN CR_Data 311 | FETCH NEXT FROM CR_Data INTO @TableData 312 | 313 | WHILE (@@fetch_status <> -1) 314 | BEGIN 315 | IF (@@fetch_status <> -2) 316 | BEGIN 317 | 318 | -- Updated by Jane 17/04/09 instead of printing at this point, store the output in a @statementToOutput variable. This allows us to try and split it to 319 | -- to print within the 8000 byte limit imposed by the PRINT function 320 | -- Updated by Jane 23/01/08 after suggestion posted to blog at http://jane.dallaway.com/blog/2007/11/generate-sql-insert-statement-from.html#c2055936172890486440 321 | IF (@producesingleinsert = 1 ) 322 | IF (@bitInsertStatementPrinted = 0) 323 | BEGIN 324 | SET @statementToOutput = @InsertStmt + char(13) + 'SELECT ' + @TableData 325 | SET @bitInsertStatementPrinted = 1 326 | END 327 | ELSE 328 | BEGIN 329 | SET @statementToOutput = 'UNION SELECT ' + @TableData 330 | END 331 | ELSE 332 | BEGIN 333 | -- updated by Jane 20/08/08 added one line per column functionality as per Christian's suggestion 334 | SET @statementToOutput = @InsertStmt + CASE WHEN @GenerateOneLinePerColumn = 1 THEN CHAR(13) ELSE '' END + 'VALUES ' + + CASE WHEN @GenerateOneLinePerColumn = 1 THEN CHAR(13) ELSE '' END + '(' + CASE WHEN @GenerateOneLinePerColumn = 1 THEN CHAR(13) ELSE '' END + @TableData + CASE WHEN @GenerateOneLinePerColumn = 1 THEN CHAR(13) ELSE '' END + ')' + CHAR(13) 335 | END 336 | 337 | -- Added by Jane - 17/04/09 - check for length of @statementToOutput 338 | -- if it exceeds the maximum length, then lets attempt to split it on CRs as these will be done via separate PRINT statements 339 | IF DATALENGTH(@statementToOutput) > @cintMaximumSupportedPrintByteCount 340 | BEGIN 341 | 342 | -- Break the @statementToOutput based on CHAR(13) and put separate data values into @statementsToOutput table 343 | 344 | -- Get rid of double line breaks 345 | -- Replace CHAR(10) with CHAR(13) 346 | SET @statementToOutput = REPLACE(@statementToOutput,CHAR(10),CHAR(13)) 347 | -- Replace CHAR(13)+CHAR(13) with CHAR(13) 348 | SET @statementToOutput = REPLACE(@statementToOutput,CHAR(13)+CHAR(13),CHAR(13)) 349 | 350 | SET @NextCR = Charindex(CHAR(13),@statementToOutput) 351 | WHILE @NextCR > 0 352 | BEGIN 353 | 354 | INSERT INTO @statementsToOutput VALUES(LEFT(@statementToOutput,@NextCR - 1)) 355 | 356 | SET @statementToOutput = Right(@statementToOutput,Len(@statementToOutput) - @NextCR) 357 | SET @NextCR = Charindex(CHAR(13),@statementToOutput) 358 | END 359 | INSERT INTO @statementsToOutput VALUES(@statementToOutput) 360 | 361 | -- Output the statements line by line 362 | SET @loop = 1 363 | SET @id = -1 364 | 365 | WHILE @loop = 1 366 | BEGIN 367 | SELECT TOP 1 @id = Id, @singleStatement = singlestatement 368 | FROM @statementsToOutput 369 | WHERE id > @id 370 | ORDER BY Id 371 | 372 | SET @loop = @@ROWCOUNT 373 | 374 | IF @loop = 0 375 | BREAK 376 | 377 | -- No guarantee that we still don't exceed the limits, but should have more of a chance of avoiding them 378 | IF DATALENGTH(@singleStatement) > @cintMaximumSupportedPrintByteCount 379 | BEGIN 380 | SET @bitDataExceedMaxPrintLength = 1 381 | SELECT @singleStatement 382 | END 383 | 384 | PRINT @singleStatement 385 | END 386 | END 387 | ELSE 388 | BEGIN 389 | -- Don't need to worry, we haven't exceeded the 8000 byte limit so just print it 390 | PRINT @statementToOutput 391 | END 392 | 393 | IF @generateGo = 1 394 | BEGIN 395 | PRINT 'GO' 396 | END 397 | END 398 | FETCH NEXT FROM CR_Data INTO @TableData 399 | END 400 | CLOSE CR_Data 401 | DEALLOCATE CR_Data 402 | 403 | -- added by Jane - 07/11/03 404 | -- AND @GenerateIdentityColumn = 1 added by Jane - 07/01/09 405 | IF @bitIdentity = 1 AND @GenerateIdentityColumn = 1 406 | BEGIN 407 | PRINT 'SET IDENTITY_INSERT [' + @table + '] OFF ' 408 | END 409 | 410 | -- added by Jane - 03/01/08 411 | PRINT '-- ** End of Inserts ** --' 412 | 413 | IF @bitHasEncounteredImage = 1 414 | BEGIN 415 | PRINT '-- ** WARNING: There is an image column in your table which has not been migrated - this has been replaced with NULL. You will need to do this by hand. Images are not supported by this script at this time. ** --' 416 | END 417 | 418 | -- added by Jane - 15/01/08 419 | IF @bitHasEncounteredBinary = 1 420 | BEGIN 421 | PRINT '-- ** WARNING: There is a binary or varbinary column in your table which has not been migrated - this has been replaced with NULL. You will need to do this by hand. Binary and VarBinary are not supported by this script at this time. ** --' 422 | END 423 | 424 | -- 16/02/09 - These checks are only required if the database is SQL Server 2000 425 | DECLARE @Version VARCHAR(100) 426 | SELECT @Version = @@VERSION 427 | IF PATINDEX('%8.00%',@Version) > 0 428 | BEGIN 429 | IF @bitHasEncounteredXML = 1 430 | BEGIN 431 | PRINT '-- ** WARNING: This will convert any ''xml'' data to be ''varchar(8000)'' ** --' 432 | END 433 | 434 | -- added by Jane - 03/01/08 435 | IF @bitHasEncounteredText = 1 436 | BEGIN 437 | PRINT '-- ** WARNING: This will convert any ''text'' or ''ntext'' data to be ''varchar(8000)'' ** --' 438 | END 439 | END 440 | 441 | IF @bitDataExceedMaxPrintLength = 1 442 | BEGIN 443 | PRINT '-- ** WARNING: The data length for at least one row exceeds '+ CONVERT(VARCHAR(6),@cintMaximumSupportedPrintByteCount) + ' bytes. The PRINT command is limited to ' + CONVERT(VARCHAR(6),@cintMaximumSupportedPrintByteCount) + ' bytes (for more information see http://msdn.microsoft.com/en-us/library/ms176047.aspx). Do not trust this data. ** --' 444 | END 445 | END 446 | ELSE 447 | BEGIN 448 | 449 | -- added by Jane - 16/04/2009 - Warn user that table doesn't exist 450 | PRINT REPLICATE('-', 43 + LEN(@table)) 451 | PRINT '-- Table [' + @TableSchema + '].[' + @table + '] doesn''t exist on this database --' 452 | PRINT REPLICATE('-', 43 + LEN(@table)) 453 | 454 | END 455 | RETURN (0) -------------------------------------------------------------------------------- /spu_scriptprocedures.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/janedallaway/SQL-Server-Helper-Scripts/c66bdf789c2a04eccf888a76bb8758190992fe43/spu_scriptprocedures.sql --------------------------------------------------------------------------------