<?xml version="1.0" encoding="UTF-8"?> <!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"> <html lang="en-us" xml:lang="en-us"> <head> <meta http-equiv="Content-Type" content="text/html; charset=utf-8" /> <meta name="security" content="public" /> <meta name="Robots" content="index,follow" /> <meta http-equiv="PICS-Label" content='(PICS-1.1 "http://www.icra.org/ratingsv02.html" l gen true r (cz 1 lz 1 nz 1 oz 1 vz 1) "http://www.rsac.org/ratingsv01.html" l gen true r (n 0 s 0 v 0 l 0) "http://www.classify.org/safesurf/" l gen true r (SS~~000 1))' /> <meta name="DC.Type" content="reference" /> <meta name="DC.Title" content="Add referential constraints" /> <meta name="abstract" content="The rule that every department number shown in the sample employee table must appear in the department table is a referential constraint." /> <meta name="description" content="The rule that every department number shown in the sample employee table must appear in the department table is a referential constraint." /> <meta name="DC.subject" content="examples, adding constraints, CREATE TABLE statement, referential constraints, ALTER TABLE statement, constraint, referential, creating tables" /> <meta name="keywords" content="examples, adding constraints, CREATE TABLE statement, referential constraints, ALTER TABLE statement, constraint, referential, creating tables" /> <meta name="DC.Relation" scheme="URI" content="rbafyrefinteg.htm" /> <meta name="copyright" content="(C) Copyright IBM Corporation 1998, 2006" /> <meta name="DC.Rights.Owner" content="(C) Copyright IBM Corporation 1998, 2006" /> <meta name="DC.Format" content="XHTML" /> <meta name="DC.Identifier" content="rbafyaddrcon" /> <meta name="DC.Language" content="en-us" /> <!-- All rights reserved. Licensed Materials Property of IBM --> <!-- US Government Users Restricted Rights --> <!-- Use, duplication or disclosure restricted by --> <!-- GSA ADP Schedule Contract with IBM Corp. --> <link rel="stylesheet" type="text/css" href="./ibmdita.css" /> <link rel="stylesheet" type="text/css" href="./ic.css" /> <title>Add referential constraints</title> </head> <body id="rbafyaddrcon"><a name="rbafyaddrcon"><!-- --></a> <!-- Java sync-link --><script language="Javascript" src="../rzahg/synch.js" type="text/javascript"></script> <h1 class="topictitle1">Add referential constraints</h1> <div><p>The rule that every department number shown in the sample employee table must appear in the department table is a referential constraint.</p> <div class="section"><p>This constraint ensures that every employee belongs to an existing department. The following SQL statements create the CORPDATA.DEPARTMENT and CORPDATA.EMPLOYEE tables with those constraint relationships defined. </p> <pre><strong>CREATE TABLE</strong> CORPDATA.DEPARTMENT (DEPTNO <strong>CHAR</strong>(3) <strong>NOT NULL PRIMARY KEY</strong>, DEPTNAME <strong>VARCHAR</strong>(29) <strong>NOT NULL</strong>, MGRNO <strong>CHAR</strong>(6), ADMRDEPT <strong>CHAR</strong>(3) <strong>NOT NULL</strong> <strong>CONSTRAINT</strong> REPORTS_TO_EXISTS <strong>REFERENCES</strong> CORPDATA.DEPARTMENT (DEPTNO) <strong>ON DELETE CASCADE</strong>) <strong>CREATE TABLE</strong> CORPDATA.EMPLOYEE (EMPNO <strong>CHAR</strong>(6) <strong>NOT NULL PRIMARY KEY</strong>, FIRSTNME <strong>VARCHAR</strong>(12) <strong>NOT NULL</strong>, MIDINIT <strong>CHAR</strong>(1) <strong>NOT NULL</strong>, LASTNAME <strong>VARCHAR</strong>(15) <strong>NOT NULL</strong>, WORKDEPT <strong>CHAR</strong>(3) <strong>CONSTRAINT</strong> WORKDEPT_EXISTS <strong>REFERENCES</strong> CORPDATA.DEPARTMENT (DEPTNO) <strong>ON DELETE SET NULL ON UPDATE RESTRICT</strong>, PHONENO <strong>CHAR</strong>(4), HIREDATE <strong>DATE</strong>, JOB <strong>CHAR</strong>(8), EDLEVEL <strong>SMALLINT NOT NULL,</strong> SEX <strong>CHAR</strong>(1), BIRTHDATE <strong>DATE</strong>, SALARY <strong>DECIMAL</strong>(9,2), BONUS <strong>DECIMAL</strong>(9,2), COMM <strong>DECIMAL</strong>(9,2), <strong>CONSTRAINT</strong> UNIQUE_LNAME_IN_DEPT <strong>UNIQUE</strong> (WORKDEPT, LASTNAME))</pre> </div> <div class="section"><p>In this case, the DEPARTMENT table has a column of unique department numbers (DEPTNO) which functions as a primary key, and is a parent table in two constraint relationships: </p> <dl><dt class="dlterm">REPORTS_TO_EXISTS</dt> <dd>is a self-referencing constraint in which the DEPARTMENT table is both the parent and the dependent in the same relationship. Every non-null value of ADMRDEPT must match a value of DEPTNO. A department must report to an existing department in the database. The DELETE CASCADE rule indicates that if a row with a DEPTNO value <em>n</em> is deleted, every row in the table for which the ADMRDEPT is <em>n</em> is also deleted.</dd> <dt class="dlterm">WORKDEPT_EXISTS</dt> <dd>establishes the EMPLOYEE table as a dependent table, and the column of employee department assignments (WORKDEPT) as a foreign key. Thus, every value of WORKDEPT must match a value of DEPTNO. The DELETE SET NULL rule says that if a row is deleted from DEPARTMENT in which the value of DEPTNO is <em>n</em>, then the value of WORKDEPT in EMPLOYEE is set to null in every row in which the value was <em>n</em>. The UPDATE RESTRICT rule says that a value of DEPTNO in DEPARTMENT cannot be updated if there are values of WORKDEPT in EMPLOYEE that match the current DEPTNO value.</dd> </dl> </div> <div class="section"><p>Constraint UNIQUE_LNAME_IN_DEPT in the EMPLOYEE table causes LASTNAME to be unique within a department. While this constraint is unlikely, it illustrates how a constraint made up of several columns can be defined at the table level.</p> </div> </div> <div> <div class="familylinks"> <div class="parentlink"><strong>Parent topic:</strong> <a href="rbafyrefinteg.htm" title="Referential integrity is the condition of a set of tables in a database in which all references from one table to another are valid.">Referential integrity and tables</a></div> </div> </div> </body> </html>