Query Syntax

  • Trying to get the following to run only on certain databases but I can't get the formatting correct. What am I doing wrong?

    DECLARE AllDatabases CURSOR FOR

    SELECT [name] FROM master.dbo.sysdatabases WHERE dbid > 4

    OPEN AllDatabases

    DECLARE @DBNameVar NVARCHAR(128),@Statement NVARCHAR(300)

    FETCH NEXT FROM AllDatabases INTO @DBNameVar

    WHILE (@@FETCH_STATUS = 0)

    BEGIN

    PRINT N'CHECKING DATABASE ' + @DBNameVar

    SET @Statement = N'USE ' + @DBNameVar + CHAR(13)

    + N'

    SELECT sys.objects.name

    , (avg_total_user_cost * avg_user_impact) * (user_seeks + user_scans) AS Impact

    , 'CREATE NONCLUSTERED INDEX ix_IndexName ON ' + sys.objects.name COLLATE DATABASE_DEFAULT + ' ( ' + IsNull(mid.equality_columns, '') + CASE WHEN mid.inequality_columns IS NULL

    THEN ''

    ELSE CASE WHEN mid.equality_columns IS NULL

    THEN ''

    ELSE ',' END + mid.inequality_columns END + ' ) ' + CASE WHEN mid.included_columns IS NULL

    THEN ''

    ELSE 'INCLUDE (' + mid.included_columns + ')' END + ';' AS CreateIndexStatement

    , mid.equality_columns

    , mid.inequality_columns

    , mid.included_columns

    FROM sys.dm_db_missing_index_group_stats AS migs

    INNER JOIN sys.dm_db_missing_index_groups AS mig ON migs.group_handle = mig.index_group_handle

    INNER JOIN sys.dm_db_missing_index_details AS mid ON mig.index_handle = mid.index_handle AND mid.database_id = DB_ID()

    INNER JOIN sys.objects WITH (nolock) ON mid.OBJECT_ID = sys.objects.OBJECT_ID

    WHERE (migs.group_handle IN

    (

    SELECT TOP (500) group_handle

    FROM sys.dm_db_missing_index_group_stats WITH (nolock)

    ORDER BY (avg_total_user_cost * avg_user_impact) * (user_seeks + user_scans) DESC))

    AND OBJECTPROPERTY(sys.objects.OBJECT_ID, 'isusertable')=1

    ORDER BY 2 DESC , 3 DESC'

    EXEC sp_executesql @Statement

    PRINT CHAR(13) + CHAR(13)

    FETCH NEXT FROM AllDatabases INTO @DBNameVar

    END

    CLOSE AllDatabases

    DEALLOCATE AllDatabases

  • This should fix it

    DECLARE AllDatabases CURSOR FOR

    SELECT [name] FROM master.dbo.sysdatabases WHERE dbid > 4

    OPEN AllDatabases

    DECLARE @DBNameVar NVARCHAR(128),@Statement NVARCHAR(max)

    FETCH NEXT FROM AllDatabases INTO @DBNameVar

    WHILE (@@FETCH_STATUS = 0)

    BEGIN

    PRINT N'CHECKING DATABASE ' + @DBNameVar

    SET @Statement = N'USE ' + @DBNameVar + CHAR(13)

    + N'

    SELECT sys.objects.name

    , (avg_total_user_cost * avg_user_impact) * (user_seeks + user_scans) AS Impact

    , ''CREATE NONCLUSTERED INDEX ix_IndexName ON '' + sys.objects.name COLLATE DATABASE_DEFAULT + '' ( '' + IsNull(mid.equality_columns, '''') + CASE WHEN mid.inequality_columns IS NULL

    THEN ''''

    ELSE CASE WHEN mid.equality_columns IS NULL

    THEN ''''

    ELSE '','' END + mid.inequality_columns END + '' ) '' + CASE WHEN mid.included_columns IS NULL

    THEN ''''

    ELSE ''INCLUDE ('' + mid.included_columns + '')'' END + '';'' AS CreateIndexStatement

    , mid.equality_columns

    , mid.inequality_columns

    , mid.included_columns

    FROM sys.dm_db_missing_index_group_stats AS migs

    INNER JOIN sys.dm_db_missing_index_groups AS mig ON migs.group_handle = mig.index_group_handle

    INNER JOIN sys.dm_db_missing_index_details AS mid ON mig.index_handle = mid.index_handle AND mid.database_id = DB_ID()

    INNER JOIN sys.objects WITH (nolock) ON mid.OBJECT_ID = sys.objects.OBJECT_ID

    WHERE (migs.group_handle IN

    (

    SELECT TOP (500) group_handle

    FROM sys.dm_db_missing_index_group_stats WITH (nolock)

    ORDER BY (avg_total_user_cost * avg_user_impact) * (user_seeks + user_scans) DESC))

    AND OBJECTPROPERTY(sys.objects.OBJECT_ID, ''isusertable'')=1

    ORDER BY 2 DESC , 3 DESC'

    PRINT @Statement

    --EXEC sp_executesql @Statement

    PRINT CHAR(13) + CHAR(13)

    FETCH NEXT FROM AllDatabases INTO @DBNameVar

    END

    CLOSE AllDatabases

    DEALLOCATE AllDatabases

    The issues were related to a variable defined too small for the statement and the quotes in the dynamic sql.

    Jason...AKA CirqueDeSQLeil
    _______________________________________________
    I have given a name to my pain...MCM SQL Server, MVP
    SQL RNNR
    Posting Performance Based Questions - Gail Shaw[/url]
    Learn Extended Events

Viewing 2 posts - 1 through 1 (of 1 total)

You must be logged in to reply to this topic. Login to reply