在 Oracle 12c 中添加 Scott 用户

Posted by Yitar on November 15, 2015

Oracle 12c 中,引入了 CDB 与 PDB 的新特性,在 Oracle 12c 数据库引入的多租用户环境(Multitenant Environment)中,允许一个数据库容器(CDB)承载多个可插拔数据库(PDB)。CDB全称为 Container Database,中文翻译为数据库容器,PDB 全称为 Pluggable Database,即可插拔数据库。使用 sys 默认登录的是 CDB,在 CDB中创建公共用户必须在用户名前面加上 “c##”,Oracle12c 中移除了 Scott用户,如果需要可按照如下步骤自行添加。

使用 sys 连入数据库

sqlplus sys/change_on_install123 as sysdba;

创建 c##scott 用户

CREATE USER c##scott IDENTIFIED BY tiger;

为用户授权

GRANT CONNECT,RESOURCE,UNLIMITED TABLESPACE TO c##scottCONTAINER=ALL; 

设置用户使用的表空间

ALTER USER c##scott DEFAULT TABLESPACE USERS;
ALTER USER c##scott TEMPORARY TABLESPACE TEMP;

使用 c##scott 用户登录

CONN c##scott/tiger

删除数据表

DROP TABLE emp  PURGE ;
DROP TABLE dept PURGE ;
DROP TABLE bonus PURGE ;
DROP TABLE salgrade PURGE ;

创建数据表

CREATE TABLE dept (
deptno NUMBER(2) CONSTRAINT PK_DEPT PRIMARY KEY,
dname VARCHAR2(14) ,
loc VARCHAR2(13) ) ;
CREATE TABLE emp (
empno NUMBER(4) CONSTRAINT PK_EMP PRIMARY KEY,
ename VARCHAR2(10),
job VARCHAR2(9),
mgr NUMBER(4),
hiredate DATE,
sal NUMBER(7,2),
comm NUMBER(7,2),
deptno NUMBER(2) CONSTRAINT FK_DEPTNO REFERENCES DEPT );
CREATE TABLE bonus (
enamE VARCHAR2(10) ,
job VARCHAR2(9)  ,
sal NUMBER,
comm NUMBER ) ;
CREATE TABLE salgrade ( 
grade NUMBER,
losal NUMBER,
hisal NUMBER );

插入测试数据 —— dept

INSERT INTO dept VALUES (10,'ACCOUNTING','NEW YORK');
INSERT INTO dept VALUES (20,'RESEARCH','DALLAS');
INSERT INTO dept VALUES (30,'SALES','CHICAGO');
INSERT INTO dept VALUES (40,'OPERATIONS','BOSTON');

插入测试数据 —— emp

INSERT INTO emp VALUES(7369,'SMITH','CLERK',7902,to_date('17-12-1980','dd-mm-yyyy'),800,NULL,20);
INSERT INTO emp VALUES(7499,'ALLEN','SALESMAN',7698,to_date('20-2-1981','dd-mm-yyyy'),1600,300,30);
INSERT INTO emp VALUES(7521,'WARD','SALESMAN',7698,to_date('22-2-1981','dd-mm-yyyy'),1250,500,30);
INSERT INTO emp VALUES(7566,'JONES','MANAGER',7839,to_date('2-4-1981','dd-mm-yyyy'),2975,NULL,20);
INSERT INTO emp VALUES(7654,'MARTIN','SALESMAN',7698,to_date('28-9-1981','dd-mm-yyyy'),1250,1400,30);
INSERT INTO emp VALUES(7698,'BLAKE','MANAGER',7839,to_date('1-5-1981','dd-mm-yyyy'),2850,NULL,30);
INSERT INTO emp VALUES(7782,'CLARK','MANAGER',7839,to_date('9-6-1981','dd-mm-yyyy'),2450,NULL,10);
INSERT INTO emp VALUES(7788,'SCOTT','ANALYST',7566,to_date('19-04-1987','dd-mm-yyyy')-85,3000,NULL,20);
INSERT INTO emp VALUES(7839,'KING','PRESIDENT',NULL,to_date('17-11-1981','dd-mm-yyyy'),5000,NULL,10);
INSERT INTO emp VALUES(7844,'TURNER','SALESMAN',7698,to_date('8-9-1981','dd-mm-yyyy'),1500,0,30);
INSERT INTO emp VALUES(7876,'ADAMS','CLERK',7788,to_date('23-05-1987','dd-mm-yyyy')-51,1100,NULL,20);
INSERT INTO emp VALUES(7900,'JAMES','CLERK',7698,to_date('3-12-1981','dd-mm-yyyy'),950,NULL,30);
INSERT INTO emp VALUES(7902,'FORD','ANALYST',7566,to_date('3-12-1981','dd-mm-yyyy'),3000,NULL,20);
INSERT INTO emp VALUES(7934,'MILLER','CLERK',7782,to_date('23-1-1982','dd-mm-yyyy'),1300,NULL,10);

插入测试数据 —— salgrade

INSERT INTO salgrade VALUES (1,700,1200);
INSERT INTO salgrade VALUES (2,1201,1400);
INSERT INTO salgrade VALUES (3,1401,2000);
INSERT INTO salgrade VALUES (4,2001,3000);
INSERT INTO salgrade VALUES (5,3001,9999);

事务提交

COMMIT;

Oracle 12c 中的分页

oracle 12c 中终于有了类似 SQL 数据库中 LIMIT 的全新分页方式,在 c##scott 中当我们执行:

select * from emp order by empno desc
fetch first 5 rows only;

就能得到如下结果:

     EMPNO ENAME      JOB              MGR HIREDATE              SAL       COMM
---------- ---------- --------- ---------- -------------- ---------- ----------
    DEPTNO
----------
      7934 MILLER     CLERK           7782 23-1 -82           1300
        10

      7902 FORD       ANALYST         7566 03-12-81           3000
        20

      7900 JAMES      CLERK           7698 03-12-81            950
        30


     EMPNO ENAME      JOB              MGR HIREDATE              SAL       COMM
---------- ---------- --------- ---------- -------------- ---------- ----------
    DEPTNO
----------
      7876 ADAMS      CLERK           7788 02-4 -87           1100
        20

      7844 TURNER     SALESMAN        7698 08-9 -81           1500          0
        30