ORACLE 12C PDB 维护基础介绍

联系:手机/微信(+86 17813235971) QQ(107644445)QQ咨询惜分飞

标题:ORACLE 12C PDB 维护基础介绍

作者:惜分飞©版权所有[未经本人同意,不得以任何形式转载,否则有进一步追究法律责任的权利.]

CDB和PDB是ORACLE 12C一个很亮的新特性,由于他们的引入导致传统的ORACLE数据库管理理念不少发生了改变,这里列举了部分最基本的cdb和pdb管理方式
cdb和pdb关系图

ORACLE 12C版本

SQL> select * from v$version;

BANNER                                                                               CON_ID
-------------------------------------------------------------------------------- ----------
Oracle Database 12c Enterprise Edition Release 12.1.0.1.0 - 64bit Production              0
PL/SQL Release 12.1.0.1.0 - Production                                                    0
CORE    12.1.0.1.0      Production                                                        0
TNS for Linux: Version 12.1.0.1.0 - Production                                            0
NLSRTL Version 12.1.0.1.0 - Production                                                    0

启动关闭pdb

SQL> startup
ORACLE instance started.

Total System Global Area  597098496 bytes
Fixed Size                  2291072 bytes
Variable Size             272632448 bytes
Database Buffers          314572800 bytes
Redo Buffers                7602176 bytes
Database mounted.
Database opened.
SQL> select con_id,dbid,NAME,OPEN_MODE from v$pdbs;

    CON_ID       DBID NAME                           OPEN_MODE
---------- ---------- ------------------------------ ----------
         2 4048821679 PDB$SEED                       READ ONLY
         3 3313918585 PDB1                           MOUNTED
         4 3872456618 PDB2                           MOUNTED

SQL> alter PLUGGABLE database pdb1 open;

Pluggable database altered.

SQL> select con_id,dbid,NAME,OPEN_MODE from v$pdbs;

    CON_ID       DBID NAME                           OPEN_MODE
---------- ---------- ------------------------------ ----------
         2 4048821679 PDB$SEED                       READ ONLY
         3 3313918585 PDB1                           READ WRITE
         4 3872456618 PDB2                           MOUNTED

SQL> alter PLUGGABLE database pdb1 close;

Pluggable database altered.

SQL> select con_id,dbid,NAME,OPEN_MODE from v$pdbs;

    CON_ID       DBID NAME                           OPEN_MODE
---------- ---------- ------------------------------ ----------
         2 4048821679 PDB$SEED                       READ ONLY
         3 3313918585 PDB1                           MOUNTED
         4 3872456618 PDB2                           MOUNTED

SQL> alter PLUGGABLE database all open;

Pluggable database altered.

SQL> select con_id,dbid,NAME,OPEN_MODE from v$pdbs;

    CON_ID       DBID NAME                           OPEN_MODE
---------- ---------- ------------------------------ ----------
         2 4048821679 PDB$SEED                       READ ONLY
         3 3313918585 PDB1                           READ WRITE
         4 3872456618 PDB2                           READ WRITE

SQL> alter PLUGGABLE database all close;

Pluggable database altered.

SQL> select con_id,dbid,NAME,OPEN_MODE from v$pdbs;

    CON_ID       DBID NAME                           OPEN_MODE
---------- ---------- ------------------------------ ----------
         2 4048821679 PDB$SEED                       READ ONLY
         3 3313918585 PDB1                           MOUNTED
         4 3872456618 PDB2                           MOUNTED

SQL> alter session set container=pdb1;

Session altered.

SQL> startup
Pluggable Database opened.
SQL>  select con_id,dbid,NAME,OPEN_MODE from v$pdbs;

    CON_ID       DBID NAME                           OPEN_MODE
---------- ---------- ------------------------------ ----------
         3 3313918585 PDB1                           READ WRITE

pdb的管理可以在cdb中进行也可以在pdb中进行,如果是cdb中进行,需要PLUGGABLE关键字,如果是pdb中直接和普通数据库一样

登录pdb

[oracle@xifenfei ~]$ lsnrctl status

LSNRCTL for Linux: Version 12.1.0.1.0 - Production on 12-MAY-2013 08:07:02

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

Connecting to (DESCRIPTION=(ADDRESS=(PROTOCOL=TCP)(HOST=xifenfei)(PORT=1521)))
STATUS of the LISTENER
------------------------
Alias                     LISTENER
Version                   TNSLSNR for Linux: Version 12.1.0.1.0 - Production
Start Date                11-MAY-2013 18:30:54
Uptime                    0 days 13 hr. 36 min. 8 sec
Trace Level               off
Security                  ON: Local OS Authentication
SNMP                      OFF
Listener Parameter File   /u01/app/grid/product/12.1/network/admin/listener.ora
Listener Log File         /u01/app/grid/diag/tnslsnr/xifenfei/listener/alert/log.xml
Listening Endpoints Summary...
  (DESCRIPTION=(ADDRESS=(PROTOCOL=ipc)(KEY=EXTPROC1521)))
  (DESCRIPTION=(ADDRESS=(PROTOCOL=tcp)(HOST=xifenfei)(PORT=1521)))
  (DESCRIPTION=(ADDRESS=(PROTOCOL=tcps)(HOST=xifenfei)(PORT=5500))
(Security=(my_wallet_directory=/u01/oracle/12.1/db_1/admin/cdb/xdb_wallet))(Presentation=HTTP)(Session=RAW))
Services Summary...
Service "+ASM" has 1 instance(s).
  Instance "+ASM", status READY, has 1 handler(s) for this service...
Service "cdb" has 1 instance(s).
  Instance "cdb", status READY, has 1 handler(s) for this service...
Service "cdbXDB" has 1 instance(s).
  Instance "cdb", status READY, has 1 handler(s) for this service...
Service "pdb1" has 1 instance(s).
  Instance "cdb", status READY, has 1 handler(s) for this service...
Service "pdb2" has 1 instance(s).
  Instance "cdb", status READY, has 1 handler(s) for this service...
The command completed successfully
[oracle@xifenfei ~]$ tnsping pdb1

TNS Ping Utility for Linux: Version 12.1.0.1.0 - Production on 12-MAY-2013 08:07:09

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

Used parameter files:


Used TNSNAMES adapter to resolve the alias
Attempting to contact (DESCRIPTION = (ADDRESS = (PROTOCOL = TCP)(HOST = xifenfei)
(PORT = 1521)) (CONNECT_DATA = (SERVER = DEDICATED) (SERVICE_NAME = pdb1)))
OK (20 msec)
[oracle@xifenfei ~]$ sqlplus sys/xifenfei@pdb1 as sysdba

SQL*Plus: Release 12.1.0.1.0 Production on Sun May 12 08:08:02 2013

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


Connected to:
Oracle Database 12c Enterprise Edition Release 12.1.0.1.0 - 64bit Production
With the Partitioning, Automatic Storage Management, OLAP, Advanced Analytics
and Real Application Testing options

SQL> show con_name;

CON_NAME
------------------------------
PDB1


[oracle@xifenfei ~]$ sqlplus / as sysdba

SQL*Plus: Release 12.1.0.1.0 Production on Sun May 12 08:09:14 2013

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


Connected to:
Oracle Database 12c Enterprise Edition Release 12.1.0.1.0 - 64bit Production
With the Partitioning, Automatic Storage Management, OLAP, Advanced Analytics
and Real Application Testing options

SQL> alter session set container=pdb1;

Session altered.

SQL> show con_name;

CON_NAME
------------------------------
PDB1

pdb可以通过alter session container进入也可以直接通过tns方式登录

创建用户

SQL> show con_name;

CON_NAME
------------------------------
CDB$ROOT

SQL> select con_id,dbid,NAME,OPEN_MODE from v$pdbs;

    CON_ID       DBID NAME                           OPEN_MODE
---------- ---------- ------------------------------ ----------
         2 4048821679 PDB$SEED                       READ ONLY
         3 3313918585 PDB1                           READ WRITE
         4 3872456618 PDB2                           MOUNTED

SQL> create user xff identified by xifenfei;
create user xff identified by xifenfei
            *
ERROR at line 1:
ORA-65096: invalid common user or role name


SQL> !oerr ora 65096
65096, 00000, "invalid common user or role name"
// *Cause:  An attempt was made to create a common user or role with a name
//          that wass not valid for common users or roles.  In addition to 
//          the usual rules for user and role names, common user and role 
//          names must start with C## or c## and consist only of ASCII 
//          characters.
// *Action: Specify a valid common user or role name.
//

SQL> create user c##xff identified by xifenfei;

User created.

SQL> SELECT USERNAME,CON_ID,USER_ID FROM CDB_USERS WHERE USERNAME='C##XFF';

USERNAME       CON_ID    USER_ID
---------- ---------- ----------
C##XFF              1        103
C##XFF              3        104

SQL> alter session set container=pdb1;

Session altered.

SQL> show con_name

CON_NAME
------------------------------
PDB1
SQL> create user xff identified by xifenfei;

User created.

SQL> create user c##abc identified by xifenfei;
create user c##abc identified by xifenfei
            *
ERROR at line 1:
ORA-65094: invalid local user or role name

创建用户默认的是container=all,在cdb中只能创建全局用户(c##开头),会在cdb和所有的pdb中创建该用户(但是pdb中的全局用户需要另外授权才能够在pdb中访问)。在pdb中只能创建的用户为本地用户

用户授权

SQL> grant connect to c##xff;

Grant succeeded.

SQL> select GRANTEE,con_id from cdb_ROLE_PRIVS where GRANTED_ROLE='CONNECT' AND GRANTEE='C##XFF';

GRANTEE                            CON_ID
------------------------------ ----------
C##XFF                                  1

SQL> grant resource to c##xff container=all;

Grant succeeded.

SQL>  select GRANTEE,con_id from cdb_ROLE_PRIVS where GRANTED_ROLE='RESOURCE' AND  GRANTEE='C##XFF';

GRANTEE                            CON_ID
------------------------------ ----------
C##XFF                                  1
C##XFF                                  3

用户授权默认情况下是只会给当前container,在cdb中也可以指定container=all,对所有open的pdb且存在该用户都进行授权

修改参数

SQL> alter system set open_cursors=500 container=all;

System altered.

SQL> conn sys/xifenfei@pdb1 as sysdba
Connected.
SQL> show parameter open_cursors;

NAME                                 TYPE        VALUE
------------------------------------ ----------- ------------------------------
open_cursors                         integer     500
SQL>  alter system set open_cursors=100;
 alter system set open_cursors=100
*
ERROR at line 1:
ORA-01219: database or pluggable database not open: queries allowed on fixed
tables or views only


SQL> alter database open;

Database altered.

SQL> alter system set open_cursors=100;

System altered.

SQL>  show parameter open_cursors;

NAME                                 TYPE        VALUE
------------------------------------ ----------- ------------------------------
open_cursors                         integer     100
SQL> conn / as sysdba
Connected.
SQL> show parameter open_cursors;

NAME                                 TYPE        VALUE
------------------------------------ ----------- ------------------------------
open_cursors                         integer     500

这里可以看到在cdb中修改,pdb会继承进去;如果在pdb中修改会覆盖pdb从cdb中继承的参数含义

此条目发表在 ORACLE 12C 分类目录。将固定链接加入收藏夹。

ORACLE 12C PDB 维护基础介绍》有 8 条评论

  1. 惜分飞 说:

    crystalj,

    ORA-01034: ORACLE not available
    ORA-27101: shared memory realm does not exist
    Linux-x86_64 Error: 2: No such file or directory
    这个错误,证明可能是你的tns写的有问题,提供你的如下信息
    sqlplus / as sysdba
    show pdbs;
    exit
    lsntctl status
    cat tnsnames.ora

  2. crystalj 说:

    请教关于pdb的listener是怎么设置的? 我配置了listener之后,cdb通过tns访问是没问题的,但是通过tns访问pdb就总是报错
    ERROR:
    ORA-01034: ORACLE not available
    ORA-27101: shared memory realm does not exist
    Linux-x86_64 Error: 2: No such file or directory
    Process ID: 0
    Session ID: 0 Serial number: 0

    以下是我的listener.ora

    SID_LIST_LISTENER_DB12C =
    (SID_LIST =
    (SID_DESC =
    (GLOBAL_DBNAME = db12c)
    (ORACLE_HOME = /ora/app/oracle/product/12.1)
    (SID_NAME = db12c)
    )
    (SID_DESC =
    (GLOBAL_DBNAME = pdb1)
    (ORACLE_HOME = /ora/app/oracle/product/12.1)
    (SID_NAME = pdb1)
    )
    )

    LISTENER_DB12C =
    (DESCRIPTION_LIST =
    (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCP)(HOST = lxqdrmdb1)(PORT = 1528))
    )
    (DESCRIPTION =
    (ADDRESS = (PROTOCOL = IPC)(KEY = EXTPROC1528))
    )
    )

  3. czs_bj 说:

    SQL> !oerr ora 65096
    65096, 00000, “invalid common user or role name”
    // *Cause: An attempt was made to create a common user or role with a name
    // that wass not valid for common users or roles. In addition to
    // the usual rules for user and role names, common user and role
    // names must start with C## or c## and consist only of ASCII
    // characters.
    // *Action: Specify a valid common user or role name.

    //……//部分你是怎么设置的,我的只能报错命令出错:
    行: 1 列: 13
    错误报告:
    SQL 错误: ORA-65096: 公用用户名或角色名无效

    没有显示//…….//部分,请问一下这个是不是要单独设置

  4. 惜分飞 说:

    bin_huhj,

    谢谢指正出来,我也测试了一遍,确实是这样的,pdb的权限需要授权,用户是继承过来了

  5. bin_huhj 说:

    你上面文章中提到如果pdb在mount状态下,在cdb中创建的全局用户是不会在该pdb中创建的,但好像pdb在mount下也会创建用户,请看下面测试:

    SQL> alter pluggable database pdb1 close;
    Pluggable database altered.
    SQL> show pdbs
    CON_ID CON_NAME OPEN MODE RESTRICTED
    ———- —————————— ———- ———-
    2 PDB$SEED READ ONLY NO
    3 PDB1 MOUNTED
    SQL> create user c##t2 identified by t2;
    User created.
    SQL> grant resource,connect to c##t2;
    Grant succeeded.
    SQL> conn c##t2/t2@pdb1;
    ERROR:
    ORA-01033: ORACLE 正在初始化或关闭
    Process ID: 0
    Session ID: 0 Serial number: 0
    Warning: You are no longer connected to ORACLE.
    SQL> conn / as sysdba
    Connected.
    SQL> alter pluggable database pdb1 open;
    Pluggable database altered.
    SQL> conn c##t2/t2@pdb1;
    ERROR:
    ORA-01045: 用户 C##T2 没有 CREATE SESSION 权限; 登录被拒绝
    Warning: You are no longer connected to ORACLE.
    SQL> conn / as sysdba
    Connected.
    SQL> grant resource,connect to c##t2 container=all;
    Grant succeeded.
    SQL> conn c##t2/t2@pdb1;
    Connected.
    SQL>
    SQL> show con_name;
    CON_NAME
    ——————————
    PDB1