重庆思庄Oracle、Redhat认证学习论坛
标题: Oracle 11g新特性之--虚拟列(Virtual Column) [打印本页]
作者: 郑全 时间: 2021-2-5 10:01
标题: Oracle 11g新特性之--虚拟列(Virtual Column)
本帖最后由 郑全 于 2021-2-7 00:11 编辑
Oracle 11G虚拟列Virtual Column介绍
在老的 Oracle 版本,当我们需要使用表达式或者一些计算公式时,我们会创建数据库视图,如果我们需要在这个视图上使用索引,我们会创建基于函数的索引。
我们从Oracle官方文档中,找到下面对于虚拟列技术的描述。
“Tables can also include virtual columns. A virtual column is like any other table column, except that its value is derived by evaluating an expression. The expression can include columns from the same table, constants, SQL functions, and user-defined PL/SQL functions. You cannot explicitly write to a virtual column.”
Oracle 11G 在表中引入了虚拟列,虚拟列是一个表达式,在运行时计算,不存储在数据库中,不能更新虚拟列的值。
column_name [datatype] [GENERATED ALWAYS] AS [expression] [VIRTUAL]
1.虚拟列可以用在select,update,delete语句的where条件中,但是不能用于DML语句
2.可以基于虚拟列来做分区
3. 可以在虚拟列上建索引,oracle的函数索引就类似。
4. 可以在虚拟列上建约束
案例:
1、创建一个带虚拟列的表:
CREATE TABLE EMP1
(
EMPNO NUMBER(6),
SAL NUMBER(8,2),
COMM NUMBER(8,2),
SAL_PACK GENERATED ALWAYS AS ( SAL + NVL(COMM,0) ) VIRTUAL
);
CREATE TABLE EMP2
(
EMPNO NUMBER(6),
SAL NUMBER(8,2),
COMM NUMBER(8,2),
SAL_PACK GENERATED ALWAYS AS ( SAL + NVL(COMM,0) )
);
2、查看虚拟列属性
COL TABLE_NAME FOR A10
COL COLUMN_NAME FOR A20
COL DATA_TYPE FOR A20
COL DATA_DEFAULT FOR A20
SQL> select table_name,COLUMN_NAME,data_type,data_default,VIRTUAL_COLUMN from user_tab_cols
2 where table_name='EMP1';
TABLE_NAME COLUMN_NAME DATA_TYPE DATA_DEFAULT VIRTUA
---------- -------------------- -------------------- -------------------- ------
EMP1 EMPNO NUMBER NO
EMP1 SAL NUMBER NO
EMP1 COMM NUMBER NO
EMP1 SAL_PACK NUMBER "SAL"+NVL("COMM",0) YES
上述建的虚拟列 SAL_PACK 是由一个简单的表达式创建的,使用的关键字有 VIRTUAL(不过这个关键字是可选的),该字段的值是由 COMM 这个字段通过表达式计算而来的。
在Table上添加虚拟列:
alter table emp3 add (sal_total as (sal*12+comm) virtual);
desc emp3;
Name Null? Type
----------------------------------------------------------------- -------- --------------------------------------------
EMPNO NUMBER(6)
SAL NUMBER(8,2)
COMM NUMBER(8,2)
SAL_PACK NOT NULL NUMBER
SAL_TOTAL NUMBER
select * from emp3;
EMPNO SAL COMM SAL_PACK SAL_TOTAL
---------- ---------- ---------- ---------- ----------
10 1500 500 2000 18500
20 3000 500 3500 36500
30 4000 500 4500 48500
40 6000 500 6500 72500
select table_name,COLUMN_NAME,data_type,data_default,VIRTUAL_COLUMN from user_tab_cols
where table_name='EMP3';
TABLE_NAME COLUMN_NAME DATA_TYPE DATA_DEFAULT VIR
---------- -------------------- -------------------- -------------------- ---
EMP3 SAL_TOTAL NUMBER "SAL"*12+"COMM" YES
EMP3 SAL_PACK NUMBER "SAL"+NVL("COMM",0) YES
EMP3 COMM NUMBER NO
EMP3 SAL NUMBER NO
EMP3 EMPNO NUMBER NO
在虚拟列中使用函数:
CREATE OR REPLACE FUNCTION sum_sal (in_num1 NUMBER, in_num2 NUMBER)
RETURN NUMBER DETERMINISTIC
AS
BEGIN
RETURN in_num1 + in_num2;
END;
alter table emp3 add ( sal_comm as (sum_sal(sal,comm)) virtual);
desc emp3
Name Null? Type
----------------------------------------------------------------- -------- --------------------------------------------
EMPNO NUMBER(6)
SAL NUMBER(8,2)
COMM NUMBER(8,2)
SAL_PACK NOT NULL NUMBER
SAL_TOTAL NUMBER
SAL_COMM NUMBER
select * from emp3;
EMPNO SAL COMM SAL_PACK SAL_TOTAL SAL_COMM
---------- ---------- ---------- ---------- ---------- ----------
10 1500 500 2000 18500 2000
20 3000 500 3500 36500 3500
30 4000 500 4500 48500 4500
40 6000 500 6500 72500 6500
虚拟列的值是不存储在磁盘的,它们是在查询时根据定义的表达式临时计算的。
3、对虚拟列的操作
Insert 操作:
我们不能往虚拟列中插入数据:
insert into emp3 values (10,1500,500,2000);
insert into emp3 values (10,1500,500,2000) *ERROR at line 1:ORA-54013: INSERT operation disallowed on virtual columns
也不能隐式的添加数据到虚拟列:
insert into emp3 values (10,1500,500);
insert into emp3 values (10,1500,500) *ERROR at line 1:ORA-00947: not enough values
虚拟列的数据会自动计算生成
insert into emp3(empno,sal,comm) values (10,1500,500);
1 row created.
select * from emp3;
EMPNO SAL COMM SAL_PACK
---------- ---------- ---------- ----------
10 1500 500 2000对虚拟列不能做update操作:
update emp3 set sal_pack=3000;
update emp3 set sal_pack=3000 *ERROR at line 1:ORA-54017: UPDATE operation disallowed on virtual columns在虚拟列上创建索引和约束:
create index emp3_val_ind on emp3(sal_pack) tablespace indx;
Index created.
select table_name,index_name,INDEX_TYPE from user_indexes
where table_name='EMP3';
TABLE_NAME INDEX_NAME INDEX_TYPE
---------- ------------------------------ ---------------------------
EMP3 EMP3_VAL_IND FUNCTION-BASED NORMAL
drop index EMP3_VAL_IND;
Index dropped
alter table emp3 add constraint pk_emp3 primary key (sal_pack);
select table_name,index_name,INDEX_TYPE from user_indexes
where table_name='EMP3';
TABLE_NAME INDEX_NAME INDEX_TYPE
---------- ------------------------------ ---------------------------
EMP3 PK_EMP3 FUNCTION-BASED NORMAL在虚拟列上建立分区表:
CREATE TABLE EMP3_part
(
EMPNO NUMBER(6),
AL NUMBER(8,2),
COMM NUMBER(8,2),
SAL_PACK GENERATED ALWAYS AS ( SAL + NVL(COMM,0) ) VIRTUAL
)
PARTITION BY range (sal_pack)
(PARTITION sal_2000 VALUES LESS THAN (2000),
PARTITION sal_4000 VALUES LESS THAN (4000),
PARTITION sal_6000 VALUES LESS THAN (6000),
PARTITION sal_8000 VALUES LESS THAN (8000),
PARTITION sal_default VALUES LESS THAN (MAXVALUE)
);
Table created.
insert into emp3_part(empno,sal,comm)
select empno,sal,comm from emp3;
4 rows created.
commit;
select * from emp3_part;
EMPNO SAL COMM SAL_PACK
---------- ---------- ---------- ----------
10 1500 500 2000
20 3000 500 3500
30 4000 500 4500
40 6000 500 6500
select * from emp3_part partition(sal_2000);
no rows selected
select * from emp3_part partition(sal_4000);
EMPNO SAL COMM SAL_PACK
---------- ---------- ---------- ----------
10 1500 500 2000
20 3000 500 3500
--通过以上对虚拟列的特性可以看出,Oracle采用虚拟列是占用了CPU计算时间,而节约了磁盘的存储空间。
欢迎光临 重庆思庄Oracle、Redhat认证学习论坛 (http://bbs.cqsztech.com/) |
Powered by Discuz! X3.2 |