oracle 19c pdb操作命令
查看数据库是否为CDB
SQL> select name, decode(cdb, 'YES', 'Multitenant Option enabled', 'Regular 12c Database: ') "Multitenant Option" , open_mode, con_id from v$database;
NAME Multitenant Option OPEN_MODE CON_ID
--------- ----------------------------- -------------------- ----------
EPPS Multitenant Option enabled READ WRITE 0
YES表示该数据库是CDB,如果是NO表示是NO-CDB(普通数据库)
查看容器:
show con_name
select name from v$containers ;
SELECT SYS_CONTEXT('USERENV','CON_NAME') FROM dual;
show pdbs ;
确认当前是cdb还是no-cdb ?
SQL> select name,cdb from v$database;
NAME CDB
--------- ---
ZARADB YES
查询pdb
col pdb_name for a30
select pdb_id,pdb_name,dbid,status,creation_scn from dba_pdbs;
select con_id,dbid,NAME,OPEN_MODE from v$pdbs;
PDB_ID PDB_NAME DBID STATUS CREATION_SCN
---------- ------------------------------ ---------- ------------- ------------
3 PDB1 3337485269 NORMAL 1909544
2 PDB$SEED 4072348290 NORMAL 1720741
SQL>show pdbs
CON_ID DBID NAME OPEN_MODE
---------- ---------- ------------------------------ ----------
2 4072348290 PDB$SEED READ ONLY
3 3337485269 PDB1 READ WRITE
直接创建pdb
CREATE PLUGGABLE DATABASE pdb2
ADMIN USER pdb2dba IDENTIFIED BY anbaisheng
STORAGE (MAXSIZE 2G MAX_SHARED_TEMP_SIZE 100M)
DEFAULT TABLESPACE tbs_pdb2 DATAFILE '/opt/oracle/oradata/ZARADB/datafile/pdb2_001.dbf' SIZE 25M AUTOEXTEND ON;
模板创建pdb
以现有pdb为模板创建,现有pdb必须在read only模式下才能被创建,否则报错
以pdb1为模板创建pdb2
drop pluggable database pdb2 including datafiles;
alter pluggable database pdb1 close;
alter pluggable database pdb1 open read only;
create pluggable database pdb2
from pdb1
file_name_convert =('/opt/oracle/oradata/ZARADB/E98BEB85B1A80C56E0439A02A8C05841/datafile/','/opt/oracle/oradata/ZARADB/datafile/pdb2');
打开、关闭pdb
alter pluggable database pdb2 close;
alter pluggable database all close;
alter pluggable database pdb2 close immediate;
alter pluggable database pdb2 open;
alter pluggable database all open;
删除pdb,与删除表空间类似,可以级联删除数据文件
drop pluggable database pdb2;
drop pluggable database pdb2 including datafiles;
unplug后pdb只能mount不能open
alter pluggable database pdb2 unplug into '/tmp/pdb2.xml';
unplug后删除pdb,再使用xml文件加回pdb
drop pluggable database pdb2;
create pluggable database pdb2 using '/tmp/pdb2.xml' nocopy;
在pdb管理用户权限:
alter session set container=PDBORCL;
GRANT CONNECT,RESOURCE,CREATE VIEW TO COMPANY IDENTIFIED BY <password> ;
grant create any directory to company;
ALTER USER companycompany QUOTA UNLIMITED ON sales;
GRANT RESOURCE TO company;
ALTER USER COMPANY DEFAULT TABLESPACE company_data TEMPORARY TABLESPACE company_temp;
连接到CDB
[oracle@Ora12c /]$ sqlplus / as sysdba
--查看CDB中可用的service:
SQL> SELECT name,pdb FROM v$services ORDER BY name;
--通过lsnrctl 也可以判断:
oracle@node1:/home/db/oracle$ lsnrctl status
....
(DESCRIPTION=(ADDRESS=(PROTOCOL=tcp)(HOST=node1)(PORT=1521)))
(DESCRIPTION=(ADDRESS=(PROTOCOL=ipc)(KEY=EXTPROC1521)))
Services Summary...
Service "86b637b62fdf7a65e053f706e80a27ca" has 1 instance(s).
Instance "testdb", status READY, has 1 handler(s) for this service...
Service "a2f51f35f5e34975e0536542a8c0adea" has 1 instance(s).
Instance "testdb", status READY, has 1 handler(s) for this service...
Service "testdb" has 1 instance(s).
Instance "testdb", status READY, has 1 handler(s) for this service...
Service "testdbXDB" has 1 instance(s).
Instance "testdb", status READY, has 1 handler(s) for this service...
Service "testpdb" has 1 instance(s).
Instance "testdb", status READY, has 1 handler(s) for this service...
The command completed successfully
[oracle@Ora12c /]$
通过这些service,就可以远程连接CDB。
--EZCONNECT
oracle@node1:/home/db/oracle$ sqlplus system/oracle@127.0.0.1:1521/testdb
oracle@node1:/home/db/oracle$ sqlplus system/oracle@127.0.0.1:1521/testpdb
--通过TNSNAMES.ORA连接:
在tnsnames.ora 中配置如下:
testdb=
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP)(HOST = 192.168.1.10)(PORT = 1521))
(CONNECT_DATA =
(SERVER = DEDICATED)
(SERVICE_NAME = testdb)
)
)
--连接:
oracle@node1:/home/db/oracle$ sqlplus system/oracle@testdb
SQL> show con_name
CON_NAME
CDB$ROOT
pdb切换
SQL> select con_id,name from v$pdbs ;
SQL> show con_name
SQL> SELECT SYS_CONTEXT('USERENV','CON_NAME') FROM dual;
SQL> show con_name
SQL> alter session set container=testpdb;
Session altered
SQL> show con_name ;
SQL> SELECT SYS_CONTEXT('USERENV','CON_NAME') FROM dual;
SYS_CONTEXT('USERENV','CON_NAM
TESTPDB
SQL>
SQL> alter session set container=CDB$ROOT ;
SQL> show con_name ;
SQL> SELECT SYS_CONTEXT('USERENV','CON_NAME') FROM dual;
SYS_CONTEXT('USERENV','CON_NAM
CDB$ROOT