108 lines
6.4 KiB
HTML
108 lines
6.4 KiB
HTML
|
<?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="BEFORE SQL triggers" />
|
|||
|
<meta name="abstract" content="BEFORE triggers may not modify tables, but they can be used to verify input column values and also to modify column values that are inserted or updated in a table." />
|
|||
|
<meta name="description" content="BEFORE triggers may not modify tables, but they can be used to verify input column values and also to modify column values that are inserted or updated in a table." />
|
|||
|
<meta name="DC.subject" content="trigger, BEFORE trigger, example, CREATE TRIGGER statement, examples" />
|
|||
|
<meta name="keywords" content="trigger, BEFORE trigger, example, CREATE TRIGGER statement, examples" />
|
|||
|
<meta name="DC.Relation" scheme="URI" content="rbafysqltrig.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="rbafybeforesql" />
|
|||
|
<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>BEFORE SQL triggers</title>
|
|||
|
</head>
|
|||
|
<body id="rbafybeforesql"><a name="rbafybeforesql"><!-- --></a>
|
|||
|
<!-- Java sync-link --><script language="Javascript" src="../rzahg/synch.js" type="text/javascript"></script>
|
|||
|
<h1 class="topictitle1">BEFORE SQL triggers</h1>
|
|||
|
<div><p>BEFORE triggers may not modify tables, but they can be used to
|
|||
|
verify input column values and also to modify column values that are inserted
|
|||
|
or updated in a table. </p>
|
|||
|
<div class="section"><p>In the following example, the trigger is used to set the fiscal
|
|||
|
quarter for the corporation before inserting the row into the target table.</p>
|
|||
|
<pre><strong>CREATE TABLE</strong> TransactionTable (DateOfTransaction <strong>DATE</strong>, FiscalQuarter <strong>SMALLINT</strong>)
|
|||
|
|
|||
|
<strong>CREATE TRIGGER</strong> TransactionBeforeTrigger <strong>BEFORE INSERT ON</strong> TransactionTable
|
|||
|
<strong>REFERENCING NEW AS</strong> new_row
|
|||
|
<strong>FOR EACH ROW MODE DB2ROW</strong>
|
|||
|
<strong>BEGIN</strong>
|
|||
|
<strong>DECLARE</strong> newmonth <strong>SMALLINT</strong>;
|
|||
|
<strong>SET</strong> newmonth = <strong>MONTH</strong>(new_row.DateOfTransaction);
|
|||
|
<strong>IF</strong> newmonth < 4 <strong>THEN</strong>
|
|||
|
<strong>SET</strong> new_row.FiscalQuarter=3;
|
|||
|
<strong>ELSEIF</strong> newmonth < 7 <strong>THEN</strong>
|
|||
|
<strong>SET</strong> new_row.FiscalQuarter=4;
|
|||
|
<strong>ELSEIF</strong> newmonth < 10 <strong>THEN</strong>
|
|||
|
<strong>SET</strong> new_row.FiscalQuarter=1;
|
|||
|
<strong>ELSE</strong>
|
|||
|
<strong>SET</strong> new_row.FiscalQuarter=2;
|
|||
|
<strong>END IF</strong>;
|
|||
|
<strong>END</strong></pre>
|
|||
|
<p>For the SQL insert statement below, the "FiscalQuarter"
|
|||
|
column is set to 2, if the current date is November 14, 2000.</p>
|
|||
|
<pre><strong>INSERT INTO</strong> TransactionTable(DateOfTransaction)
|
|||
|
<strong>VALUES</strong>(<strong>CURRENT DATE</strong>) </pre>
|
|||
|
<p>SQL triggers
|
|||
|
have access to and can use User-defined Distinct Types (UDTs) and stored procedures.
|
|||
|
In the following example, the SQL trigger calls a stored procedure to execute
|
|||
|
some predefined business logic, in this case, to set a column to a predefined
|
|||
|
value for the business.</p>
|
|||
|
<pre><strong>CREATE DISTINCT TYPE</strong> enginesize <strong>AS DECIMAL</strong>(5,2) <strong>WITH COMPARISONS</strong>
|
|||
|
|
|||
|
<strong>CREATE DISTINCT TYPE</strong> engineclass <strong>AS VARCHAR</strong>(25) <strong>WITH COMPARISONS</strong>
|
|||
|
|
|||
|
<strong>CREATE PROCEDURE</strong> SetEngineClass(<strong>IN</strong> SizeInLiters enginesize,
|
|||
|
<strong>OUT</strong> CLASS engineclass)
|
|||
|
<strong>LANGUAGE SQL CONTAINS SQL</strong>
|
|||
|
<strong>BEGIN</strong>
|
|||
|
<strong>IF</strong> SizeInLiters<2.0 <strong>THEN</strong>
|
|||
|
<strong>SET</strong> CLASS = 'Mouse';
|
|||
|
<strong>ELSEIF</strong> SizeInLiters<3.1 <strong>THEN</strong>
|
|||
|
<strong>SET</strong> CLASS ='Economy Class';
|
|||
|
<strong>ELSEIF</strong> SizeInLiters<4.0 <strong>THEN</strong>
|
|||
|
<strong>SET</strong> CLASS ='Most Common Class';
|
|||
|
<strong>ELSEIF</strong> SizeInLiters<4.6 <strong>THEN</strong>
|
|||
|
<strong>SET</strong> CLASS = 'Getting Expensive';
|
|||
|
<strong>ELSE</strong>
|
|||
|
<strong>SET</strong> CLASS ='Stop Often for Fillups';
|
|||
|
<strong>END IF</strong>;
|
|||
|
<strong>END</strong>
|
|||
|
|
|||
|
<strong>CREATE TABLE</strong> EngineRatings (VariousSizes enginesize, ClassRating engineclass)
|
|||
|
|
|||
|
<strong>CREATE TRIGGER</strong> SetEngineClassTrigger <strong>BEFORE INSERT ON</strong> EngineRatings
|
|||
|
<strong>REFERENCING NEW AS</strong> new_row
|
|||
|
<strong>FOR EACH ROW MODE DB2ROW</strong>
|
|||
|
<strong>CALL</strong> SetEngineClass(new_row.VariousSizes, new_row.ClassRating)</pre>
|
|||
|
<p>For
|
|||
|
the SQL insert statement below, the "ClassRating" column is set to "Economy
|
|||
|
Class", if the "VariousSizes" column has the value of 3.0.</p>
|
|||
|
<pre><strong>INSERT INTO</strong> EngineRatings(VariousSizes) <strong>VALUES</strong>(3.0)</pre>
|
|||
|
<p>SQL requires all tables, user-defined functions, procedures and user-defined
|
|||
|
types to exist before creating an SQL trigger. In the examples above, all
|
|||
|
of the tables, stored procedures, and user-defined types are defined before
|
|||
|
the trigger is created.</p>
|
|||
|
</div>
|
|||
|
</div>
|
|||
|
<div>
|
|||
|
<div class="familylinks">
|
|||
|
<div class="parentlink"><strong>Parent topic:</strong> <a href="rbafysqltrig.htm" title="The SQL CREATE TRIGGER statement provides a way for the database management system to actively control, monitor, and manage a group of tables and views whenever an insert, update, or delete operation is performed.">SQL triggers</a></div>
|
|||
|
</div>
|
|||
|
</div>
|
|||
|
</body>
|
|||
|
</html>
|