sp_MSForEachdb syntax error

  • I need to execute the following script againts each database on a server to capture all the sql users and their permission. I got the 'select' script from a forum in sql central.The script gave me exactly what I need but when I try to add sp_msforeachdb functionallity I receive the following error msg,

    Msg 102, Level 15, State 1, Line 19

    Incorrect syntax near 'principal_id'.

    Script

    DECLARE @cmd1 nvarchar(2000)

    SET @cmd1 = 'IF ''?'' NOT IN(''master'', ''model'', ''tempdb'', ''msdb'')' + 'BEGIN '

    + 'Print ''Populating Audit table for ?...'';'

    + 'INSERT INTO [AW ].[dbo].[Audit]([Login Type],srvLogin,srvRole,dbUser,dbRole) ' +

    + 'Use ?

    select

    [Login Type]=

    case sp.type

    when ''u'' then ''WIN''

    when ''s'' then ''SQL''

    when ''g'' then ''GRP''

    end,

    convert(char(45),sp.name) as srvLogin,

    convert(char(45),sp2.name) as srvRole,

    convert(char(25),dbp.name) as dbUser,

    convert(char(25),dbp2.name) as dbRole

    from

    sys.server_principals as sp join

    sys.database_principals as dbp on [sp].[sid]=[dbp].[sid] join

    sys.database_role_members as dbrm on [dbp].[principal_Id]=[dbrm].[member_principal_Id] join

    sys.database_principals as dbp2 on [dbrm].[role_principal_id]=[dbp2].[principal_id] left join

    sys.server_role_members as srm on [sp].[principal_id]=[srm].[member_principal_id] left join

    sys.server_principals as sp2 on [srm].[role_principal_id]=[sp2].[principal_id]'

    EXEC sp_MSForEachdb @cmd1

    GO

    ** The Audit table that needs to be populated sits in the AW database and the select script needs to be executed againts all database. Im not sure if I have correct above.

  • Try changing:

    + 'Use ?

    to

    + 'Use [?]

    Wayne
    Microsoft Certified Master: SQL Server 2008
    Author - SQL Server T-SQL Recipes


    If you can't explain to another person how the code that you're copying from the internet works, then DON'T USE IT on a production system! After all, you will be the one supporting it!
    Links:
    For better assistance in answering your questions
    Performance Problems
    Common date/time routines
    Understanding and Using APPLY Part 1 & Part 2

  • I tried Use [?] and also Use ''?'' both returned the same error msg as below

    Msg 156, Level 15, State 1, Line 1

    Incorrect syntax near the keyword 'Use'.

    Msg 102, Level 15, State 1, Line 19

    Incorrect syntax near 'principal_id'.

    Here is what I get when i do print @cmd1

    IF '?' NOT IN('master', 'model', 'tempdb', 'msdb')BEGIN Print 'Populating Login Audit table for ?...'; INSERT [AW].[dbo].[Audit]([Login Type],srvLogin,srvRole,dbUser,dbRole) Use [?]

    select

    [Login Type]=

    case sp.type

    when 'u' then 'WIN'

    when 's' then 'SQL'

    when 'g' then 'GRP'

    end,

    convert(char(45),sp.name) as srvLogin,

    convert(char(45),sp2.name) as srvRole,

    convert(char(25),dbp.name) as dbUser,

    convert(char(25),dbp2.name) as dbRole

    from

    sys.server_principals as sp join

    sys.database_principals as dbp on [sp].[sid]=[dbp].[sid] join

    sys.database_role_members as dbrm on [dbp].[principal_Id]=[dbrm].[member_principal_Id] join

    sys.database_principals as dbp2 on [dbrm].[role_principal_id]=[dbp2].[principal_id] left join

    sys.server_role_members as srm on [sp].[principal_id]=[srm].[member_principal_id] left join

    sys.server_principals as sp2 on [srm].[role_principal_id]=[sp2].[principal_id]

  • I have changed my code a little as well and now I get different error message

    DECLARE @cmd1 nvarchar(2000)

    SET @cmd1 = 'IF ''?'' NOT IN(''master'', ''model'', ''tempdb'', ''msdb'')' + 'BEGIN '

    + 'Print ''Populating Login Audit table for ?...''; '

    + 'INSERT INTO [AW]..[Audit]([Login Type],srvLogin,srvRole,dbUser,dbRole) ' +

    'select

    [Login Type]=

    case sp.type

    when ''u'' then ''WIN''

    when ''s'' then ''SQL''

    when ''g'' then ''GRP''

    end,

    convert(varchar(80),sp.name) as srvLogin,

    convert(varchar(50),sp2.name) as srvRole,

    convert(varchar(50),dbp.name) as dbUser,

    convert(varchar(50),dbp2.name) as dbRole

    from

    ''?''.sys.server_principals as sp join

    ''?''.sys.database_principals as dbp on [sp].[sid]=[dbp].[sid] join

    ''?''.sys.database_role_members as dbrm on [dbp].[principal_Id]=[dbrm].[member_principal_Id] join

    ''?''.sys.database_principals as dbp2 on [dbrm].[role_principal_id]=[dbp2].[principal_id] left join

    ''?''.sys.server_role_members as srm on [sp].[principal_id]=[srm].[member_principal_id] left join

    ''?''.sys.server_principals as sp2 on [srm].[role_principal_id]=[sp2].[principal_id]'+

    'END'

    print @cmd1

    EXEC sp_MSForEachdb @cmd1

    GO

    Error

    Msg 102, Level 15, State 1, Line 13

    Incorrect syntax near 'master'.

    Msg 102, Level 15, State 1, Line 13

    Incorrect syntax near 'tempdb'.

    Msg 102, Level 15, State 1, Line 13

    Incorrect syntax near 'model'.

    Msg 102, Level 15, State 1, Line 13

    Incorrect syntax near 'msdb'.

    Msg 102, Level 15, State 1, Line 13

    Incorrect syntax near 'ReportServer'.

    Msg 102, Level 15, State 1, Line 13

    Incorrect syntax near 'ReportServerTempDB'.

    Msg 102, Level 15, State 1, Line 13

    Incorrect syntax near 'AdventureWorksDW2008R2'.

    Msg 102, Level 15, State 1, Line 13

    Incorrect syntax near 'AdventureWorksLT2008R2'.

    Msg 102, Level 15, State 1, Line 13

    Incorrect syntax near 'AdventureWorks'.

    Msg 102, Level 15, State 1, Line 13

    Incorrect syntax near 'AdventureWorksDW'.

    Msg 102, Level 15, State 1, Line 13

    Incorrect syntax near 'AdventureWorksLT'.

    1. I want to run a single query that give back a result set of all the sql users and permission a login has in all the databases in one server

    2. Next, I want to feed this information to a table [AW]..[Audit] in a specific database and store it there.

    --------------------------------------------------------------------------------

  • DECLARE @cmd1 nvarchar(2000)

    SET @cmd1 = 'IF ''?'' NOT IN(''master'', ''model'', ''tempdb'', ''msdb'')' + 'BEGIN '

    + 'Print ''Populating Login Audit table for ?...''; '

    + 'INSERT INTO [AW]..[Audit]([Login Type],srvLogin,srvRole,dbUser,dbRole) ' +

    'select

    [Login Type]=

    case sp.type

    when ''u'' then ''WIN''

    when ''s'' then ''SQL''

    when ''g'' then ''GRP''

    end,

    convert(varchar(80),sp.name) as srvLogin,

    convert(varchar(50),sp2.name) as srvRole,

    convert(varchar(50),dbp.name) as dbUser,

    convert(varchar(50),dbp2.name) as dbRole

    from

    [?].sys.server_principals as sp join

    [?].sys.database_principals as dbp on [sp].[sid]=[dbp].[sid] join

    [?].sys.database_role_members as dbrm on [dbp].[principal_Id]=[dbrm].[member_principal_Id] join

    [?].sys.database_principals as dbp2 on [dbrm].[role_principal_id]=[dbp2].[principal_id] left join

    [?].sys.server_role_members as srm on [sp].[principal_id]=[srm].[member_principal_id] left join

    [?].sys.server_principals as sp2 on [srm].[role_principal_id]=[sp2].[principal_id]'+

    'END'

    print @cmd1

    EXEC sp_MSForEachdb @cmd1

    GO

    Wayne
    Microsoft Certified Master: SQL Server 2008
    Author - SQL Server T-SQL Recipes


    If you can't explain to another person how the code that you're copying from the internet works, then DON'T USE IT on a production system! After all, you will be the one supporting it!
    Links:
    For better assistance in answering your questions
    Performance Problems
    Common date/time routines
    Understanding and Using APPLY Part 1 & Part 2

  • Thank you so much WayneS :-D.

    The [] did the trick

  • LOOKUP_BI-756009 (11/2/2010)


    Thank you so much WayneS :-D.

    The [] did the trick

    I'm glad it worked for you. I have to admit, I thought you had used double-quotes there (which should have been okay), and it wasn't until I copied it and tried to run it that I saw they were just doubled-up single-quotes.

    Wayne
    Microsoft Certified Master: SQL Server 2008
    Author - SQL Server T-SQL Recipes


    If you can't explain to another person how the code that you're copying from the internet works, then DON'T USE IT on a production system! After all, you will be the one supporting it!
    Links:
    For better assistance in answering your questions
    Performance Problems
    Common date/time routines
    Understanding and Using APPLY Part 1 & Part 2

Viewing 7 posts - 1 through 6 (of 6 total)

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