How to fix Logon trigger issue

  • hi,

    I have this trigger (see below) and I get the login failure due to trigger execution (SQL error 17892) every time I try to login. If I drop the trigger (drop trigger <trigger name> on all server) the error is gone but I need to have that trigger and also need the user's to log in.

    Can anyone look at the code and help me to fix the trigger so that I can use that trigger to capture login information into that table.

    create trigger [Tr_ServerLoginAudit]

    on all server for logon

    as

    begin

    INSERT INTO PG_LoginAudit

    select @@SPID, SYSTEM_USER, HOST_NAME(), HOST_ID(), CURRENT_TIMESTAMP, APP_NAME (), DB_NAME()

    END

    GO

    thanks

  • Look in the SQL error log. iirc, errors that occur in a login trigger's execution are logged to the error log. Check what's there.

    What's the schema of that table?

    What database is it in?

    Does everyone have insert permissions on it?

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • this is the schema and this table is created I the user database

    [SPID] [int] NULL,

    [LoginName] [varchar](512) NULL,

    [HostName] [varchar](512) NULL,

    [HostID] [int] NULL,

    [LoginTime] [datetime] NULL,

    [ApplicationName] [varchar](512) NULL,

    [DatabaseName] [varchar] (10)

    which login should I give insert permission to this table and why it is blocking all user's to log into the database

  • Still need...

    GilaMonster (9/5/2013)


    Look in the SQL error log. iirc, errors that occur in a login trigger's execution are logged to the error log. Check what's there.

    As for permissions, unless you use impersonation on the procedure, every single person who can log into that server needs insert rights on that table or the trigger will fail.

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • you mean use impersonation on that trigger?

  • Please look in the SQL error log and see what error messages were logged there from that login trigger.

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • the error message:

    "login failed for login <login name> due to trigger execution."

    if I change the trigger (see below) then also I get the login failed error.

    create trigger [LoginAudit]

    on all server with execute as 'sa'

    for logon

    as

    begin

    INSERT INTO Audit_Log

    select @@SPID, SYSTEM_USER, HOST_NAME(), HOST_ID(), CURRENT_TIMESTAMP, APP_NAME (), DB_NAME()

    END

    GO

  • Not the error message that you get. Open up the SQL Server error log and see if there are any errors in there that may suggest why the trigger failed. If not, change your trigger as follows and then see what's in the error log after another login attempt

    CREATE TRIGGER [LoginAudit] ON ALL SERVER

    WITH EXECUTE AS 'sa'

    FOR LOGON

    AS

    BEGIN

    BEGIN TRY

    INSERT INTO Audit_Log

    SELECT @@SPID ,

    SYSTEM_USER ,

    HOST_NAME() ,

    HOST_ID() ,

    CURRENT_TIMESTAMP ,

    APP_NAME() ,

    DB_NAME()

    END TRY

    BEGIN CATCH

    PRINT CAST(ERROR_NUMBER() AS VARCHAR(5)) + ' ' + ERROR_MESSAGE();

    END CATCH

    END

    GO

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • sorry for not making myself clear but that is what I saw in the SQL Server error log.

    Logon failed for login <login name> due to trigger execution. [CLIENT: <local machine>]

    Error: 17892, Severity: 20, State:1.

  • and what messages (in the error log) does the revised trigger above produce?

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • I changed the trigger but got the same login error when I tried to log in and the SQL Server error log also has the same error.

    but I found out one thing.

    if I create the table in master database and then create the trigger. it works fine. I am able to log into the user database and I believe other user's will also be able to log in

    but when I run a select on the Audit table, the DB_NAME column only shows master and not the user database.

  • the sql server error log shows the same error even after creating the revised trigger.

    but if i create the Audit table in the master database and then it works fine. i am able to log in and i believe all other users will be able to do the same but when i run a select statement on that Audit table i see only master listed in the DB_NAME column and not the user database.

  • Then...

    INSERT INTO <database name>.<schema_name>.Audit_Log...

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • i got the same error message after creating the revised trigger

  • changing the insert statement in the trigger worked but why in the SYSTEM_USER column and the DB_NAME column I see only sa and master respectively.

    i clicked options and changed the database to the users database and then logged in but when i select the Audit table still it shows up as "master" in the DB_NAME column and "sa" in the SYSTEM_USER column

    can you please help..

Viewing 15 posts - 1 through 15 (of 20 total)

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