Forum Discussion
Catch Error in a SQL Server Logon Trigger
- Dec 12, 2024
Yes, base on my test, I think it's correct.
After digging into the document of SQL Server and doing some testing, I feel I can tell you what the problem is and how to fix it:
- Don't return result in the trigger. The way you try to raise exception is select 10/0, this will raise a exception but not the exception you expect. select 1 has the same effect.
- Before the LOGON TRIGGER, an implicit transaction has been start, that's why when you want to refuse certain account login, you should use ROLLBACK, it cancel the login process. When a exception has been raised and you were not call ROLLBACK explicit in CATCH block, an implicit ROLLBACK will be called after the trigger executed. As you know, any data modifications made up to the point of ROLLBACK are rolled back. That's the reason your INSERT INTO ERROR_LOG not working.
- To confirm these points, add a ROLLBACK before the INSERT INTO in CATCH block, and change the value for [ERROR_DATA] to ERROR_MESSAGE(), you will get a exception message in the ERROE_LOG table.
Code below is base on your requiement, but the requirement that "in case of whatever error the login is allowed to login and write a error log" I cannot find a way to implement yet. Keeping work on it. And this code cannot be tested in my computer, so it could have incorrect things, you have to fix them by yourself.
ALTER TRIGGER [LOG_TRG_02]
ON ALL SERVER WITH EXECUTE AS 'SA'
FOR LOGON
AS
BEGIN
BEGIN TRY
IF ORIGINAL_LOGIN() = 'OMEGACAEVDEV1'
BEGIN
-- not allowed to logon
ROLLBACK;
-- Insert Trail of OMEGACAEVDEV1
EXEC [OmegaCoreAudit].[OMEGACA].[P_ACC_UNF_TRAIL]
0, 'trail_details', 'ip', 'server', 'db', 0 ;
END;
IF ORIGINAL_LOGIN() = 'OMEGACAEVDEV2'
BEGIN
-- Allow login and Insert Trail of OMEGACAEVDEV2
EXEC [OmegaCoreAudit].[OMEGACA].[P_ACC_UNF_TRAIL]
0, 'trail_details', 'ip', 'server', 'db', 0 ;
END;
END TRY
BEGIN CATCH
ROLLBACK; --refuse logon with exception, and make the insert statement atfer this work.
--I cannot find a way to allow login with exception yet.
INSERT INTO OmegaCoreAudit.OMEGACA.SYS_ERROR_LOG
([LOGIN_USER_NAME], [DB_USER_NAME], [USERHOST], [IP_ADDRESS], [OS_USER], [BG_JOB_ID], [ERROR_DATA])
VALUES
(ORIGINAL_LOGIN(), 'USER_NAME', 'USER_HOST', 'IP', NULL, NULL, ERROR_MESSAGE());
END CATCH
END
GO
So it is not a matter of writing a log in a table (transaction), or writing in a file (or using SQL).
The statement:
If an error goes on during logon trigger execution the user will NOT be able to log on (with or without try-catch).
... is correct ?
- rodgerkongDec 12, 2024Iron Contributor
Yes, base on my test, I think it's correct.
- akaraulliDec 13, 2024Brass Contributor
Thank You very much rodgerkong.
This brings me to ...
Statement 2:
The CATCH is working, It is just that the Insert to SYS_ERROR_LOG is not persisted, because the insert was not persisted by an implicit auto-rollback at the end of trigger execution.
My expression on the body of this Discussion, "CATCH is not working.", is wrong.- rodgerkongDec 17, 2024Iron Contributor
But if you call rollback before the insert statement, the error log will work, because the implicit transaction has completed.