Data types are a way to limit the kind of data that can be stored
in a table. For many applications, however, the constraint they
provide is too coarse. For example, a column containing a product
price should probably only accept positive values. But there is no
data type that accepts only positive numbers. Another issue is
that you might want to constrain column data with respect to other
columns or rows. For example, in a table containing employee
information, there should only be one row for each employee.
To that end, SQL allows you to define constraints on columns and
tables. Constraints give you as much control over the data in your
tables as you wish. If a user attempts to store data in a column
that would violate a constraint, an error is raised. This applies
even if the value came from the default value definition.
A check constraint is the most generic constraint type. It allows
you to specify that the value in a certain column must satisfy an
arbitrary expression. For instance, to require positive salaries,
you could use:
CREATE TABLE emp (
empno NUMBER(4),
ename VARCHAR2(10),
job VARCHAR2(9),
mgr NUMBER(4),
hiredate DATE,
sal NUMBER(7,2) CHECK (sal > 0),
comm NUMBER(7,2),
deptno NUMBER(2)
)
As you see, the constraint definition comes after the data type,
just like default value definitions. Default values and
constraints can be listed in any order. A check constraint
consists of the key word CHECK followed by an
expression in parentheses. The check constraint expression should
involve the column thus constrained, otherwise the constraint
would not make too much sense.
You can also give the constraint a separate name. This clarifies
error messages and allows you to refer to the constraint when you
need to change it. The syntax is:
CREATE TABLE emp (
empno NUMBER(4),
ename VARCHAR2(10),
job VARCHAR2(9),
mgr NUMBER(4),
hiredate DATE,
sal NUMBER(7,2) CONSTRAINT chk_salary CHECK (sal > 0),
comm NUMBER(7,2),
deptno NUMBER(2)
)
So, to specify a named constraint, use the key word
CONSTRAINT followed by an identifier followed
by the constraint definition. A check constraint can also refer to
several columns. Say we wanted to limit an employee's total
commission (the product of salary and commission) to $5000.00,
we would do something like the following:
CREATE TABLE emp (
empno NUMBER(4),
ename VARCHAR2(10),
job VARCHAR2(9),
mgr NUMBER(4),
hiredate DATE,
sal NUMBER(7,2) CONSTRAINT chk_salary CHECK (sal > 0),
comm NUMBER(7,2),
deptno NUMBER(2),
CHECK (sal * comm <=5000));
The first two constraints should look familiar. The third one
uses a new syntax. It is not attached to a particular column,
instead it appears as a separate item in the comma-separated
column list. Column definitions and these constraint
definitions can be listed in mixed order.
We say that the first two constraints are column constraints, whereas the
third one is a table constraint because it is written separately
from the column definitions. Column constraints can also be
written as table constraints, while the reverse is not necessarily
possible. The above example could also be written as
CREATE TABLE emp (
empno NUMBER(4),
ename VARCHAR2(10),
job VARCHAR2(9),
mgr NUMBER(4),
hiredate DATE,
sal NUMBER(7,2),
comm NUMBER(7,2),
deptno NUMBER(2),
CHECK (sal > 0),
CHECK (sal * comm <=5000))
It's a matter of taste.
It should be noted that a check constraint is satisfied if the
check expression evaluates to true or the null value. Since most
expressions will evaluate to the null value if one operand is null,
they will not prevent null values in the constrained columns. To
ensure that a column does not contain null values, the not-null
constraint described in the next section should be used.
A not-null constraint simply specifies that a column must not
assume the null value. A syntax example:
CREATE TABLE emp (
empno NUMBER(4) NOT NULL,
ename VARCHAR2(10),
job VARCHAR2(9),
mgr NUMBER(4),
hiredate DATE,
sal NUMBER(7,2),
comm NUMBER(7,2),
deptno NUMBER(2)
);
A not-null constraint is always written as a column constraint. A
not-null constraint is functionally equivalent to creating a check
constraint CHECK (column_name
IS NOT NULL), but in
EnterpriseDB creating an explicit
not-null constraint is more efficient. The drawback is that you
cannot give explicit names to not-null constraints created that
way.
Of course, a column can have more than one constraint. Just write
the constraints after one another:
CREATE TABLE emp (
empno NUMBER(4) NOT NULL,
ename VARCHAR2(10),
job VARCHAR2(9),
mgr NUMBER(4),
hiredate DATE,
sal NUMBER(7,2) NOT NULL CHECK (sal > 0) ,
comm NUMBER(7,2),
deptno NUMBER(2),
CHECK (sal * comm <=5000)
);
The order doesn't matter. It does not necessarily determine in which
order the constraints are checked.
The NOT NULL constraint has an inverse: the
NULL constraint. This does not mean that the
column must be null, which would surely be useless. Instead, this
simply defines the default behavior that the column may be null.
The NULL constraint is not defined in the SQL
standard and should not be used in portable applications. (It was
only added to EnterpriseDB to be
compatible with some other database systems.) Some users, however,
like it because it makes it easy to toggle the constraint in a
script file. For example, you could start with
CREATE TABLE emp (
empno NUMBER(4) NOT NULL,
ename VARCHAR2(10) NOT NULL,
job VARCHAR2(9) NULL,
mgr NUMBER(4) NULL,
hiredate DATE NULL,
sal NUMBER(7,2) NOT NULL CHECK (sal > 0),
comm NUMBER(7,2) NULL,
deptno NUMBER(2) NOT NULL
);
and then insert the NOT key word where desired.
Tip: In most database designs the majority of columns should be marked
not null.
Unique constraints ensure that the data contained in a column or a
group of columns is unique with respect to all the rows in the
table. The syntax is
CREATE TABLE emp (
empno NUMBER(4) UNIQUE,
ename VARCHAR2(10),
job VARCHAR2(9),
mgr NUMBER(4),
hiredate DATE,
sal NUMBER(7,2) CHECK (sal > 0),
comm NUMBER(7,2),
deptno NUMBER(2)
);
when written as a column constraint, and
CREATE TABLE emp (
empno NUMBER(4),
ename VARCHAR2(10),
job VARCHAR2(9),
mgr NUMBER(4),
hiredate DATE,
sal NUMBER(7,2) CHECK (sal > 0),
comm NUMBER(7,2),
deptno NUMBER(2),
UNIQUE (empno)
);
when written as a table constraint.
If a unique constraint refers to a group of columns, the columns
are listed separated by commas:
CREATE TABLE emp (
empno NUMBER(4),
ename VARCHAR2(10),
job VARCHAR2(9),
mgr NUMBER(4),
hiredate DATE,
sal NUMBER(7,2) CHECK (sal > 0),
comm NUMBER(7,2),
deptno NUMBER(2),
UNIQUE (empno,deptno)
);
It is also possible to assign names to unique constraints:
CREATE TABLE emp (
empno NUMBER(4) CONSTRAINT unique_empno UNIQUE,
ename VARCHAR2(10),
job VARCHAR2(9),
mgr NUMBER(4),
hiredate DATE,
sal NUMBER(7,2) CHECK (sal > 0),
comm NUMBER(7,2),
deptno NUMBER(2)
);
In general, a unique constraint is violated when there are (at
least) two rows in the table where the values of each of the
corresponding columns that are part of the constraint are equal.
However, null values are not considered equal in this
consideration. That means even in the presence of a
unique constraint it is possible to store an unlimited number of
rows that contain a null value in at least one of the constrained
columns. This behavior conforms to the SQL standard, but we have
heard that other SQL databases may not follow this rule. So be
careful when developing applications that are intended to be
portable.
Technically, a primary key constraint is simply a combination of a
unique constraint and a not-null constraint. So, the following
two table definitions accept the same data:
CREATE TABLE emp (
empno NUMBER(4) UNIQUE NOT NULL,
ename VARCHAR2(10),
job VARCHAR2(9),
mgr NUMBER(4),
hiredate DATE,
sal NUMBER(7,2) CHECK (sal > 0),
comm NUMBER(7,2),
deptno NUMBER(2)
);
CREATE TABLE emp (
empno NUMBER(4) PRIMARY KEY,
ename VARCHAR2(10),
job VARCHAR2(9),
mgr NUMBER(4),
hiredate DATE,
sal NUMBER(7,2) CHECK (sal > 0),
comm NUMBER(7,2),
deptno NUMBER(2)
);
Primary keys can also constrain more than one column; the syntax
is similar to unique constraints:
CREATE TABLE emp (
empno NUMBER(4),
ename VARCHAR2(10),
job VARCHAR2(9),
mgr NUMBER(4),
hiredate DATE,
sal NUMBER(7,2) CHECK (sal > 0),
comm NUMBER(7,2),
deptno NUMBER(2),
PRIMARY KEY (empno, ename)
);
A primary key indicates that a column or group of columns can be
used as a unique identifier for rows in the table. (This is a
direct consequence of the definition of a primary key. Note that
a unique constraint does not, by itself, provide a unique identifier
because it does not exclude null values.) This is useful both for
documentation purposes and for client applications. For example,
a GUI application that allows modifying row values probably needs
to know the primary key of a table to be able to identify rows
uniquely.
A table can have at most one primary key (while it can have many
unique and not-null constraints). Relational database theory
dictates that every table must have a primary key. This rule is
not enforced by EnterpriseDB, but it is
usually best to follow it.
A foreign key constraint specifies that the values in a column (or
a group of columns) must match the values appearing in some row
of another table.
We say this maintains the referential
integrity between two related tables.
Let's refer to the dept table that stores the department related information:
CREATE TABLE dept (
deptno NUMBER(2) PRIMARY KEY,
dname VARCHAR2(14),
loc VARCHAR2(13)
);
We want to ensure that the emp table only contains the id's
of departments that actually exist. So we define a foreign
key constraint in the emp table that references the dept table:
CREATE TABLE emp (
empno NUMBER(4) PRIMARY KEY,
ename VARCHAR2(10),
job VARCHAR2(9),
mgr NUMBER(4),
hiredate DATE,
sal NUMBER(7,2),
comm NUMBER(7,2),
deptno NUMBER(2) REFERENCES dept (deptno)
);
Now it is impossible to create employees with
deptno entries that
do not appear in the dept table. However, keep
in mind that the column being referenced in the
other table (in this case the deptno column of
the dept table) must be the primary key of that
table.
We say that in this situation the emp table is the
referencing table and the dept
table is the referenced table.
Similarly, there are referencing and referenced columns.
You can also shorten the above command to
CREATE TABLE emp (
empno NUMBER(4) PRIMARY KEY,
ename VARCHAR2(10),
job VARCHAR2(9),
mgr NUMBER(4),
hiredate DATE,
sal NUMBER(7,2) CHECK (sal > 0),
comm NUMBER(7,2),
deptno NUMBER(2) REFERENCES dept
);
A foreign key can also constrain and reference a group of columns.
As usual, it then needs to be written in table constraint form.
Here is a contrived syntax example:
CREATE TABLE t1 (
a integer PRIMARY KEY,
b integer,
c integer,
FOREIGN KEY (b, c) REFERENCES other_table (c1, c2)
);
Of course, the number and type of the constrained columns needs to
match the number and type of the referenced columns.
A table can contain more than one foreign key constraint. This is
used to implement many-to-many relationships between tables.
Say we have a table for keeping a track record of all our employees.
You could use this table structure:
CREATE TABLE jobhist (
empno NUMBER(4) NOT NULL REFERENCES emp,
startdate DATE NOT NULL,
enddate DATE,
job VARCHAR2(9),
sal NUMBER(7,2),
comm NUMBER(7,2),
deptno NUMBER(2) REFERENCES dept,
chgdesc VARCHAR2(80),
PRIMARY KEY (empno, startdate),
CHECK (startdate <= enddate)
);
We know that the foreign keys disallow creation of history records
for employees who do not exist in the emp table. But what if an
employee is removed after his/her history is created in the history table?
SQL allows you to specify that as well. Intuitively, we have a few options:
To illustrate this, let's implement the following policy on the
many-to-many relationship example above: when someone wants to
remove an employees that is still referenced by a history record,
we disallow it. If someone removes an employee from the emp table,
then the employee's history is also removed from the history table.
CREATE TABLE emp (
empno NUMBER(4) NOT NULL CONSTRAINT emp_pk PRIMARY KEY,
ename VARCHAR2(10),
job VARCHAR2(9),
mgr NUMBER(4),
hiredate DATE,
sal NUMBER(7,2) CHECK (sal > 0),
comm NUMBER(7,2),
deptno NUMBER(2) CONSTRAINT emp_ref_dept_fk
REFERENCES dept(deptno)
);
CREATE TABLE dept (
deptno NUMBER(2) NOT NULL CONSTRAINT dept_pk PRIMARY KEY,
dname VARCHAR2(14) CONSTRAINT dept_dname_uq UNIQUE,
loc VARCHAR2(13)
);
CREATE TABLE jobhist (
empno NUMBER(4) NOT NULL,
startdate DATE NOT NULL,
enddate DATE,
job VARCHAR2(9),
sal NUMBER(7,2),
comm NUMBER(7,2),
deptno NUMBER(2),
chgdesc VARCHAR2(80),
CONSTRAINT jobhist_pk PRIMARY KEY (empno, startdate),
CONSTRAINT jobhist_ref_emp_fk FOREIGN KEY (empno)
REFERENCES emp(empno) ON DELETE CASCADE,
CONSTRAINT jobhist_ref_dept_fk FOREIGN KEY (deptno)
REFERENCES dept (deptno) ON DELETE SET NULL,
CONSTRAINT jobhist_date_chk CHECK (startdate <= enddate)
);
Restricting and cascading deletes are the two most common options.
RESTRICT prevents a statement from deleting a
referenced row. NO ACTION means that if any
referencing rows still exist when the constraint is checked, an error
is raised; this is the default if you do not specify anything.
(The essential difference between these choices is that
NO ACTION allows the check to be deferred until
later in the transaction, whereas RESTRICT does not.)
There are two other options:
SET NULL and SET DEFAULT.
These cause the referencing columns to be set to nulls or default
values, respectively, when the referenced row is deleted.
Note that these do not excuse you from observing any constraints.
For example, if an action specifies SET DEFAULT
but the default value would not satisfy the foreign key, the
deletion of the primary key will fail.
Analogous to ON DELETE there is also
ON UPDATE which is invoked when a primary key
is changed (updated). The possible actions are the same.
More information about updating and deleting data is in Chapter 5.
Finally, we should mention that a foreign key must reference
columns that either are a primary key or form a unique constraint.
If the foreign key references a unique constraint, there are some
additional possibilities regarding how null values are matched.
These are explained in the reference documentation for
CREATE TABLE.