CREATE PROCEDURE DBA.login_check( )
BEGIN
DECLARE INVALID_LOGON EXCEPTION FOR SQLSTATE '28000';
// Allow a maximum of 3 concurrent connections
IF( DB_PROPERTY( 'ConnCount' ) > 3 ) THEN
SIGNAL INVALID_LOGON;
ELSE
CALL sp_login_environment;
END IF;
END
go
GRANT EXECUTE ON DBA.login_check TO PUBLIC
go
SET OPTION PUBLIC.login_procedure='DBA.login_check'
go
CREATE TABLE DBA.ConnectionFailure(
pk INT PRIMARY KEY DEFAULT AUTOINCREMENT,
user_name CHAR(128) NOT NULL,
tm TIMESTAMP NOT NULL DEFAULT CURRENT TIMESTAMP
)
go
CREATE INDEX ConnFailTime ON DBA.ConnectionFailure(
user_name, tm )
go
CREATE EVENT ConnFail TYPE ConnectFailed
HANDLER
BEGIN
DECLARE usr CHAR(128);
SET usr = event_parameter( 'User' );
// Put a limit on the number of failures logged.
IF (SELECT COUNT(*) FROM DBA.ConnectionFailure
WHERE user_name = usr
AND tm >= DATEADD( minute, -30,
CURRENT TIMESTAMP )) < 20 THEN
INSERT INTO DBA.ConnectionFailure( user_name )
VALUES( usr );
COMMIT;
// Delete failures older than 7 days.
DELETE DBA.ConnectionFailure
WHERE user_name = usr
AND tm < dateadd( day, -7, CURRENT TIMESTAMP );
COMMIT;
END IF;
END
go
CREATE PROCEDURE DBA.login_check( )
BEGIN
DECLARE usr CHAR(128);
DECLARE INVALID_LOGON EXCEPTION FOR SQLSTATE '28000';
SET usr = CONNECTION_PROPERTY( 'Userid' );
// Block connection attempts from this user
// if 3 or more failed connection attempts have occurred
// within the past 30 minutes.
IF ( SELECT COUNT( * ) FROM DBA.ConnectionFailure
WHERE user_name = usr
AND tm >= DATEADD( minute, -30,
CURRENT TIMESTAMP ) ) >= 3 THEN
SIGNAL INVALID_LOGON;
ELSE
CALL sp_login_environment;
END IF;
END
go
GRANT EXECUTE ON DBA.login_check TO PUBLIC
go
SET OPTION PUBLIC.login_procedure='DBA.login_check'
go
CREATE PROCEDURE DBA.check_expired_login( )
BEGIN
DECLARE PASSWORD_EXPIRED EXCEPTION FOR SQLSTATE '08WA0';
IF( condition-to-check-for-expired-password ) THEN
SIGNAL PASSWORD_EXPIRED;
ELSE
CALL sp_login_environment;
END IF;
END;