在12c之前VARCHAR2, NVARCHAR2 和 RAW 类型字段长度如下:
* VARCHAR2 : 4000 bytes
* NVARCHAR2 : 4000 bytes
* RAW : 2000 bytes
12c之后对这些字段类型长度进行了扩展
* VARCHAR2 : 32767 bytes
* NVARCHAR2 : 32767 bytes
* RAW : 32767 bytes
注意这里是字节长度,字符长度还要取决与使用的字符集。
下面是简单的测试:
1、修改参数max_string_size为extended
[code]SQL> show parameter max_string_size
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
max_string_size string STANDARD
SQL> ALTER SYSTEM SET max_string_size=extended scope=both;
ALTER SYSTEM SET max_string_size=extended scope=both
*
ERROR at line 1:
ORA-02097: parameter cannot be modified because specified value is invalid
ORA-02095: specified initialization parameter cannot be modified
Elapsed: 00:00:00.00
SQL> ALTER SYSTEM SET max_string_size=extended scope=spfile;
System altered.
Elapsed: 00:00:00.01[/code]
2、关闭数据库,以UPGRADE方式打开数据库
[code]SQL> SHUTDOWN IMMEDIATE;
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> STARTUP UPGRADE;
ORACLE instance started.
Total System Global Area 417546240 bytes
Fixed Size 2289064 bytes
Variable Size 339739224 bytes
Database Buffers 71303168 bytes
Redo Buffers 4214784 bytes
Database mounted.
Database opened.
SQL> show parameter max_string_size
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
max_string_size string EXTENDED[/code]
3、执行脚本utl32k.sql,测试发现执行脚本会消耗大量CPU,几乎100%,另外,时间大约需要20min(2颗CPU、2G内存)
[code]SQL> @?/rdbms/admin/utl32k.sql
Session altered.
DOC>#######################################################################
DOC>#######################################################################
DOC> The following statement will cause an "ORA-01722: invalid number"
DOC> error if the database has not been opened for UPGRADE.
DOC>
DOC> Perform a "SHUTDOWN ABORT" and
DOC> restart using UPGRADE.
DOC>#######################################################################
DOC>#######################################################################
DOC>#
no rows selected
DOC>#######################################################################
DOC>#######################################################################
DOC> The following statement will cause an "ORA-01722: invalid number"
DOC> error if the database does not have compatible >= 12.0.0
DOC>
DOC> Set compatible >= 12.0.0 and retry.
DOC>#######################################################################
DOC>#######################################################################
DOC>#
PL/SQL procedure successfully completed.
Session altered.
0 rows updated.
Commit complete.
System altered.
PL/SQL procedure successfully completed.
Commit complete.
System altered.
Session altered.
PL/SQL procedure successfully completed.
No errors.
Session altered.
PL/SQL procedure successfully completed.
Commit complete.
Package altered.
TIMESTAMP
--------------------------------------------------------------------------------
COMP_TIMESTAMP UTLRP_BGN 2013-08-30 11:11:51
DOC> The following PL/SQL block invokes UTL_RECOMP to recompile invalid
DOC> objects in the database. Recompilation time is proportional to the
DOC> number of invalid objects in the database, so this command may take
DOC> a long time to execute on a database with a large number of invalid
DOC> objects.
DOC>
DOC> Use the following queries to track recompilation progress:
DOC>
DOC> 1. Query returning the number of invalid objects remaining. This
DOC> number should decrease with time.
DOC> SELECT COUNT(*) FROM obj$ WHERE status IN (4, 5, 6);
DOC>
DOC> 2. Query returning the number of objects compiled so far. This number
DOC> should increase with time.
DOC> SELECT COUNT(*) FROM UTL_RECOMP_COMPILED;
DOC>
DOC> This script automatically chooses serial or parallel recompilation
DOC> based on the number of CPUs available (parameter cpu_count) multiplied
DOC> by the number of threads per CPU (parameter parallel_threads_per_cpu).
DOC> On RAC, this number is added across all RAC nodes.
DOC>
DOC> UTL_RECOMP uses DBMS_SCHEDULER to create jobs for parallel
DOC> recompilation. Jobs are created without instance affinity so that they
DOC> can migrate across RAC nodes. Use the following queries to verify
DOC> whether UTL_RECOMP jobs are being created and run correctly:
DOC>
DOC> 1. Query showing jobs created by UTL_RECOMP
DOC> SELECT job_name FROM dba_scheduler_jobs
DOC> WHERE job_name like 'UTL_RECOMP_SLAVE_%';
DOC>
DOC> 2. Query showing UTL_RECOMP jobs that are running
DOC> SELECT job_name FROM dba_scheduler_running_jobs
DOC> WHERE job_name like 'UTL_RECOMP_SLAVE_%';
DOC>#
PL/SQL procedure successfully completed.
TIMESTAMP
--------------------------------------------------------------------------------
COMP_TIMESTAMP UTLRP_END 2013-08-30 11:12:15
DOC> The following query reports the number of objects that have compiled
DOC> with errors.
DOC>
DOC> If the number is higher than expected, please examine the error
DOC> messages reported with each object (using SHOW ERRORS) to see if they
DOC> point to system misconfiguration or resource constraints that must be
DOC> fixed before attempting to recompile these objects.
DOC>#
OBJECTS WITH ERRORS
-------------------
0
DOC> The following query reports the number of errors caught during
DOC> recompilation. If this number is non-zero, please query the error
DOC> messages in the table UTL_RECOMP_ERRORS to see if any of these errors
DOC> are due to misconfiguration or resource constraints that must be
DOC> fixed before objects can compile successfully.
DOC>#
ERRORS DURING RECOMPILATION
---------------------------
0
Function created.
PL/SQL procedure successfully completed.
Function dropped.
...Database user "SYS", database schema "APEX_040200", user# "98" 11:46:56
...Compiled 0 out of 2998 objects considered, 0 failed compilation 11:46:57
...263 packages
...255 package bodies
...453 tables
...11 functions
...16 procedures
...3 sequences
...458 triggers
...1322 indexes
...207 views
...0 libraries
...6 types
...0 type bodies
...0 operators
...0 index types
...Begin key object existence check 11:46:57
...Completed key object existence check 11:46:57
...Setting DBMS Registry 11:46:57
...Setting DBMS Registry Complete 11:46:57
...Exiting validate 11:46:57
PL/SQL procedure successfully completed.[/code]
4、重启数据库
[code]SQL> SHUTDOWN
SQL> startup
ORACLE instance started.
Total System Global Area 417546240 bytes
Fixed Size 2289064 bytes
Variable Size 327156312 bytes
Database Buffers 79691776 bytes
Redo Buffers 8409088 bytes
Database mounted.
ORA-01092: ORACLE instance terminated. Disconnection forced
ORA-14696: MAX_STRING_SIZE migration is incomplete for pluggable database
PDB$SEED
Process ID: 3479
Session ID: 10 Serial number: 3[/code]
在startup时候报错ORA-14696。根据提示切换到PDB$SEED,再次运行脚本utl32k.sql。重启数据库OK
5、简单测试
[code]SQL> show parameter max_string_size
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
max_string_size string EXTENDED
SQL> CREATE TABLE t1 (
2 id NUMBER,
3 varchar2_data VARCHAR2(32767),
4 nvarchar2_data NVARCHAR2(16383),
5 raw_data RAW(32767)
6 );
Table created.
SQL> insert into t1
2 select 1,
3 rpad('awen',32767,'o'),
4 rpad('awen',16383,'b'),
5 UTL_RAW.cast_to_raw(rpad('awen',32767,'o'))
6 from dual;
1 row created.
SQL> select id,length(varchar2_data),length(nvarchar2_data),length(raw_data) from t1;
ID LENGTH(VARCHAR2_DATA) LENGTH(NVARCHAR2_DATA) LENGTH(RAW_DATA)
---------- --------------------- ---------------------- ----------------
1 32767 16383 32767
SQL> select substr(varchar2_data,32760,32767),substr(nvarchar2_data,16380,16383) from t1;
SUBSTR(V SUBS
-------- ----
oooooooo bbbb[/code]
官方文档:http://docs.oracle.com/cd/E16655_01/server.121/e17615/refrn10321.htm#sthref422
* VARCHAR2 : 4000 bytes
* NVARCHAR2 : 4000 bytes
* RAW : 2000 bytes
12c之后对这些字段类型长度进行了扩展
* VARCHAR2 : 32767 bytes
* NVARCHAR2 : 32767 bytes
* RAW : 32767 bytes
注意这里是字节长度,字符长度还要取决与使用的字符集。
下面是简单的测试:
1、修改参数max_string_size为extended
[code]SQL> show parameter max_string_size
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
max_string_size string STANDARD
SQL> ALTER SYSTEM SET max_string_size=extended scope=both;
ALTER SYSTEM SET max_string_size=extended scope=both
*
ERROR at line 1:
ORA-02097: parameter cannot be modified because specified value is invalid
ORA-02095: specified initialization parameter cannot be modified
Elapsed: 00:00:00.00
SQL> ALTER SYSTEM SET max_string_size=extended scope=spfile;
System altered.
Elapsed: 00:00:00.01[/code]
2、关闭数据库,以UPGRADE方式打开数据库
[code]SQL> SHUTDOWN IMMEDIATE;
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> STARTUP UPGRADE;
ORACLE instance started.
Total System Global Area 417546240 bytes
Fixed Size 2289064 bytes
Variable Size 339739224 bytes
Database Buffers 71303168 bytes
Redo Buffers 4214784 bytes
Database mounted.
Database opened.
SQL> show parameter max_string_size
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
max_string_size string EXTENDED[/code]
3、执行脚本utl32k.sql,测试发现执行脚本会消耗大量CPU,几乎100%,另外,时间大约需要20min(2颗CPU、2G内存)
[code]SQL> @?/rdbms/admin/utl32k.sql
Session altered.
DOC>#######################################################################
DOC>#######################################################################
DOC> The following statement will cause an "ORA-01722: invalid number"
DOC> error if the database has not been opened for UPGRADE.
DOC>
DOC> Perform a "SHUTDOWN ABORT" and
DOC> restart using UPGRADE.
DOC>#######################################################################
DOC>#######################################################################
DOC>#
no rows selected
DOC>#######################################################################
DOC>#######################################################################
DOC> The following statement will cause an "ORA-01722: invalid number"
DOC> error if the database does not have compatible >= 12.0.0
DOC>
DOC> Set compatible >= 12.0.0 and retry.
DOC>#######################################################################
DOC>#######################################################################
DOC>#
PL/SQL procedure successfully completed.
Session altered.
0 rows updated.
Commit complete.
System altered.
PL/SQL procedure successfully completed.
Commit complete.
System altered.
Session altered.
PL/SQL procedure successfully completed.
No errors.
Session altered.
PL/SQL procedure successfully completed.
Commit complete.
Package altered.
TIMESTAMP
--------------------------------------------------------------------------------
COMP_TIMESTAMP UTLRP_BGN 2013-08-30 11:11:51
DOC> The following PL/SQL block invokes UTL_RECOMP to recompile invalid
DOC> objects in the database. Recompilation time is proportional to the
DOC> number of invalid objects in the database, so this command may take
DOC> a long time to execute on a database with a large number of invalid
DOC> objects.
DOC>
DOC> Use the following queries to track recompilation progress:
DOC>
DOC> 1. Query returning the number of invalid objects remaining. This
DOC> number should decrease with time.
DOC> SELECT COUNT(*) FROM obj$ WHERE status IN (4, 5, 6);
DOC>
DOC> 2. Query returning the number of objects compiled so far. This number
DOC> should increase with time.
DOC> SELECT COUNT(*) FROM UTL_RECOMP_COMPILED;
DOC>
DOC> This script automatically chooses serial or parallel recompilation
DOC> based on the number of CPUs available (parameter cpu_count) multiplied
DOC> by the number of threads per CPU (parameter parallel_threads_per_cpu).
DOC> On RAC, this number is added across all RAC nodes.
DOC>
DOC> UTL_RECOMP uses DBMS_SCHEDULER to create jobs for parallel
DOC> recompilation. Jobs are created without instance affinity so that they
DOC> can migrate across RAC nodes. Use the following queries to verify
DOC> whether UTL_RECOMP jobs are being created and run correctly:
DOC>
DOC> 1. Query showing jobs created by UTL_RECOMP
DOC> SELECT job_name FROM dba_scheduler_jobs
DOC> WHERE job_name like 'UTL_RECOMP_SLAVE_%';
DOC>
DOC> 2. Query showing UTL_RECOMP jobs that are running
DOC> SELECT job_name FROM dba_scheduler_running_jobs
DOC> WHERE job_name like 'UTL_RECOMP_SLAVE_%';
DOC>#
PL/SQL procedure successfully completed.
TIMESTAMP
--------------------------------------------------------------------------------
COMP_TIMESTAMP UTLRP_END 2013-08-30 11:12:15
DOC> The following query reports the number of objects that have compiled
DOC> with errors.
DOC>
DOC> If the number is higher than expected, please examine the error
DOC> messages reported with each object (using SHOW ERRORS) to see if they
DOC> point to system misconfiguration or resource constraints that must be
DOC> fixed before attempting to recompile these objects.
DOC>#
OBJECTS WITH ERRORS
-------------------
0
DOC> The following query reports the number of errors caught during
DOC> recompilation. If this number is non-zero, please query the error
DOC> messages in the table UTL_RECOMP_ERRORS to see if any of these errors
DOC> are due to misconfiguration or resource constraints that must be
DOC> fixed before objects can compile successfully.
DOC>#
ERRORS DURING RECOMPILATION
---------------------------
0
Function created.
PL/SQL procedure successfully completed.
Function dropped.
...Database user "SYS", database schema "APEX_040200", user# "98" 11:46:56
...Compiled 0 out of 2998 objects considered, 0 failed compilation 11:46:57
...263 packages
...255 package bodies
...453 tables
...11 functions
...16 procedures
...3 sequences
...458 triggers
...1322 indexes
...207 views
...0 libraries
...6 types
...0 type bodies
...0 operators
...0 index types
...Begin key object existence check 11:46:57
...Completed key object existence check 11:46:57
...Setting DBMS Registry 11:46:57
...Setting DBMS Registry Complete 11:46:57
...Exiting validate 11:46:57
PL/SQL procedure successfully completed.[/code]
4、重启数据库
[code]SQL> SHUTDOWN
SQL> startup
ORACLE instance started.
Total System Global Area 417546240 bytes
Fixed Size 2289064 bytes
Variable Size 327156312 bytes
Database Buffers 79691776 bytes
Redo Buffers 8409088 bytes
Database mounted.
ORA-01092: ORACLE instance terminated. Disconnection forced
ORA-14696: MAX_STRING_SIZE migration is incomplete for pluggable database
PDB$SEED
Process ID: 3479
Session ID: 10 Serial number: 3[/code]
在startup时候报错ORA-14696。根据提示切换到PDB$SEED,再次运行脚本utl32k.sql。重启数据库OK
5、简单测试
[code]SQL> show parameter max_string_size
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
max_string_size string EXTENDED
SQL> CREATE TABLE t1 (
2 id NUMBER,
3 varchar2_data VARCHAR2(32767),
4 nvarchar2_data NVARCHAR2(16383),
5 raw_data RAW(32767)
6 );
Table created.
SQL> insert into t1
2 select 1,
3 rpad('awen',32767,'o'),
4 rpad('awen',16383,'b'),
5 UTL_RAW.cast_to_raw(rpad('awen',32767,'o'))
6 from dual;
1 row created.
SQL> select id,length(varchar2_data),length(nvarchar2_data),length(raw_data) from t1;
ID LENGTH(VARCHAR2_DATA) LENGTH(NVARCHAR2_DATA) LENGTH(RAW_DATA)
---------- --------------------- ---------------------- ----------------
1 32767 16383 32767
SQL> select substr(varchar2_data,32760,32767),substr(nvarchar2_data,16380,16383) from t1;
SUBSTR(V SUBS
-------- ----
oooooooo bbbb[/code]
官方文档:http://docs.oracle.com/cd/E16655_01/server.121/e17615/refrn10321.htm#sthref422
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。




