有疑问可以去itpub讨论:http://www.itpub.net/thread-1804872-1-1.html
对于alter table setunused的用法,查官方文档:
alter_table::=
SET UNUSED Clause
Specify SET UNUSED to mark one or more columns asunused. Specifying this clause does not actually remove the target columns fromeach row in the table. That is, it does not restore the disk space used bythese columns. Therefore, the response time is faster than when you execute theDROP clause.
You can view all tables with columns marked UNUSED in the data dictionary views USER_UNUSED_COL_TABS, DBA_UNUSED_COL_TABS, and ALL_UNUSED_COL_TABS.
Unused columns are treated as if they were dropped, even though theircolumn data remains in the table rows. After a column has been marked UNUSED, you have no access to that column. A SELECT * query will not retrieve data from unusedcolumns. In addition, the names and types of columns marked UNUSED will not be displayed during a DESCRIBE, and you can add to the table a new column with the same name as an unusedcolumn.
对上面的题,先做实验,看测试结果,一一验证:
1、在gyj用户下创建一个表:
gyj@OCM> create table emp as select employee_id,first_name,manager_idfrom hr.employees;
Table created.
2、 创建一个公共的同义词e
gyj@OCM> create public synonym e for emp;
Synonym created.
gyj@OCM> select * from e;
EMPLOYEE_ID FIRST_NAME MANAGER_ID
----------- -------------------- ----------
198 Donald 124
199 Douglas 124
省略结果。。。。。
3、创建一个私有的同义词m
gyj@OCM> create synonym m foremp;
Synonym created.
gyj@OCM> select * from m;
EMPLOYEE_ID FIRST_NAME MANAGER_ID
----------- -------------------- ----------
198 Donald 124
199 Douglas 124
省略结果。。。。。
4、在字段manager_id列上建一个条件check约束
gyj@OCM> alter table emp add(constraint c_emp_manageridcheck(manager_id>=100));
Table altered.
gyj@OCM> select CONSTRAINT_NAME from user_constraints wheretable_name='EMP';
CONSTRAINT_NAME
------------------------------
C_EMP_MANAGERID
gyj@OCM> insert into emp values(500,'guoyJoe',99);
insert into emp values(500,'guoyJoe',99)
*
ERROR at line 1:
ORA-02290: check constraint (GYJ.C_EMP_MANAGERID) violated
报错是说明不满足约束,说明约束起作用了
5、创建一个视图v_emp
gyj@OCM> create view v_emp as select * from emp;
View created.
gyj@OCM> select * from v_emp;
EMPLOYEE_ID FIRST_NAME MANAGER_ID
----------- -------------------- ----------
198 Donald 124
199 Douglas 124
省略结果。。。
6、在列manager_id上创建一个索引
gyj@OCM> create index idx_id on emp(manager_id);
Index created.
gyj@OCM> select index_name from user_indexes where table_name='EMP';
INDEX_NAME
------------------------------
IDX_ID
好,我们按上面的题意,开始做alter table set unused操作:
gyj@OCM> altertable emp set unused ( manager_id);
Table altered.
同义词在数据字典中还能用,无需重建,所以答案A错
gyj@OCM> select OBJECT_NAME FROM user_objects where object_type='SYNONYM'AND OBJECT_NAME IN('M','E');
OBJECT_NAME
--------------------------------------------------
M
gyj@OCM> select * from e;
EMPLOYEE_ID FIRST_NAME MANAGER_ID
----------- -------------------- ----------
198 Donald 124
199 Douglas 124
省略结果。。。。。
gyj@OCM> select * from m;
EMPLOYEE_ID FIRST_NAME MANAGER_ID
----------- -------------------- ----------
198 Donald 124
199 Douglas 124
省略结果。。。。。
数据字典中manager_id列的约束被删除了。所以答案B对
gyj@OCM> select CONSTRAINT_NAME from user_constraints wheretable_name='EMP';
no rows selected
去查视图,报错如下:
gyj@OCM> select * from v_emp;
select * from v_emp
*
ERROR at line 1:
ORA-04063: view "GYJ.V_EMP" has errors
此时视图不能用了。。。答案C的意思必须删除这个视图再重建这个视图才行,一定要这做吗?我不重建视图,在视图所在表中重新添加manager_id这一列,看看视图能不能用:
gyj@OCM> alter table emp add( MANAGER_ID NUMBER(6));
Table altered.
gyj@OCM> select * from v_emp;
EMPLOYEE_ID FIRST_NAME MANAGER_ID
----------- -------------------- ----------
198 Donald
199 Douglas
省略结果。。。
说明视图无须删除和重建,只在表中添加刚刚被unused的这列就可以了,所以答案C错的
数据字典中manager_id列的索引被删除了。所以答案D错
gyj@OCM> select index_name fromuser_indexes where table_name='EMP';
no rows selected
正确答案是:B