关于PDB的几种启动方式

举报
Lucifer三思而后行 发表于 2021/10/28 10:02:01 2021/10/28
【摘要】 自从12C开始支持pdb以来,我们多多少少的接触或是使用了ORACLE的CDB+PDB的模式,对于数据库实例开启后,PDB为mount状态,需要再次开启,我想大家应该也觉得不是很方便。下面就来聊聊关于PDB启动的几种方式: 一、手动启动打开数据库实例时,默认PDB是mounted状态,需要手动执行命令打开PDB:SQL> show pdbs CON_ID CON_NAME OP...

自从12C开始支持pdb以来,我们多多少少的接触或是使用了ORACLE的CDB+PDB的模式,对于数据库实例开启后,PDB为mount状态,需要再次开启,我想大家应该也觉得不是很方便。

下面就来聊聊关于PDB启动的几种方式:

一、手动启动

打开数据库实例时,默认PDB是mounted状态,需要手动执行命令打开PDB:

SQL> show pdbs

    CON_ID CON_NAME			  OPEN MODE  RESTRICTED
---------- ------------------------------ ---------- ----------
	 2 PDB$SEED			  READ ONLY  NO
	 3 ORCL 			  MOUNTED

--启动所有PDB
SQL> alter pluggable database all open;

Pluggable database altered.

SQL> show pdbs

    CON_ID CON_NAME			  OPEN MODE  RESTRICTED
---------- ------------------------------ ---------- ----------
	 2 PDB$SEED			  READ ONLY  NO
	 3 ORCL 			  READ WRITE NO

这个方法,最为常见,但是每次开库都要去手动执行,在当今自动化运维的社会,显得很不自动化,如果为RAC数据库,需要每个实例都手动去开启。

二、触发器启动

--创建触发器,cdb启动时,open所有的pdb
CREATE TRIGGER open_all_pdbs
   AFTER STARTUP
   ON DATABASE
BEGIN
   EXECUTE IMMEDIATE 'alter pluggable database all open';
END open_all_pdbs;
  7  /

Trigger created.

--查看触发器
SQL> select owner,TRIGGER_NAME,TRIGGER_TYPE from dba_triggers where owner='SYS' and TRIGGER_NAME='OPEN_ALL_PDBS';

OWNER		     TRIGGER_NAME	  TRIGGER_TYPE
-------------------- -------------------- ----------------
SYS		     OPEN_ALL_PDBS	  AFTER EVENT

SQL> select text from all_source where type='TRIGGER' AND name='OPEN_ALL_PDBS';

TEXT
-----------------------------------------------------------------------------------
TRIGGER open_all_pdbs
   AFTER STARTUP
   ON DATABASE
BEGIN
   EXECUTE IMMEDIATE 'alter pluggable database all open';
END open_all_pdbs;

6 rows selected.

--测试触发器是否生效
SQL> show pdbs

    CON_ID CON_NAME			  OPEN MODE  RESTRICTED
---------- ------------------------------ ---------- ----------
	 2 PDB$SEED			  READ ONLY  NO
	 3 ORCL 			  READ WRITE NO
--关闭所有pdb
SQL> alter pluggable database all close;

Pluggable database altered.
--查看pdb是否全部关闭
SQL> show pdbs

    CON_ID CON_NAME			  OPEN MODE  RESTRICTED
---------- ------------------------------ ---------- ----------
	 2 PDB$SEED			  READ ONLY  NO
	 3 ORCL 			  MOUNTED
--关闭数据库实例
SQL> shutdown immediate
Database closed.
Database dismounted.
ORACLE instance shut down.
--启动数据库实例
SQL> startup
ORACLE instance started.

Total System Global Area 3355441944 bytes
Fixed Size		    9141016 bytes
Variable Size		  704643072 bytes
Database Buffers	 2634022912 bytes
Redo Buffers		    7634944 bytes
Database mounted.
Database opened.
--pdb已自动启动
SQL> show pdbs

    CON_ID CON_NAME			  OPEN MODE  RESTRICTED
---------- ------------------------------ ---------- ----------
	 2 PDB$SEED			  READ ONLY  NO
	 3 ORCL 			  READ WRITE NO

三、SAVE STATE

通过设置视图DBA_PDB_SAVED_STATES来控制PDB的启动模式:

--这里我们先DROP触发器
SQL> drop trigger OPEN_ALL_PDBS;

Trigger dropped.
SQL> 
SQL> select owner,TRIGGER_NAME,TRIGGER_TYPE from dba_triggers where owner='SYS' and TRIGGER_NAME='OPEN_ALL_PDBS';

no rows selected

SQL> select text from all_source where type='TRIGGER' AND name='OPEN_ALL_PDBS';

no rows selected

--设置state为open
SQL> show pdbs

    CON_ID CON_NAME			  OPEN MODE  RESTRICTED
---------- ------------------------------ ---------- ----------
	 2 PDB$SEED			  READ ONLY  NO
	 3 ORCL 			  READ WRITE NO
SQL> 
--记录当前所有pdb的启动状态
SQL> alter pluggable database all save state;

Pluggable database altered.

SQL> set line222
SQL> col con_name for a20
SQL> col instance_name for a20
SQL> select * from dba_pdb_saved_states;

    CON_ID CON_NAME		INSTANCE_NAME		CON_UID GUID				 STATE		RES
---------- -------------------- -------------------- ---------- -------------------------------- -------------- ---
	 3 ORCL 		lucifer 	      251291369 BF269544BE8B17F9E053AC01A8C0447F OPEN		NO

--重启数据库实例
SQL> shutdown immediate
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> startup
ORACLE instance started.

Total System Global Area 3355441944 bytes
Fixed Size		    9141016 bytes
Variable Size		  704643072 bytes
Database Buffers	 2634022912 bytes
Redo Buffers		    7634944 bytes
Database mounted.
Database opened.
--PDB已自动启动
SQL> show pdbs

    CON_ID CON_NAME			  OPEN MODE  RESTRICTED
---------- ------------------------------ ---------- ----------
	 2 PDB$SEED			  READ ONLY  NO
	 3 ORCL 			  READ WRITE NO
--如何取消自动启动
--先关闭pdb
SQL> alter pluggable database ORCL close;

Pluggable database altered.

SQL> show pdbs

    CON_ID CON_NAME			  OPEN MODE  RESTRICTED
---------- ------------------------------ ---------- ----------
	 2 PDB$SEED			  READ ONLY  NO
	 3 ORCL 			  MOUNTED

--记录当前关闭状态
SQL> alter pluggable database ORCL save state;

Pluggable database altered.

SQL> select * from dba_pdb_saved_states;

no rows selected

--重启数据库实例
SQL> shutdown immediate
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> startup
ORACLE instance started.

Total System Global Area 3355441944 bytes
Fixed Size		    9141016 bytes
Variable Size		  704643072 bytes
Database Buffers	 2634022912 bytes
Redo Buffers		    7634944 bytes
Database mounted.
Database opened.

--pdb为mounted状态
SQL> show pdbs

    CON_ID CON_NAME			  OPEN MODE  RESTRICTED
---------- ------------------------------ ---------- ----------
	 2 PDB$SEED			  READ ONLY  NO
	 3 ORCL 			  MOUNTED

总结:

三种方式都可以打开PDB,孰优孰劣大家自可斟酌。

个人建议是第三种方式,从12C开始就可以支持,设置简单,方便快捷,缺点是基于实例的,如果是RAC需要实例都需要去保存一下。不像触发器是基于数据库的,当然触发器可以是万能的。

【声明】本内容来自华为云开发者社区博主,不代表华为云及华为云开发者社区的观点和立场。转载时必须标注文章的来源(华为云社区)、文章链接、文章作者等基本信息,否则作者和本社区有权追究责任。如果您发现本社区中有涉嫌抄袭的内容,欢迎发送邮件进行举报,并提供相关证据,一经查实,本社区将立刻删除涉嫌侵权内容,举报邮箱: cloudbbs@huaweicloud.com
  • 点赞
  • 收藏
  • 关注作者

评论(0

0/1000
抱歉,系统识别当前为高风险访问,暂不支持该操作

全部回复

上滑加载中

设置昵称

在此一键设置昵称,即可参与社区互动!

*长度不超过10个汉字或20个英文字符,设置后3个月内不可修改。

*长度不超过10个汉字或20个英文字符,设置后3个月内不可修改。