During the Data Guard round table of the excellent UKOUG Tech18 conference I got aware of this topic that I’d like to share with the Oracle community:
What is the locking behavior for user accounts in an environment where users may connect to the primary as well as to the standby database?
User gets locked on the primary
SQL> alter profile default limit failed_login_attempts 2;
Profile altered.
SQL> create user adam identified by adam;
User created.
SQL> grant create session to adam;
Grant succeeded.
SQL> connect adam/wrong@prima
ERROR:
ORA-01017: invalid username/password; logon denied
Warning: You are no longer connected to ORACLE.
SQL> connect adam/wrong@prima
ERROR:
ORA-01017: invalid username/password; logon denied
SQL> connect adam/wrong@prima
ERROR:
ORA-28000: The account is locked.
I changed the default profile so the account lock happens faster. The change of the default profile reaches the standby via redo apply. The same goes for account locks that happened on the primary like above.
Standby inherits the locked accounts from primary
SQL> connect adam/wrong@physt
ERROR:
ORA-28000: The account is locked.
This inherited lock cannot be unlocked on the standby:
SQL> connect sys/oracle@physt as sysdba Connected. SQL> alter user adam account unlock; alter user adam account unlock * ERROR at line 1: ORA-28015: account unlock attempted on read-only database but a conflicting account lockout on the primary exists
The account can only be unlocked on the primary and that implictly unlocks it on the standby too:
SQL> connect sys/oracle@prima as sysdba Connected. SQL> alter user adam account unlock; User altered. SQL> connect adam/adam@prima Connected. SQL> connect adam/adam@physt Connected.
Account gets locked on the standby only
SQL> connect adam/wrong@physt
ERROR:
ORA-01017: invalid username/password; logon denied
Warning: You are no longer connected to ORACLE.
SQL> connect adam/wrong@physt
ERROR:
ORA-01017: invalid username/password; logon denied
SQL> connect adam/wrong@physt
ERROR:
ORA-28000: The account is locked.
This lock at the standby is kept there in memory only and doesn’t impact the primary:
SQL> connect adam/adam@prima Connected.
It can be unlocked on the standby:
SQL> connect sys/oracle@physt as sysdba Connected. SQL> alter user adam account unlock; User altered. SQL> connect adam/adam@physt Connected.
Standby locks are kept in memory
After a restart, the lock is gone:
SQL> connect adam/wrong@physt
ERROR:
ORA-01017: invalid username/password; logon denied
Warning: You are no longer connected to ORACLE.
SQL> connect adam/wrong@physt
ERROR:
ORA-01017: invalid username/password; logon denied
SQL> connect adam/wrong@physt
ERROR:
ORA-28000: The account is locked.
SQL> connect sys/oracle@physt as sysdba
Connected.
SQL> shutdown immediate
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> startup
ORACLE instance started.
Total System Global Area 629143384 bytes
Fixed Size 8660824 bytes
Variable Size 180355072 bytes
Database Buffers 436207616 bytes
Redo Buffers 3919872 bytes
Database mounted.
Database opened.
SQL> connect adam/adam@physt
Connected.
Role change involving a restart of the standby
That will also lose the previous locks that have been done at the standby only:
SQL> connect adam/wrong@physt
ERROR:
ORA-01017: invalid username/password; logon denied
Warning: You are no longer connected to ORACLE.
SQL> connect adam/wrong@physt
ERROR:
ORA-01017: invalid username/password; logon denied
SQL> connect adam/wrong@physt
ERROR:
ORA-28000: The account is locked.
SQL> exit
[oracle@uhesse ~]$ dgmgrl sys/oracle@prima
DGMGRL for Linux: Release 18.0.0.0.0 - Production on Fri Dec 7 08:28:59 2018
Version 18.3.0.0.0
Copyright (c) 1982, 2018, Oracle and/or its affiliates. All rights reserved.
Welcome to DGMGRL, type "help" for information.
Connected to "prima"
Connected as SYSDBA.
DGMGRL> switchover to physt;
Performing switchover NOW, please wait...
Operation requires a connection to database "physt"
Connecting ...
Connected to "physt"
Connected as SYSDBA.
New primary database "physt" is opening...
Operation requires start up of instance "prima" on database "prima"
Starting instance "prima"...
Connected to an idle instance.
ORACLE instance started.
Database mounted.
Database opened.
Connected to "prima"
Switchover succeeded, new primary is "physt"
DGMGRL> show configuration;
Configuration - myconf
Protection Mode: MaxPerformance
Members:
physt - Primary database
prima - Physical standby database
Fast-Start Failover: DISABLED
Configuration Status:
SUCCESS (status updated 18 seconds ago)
DGMGRL> exit
[oracle@uhesse ~]$ sqlplus /nolog
SQL*Plus: Release 18.0.0.0.0 - Production on Fri Dec 7 08:31:16 2018
Version 18.3.0.0.0
Copyright (c) 1982, 2018, Oracle. All rights reserved.
SQL> connect adam/adam@prima
Connected.
SQL> connect adam/adam@physt
Connected.
I did the tests on 18c but I don’t think this is a new feature. I just didn’t have that topic on the radar before. Which is one reason why we go to conferences, right? 🙂
#1 von Sai Prathyush am Dezember 7, 2018 - 22:10
I saw this behavior even in 12c , and account got unlocked on standby itself.
#2 von Vineet Kulria am November 23, 2020 - 13:10
How does the standby database know its an second attempt on database if db is in read only mode ?