9. Datatype Packages
Contents:
This chapter introduces you to several packages that let you work effectively with particular types of Oracle data:
9.1 DBMS_ROWID: Working with the ROWID Pseudo-Column (Oracle8 only)The DBMS_ROWID package lets you work with ROWIDs from within PL/SQL programs and SQL statements. You can use the programs in this package to both create and manipulate ROWIDs. You can determine the data block number, the object number, and other components of the ROWID without having to write code to translate the base-64 character external ROWID.
9.1.1 Getting Started with DBMS_ROWIDThe DBMS_ROWID package is created when the Oracle8 database is installed. The dbmsutil.sql script (found in the built-in packages source code directory, as described in Chapter 1, Introduction ), contains the source code for this package's specification. This script is called by catproc.sql , which is normally run immediately after database creation. The script creates the public synonym DBMS_ROWID for the package and grants EXECUTE privilege on the package to public. All Oracle users can reference and make use of this package. All of the programs in DBMS_ROWID run as invoker, meaning that the privileges of the programs are taken from the session running the DBMS_ROWID programs and not from the owner of that package. 9.1.1.1 DBMS_ROWID programsTable 9.1 lists the programs defined for the DBMS_ROWID package. For a dicussion of some of the concepts underlying these program operations, see the next section, " Section 9.1.2, "ROWID Concepts" ."
9.1.1.2 DBMS_ROWID exceptionsTable 9.2 lists the named exceptions defined in the DBMS_ROWID package; they are associated with the error number listed beside the name.
9.1.1.3 DBMS_ROWID nonprogram elementsTable 9.3 lists the named constants defined by the DBMS_ROWID package for use with its programs.
9.1.2 ROWID ConceptsThis section offers a quick overview of the Oracle ROWID. You can get much more extensive information on ROWIDs from the Oracle documentation. In the Oracle RDBMS, ROWID is a pseudocolumn that is a part of every table you create. The ROWID is an internally generated and maintained binary value that identifies a row of data in your table. It is called a pseudocolumn because a SQL statement includes it in places where you would normally use a column. However, it is not a column that you create for the table. Instead, the RDBMS generates the ROWID for each row as it is inserted into the database. The information in the ROWID provides the exact physical location of the row in the database. You cannot change the value of a ROWID. You can use the ROWID datatype to store ROWIDs from the database in your PL/SQL program. You can SELECT or FETCH the ROWID for a row into a ROWID variable. To manipulate ROWIDs in Oracle8, you will want to use the DBMS_ROWID package described in this chapter. In Oracle7, you will use the ROWIDTOCHAR function to convert the ROWID to a fixed-length string and then perform operations against that string. In Oracle7, the format of the fixed-length ROWID is,
where components of this format have the following meanings:
All these numbers are hexadecimal; the database file is a number that you would then use to look up the actual name of the database file through the data dictionary. In Oracle8, ROWIDs have been "extended" to support partitioned tables and indexes. The new, extended ROWIDs include a data object number, identifying the d atabase segment. Any schema object found in the same segment, such as a cluster of tables, will have the same object number. In Oracle8, then, a ROWID contains the following information:
Usually (and always in Oracle7), a ROWID will uniquely identify a row of data. Within Oracle8, however, rows in different tables stored in the same cluster can have the same ROWID value. 9.1.3 The DBMS_ROWID InterfaceThe following sections describe the procedures and functions available through DBMS_ROWID. 9.1.3.1 The DBMS_ROWID. ROWID_BLOCK_NUMBER functionThe ROWID_BLOCK_NUMBER function returns the block number of a ROWID. Its header is, FUNCTION DBMS_ROWID.ROWID_BLOCK_NUMBER (row_id IN ROWID) RETURN NUMBER; where the ROWID parameter is the ROWID from which the value is extracted. 9.1.3.1.1 RestrictionsThe DBMS_ROWID package supplies the following pragma for ROWID_BLOCK_NUMBER: PRAGMA RESTRICT_REFERENCES (ROWID_BLOCK_NUMBER, WNDS, RNDS, WNPS, RNPS); 9.1.3.2 The DBMS_ROWID. CREATE_ROWID functionThe CREATE_ROWID function creates and returns a ROWID (either restricted or extended, as you request) based on the individual ROWID component values you specify. Use this function for test purposes only. Here is its header: FUNCTION DBMS_ROWID.ROWID_CREATE (rowid_type IN NUMBER ,object_number IN NUMBER ,relative_fno IN NUMBER ,block_number IN NUMBER ,row_number IN NUMBER) RETURN ROWID; Parameters are summarized in the following table.
9.1.3.2.1 RestrictionsThe DBMS_ROWID package supplies the following pragma for CREATE_ROWID: PRAGMA RESTRICT_REFERENCES (CREATE_ROWID, WNDS, RNDS, WNPS, RNPS); 9.1.3.2.2 ExampleHere is an example of a call to the ROWID_CREATE procedure: my_rowid ROWID; BEGIN my_rowid := DBMS_ROWID.ROWID_CREATE (DBMS_ROWID.ROWID_TYPE_EXTENDED, 100, 15, 103, 345); END; / 9.1.3.3 The DBMS_ROWID. ROWID_INFO procedureThe ROWID_INFO procedure parses out and returns the individual components of the specified ROWID. Here is its header: PROCEDURE DBMS_ROWID.ROWID_INFO (rowid_in IN ROWID ,rowid_type OUT NUMBER ,object_number OUT NUMBER ,relative_fno OUT NUMBER ,block_number OUT NUMBER ,row_number OUT NUMBER); Parameters are summarized in the following table.
9.1.3.3.1 RestrictionsThe DBMS_ROWID package supplies the following pragma for ROWID_INFO: PRAGMA RESTRICT_REFERENCES (ROWID_INFO, WNDS, RNDS, WNPS, RNPS); 9.1.3.4 The DBMS_ROWID. ROWID_OBJECT functionThe ROWID_OBJECT function returns the object number of a ROWID. The ROWID_OBJECT_UNDEFINED constant is returned for restricted ROWIDs. Its header is, FUNCTION DBMS_ROWID.ROWID_OBJECT (row_id IN ROWID) RETURN NUMBER; where the row_id parameter is the ROWID from which the value is extracted. 9.1.3.4.1 RestrictionsThe DBMS_ROWID package supplies the following pragma for ROWID_OBJECT: PRAGMA RESTRICT_REFERENCES (ROWID_OBJECT, WNDS, RNDS, WNPS, RNPS); 9.1.3.4.2 ExampleYou will want to obtain a ROWID's object number only if the ROWID type is extended. You would write code like this to perform that check: IF DBMS_ROWID.ROWID_TYPE (v_rowid) = DBMS_ROWID.ROWID_TYPE_EXTENDED THEN v_objnum := DBMS_ROWID.ROWID_OBJECT (v_rowid); END IF; 9.1.3.5 The DBMS_ROWID. ROWID_RELATIVE_FNO functionThe ROWID_RELATIVE_FNO function returns the relative file number of a ROWID. Its header is, FUNCTION DBMS_ROWID.ROWID_RELATIVE_FNO (row_id IN ROWID) RETURN NUMBER; where the row_id parameter is the ROWID from which the value is extracted. 9.1.3.5.1 RestrictionsThe DBMS_ROWID package supplies the following pragma for ROWID_RELATIVE_FNO: PRAGMA RESTRICT_REFERENCES (ROWID_RELATIVE_FNO, WNDS, RNDS, WNPS, RNPS); 9.1.3.6 The DBMS_ROWID. ROWID_ROW_NUMBER functionThe ROWID_ROW_NUMBER function returns the row number of a ROWID. Its header is, FUNCTION DBMS_ROWID.ROWID_ROW_NUMBER (row_id IN ROWID) RETURN NUMBER; where the row_id parameter is the ROWID from which the value is extracted. 9.1.3.6.1 RestrictionsThe DBMS_ROWID package supplies the following pragma for ROWID_ROW_NUMBER: PRAGMA RESTRICT_REFERENCES (ROWID_ROW_NUMBER, WNDS, RNDS, WNPS, RNPS); 9.1.3.7 The DBMS_ROWID. ROWID_TO_ABSOLUTE_FNO functionThe ROWID_TO_ABSOLUTE_FNO function returns the absolute file number of a ROWID. Here is its header: FUNCTION DBMS_ROWID.ROWID_TO_ABSOLUTE_FNO (row_id IN ROWID ,schema_name IN VARCHAR2 ,object_name IN VARCHAR2) RETURN NUMBER; Parameters are summarized in the following table.
9.1.3.7.1 RestrictionsThe DBMS_ROWID package supplies the following pragma for ROWID_RELATIVE_FNO: PRAGMA RESTRICT_REFERENCES (ROWID_RELATIVE_FNO, WNDS, WNPS, RNPS); 9.1.3.8 The DBMS_ROWID. ROWID_TO_EXTENDED functionThe ROWID_TO_EXTENDED function converts a restricted ROWID, addressing a specific row in a table, to an extended ROWID. Here is its header: FUNCTION DBMS_ROWID.ROWID_TO_EXTENDED (old_rowid IN ROWID ,schema_name IN VARCHAR2 ,object_name IN VARCHAR2 ,conversion_type IN INTEGER) RETURN ROWID; Parameters are summarized in the following table.
9.1.3.8.1 RestrictionsNote the following restrictions on calling ROWID_TO_EXTENDED:
9.1.3.8.2 ExampleSuppose that I have a table in my APP schema called ROWID_conversion. This table contains two columns: ROWID_value and table_name. The ROWID_value column contains the restricted-format ROWIDs for rows in the table specifed by the table_name column. I can then convert all of my restricted ROWID values to extended ones with the following UPDATE statement: UPDATE app.rowid_conversion SET rowid_value = DBMS_ROWID.ROWID_TO_EXTENDED (rowid_value, 'APP', table_name, DBMS_ROWID.ROWID_CONVERT_INTERNAL) ;. 9.1.3.9 The DBMS_ROWID. ROWID_TO_RESTRICTED function
The ROWID_TO_RESTRICTED FUNCTION DBMS_ROWID.ROWID_TO_RESTRICTED (old_rowid IN ROWID ,conversion_type IN INTEGER) RETURN ROWID; Parameters are summarized in the following table.
9.1.3.9.1 RestrictionsThe DBMS_ROWID package supplies the following pragma for ROWID_TO_RESTRICTED: PRAGMA RESTRICT_REFERENCES (ROWID_TO_RESTRICTED, WNDS, RNDS, WNPS, RNPS); 9.1.3.10 The DBMS_ROWID. ROWID_TYPE functionThe ROWID_TYPE function returns the type of a ROWID via one of the following package constants: ROWID_TYPE_RESTRICTED or ROWID_TYPE_EXTENDED. Its header is, FUNCTION DBMS_ROWID.ROWID_TYPE (row_id IN ROWID) RETURN NUMBER; where the row_id parameter is the ROWID from which the value is extracted. 9.1.3.10.1 RestrictionsThe DBMS_ROWID package supplies the following pragma for ROWID_TYPE: PRAGMA RESTRICT_REFERENCES (ROWID_TYPE, WNDS, RNDS, WNPS, RNPS); 9.1.3.10.2 ExampleIn the following query, I determine the ROWID types in the emp table: SELECT DISTINCT (DBMS_ROWID.ROWID_TYPE(ROWID)) FROM emp; This returns the value of 1, that is: DBMS_ROWID.ROWID_TYPE_EXTENDED. The emp table was created under Oracle8 and therefore uses the Oracle8 type of ROWID. 9.1.3.11 The DBMS_ROWID. ROWID_VERIFY functionThe ROWID_VERIFY function verifies a ROWID. It returns either the ROWID_VALID or ROWID_INVALID constants. Here is its header: FUNCTION DBMS_ROWID.ROWID_VERIFY (rowid_in IN ROWID ,schema_name IN VARCHAR2 ,object_name IN VARCHAR2 ,conversion_type IN INTEGER) RETURN NUMBER; Parameters are summarized in the following table.
9.1.3.11.1 RestrictionsThe DBMS_ROWID package supplies the following pragma for ROWID_VERIFY: PRAGMA RESTRICT_REFERENCES (ROWID_VERIFY, WNDS, WNPS, RNPS); 9.1.3.11.2 ExampleInterestingly, you can call this numeric function as a kind of Boolean function within SQL. Suppose that I want to find all the invalid ROWIDs prior to converting them from restricted to extended. I could write the following query (using the same tables used in the example for the ROWID_TO_EXTENDED function): SELECT ROWID, rowid_value FROM app.rowid_conversion WHERE DBMS_ROWID.ROWID_VERIFY (rowid_value, NULL, NULL, 0) = 1; Copyright (c) 2000 O'Reilly & Associates. All rights reserved. | ||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||||
|