lang_createtrigger.html 9.7 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237
  1. <!DOCTYPE HTML PUBLIC "-//W3C//DTD HTML 4.01//EN" "http://www.w3.org/TR/html4/strict.dtd">
  2. <html><head>
  3. <title>SQLite Query Language: CREATE TRIGGER</title>
  4. <style type="text/css">
  5. body {
  6. margin: auto;
  7. font-family: Verdana, sans-serif;
  8. padding: 8px 1%;
  9. }
  10. a { color: #45735f }
  11. a:visited { color: #734559 }
  12. .logo { position:absolute; margin:3px; }
  13. .tagline {
  14. float:right;
  15. text-align:right;
  16. font-style:italic;
  17. width:240px;
  18. margin:12px;
  19. margin-top:58px;
  20. }
  21. .toolbar {
  22. font-variant: small-caps;
  23. text-align: center;
  24. line-height: 1.6em;
  25. margin: 0;
  26. padding:1px 8px;
  27. }
  28. .toolbar a { color: white; text-decoration: none; padding: 6px 12px; }
  29. .toolbar a:visited { color: white; }
  30. .toolbar a:hover { color: #80a796; background: white; }
  31. .content { margin: 5%; }
  32. .content dt { font-weight:bold; }
  33. .content dd { margin-bottom: 25px; margin-left:20%; }
  34. .content ul { padding:0px; padding-left: 15px; margin:0px; }
  35. /* rounded corners */
  36. .se { background: url(images/se.png) 100% 100% no-repeat #80a796}
  37. .sw { background: url(images/sw.png) 0% 100% no-repeat }
  38. .ne { background: url(images/ne.png) 100% 0% no-repeat }
  39. .nw { background: url(images/nw.png) 0% 0% no-repeat }
  40. </style>
  41. <meta http-equiv="content-type" content="text/html; charset=UTF-8">
  42. </head>
  43. <body>
  44. <div><!-- container div to satisfy validator -->
  45. <a href="lang.html">
  46. <h2 align="center">SQL As Understood By SQLite</h2></a><h1>CREATE TRIGGER</h1><h4><a href="syntaxdiagrams.html#create-trigger-stmt">create-trigger-stmt:</a></h4><blockquote> <img alt="syntax diagram create-trigger-stmt" src="images/syntax/create-trigger-stmt.gif"></img> </blockquote>
  47. <p>The CREATE TRIGGER statement is used to add triggers to the
  48. database schema. Triggers are database operations
  49. that are automatically performed when a specified database event
  50. occurs. </p>
  51. <p>A trigger may be specified to fire whenever a <a href="lang_delete.html">DELETE</a>, <a href="lang_insert.html">INSERT</a>,
  52. or <a href="lang_update.html">UPDATE</a> of a
  53. particular database table occurs, or whenever an <a href="lang_update.html">UPDATE</a> occurs on
  54. on one or more specified columns of a table.</p>
  55. <p>At this time SQLite supports only FOR EACH ROW triggers, not FOR EACH
  56. STATEMENT triggers. Hence explicitly specifying FOR EACH ROW is optional. FOR
  57. EACH ROW implies that the SQL statements specified in the trigger
  58. may be executed (depending on the WHEN clause) for each database row being
  59. inserted, updated or deleted by the statement causing the trigger to fire.</p>
  60. <p>Both the WHEN clause and the trigger actions may access elements of
  61. the row being inserted, deleted or updated using references of the form
  62. "NEW.<i>column-name</i>" and "OLD.<i>column-name</i>", where
  63. <i>column-name</i> is the name of a column from the table that the trigger
  64. is associated with. OLD and NEW references may only be used in triggers on
  65. events for which they are relevant, as follows:</p>
  66. <table border=0 cellpadding=10>
  67. <tr>
  68. <td valign="top" align="right" width=120><i>INSERT</i></td>
  69. <td valign="top">NEW references are valid</td>
  70. </tr>
  71. <tr>
  72. <td valign="top" align="right" width=120><i>UPDATE</i></td>
  73. <td valign="top">NEW and OLD references are valid</td>
  74. </tr>
  75. <tr>
  76. <td valign="top" align="right" width=120><i>DELETE</i></td>
  77. <td valign="top">OLD references are valid</td>
  78. </tr>
  79. </table>
  80. </p>
  81. <p>If a WHEN clause is supplied, the SQL statements specified
  82. are only executed for rows for which the WHEN
  83. clause is true. If no WHEN clause is supplied, the SQL statements
  84. are executed for all rows.</p>
  85. <p>The BEFORE or AFTER keyword determines when the trigger actions
  86. will be executed relative to the insertion, modification or removal of the
  87. associated row.</p>
  88. <p>An <a href="lang_conflict.html">ON CONFLICT</a> clause may be specified as part of an <a href="lang_update.html">UPDATE</a> or <a href="lang_insert.html">INSERT</a>
  89. action within the body of the trigger.
  90. However if an <a href="lang_conflict.html">ON CONFLICT</a> clause is specified as part of
  91. the statement causing the trigger to fire, then conflict handling
  92. policy of the outer statement is used instead.</p>
  93. <p>Triggers are automatically <a href="lang_droptrigger.html">dropped</a>
  94. when the table that they are
  95. associated with (the <i>table-name</i> table) is
  96. <a href="lang_droptable.html">dropped</a>. However if the the trigger actions reference
  97. other tables, the trigger is not dropped or modified if those other
  98. tables are <a href="lang_droptable.html">dropped</a> or <a href="lang_altertable.html">modified</a>.</p>
  99. <p>Triggers are removed using the <a href="lang_droptrigger.html">DROP TRIGGER</a> statement.</p>
  100. <h3>Syntax Restrictions On UPDATE, DELETE, and INSERT Statements Within
  101. Triggers</h3>
  102. <p>The <a href="lang_update.html">UPDATE</a>, <a href="lang_delete.html">DELETE</a>, and <a href="lang_insert.html">INSERT</a>
  103. statements within triggers do not support
  104. the full syntax for <a href="lang_update.html">UPDATE</a>, <a href="lang_delete.html">DELETE</a>, and <a href="lang_insert.html">INSERT</a> statements. The following
  105. restrictions apply:</p>
  106. <ul>
  107. <li><p>
  108. The name of the table to be modified in an <a href="lang_update.html">UPDATE</a>, <a href="lang_delete.html">DELETE</a>, or <a href="lang_insert.html">INSERT</a>
  109. statement must be an unqualified table name. In other words, one must
  110. use just "<i>tablename</i>" not "<i>database</i><b>.</b><i>tablename</i>"
  111. when specifying the table. The table to be modified must exist in the
  112. same database as the table or view to which the trigger is attached.
  113. </p></li>
  114. <li><p>
  115. The "INSERT INTO <i>table</i> DEFAULT VALUES" form of the <a href="lang_insert.html">INSERT</a> statement
  116. is not supported.
  117. </p></li>
  118. <li><p>
  119. The INDEXED BY and NOT INDEXED clauses are not supported for <a href="lang_update.html">UPDATE</a> and
  120. <a href="lang_delete.html">DELETE</a> statements.
  121. </p></li>
  122. <li><p>
  123. The ORDER BY and LIMIT clauses on <a href="lang_update.html">UPDATE</a> and <a href="lang_delete.html">DELETE</a> statements are not
  124. supported. ORDER BY and LIMIT are not normally supported for <a href="lang_update.html">UPDATE</a> or
  125. <a href="lang_delete.html">DELETE</a> in any context but can be enabled for top-level statements
  126. using the <a href="compile.html#enable_update_delete_limit">SQLITE_ENABLE_UPDATE_DELETE_LIMIT</a> compile-time option. However,
  127. that compile-time option only applies to top-level <a href="lang_update.html">UPDATE</a> and <a href="lang_delete.html">DELETE</a>
  128. statements, not <a href="lang_update.html">UPDATE</a> and <a href="lang_delete.html">DELETE</a> statements within triggers.
  129. </p></li>
  130. </ul>
  131. <a name="instead_of_trigger"></a>
  132. <h3>INSTEAD OF trigger</h3>
  133. <p>Triggers may be created on <a href="lang_createview.html">views</a>, as well as ordinary tables, by
  134. specifying INSTEAD OF in the CREATE TRIGGER statement.
  135. If one or more ON INSERT, ON DELETE
  136. or ON UPDATE triggers are defined on a view, then it is not an
  137. error to execute an INSERT, DELETE or UPDATE statement on the view,
  138. respectively. Thereafter,
  139. executing an INSERT, DELETE or UPDATE on the view causes the associated
  140. triggers to fire. The real tables underlying the view are not modified
  141. (except possibly explicitly, by a trigger program).</p>
  142. <h3>Examples</h3>
  143. <p>Assuming that customer records are stored in the "customers" table, and
  144. that order records are stored in the "orders" table, the following trigger
  145. ensures that all associated orders are redirected when a customer changes
  146. his or her address:</p>
  147. <blockquote><pre>
  148. CREATE TRIGGER update_customer_address UPDATE OF address ON customers
  149. BEGIN
  150. UPDATE orders SET address = new.address WHERE customer_name = old.name;
  151. END;
  152. </pre></blockquote>
  153. <p>With this trigger installed, executing the statement:</p>
  154. <blockquote><pre>
  155. UPDATE customers SET address = '1 Main St.' WHERE name = 'Jack Jones';
  156. </pre></blockquote>
  157. <p>causes the following to be automatically executed:</p>
  158. <blockquote><pre>
  159. UPDATE orders SET address = '1 Main St.' WHERE customer_name = 'Jack Jones';
  160. </pre></blockquote>
  161. <a name="undef_before"></a>
  162. <h3>Cautions On The Use Of BEFORE triggers</h3>
  163. <p>If a BEFORE UPDATE or BEFORE DELETE trigger modifies or deletes a row
  164. that was to have been updated or deleted, then the result of the subsequent
  165. update or delete operation is undefined. Furthermore, if a BEFORE trigger
  166. modifies or deletes a row, then it is undefined whether or not AFTER triggers
  167. that would have otherwise run on those rows will in fact run.
  168. </p>
  169. <p>The value of NEW.rowid is undefined in a BEFORE INSERT trigger in which
  170. the rowid is not explicitly set to an integer.</p>
  171. <p>Because of the behaviors described above, programmers are encouraged to
  172. prefer AFTER triggers over BEFORE triggers.</p>
  173. <h3>The RAISE() function</h3>
  174. <p>A special SQL function RAISE() may be used within a trigger-program,
  175. with the following syntax</p>
  176. <h4><a href="syntaxdiagrams.html#raise-function">raise-function:</a></h4><blockquote> <img alt="syntax diagram raise-function" src="images/syntax/raise-function.gif"></img> </blockquote>
  177. <p>When one of the first three forms is called during trigger-program
  178. execution, the specified <a href="lang_conflict.html">ON CONFLICT</a> processing is performed
  179. (either ABORT, FAIL or ROLLBACK) and the current query terminates.
  180. An error code of SQLITE_CONSTRAINT is returned to the application,
  181. along with the specified error message.</p>
  182. <p>When RAISE(IGNORE) is called, the remainder of the current trigger program,
  183. the statement that caused the trigger program to execute and any subsequent
  184. trigger programs that would of been executed are abandoned. No database
  185. changes are rolled back. If the statement that caused the trigger program
  186. to execute is itself part of a trigger program, then that trigger program
  187. resumes execution at the beginning of the next step.
  188. </p>