Compile Invalid Objects In Oracle : In this article we will discuss about how to Compile Invalid Objects In Oracle.
Objects in the database can become invalid, if there are any changes to the dependent objects. Oracle recommends that you run the utlrp.sql script after you install, patch, or upgrade a database, to identify and recompile invalid objects. Compiling the invalid objects can make them valid if they are eligible.
Firstly, Query to findout invalid objects present in the Database:
SQL> set lines 400 pages 4000
SQL> col owner for a40
SQL> col OBJECT_NAME for a40
SQL> select owner, object_name, object_type, status from dba_objects where status='INVALID';
OWNER OBJECT_NAME OBJECT_TYPE STATUS
---------------------------------------- ---------------------------------------- ----------------------- -------
SYS DATABASE_GROWTH PROCEDURE INVALID
SQL>
Compile all invalid objects present in the Database :
The utlrp.sql script recompiles all invalid objects. Run the script immediately after installation, to ensure that users do not encounter invalid objects. This script may take some time, depending on the number of objects.
SQL>
SQL> @$ORACLE_HOME/rdbms/admin/utlrp.sql
Session altered.
TIMESTAMP
----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
COMP_TIMESTAMP UTLRP_BGN 2021-06-16 12:03:07
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 2021-06-16 12:03:12
DOC> The following query reports the number of invalid objects.
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
-------------------
1
DOC> The following query reports the number of exceptions 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> Note: Typical compilation errors (due to coding errors) are not
DOC> logged into this table: they go into DBA_ERRORS instead.
DOC>#
ERRORS DURING RECOMPILATION
---------------------------
0
Function created.
PL/SQL procedure successfully completed.
Function dropped.
PL/SQL procedure successfully completed.
SQL>
Compile objects of a schema in the Database :
SQL>
SQL> exec dbms_utility.compile_schema(schema => 'SCOTT');
PL/SQL procedure successfully completed.
SQL>
Compile individual objects in the Database :
-- Compiling a package;
SQL> alter package SCOTT.ORAKLDBA compile;
PL/SQL procedure successfully completed.
SQL>
SQL> alter package SCOTT.ORAKLDBA compile body;
PL/SQL procedure successfully completed.
SQL>
-- Compiling a procedure:
SQL> alter procedure SCOTT.ORAKLDBA_PROC compile;
PL/SQL procedure successfully completed.
SQL>
-- Compiling a view:
SQL> alter view SCOTT.ORAKLDBA_VW compile;
PL/SQL procedure successfully completed.
SQL>
-- Compiling a function:
SQL> alter function SCOTT.ORAKLDBA_FUNC compile;
PL/SQL procedure successfully completed.
SQL>
I hope my written content will helped you. Your suggestions/feedback are most welcome from orakldba.com.
Keep learning… Have a great day!!!
Please comment here for your any query related to above content. You can write to mail me through : orakldba@gmail.com.