When you need to modify the open mode of all your PDBs at the same time (look at this post if you want to change the open mode of only a specific pluggable database) you can use ALTER PLUGGABLE DATABASE command and the ALL option.
As usual you have to ensure that the current container is the root.SQL> SELECT SYS_CONTEXT ('USERENV', 'CON_NAME') FROM DUAL; SYS_CONTEXT('USERENV','CON_NAME') -------------------------------------------------------------------------------- CDB$ROOTThe following statement for example changes the open mode of all your pluggable databases at the same time.
SQL>ALTER PLUGGABLE DATABASE ALL CLOSE IMMEDIATE; Pluggable database altered. SQL> select NAME, OPEN_MODE, CON_ID from V$PDBS; NAME OPEN_MODE CON_ID ------------------------------ ---------- ---------- PDB$SEED READ ONLY 2 PDB001 MOUNTED 3 PDB002 MOUNTED 4When you need to change the open mode of all pluggable database except for listed ones you can include also the EXCEPT option as in the following example:
SQL> ALTER PLUGGABLE DATABASE ALL EXCEPT PDB001 OPEN READ WRITE; Pluggable database altered. SQL> select NAME, OPEN_MODE, CON_ID from V$PDBS; NAME OPEN_MODE CON_ID ------------------------------ ---------- ---------- PDB$SEED READ ONLY 2 PDB001 MOUNTED 3 PDB002 READ WRITE 4To open all my pluggable databases I can simply execute the following command. It doesn't take care that PDB002 is already open in READ WRITE mode: any error is returned because the pluggable databases are in different open mode.
SQL> ALTER PLUGGABLE DATABASE ALL OPEN READ WRITE; Pluggable database altered. SQL> select NAME, OPEN_MODE, CON_ID from V$PDBS; NAME OPEN_MODE CON_ID ------------------------------ ---------- ---------- PDB$SEED READ ONLY 2 PDB001 READ WRITE 3 PDB002 READ WRITE 4However, if any of your pluggable databases are in READ ONLY mode, then the statement returns the error "ORA-65019: pluggable database PDB001 already open" as you can see:
SQL> ALTER PLUGGABLE DATABASE ALL CLOSE IMMEDIATE; Pluggable database altered. SQL> select NAME, OPEN_MODE, CON_ID from V$PDBS; NAME OPEN_MODE CON_ID ------------------------------ ---------- ---------- PDB$SEED READ ONLY 2 PDB001 MOUNTED 3 PDB002 MOUNTED 4 SQL> ALTER PLUGGABLE DATABASE PDB001 OPEN READ ONLY; Pluggable database altered. SQL> select NAME, OPEN_MODE, CON_ID from V$PDBS; NAME OPEN_MODE CON_ID ------------------------------ ---------- ---------- PDB$SEED READ ONLY 2 PDB001 READ ONLY 3 PDB002 MOUNTED 4 SQL> ALTER PLUGGABLE DATABASE ALL OPEN READ WRITE; ALTER PLUGGABLE DATABASE ALL OPEN READ WRITE * ERROR at line 1: ORA-65019: pluggable database PDB001 already openEven if the statement fails for pluggable database PDB001 it was able to open PDB002 as requested:
SQL> select NAME, OPEN_MODE, CON_ID from V$PDBS; NAME OPEN_MODE CON_ID ------------------------------ ---------- ---------- PDB$SEED READ ONLY 2 PDB001 READ ONLY 3 PDB002 READ WRITE 4To avoid the error ORA-65019 you can include the FORCE option in your command:
SQL> ALTER PLUGGABLE DATABASE ALL OPEN READ WRITE FORCE; Pluggable database altered. SQL> select NAME, OPEN_MODE, CON_ID from V$PDBS; NAME OPEN_MODE CON_ID ------------------------------ ---------- ---------- PDB$SEED READ ONLY 2 PDB001 READ WRITE 3 PDB002 READ WRITE 4To shutdown all your pluggable databases except one you can use the following command:
SQL> alter pluggable database all except PDB002 close immediate; Pluggable database altered. SQL> select name, open_mode from V$PDBS; NAME OPEN_MODE ------------------------------ ---------- PDB$SEED READ ONLY PDB001 MOUNTED PDB002 READ WRITETo list some of your pluggable databases you can use the comma as in the following example where I need to open all my pluggable databases (PDB001 and PDB002) except those listed (just PDB001 and PDB002!!). Nothing happens of course.
SQL> alter pluggable database all except PDB002,PDB001 open; Pluggable database altered. SQL> select name, open_mode from V$PDBS; NAME OPEN_MODE ------------------------------ ---------- PDB$SEED READ ONLY PDB001 MOUNTED PDB002 READ WRITE
No comments:
Post a Comment