@@ -16,7 +16,7 @@ ALTER PROCEDURE dbo.sp_BlitzIndex
1616 @ObjectName NVARCHAR (386 ) = NULL , /* 'dbname.schema.table' -- if you are lazy and want to fill in @DatabaseName, @SchemaName and @TableName, and since it's the first parameter can simply do: sp_BlitzIndex 'sch.table' */
1717 @DatabaseName NVARCHAR (128 ) = NULL , /* Defaults to current DB if not specified*/
1818 @SchemaName NVARCHAR (128 ) = NULL , /* Requires table_name as well.*/
19- @TableName NVARCHAR (128 ) = NULL , /* Requires schema_name as well.*/
19+ @TableName NVARCHAR (261 ) = NULL , /* Requires schema_name as well.*/
2020 @Mode TINYINT = 0 , /* 0=Diagnose, 1=Summarize, 2=Index Usage Detail, 3=Missing Index Detail, 4=Diagnose Details*/
2121 /* Note:@Mode doesn't matter if you're specifying schema_name and @TableName.*/
2222 @Filter TINYINT = 0 , /* 0=no filter (default). 1=No low-usage warnings for objects with 0 reads. 2=Only warn for objects >= 500MB */
@@ -33,7 +33,7 @@ ALTER PROCEDURE dbo.sp_BlitzIndex
3333 @OutputServerName NVARCHAR (256 ) = NULL ,
3434 @OutputDatabaseName NVARCHAR (256 ) = NULL ,
3535 @OutputSchemaName NVARCHAR (256 ) = NULL ,
36- @OutputTableName NVARCHAR (256 ) = NULL ,
36+ @OutputTableName NVARCHAR (261 ) = NULL ,
3737 @IncludeInactiveIndexes BIT = 0 /* Will skip indexes with no reads or writes */ ,
3838 @ShowAllMissingIndexRequests BIT = 0 /* Will make all missing index requests show up*/ ,
3939 @ShowPartitionRanges BIT = 0 /* Will add partition range values column to columnstore visualization */ ,
@@ -134,12 +134,60 @@ DECLARE @PartitionCount INT;
134134DECLARE @OptimizeForSequentialKey BIT = 0 ;
135135DECLARE @ResumableIndexesDisappearAfter INT = 0 ;
136136DECLARE @StringToExecute NVARCHAR (MAX );
137+ DECLARE @AzureSQLDB BIT = (SELECT CASE WHEN SERVERPROPERTY (' EngineEdition' ) = 5 THEN 1 ELSE 0 END );
137138
138139/* If user was lazy and just used @ObjectName with a fully qualified table name, then lets parse out the various parts */
139140SET @DatabaseName = COALESCE (@DatabaseName, PARSENAME (@ObjectName, 3 )) /* 3 = Database name */
140141SET @SchemaName = COALESCE (@SchemaName, PARSENAME (@ObjectName, 2 )) /* 2 = Schema name */
141142SET @TableName = COALESCE (@TableName, PARSENAME (@ObjectName, 1 )) /* 1 = Table name */
142143
144+ /* Handle already quoted input if it wasn't fully qualified*/
145+ SET @DatabaseName = PARSENAME (@DatabaseName,1 );
146+ SET @SchemaName = ISNULL (PARSENAME (@SchemaName,1 ),PARSENAME (@TableName,2 ));
147+ SET @TableName = PARSENAME (@TableName,1 );
148+
149+ /* If we're on Azure SQL DB let's cut people some slack */
150+ IF (@TableName IS NOT NULL AND @AzureSQLDB = 1 AND @DatabaseName IS NULL )
151+ BEGIN
152+ SET @DatabaseName = DB_NAME ();
153+ END ;
154+
155+
156+ IF (@SchemaName IS NULL AND @TableName IS NOT NULL )
157+ BEGIN
158+ /* If the target is in the current database
159+ and there's just one table or view with this name, then we can grab the schema from sys.objects*/
160+ IF ((SELECT COUNT (1 ) FROM [sys].[objects]
161+ WHERE [name] = @TableName AND [type] IN (' U' ,' V' ))= 1
162+ AND @TableName IS NOT NULL AND @DatabaseName = DB_NAME ())
163+ BEGIN
164+ SELECT @SchemaName = SCHEMA_NAME ([schema_id])
165+ FROM [sys].[objects]
166+ WHERE [name] = @TableName AND [type] IN (' U' ,' V' );
167+ END ;
168+ /* If the target isn't in the current database, then use dynamic T-SQL*/
169+ IF (@DatabaseName <> DB_NAME ())
170+ BEGIN
171+ /* first make sure only one row is returned from sys.objects*/
172+ SET @dsql = N' SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
173+ SELECT @RowcountOUT = COUNT(1) FROM ' + QUOTENAME (@DatabaseName) + N' .[sys].[objects]
174+ WHERE [name] = @TableName_IN AND [type] IN ('' U'' ,'' V'' ) OPTION (RECOMPILE);' ;
175+ SET @params = N ' @TableName_IN NVARCHAR(128), @RowcountOUT BIGINT OUTPUT' ;
176+ EXEC sp_executesql @dsql, @params, @TableName_IN = @TableName, @RowcountOUT = @Rowcount OUTPUT ;
177+
178+ IF (@Rowcount = 1 )
179+ BEGIN
180+ SET @dsql = N' SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
181+ SELECT @SchemaName_OUT = s.[name]
182+ FROM ' + QUOTENAME (@DatabaseName) + N' .[sys].[objects] o
183+ INNER JOIN ' + QUOTENAME (@DatabaseName) + N' .[sys].[schemas] s
184+ ON o.[schema_id] = s.[schema_id]
185+ WHERE o.[name] = @TableName_IN AND o.[type] IN ('' U'' ,'' V'' ) OPTION (RECOMPILE);' ;
186+ SET @params = N ' @TableName_IN NVARCHAR(128), @SchemaName_OUT NVARCHAR(128) OUTPUT' ;
187+ EXEC sp_executesql @dsql, @params, @TableName_IN = @TableName, @SchemaName_OUT = @SchemaName OUTPUT ;
188+ END ;
189+ END ;
190+ END ;
143191
144192/* Let's get @SortOrder set to lower case here for comparisons later */
145193SET @SortOrder = REPLACE (LOWER (@SortOrder), N ' ' , N ' _' );
@@ -181,6 +229,26 @@ BEGIN
181229 RETURN ;
182230END ;
183231
232+ /* Some prep-work for output object names before checking if they're ok or not */
233+ IF (@OutputTableName IS NOT NULL )
234+ BEGIN
235+
236+ /* Deal with potentially quoted object names*/
237+ SET @OutputDatabaseName = PARSENAME (@OutputDatabaseName,1 );
238+ SET @OutputSchemaName = ISNULL (PARSENAME (@OutputSchemaName,1 ),PARSENAME (@OutputTableName,2 ));
239+ SET @OutputTableName = PARSENAME (@OutputTableName,1 );
240+
241+ /* Running on Azure SQL DB or outputting to current database? */
242+ IF (@OutputDatabaseName IS NULL AND @AzureSQLDB = 1 )
243+ BEGIN
244+ SET @OutputDatabaseName = DB_NAME ();
245+ END ;
246+ IF (@OutputSchemaName IS NULL AND @OutputDatabaseName = DB_NAME ())
247+ BEGIN
248+ SET @OutputSchemaName = SCHEMA_NAME ();
249+ END ;
250+ END ;
251+
184252IF (@OutputType = ' TABLE' AND NOT (@OutputTableName IS NULL AND @OutputSchemaName IS NULL AND @OutputDatabaseName IS NULL AND @OutputServerName IS NULL ))
185253BEGIN
186254 RAISERROR (N ' One or more output parameters specified in combination with TABLE output, changing to NONE output mode' , 0 ,1 ) WITH NOWAIT ;
0 commit comments