Passwords are Case Sensitive in Oracle11g

The passwords in Oracle11g are case sensitive. All new users created in the 11g database have case sensitive password by default. For databases upgraded from earlier releases, the passwords are not case sensitive for existing accounts. They become case sensitive when you change password. A new column PASSWORD_VERSIONS is added to DBA_USERS view. A value ‘10G 11G’ in this column indicates that case sensitivity is enforced for the account.
The PASSWORD column is still available in DBA_USERS view, it is not populated anymore. For external authenticated or global accounts, the PASSWORD column indicates such.
select username, password_versions, password from dba_users;

USERNAME                       PASSWORD PASSWORD
------------------------------ -------- ---------------
MGMT_VIEW                      10G 11G
SYS                            10G 11G
SYSTEM                         10G 11G
SAMUEL                                  EXTERNAL
BTHOMAS                        10G 11G
ANONYMOUS
XDB                            10G 11G

 

Disable Case Sensitive Passwords
Oracle11g has a new parameter to disable the password case sensitivity – SEC_CASE_SENSITIVE_LOGON. This parameter is set to TRUE by default. Change to FALSE for pre-Oracle11g password behavior. This parameter can be changed using ALTER SYSTEM.
SYSDBA/SYSOPER password
The password file created using orapwd utility is also case sensitive by default. To make the password for SYS and SYSDBA/SYSOPER case insensitive, include flag ingnorecase=y in the command line.
$ orapwd file=L11GR1.ora ignorecase=y
Enter password for SYS:

 

DB Links
When connecting to an Oracle11g database with default SEC_CASE_SENSITIVE_LOGON using a database link from pre-11g database, make sure the database password in Oracle11g database is set up as ALL UPPERCASE. Pre-Oracle11g databases send password in uppercase for db link connections. For 11g to 11g, the password case must be the same; for 11g to pre-11g database, the password case does not matter.
To Pre-Oracle11g
To Oracle11g
From Pre-Oracle11g
Case does not matter
Uppercase
From Oracle11g
Case does not matter
Same case
Users with default passwords
Oracle11g has a new very useful view to list the database accounts that have default password – DBA_USERS_WITH_DEFPWD. This view has only one column – USERNAME. By default the Oracle system accounts and example accounts are locked in Oracle11g.
select * from dba_users_with_defpwd;

USERNAME
------------------------------
DIP
MDSYS
WK_TEST
CTXSYS
HR
OUTLN
EXFSYS
SCOTT
MDDATA
ORDPLUGINS
ORDSYS
XDB
SI_INFORMTN_SCHEMA
WMSYS

 

 

Read Only Tables [Orig Published Apr 2000]


In Oracle (all versions including 10g) you can make a tablespace read only, but not a single table. To make a table read only, you need to have that table in its own tablespace. If the tablespace has many tables, then you can either make all the tables read only or not. For large or critical tables, you can have the tables that need to be made read only grouped together in tablespaces. This is especially important when you’re are partitioning large tables. For example, if you partition a table that loads historical data, you can make the older partitions read only by making their corresponding tablespace read only.
To make the tablespace read only, issue the command:

ALTER TABLESPACE READ ONLY;

To make the tablespace back to read write mode, issue the command:

ALTER TABLESPACE READ WRITE;

FYI, you cannot make the SYSTEM tablespace to READ ONLY. You can drop a table from the read only tablespace, but not truncate, update, delete or insert.
So, what do you do if you need to make just one table read only, not all the tables in the tablespace…. Well, you can use triggers. Create a trigger which fires for all insert, update and delete operations on the table… Here is an example:

SQL> create or replace trigger emp_read_only
2 before insert or update or delete
3 on emp
4 begin
5 raise_application_error (-20001, 'Table EMP is read only, you cannot modify data.');
6 end;
7 /

Trigger created.

SQL> delete from emp;
delete from emp
*
ERROR at line 1:
ORA-20001: Table EMP is read only, you cannot modify data.
ORA-06512: at "BIJU.EMP_READ_ONLY", line 2
ORA-04088: error during execution of trigger 'BIJU.EMP_READ_ONLY'
Update:
As of Oracle11g, a new clause is introduced in the ALTER TABLE statement, that can make a table to read-only.
ALTER TABLE READ ONLY;

If you try to perform insert or update or delete on read-only table, you get an ORA-12081 error. The nice part about this feature is you are not able to do TRUNCATE operation on a read-only table. Remember, even if the tablespace is read-only, you can truncate a table. You can perform operations on index associated with read-only tables.
To resume normal update activity on the table, perform 

ALTER TABLE READ WRITE;
A new column READ_ONLY is added to DBA_TABLES. To list all the read-only tables in the database, you could do
select owner, table_name, tablespace_name
from dba_tables
where read_only = ‘YES’;