创建和连接可插拔数据库PDB(PLUGGABLE DATABASE)

2024年 2月 2日 64.8k 0

因为安装的的oracle18c express edition版本,该版本对CUP和内存的使用数量做了限制,且只支持创建一个数据库实例,但对创建可插拔数据库数量没有限制。

1、容器数据库、普通数据库概念入门

是ORACLE12c新引入的特性,这个特性允许CDB容器数据库中创建并且维护多个数据库,在CDB中创建的数据库被称为PDB,每个PDB在CDB中是独立的,在单独使用PDB时与普通数据库无差别。CDB根容器数据库的主要作用就是容纳所有相关的PDB元数据,以及在CDB中对虽有PDB进行管理。

(1)ROOT:ROOT容器数据库,是CDB环境中的根数据库,在跟数据库中含有主数据字典视图,其中包含了与ROOT容器有关的元数据和CDB中包含的所有PDB信息,在CDB环境中被标识为CDB$ROOT,每个CDB环境中只能有一个ROOT容器数据库。

(2)PDB SEED:PDB SEED为PDB的种子,其中提供了数据文件,在PDB环境中被标识为PDB$SEED,是创建PDB的模板,可以连接PDB$SEED但是不能执行任何事务,因为PDB$SEED是只读的,不可修改。

(3)PDBS:PDBS数据库,在CDB环境中每个PDB都是独立存在的,与传统ORACLE数据库无差别,每个PDB拥有自己的数据文件和OBJECTS,唯一的区别就是PDB可以插入到PDB中,以及从CDB中拔出。当用户连接到PDB时不会感觉到根容器和其他PDB的存在。

普通数据库 = 非容器数据库(non-container database)

容器数据库 (container database) --- 多租户架构,也叫云数据库。

用DBCA创建数据库的时候,可以选择创建普通数据库和创建容器数据库。容器数据库体系结构如下:

创建和连接可插拔数据库PDB(PLUGGABLE DATABASE)-1

容器数据库体系结构图.png

2、创建一个名为BI的可插拔数据库(PDB)

创建PDB有两种方式,一种是用DBCA图形化配置工具,一种是命令行文本配置工具。
这里演示用命令行方式创建PDB数据库:

1、因为PDB是由PDBSEED中文件创建而来,所以要确定PDBSEED文件位置。

[oracle@hd01 XE]$ pwd
/opt/oracle/oradata/XE
[oracle@hd01 XE]$ ll
total 2096596
-rw-r-----. 1 oracle oinstall 18726912 Dec 19 23:53 control01.ctl
-rw-r-----. 1 oracle oinstall 18726912 Dec 19 23:53 control02.ctl
drwxr-x---. 2 oracle oinstall 111 Dec 12 10:27 pdbseed
-rw-r-----. 1 oracle oinstall 209715712 Dec 19 23:53 redo01.log
-rw-r-----. 1 oracle oinstall 209715712 Dec 19 22:22 redo02.log
-rw-r-----. 1 oracle oinstall 209715712 Dec 19 22:22 redo03.log
-rw-r-----. 1 oracle oinstall 524296192 Dec 19 23:52 sysaux01.dbf
-rw-r-----. 1 oracle oinstall 880812032 Dec 19 23:52 system01.dbf
-rw-r-----. 1 oracle oinstall 34611200 Dec 19 09:11 temp01.dbf
-rw-r-----. 1 oracle oinstall 68165632 Dec 19 23:52 undotbs01.dbf
-rw-r-----. 1 oracle oinstall 5251072 Dec 19 22:22 users01.dbf
drwxr-x---. 2 oracle oinstall 104 Dec 12 10:39 XEPDB1

2、创建目标PDB文件存放目录,以要创建的该PDB名字命名

[oracle@hd01 XE]$ mkdir BI
[oracle@hd01 XE]$ ll
total 2096596
drwxr-xr-x. 2 oracle oinstall 6 Dec 19 23:58 BI
-rw-r-----. 1 oracle oinstall 18726912 Dec 19 23:58 control01.ctl
-rw-r-----. 1 oracle oinstall 18726912 Dec 19 23:58 control02.ctl
drwxr-x---. 2 oracle oinstall 111 Dec 12 10:27 pdbseed
-rw-r-----. 1 oracle oinstall 209715712 Dec 19 23:58 redo01.log
-rw-r-----. 1 oracle oinstall 209715712 Dec 19 22:22 redo02.log
-rw-r-----. 1 oracle oinstall 209715712 Dec 19 22:22 redo03.log
-rw-r-----. 1 oracle oinstall 524296192 Dec 19 23:52 sysaux01.dbf
-rw-r-----. 1 oracle oinstall 880812032 Dec 19 23:57 system01.dbf
-rw-r-----. 1 oracle oinstall 34611200 Dec 19 09:11 temp01.dbf
-rw-r-----. 1 oracle oinstall 68165632 Dec 19 23:57 undotbs01.dbf
-rw-r-----. 1 oracle oinstall 5251072 Dec 19 22:22 users01.dbf
drwxr-x---. 2 oracle oinstall 104 Dec 12 10:39 XEPDB1

3、从PDBSEED创建PDB
在根容器环境下执行以下创建语句

[oracle@hd01 XE]$ sqlplus /nolog
SQL> conn sys/123456 as sysdba;
Connected.
SQL> show con_name;

CON_NAME
------------------------------
CDB$ROOT
SQL> create pluggable database bi
2 admin user bi_admin identified by 123456 roles=(connect)
3 file_name_convert=('/opt/oracle/oradata/XE/pdbseed/','/opt/oracle/oradata/XE/BI/');

Pluggable database created.

4、打开新创建BI PDB数据库

SQL> alter pluggable database bi open;

Pluggable database altered.

5、配置oracle网络配置文件

在tnsname.ora文件中追加上:
BI =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP)(HOST = hd01)(PORT = 1521))
(CONNECT_DATA =
(SERVER = DEDICATED)
(SERVICE_NAME = BI)
)
)

LISTENER_BI =
(ADDRESS = (PROTOCOL = TCP)(HOST = hd01)(PORT = 1521))

[oracle@hd01 admin]$ cat tnsnames.ora
# tnsnames.ora Network Configuration File: /opt/oracle/product/18c/dbhomeXE/network/admin/tnsnames.ora
# Generated by Oracle configuration tools.

LISTENER_XEPDB1 =
(ADDRESS = (PROTOCOL = TCP)(HOST = hd01)(PORT = 1521))

XE =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP)(HOST = hd01)(PORT = 1521))
(CONNECT_DATA =
(SERVER = DEDICATED)
(SERVICE_NAME = XE)
)
)

LISTENER_XE =
(ADDRESS = (PROTOCOL = TCP)(HOST = hd01)(PORT = 1521))

XEPDB1 =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP)(HOST = hd01)(PORT = 1521))
(CONNECT_DATA =
(SERVER = DEDICATED)
(SERVICE_NAME = XEPDB1)
)
)

BI =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP)(HOST = hd01)(PORT = 1521))
(CONNECT_DATA =
(SERVER = DEDICATED)
(SERVICE_NAME = BI)
)
)

LISTENER_BI =
(ADDRESS = (PROTOCOL = TCP)(HOST = hd01)(PORT = 1521))

5、重启数据库、查看监听服务

[oracle@hd01 admin]$ su root
Password:
[root@hd01 admin]# systemctl stop oracle-xe-18c
[root@hd01 admin]# systemctl start oracle-xe-18c
[root@hd01 admin]# su oracle
[oracle@hd01 admin]$ lsnrctl status

LSNRCTL for Linux: Version 18.0.0.0.0 - Production on 19-DEC-2020 22:23:00

Copyright (c) 1991, 2018, Oracle. All rights reserved.

Connecting to (DESCRIPTION=(ADDRESS=(PROTOCOL=TCP)(HOST=hd01)(PORT=1521)))
STATUS of the LISTENER
------------------------
Alias LISTENER
Version TNSLSNR for Linux: Version 18.0.0.0.0 - Production
Start Date 19-DEC-2020 22:22:28
Uptime 0 days 0 hr. 0 min. 32 sec
Trace Level off
Security ON: Local OS Authentication
SNMP OFF
Default Service XE
Listener Parameter File /opt/oracle/product/18c/dbhomeXE/network/admin/listener.ora
Listener Log File /opt/oracle/diag/tnslsnr/hd01/listener/alert/log.xml
Listening Endpoints Summary...
(DESCRIPTION=(ADDRESS=(PROTOCOL=tcp)(HOST=hd01)(PORT=1521)))
(DESCRIPTION=(ADDRESS=(PROTOCOL=ipc)(KEY=EXTPROC1521)))
(DESCRIPTION=(ADDRESS=(PROTOCOL=tcps)(HOST=127.0.0.1)(PORT=5500))(Security=(my_wallet_directory=/opt/oracle/product/18c/dbhomeXE/admin/XE/xdb_wallet))(Presentation=HTTP)(Session=RAW))
Services Summary...
Service "XE" has 1 instance(s).
Instance "XE", status READY, has 1 handler(s) for this service...
Service "XEXDB" has 1 instance(s).
Instance "XE", status READY, has 1 handler(s) for this service...
Service "b647330b1baf49cce053647ea8c0ad60" has 1 instance(s).
Instance "XE", status READY, has 1 handler(s) for this service...
Service "b6ddaa94879342bfe053647ea8c08dcc" has 1 instance(s).
Instance "XE", status READY, has 1 handler(s) for this service...
Service "bi" has 1 instance(s).
Instance "XE", status READY, has 1 handler(s) for this service...
Service "xepdb1" has 1 instance(s).
Instance "XE", status READY, has 1 handler(s) for this service...
The command completed successfully
[oracle@hd01 admin]$ tnsping bi

TNS Ping Utility for Linux: Version 18.0.0.0.0 - Production on 19-DEC-2020 22:23:27

Copyright (c) 1997, 2018, Oracle. All rights reserved.

Used parameter files:
/opt/oracle/product/18c/dbhomeXE/network/admin/sqlnet.ora

Used TNSNAMES adapter to resolve the alias
Attempting to contact (DESCRIPTION = (ADDRESS = (PROTOCOL = TCP)(HOST = hd01)(PORT = 1521)) (CONNECT_DATA = (SERVER = DEDICATED) (SERVICE_NAME = BI)))
OK (50 msec)

6、连接BI PDB数据库


[oracle@hd01 admin]$ sqlplus bi_admin/123456@bi

SQL*Plus: Release 18.0.0.0.0 - Production on Sun Dec 20 00:26:55 2020
Version 18.4.0.0.0

Copyright (c) 1982, 2018, Oracle. All rights reserved.

Connected to:
Oracle Database 18c Express Edition Release 18.0.0.0.0 - Production
Version 18.4.0.0.0

SQL> show con_name;

CON_NAME
------------------------------
BI
SQL>

相关文章

Oracle如何使用授予和撤销权限的语法和示例
Awesome Project: 探索 MatrixOrigin 云原生分布式数据库
下载丨66页PDF,云和恩墨技术通讯(2024年7月刊)
社区版oceanbase安装
Oracle 导出CSV工具-sqluldr2
ETL数据集成丨快速将MySQL数据迁移至Doris数据库

发布评论