Oracle8i Concepts Release 8.1.5 A67781-01 |
|
Does one's integrity ever lie in what he is not able to do?
Flannery O'Connor: Wise Blood
This chapter explains how to use integrity constraints to enforce the business rules associated with your database and prevent the entry of invalid information into tables. The chapter includes:
It is important that data adhere to a predefined set of rules, as determined by the database administrator or application developer. As an example of data integrity, consider the tables EMP and DEPT and the business rules for the information in each of the tables, as illustrated in Figure 28-1.
Note that some columns in each table have specific rules that constrain the data contained within them.
This section describes the rules that can be applied to table columns to enforce different types of data integrity.
A null is a rule defined on a single column that allows or disallows inserts or updates of rows containing a null (the absence of a value) in that column.
A unique value defined on a column (or set of columns) allows the insert or update of a row only if it contains a unique value in that column (or set of columns).
A primary key value defined on a key (a column or set of columns) specifies that each row in the table can be uniquely identified by the values in the key.
A rule defined on a key (a column or set of columns) in one table that guarantees that the values in that key match the values in a key in a related table (the referenced value).
Referential integrity also includes the rules that dictate what types of data manipulation are allowed on referenced values and how these actions affect dependent values. The rules associated with referential integrity are:
Complex integrity checking is a user-defined rule for a column (or set of columns) that allows or disallows inserts, updates, or deletes of a row based on the value it contains for the column (or set of columns).
Oracle enables you to define and enforce each type of data integrity rule defined in the previous section. Most of these rules are easily defined using integrity constraints or database triggers.
An integrity constraint is a declarative method of defining a rule for a column of a table. Oracle supports the following integrity constraints:
Oracle also allows you to enforce integrity rules with a nondeclarative approach using database triggers (stored database procedures automatically invoked on insert, update, or delete operations). For more information and examples of database triggers used to enforce data integrity, see Chapter 20, "Triggers".
Oracle uses integrity constraints to prevent invalid data entry into the base tables of the database. You can define integrity constraints to enforce the business rules you want to associate with the information in a database. If any of the results of a DML statement execution violate an integrity constraint, Oracle rolls back the statement and returns an error.
For example, assume that you define an integrity constraint for the SAL column of the EMP table. This integrity constraint enforces the rule that no row in this table can contain a numeric value greater than 10,000 in this column. If an INSERT or UPDATE statement attempts to violate this integrity constraint, Oracle rolls back the statement and returns an information error message.
The integrity constraints implemented in Oracle fully comply with ANSI X3.135-1989 and ISO 9075-1989 standards.
This section describes some of the advantages that integrity constraints have over other alternatives, which include:
You define integrity constraints using SQL commands. When you define or alter a table, no additional programming is required. The SQL statements are easy to write, eliminate programming errors, and Oracle controls their functionality. For these reasons, declarative integrity constraints are preferable to application code and database triggers. The declarative approach is also better than using stored procedures, because the stored procedure solution to data integrity controls data access, but integrity constraints do not eliminate the flexibility of ad hoc data access.
Integrity constraints are defined for tables (not an application) and are stored in the data dictionary. Any data entered by any application must adhere to the same integrity constraints associated with the table. By moving business rules from application code to centralized integrity constraints, the tables of a database are guaranteed to contain valid data, no matter which database application manipulates the information. Stored procedures cannot provide the same advantage of centralized rules stored with a table. Database triggers can provide this benefit, but the complexity of implementation is far greater than the declarative approach used for integrity constraints.
If a business rule enforced by an integrity constraint changes, the administrator need only change that integrity constraint and all applications automatically adhere to the modified constraint. In contrast, if the business rule were enforced by the code of each database application, developers would have to modify all application source code and recompile, debug, and test the modified applications.
Oracle stores specific information about each integrity constraint in the data dictionary. You can design database applications to use this information to provide immediate user feedback about integrity constraint violations, even before Oracle executes and checks the SQL statement. For example, a SQL*Forms application can use integrity constraint definitions stored in the data dictionary to check for violations as values are entered into the fields of a form, even before the application issues a statement.
The semantics of integrity constraint declarations are clearly defined, and performance optimizations are implemented for each specific declarative rule. The Oracle query optimizer can use declarations to learn more about data to improve overall query performance. (Also, taking integrity rules out of application code and database triggers guarantees that checks are only made when necessary.)
You can disable integrity constraints temporarily so that large amounts of data can be loaded without the overhead of constraint checking. When the data load is complete, you can easily enable the integrity constraints, and you can automatically report any new rows that violate integrity constraints to a separate exceptions table.
The advantages of enforcing data integrity rules do not come without some loss in performance. In general, the "cost" of including an integrity constraint is, at most, the same as executing a SQL statement that evaluates the constraint.
You can use the following integrity constraints to impose restrictions on the input of column values:
By default, all columns in a table allow nulls (the absence of a value). A NOT NULL constraint requires a column of a table contain no null values. For example, you can define a NOT NULL constraint to require that a value be input in the ENAME column for every row of the EMP table.
Figure 28-2 illustrates a NOT NULL integrity constraint.
A UNIQUE key integrity constraint requires that every value in a column or set of columns (key) be unique--that is, no two rows of a table have duplicate values in a specified column or set of columns.
For example, in Figure 28-3 a UNIQUE key constraint is defined on the DNAME column of the DEPT table to disallow rows with duplicate department names.
The column (or set of columns) included in the definition of the UNIQUE key constraint is called the unique key. The term "unique key" is often incorrectly used as a synonym for the terms "UNIQUE key constraint" or "UNIQUE index"; however, note that the term "key" refers only to the column or set of columns used in the definition of the integrity constraint.
If the UNIQUE key consists of more than one column, that group of columns is said to be a composite unique key. For example, in Figure 28-4 the CUSTOMER table has a UNIQUE key constraint defined on the composite unique key: the AREA and PHONE columns.
This UNIQUE key constraint allows you to enter an area code and telephone number any number of times, but the combination of a given area code and given telephone number cannot be duplicated in the table. This eliminates unintentional duplication of a telephone number.
Oracle enforces unique integrity constraints with indexes. (In Figure 28-4, Oracle enforces the UNIQUE key constraint by implicitly creating a unique index on the composite unique key.) Therefore, composite UNIQUE key constraints have the same limitations imposed on composite indexes: up to 32 columns can constitute a composite unique key, and the total size (in bytes) of a key value cannot exceed approximately half the associated database's block size. If a usable index exists when a unique key constraint is created, the constraint will use that index rather than implicitly creating a new one.
In Figure 28-3 and Figure 28-4, UNIQUE key constraints allow the input of nulls unless you also define NOT NULL constraints for the same columns. In fact, any number of rows can include nulls for columns without NOT NULL constraints because nulls are not considered equal to anything. A null in a column (or in all columns of a composite UNIQUE key) always satisfies a UNIQUE key constraint.
Columns with both unique keys and NOT NULL integrity constraints are common. This combination forces the user to enter values in the unique key and also eliminates the possibility that any new row's data will ever conflict with an existing row's data.
Each table in the database can have at most one PRIMARY KEY constraint. The values in the group of one or more columns subject to this constraint constitute the unique identifier of the row. In effect, each row is named by its primary key values.
The Oracle implementation of the PRIMARY KEY integrity constraint guarantees that both of the following are true:
The column (or set of columns) included in the definition of a table's PRIMARY KEY integrity constraint is called the primary key. Although it is not required, every table should have a primary key so that
Figure 28-5 illustrates a PRIMARY KEY constraint in the DEPT table and examples of rows that violate the constraint.
Oracle enforces all PRIMARY KEY constraints using indexes. In Figure 28-5, the primary key constraint created for the DEPTNO column is enforced by
Oracle enforces primary key constraints using indexes, and composite primary key constraints are limited to 32 columns, which is the same limitation imposed on composite indexes. The name of the index is the same as the name of the constraint. Also, you can specify the storage options for the index by including the ENABLE clause in the CREATE TABLE or ALTER TABLE statement used to create the constraint. If a usable index exists when a primary key constraint is created, the primary key constraint will use that index rather than implicitly creating a new one.
Different tables in a relational database can be related by common columns, and the rules that govern the relationship of the columns must be maintained. Referential integrity rules guarantee that these relationships are preserved.
Several terms are associated with referential integrity constraints:
A referential integrity constraint requires that for each row of a table, the value in the foreign key matches a value in a parent key.
Figure 28-6 shows a foreign key defined on the DEPTNO column of the EMP table. It guarantees that every value in this column must match a value in the primary key of the DEPT table (also the DEPTNO column). Therefore, no erroneous department numbers can exist in the DEPTNO column of the EMP table.
Foreign keys can consist of multiple columns. However, a composite foreign key must reference a composite primary or unique key with the same number of columns and the same datatypes. Because composite primary and unique keys are limited to 32 columns, a composite foreign key is also limited to 32 columns.
Another type of referential integrity constraint, shown in Figure 28-7, is called a self-referential integrity constraint. This type of foreign key references a parent key in the same table.
In the example in Figure 28-7, the referential integrity constraint ensures that every value in the MGR column of the EMP table corresponds to a value that currently exists in the EMPNO column of the same table, but not necessarily in the same row (that is, every manager must also be an employee). This integrity constraint eliminates the possibility of erroneous employee numbers in the MGR column.
The relational model permits the value of foreign keys either to match the referenced primary or unique key value, or be null. Several interpretations of this basic rule of the relational model are possible when composite (multicolumn) foreign keys are involved.
The ANSI/ISO SQL92 (entry-level) standard permits a composite foreign key to contain any value in its non-null columns if any other column is null, even if those non-null values are not found in the referenced key. By using other constraints (for example, NOT NULL and CHECK constraints), you can alter the treatment of partially null foreign keys from this default treatment.
A composite foreign key can be all null, all non-null, or partially null. The following terms define three alternative matching rules for composite foreign keys:
Referential integrity constraints can specify particular actions to be performed on the dependent rows in a child table if a referenced parent key value is modified. The referential actions supported by the FOREIGN KEY integrity constraints of Oracle are UPDATE and DELETE No Action, and DELETE CASCADE.
Note: Other referential actions not supported by FOREIGN KEY integrity constraints of Oracle can be enforced using database triggers. See Chapter 20, "Triggers" for more information. |
The No Action (default) option specifies that referenced key values cannot be updated or deleted if the resulting data would violate a referential integrity constraint. For example, if a primary key value is referenced by a value in the foreign key, the referenced primary key value cannot be deleted because of the dependent data.
The delete cascade action specifies that when rows containing referenced key values are deleted, all rows in child tables with dependent foreign key values are also deleted--the delete "cascades". For example, if a row in a parent table is deleted, and this row's primary key value is referenced by one or more foreign key values in a child table, the rows in the child table that reference the primary key value are also deleted from the child table.
The on delete set null action specifies that when rows containing referenced key values are deleted, all rows in child tables with dependent foreign key values have those values set to null--the delete "sets null". For example, if EMPNO references MGR in the TMP table, then deleting a manager will cause the rows for all employees working for that manager to have their MGR value set to null.
Table 28-1 outlines the DML statements allowed by the different referential actions on the primary/unique key values in the parent table, and the foreign key values in the child table.
A CHECK integrity constraint on a column or set of columns requires that a specified condition be true or unknown for every row of the table. If a DML statement results in the condition of the CHECK constraint evaluating to false, the statement is rolled back.
CHECK constraints enable you to enforce very specific or sophisticated integrity rules by specifying a check condition. The condition of a CHECK constraint has some limitations:
In evaluating CHECK constraints that contain string literals or SQL functions with NLS parameters as arguments (such as TO_CHAR, TO_DATE, and TO_NUMBER), Oracle uses the database's NLS settings by default. You can override the defaults by specifying NLS parameters explicitly in such functions within the CHECK constraint definition.
Additional Information:
See the Oracle8i National Language Support Guide for more information on NLS features. |
A single column can have multiple CHECK constraints that reference the column in its definition. There is no limit to the number of CHECK constraints that you can define on a column.
To know what types of actions are permitted when constraints are present, it is useful to understand when Oracle actually performs the checking of constraints. To illustrate this, an example or two is helpful. Assume the following:
Consider the insertion of the first row into the EMP table. No rows currently exist, so how can a row be entered if the value in the MGR column cannot reference any existing value in the EMPNO column? Three possibilities for doing this are:
This case also shows that constraint checking is deferred until the complete execution of the statement; all rows are inserted first, then all rows are checked for constraint violations. (You can also defer the checking of constraints until the end of the transaction; see "Deferred Constraint Checking".)
Consider the same self-referential integrity constraint in the following scenario:
The table currently exists as illustrated in Figure 28-8.
UPDATE emp SET empno = empno + 5000, mgr = mgr + 5000;
Even though a constraint is defined to verify that each MGR value matches an EMPNO value, this statement is legal because Oracle effectively performs its constraint checking after the statement completes. Figure 28-9 shows that Oracle performs the actions of the entire SQL statement before any constraints are checked.
The examples in this section illustrated the constraint checking mechanism during INSERT and UPDATE statements. The same mechanism is used for all types of DML statements, including UPDATE, INSERT, and DELETE statements.
The examples also used self-referential integrity constraints to illustrate the checking mechanism. The same mechanism is used for all types of constraints, including NOT NULL, UNIQUE key, PRIMARY KEY, all types of FOREIGN KEY, and CHECK constraints.
Default values are included as part of an INSERT statement before the statement is parsed. Therefore, default column values are subject to all integrity constraint checking.
You can defer checking constraints for validity until the end of the transaction.
If a constraint causes an action (for example, delete cascade), that action is always taken as part of the statement that caused it, whether the constraint is deferred or immediate.
You can define constraints as either deferrable or not deferrable, and either initially deferred or initially immediate. These attributes can be different for each constraint. You specify them with keywords in the CONSTRAINT clause:
See Oracle8i SQL Reference for information about these constraint attributes and their default values.
Additional Information:
Constraints can be added, dropped, enabled, disabled, or validated (see "Constraint States"). You can also modify a constraint's attributes (see "Modifying Constraint States").
The SET CONSTRAINTS statement makes constraints either DEFERRED or IMMEDIATE for a particular transaction (following the ANSI SQL92 standards in both syntax and semantics). You can use this statement to set the mode for a list of constraint names or for ALL constraints.
The SET CONSTRAINTS mode lasts for the duration of the transaction or until another SET CONSTRAINTS statement resets the mode.
SET CONSTRAINTS ... IMMEDIATE causes the specified constraints to be checked immediately on execution of each constrained statement. Oracle first checks any constraints that were deferred earlier in the transaction and then continues immediately checking constraints of any further statements in that transaction (as long as all the checked constraints are consistent and no other SET CONSTRAINTS statement is issued). If any constraint fails the check, an error is signalled; at that point, a COMMIT would cause the whole transaction to roll back.
The ALTER SESSION statement also has options to SET CONSTRAINTS IMMEDIATE or DEFERRED. These options imply setting ALL deferrable constraints (that is, you cannot specify a list of constraint names). They are equivalent to making a SET CONSTRAINTS statement at the start of each transaction in the current session.
Making constraints immediate at the end of a transaction is a way of checking whether COMMIT can succeed. You can avoid unexpected rollbacks by setting constraints to IMMEDIATE as the last statement in a transaction. If any constraint fails the check, you can then correct the error before committing the transaction.
The SET CONSTRAINTS statement is disallowed inside of triggers.
SET CONSTRAINTS can be a distributed statement. Existing database links that have transactions in process are told when a SET CONSTRAINTS ALL statement occurs, and new links learn that it occurred as soon as they start a transaction.
A user will see inconsistent constraints, including duplicates in unique indexes, when that user's transaction produces these inconsistencies.
You can place deferred unique and foreign key constraints on snapshots, allowing fast and complete refresh to complete successfully.
Deferrable unique constraints always use nonunique indexes. When you remove a deferrable constraint, its index remains. (This is convenient because the storage information remains available after you disable a constraint.) Not-deferrable unique constraints and primary keys also use a nonunique index if the nonunique index is placed on the key columns before the constraint is enforced.
You can enable or disable integrity constraints at the table level using the CREATE TABLE or ALTER TABLE statement. You can also set constraints to VALIDATE or NOVALIDATE, in any combination with ENABLE or DISABLE, where:
In addition:
In an ALTER TABLE statement, ENABLE NOVALIDATE resumes constraint checking on disabled constraints without first validating all data in the table.
For a UNIQUE constraint, the DISABLE VALIDATE state enables you to load data efficiently from a nonpartitioned table into a partitioned table using the EXCHANGE PARTITION option of the ALTER TABLE command.
Transitions between these states are governed by the following rules:
See Oracle8i Administrator's Guide for more information about how to use the ENABLE, DISABLE, VALIDATE, and NOVALIDATE CONSTRAINT options.
Additional Information:
You can use the MODIFY CONSTRAINT option of the ALTER TABLE command to change the following constraint states: