联系:手机/微信(+86 17813235971) QQ(107644445)
作者:惜分飞©版权所有[未经本人同意,不得以任何形式转载,否则有进一步追究法律责任的权利.]
1、出现ORA-1502
接到开发报告,我们报表程序出现SQLCODE=[-1502]错误提示,sql执行不成功,根据这个提示,我猜想是ORA-1502错误,查询ora-1502错误
[oracle@node1 ~]$ oerr ora 1502 01502, 00000, "index '%s.%s' or partition of such index is in unusable state" // MERGE: 1489 RENUMBERED TO 1502 // *Cause: An attempt has been made to access an index or index partition // that has been marked unusable by a direct load or by a DDL // operation // *Action: DROP the specified index, or REBUILD the specified index, or // REBUILD the unusable index partition
根据这个提示,错误的原因是因为有index编程unusable state
--查询分区index是否有UNUSABLE的index SQL> col index_owner for a20 SQL> col index_name for a30 SQL> col partition_name for a20 SQL> SELECT INDEX_OWNER, INDEX_NAME, PARTITION_NAME 2 FROM DBA_IND_PARTITIONS 3 WHERE INDEX_OWNER NOT IN ('SYS', 'SYSTEM', 'PUBLIC') 4 AND STATUS = 'UNUSABLE'; INDEX_OWNER INDEX_NAME PARTITION_NAME -------------------- ------------------------------ -------------------- STAT_YDZJ IND_STAT_DAY_COMPANY_DAY P_201111 STAT_YDZJ IND_STAT_DAY_COMPANY_MOBILE P_201111 STAT_YDZJ IND_STAT_DAY_COMPANY_AREA P_201111 --查询无效全局index和普通index SQL> SELECT OWNER, a.index_name 2 FROM Dba_Indexes a 3 WHERE OWNER NOT IN ('SYS', 'SYSTEM', 'PUBLIC') 4 AND ROWNUM<2; OWNER INDEX_NAME ------------------------------ ------------------------------ STAT_YDZJ PK_ND_STAT_DAY_COMPANY
2、解决问题
批量生产sql语句,重建这些unusable index
SELECT 'ALTER INDEX ' || INDEX_OWNER || '.' || INDEX_NAME || ' REBUILD PARTITION ' || PARTITION_NAME || ' NOLOGGING online;' FROM DBA_IND_PARTITIONS WHERE INDEX_OWNER NOT IN ('SYS', 'SYSTEM', 'PUBLIC') AND STATUS = 'UNUSABLE' UNION ALL SELECT 'alter index ' ||OWNER || '.' || A.INDEX_NAME || ' REBUILD online nologging;' FROM DBA_INDEXES A WHERE OWNER NOT IN ('SYS', 'SYSTEM', 'PUBLIC') AND STATUS = 'UNUSABLE';
执行完上面sql生成语句后,让开发测试程序,反馈工作正常
3、问题分析
我昨天对STAT_DAY_COMPANY表添加了分区(SPLIT拆分MAXVALUE),本以为该表的所有index都是local index不知道为何有了一个全局index(公司规定所有分区表都只能建立local index),所以没有做相关查询,导致这次出现了index无效。但是为什么还有三个local index也变成了unusable,这个估计是大批量append插入数据导致。而开发那边正好是批量append插入数据到STAT_DAY_COMPANY表中,导致出现了ORA-1502错误
建议:处理分区表时,要对index查询清楚,不要按照规定或者惯性思维办事。