145 lines
9.8 KiB
HTML
145 lines
9.8 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="concept" />
|
|
<meta name="DC.Title" content="Change data in a table using the UPDATE statement" />
|
|
<meta name="abstract" content="This topic shows the basic SQL statement and clauses that update data into tables and views. To change the data in a table, use the UPDATE statement." />
|
|
<meta name="description" content="This topic shows the basic SQL statement and clauses that update data into tables and views. To change the data in a table, use the UPDATE statement." />
|
|
<meta name="DC.subject" content="data manipulation statement (DML), table, updating data, UPDATE statement, description, statements, UPDATE, example, examples, changing data, with host variables, SET clause, SET CLAUSE, SET clause, clause, SET, column name, column name, constant, NULL value, SET clause, value, UPDATE statement, NULL value, host variable, host variable, special register, special register, expression, scalar subselect, scalar subselect, DEFAULT, changing rows in table, host variables" />
|
|
<meta name="keywords" content="data manipulation statement (DML), table, updating data, UPDATE statement, description, statements, UPDATE, example, examples, changing data, with host variables, SET clause, SET CLAUSE, SET clause, clause, SET, column name, column name, constant, NULL value, SET clause, value, UPDATE statement, NULL value, host variable, host variable, special register, special register, expression, scalar subselect, scalar subselect, DEFAULT, changing rows in table, host variables" />
|
|
<meta name="DC.Relation" scheme="URI" content="rbafydml.htm" />
|
|
<meta name="DC.Relation" scheme="URI" content="rbafyupdatesub.htm" />
|
|
<meta name="DC.Relation" scheme="URI" content="rbafyupdatediftbl.htm" />
|
|
<meta name="DC.Relation" scheme="URI" content="rbafyrfupdating.htm" />
|
|
<meta name="DC.Relation" scheme="URI" content="rbafyupdateidentity.htm" />
|
|
<meta name="DC.Relation" scheme="URI" content="rbafyupdatingasretrieved.htm" />
|
|
<meta name="DC.Relation" scheme="URI" content="../db2/rbafzmstupdt.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="rbafyupdate" />
|
|
<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>Change data in a table using the UPDATE statement</title>
|
|
</head>
|
|
<body id="rbafyupdate"><a name="rbafyupdate"><!-- --></a>
|
|
<!-- Java sync-link --><script language="Javascript" src="../rzahg/synch.js" type="text/javascript"></script>
|
|
<h1 class="topictitle1">Change data in a table using the UPDATE statement</h1>
|
|
<div><p>This topic shows the basic SQL statement and clauses that update
|
|
data into tables and views. To change the data in a table, use the UPDATE
|
|
statement.</p>
|
|
<p>With the UPDATE statement, you can change the value of one or more columns
|
|
in each row that meets the search condition of the WHERE clause. The result
|
|
of the UPDATE statement is one or more changed column values in zero or more
|
|
rows of a table (depending on how many rows meet the search condition specified
|
|
in the WHERE clause). The UPDATE statement looks like this:</p>
|
|
<pre> <strong>UPDATE</strong> table-name
|
|
<strong>SET</strong> column-1 = value-1,
|
|
column-2 = value-2, ...
|
|
<strong>WHERE</strong> search-condition ...</pre>
|
|
<p>For example, suppose an employee was relocated. To update several items
|
|
of the employee's data in the CORPDATA.EMPLOYEE table to reflect the move,
|
|
you can specify:</p>
|
|
<pre> <strong>UPDATE</strong> CORPDATA.EMPLOYEE
|
|
<strong>SET</strong> JOB = :PGM-CODE,
|
|
PHONENO = :PGM-PHONE
|
|
<strong>WHERE</strong> EMPNO = :PGM-SERIAL</pre>
|
|
<p>Use the SET clause to specify a new value for each column you want to update.
|
|
The SET clause names the columns you want updated and provides the values
|
|
you want them changed to. The value you specify can be:</p>
|
|
<ul><li>A <strong>column name.</strong> Replace the column's current value with the contents
|
|
of another column in the same row.</li>
|
|
<li>A <strong>constant.</strong> Replace the column's current value with the value
|
|
provided in the SET clause.</li>
|
|
<li>A <strong>null value.</strong> Replace the column's current value with the null
|
|
value, using the keyword NULL. The column must be defined as capable of containing
|
|
a null value when the table was created, or an error occurs.</li>
|
|
<li>A <strong>host variable.</strong> Replace the column's current value with the contents
|
|
of a host variable.</li>
|
|
<li>A <strong>special register.</strong> Replace the column's current value with a
|
|
special register value; for example, USER.</li>
|
|
<li>An <strong>expression.</strong> Replace the column's current value with the value
|
|
that results from an expression.</li>
|
|
<li>A<strong> scalar fullselect.</strong> Replace the column's current
|
|
value with the value that the subquery returns.</li>
|
|
<li>The <strong>DEFAULT</strong> keyword. Replace the column's current value with the
|
|
default value of the column. The column must have a default value defined
|
|
for it or allow the NULL value, or an error occurs.</li>
|
|
</ul>
|
|
<p>The following is an example of a statement that uses many different values:</p>
|
|
<pre> <strong>UPDATE</strong> WORKTABLE
|
|
<strong>SET</strong> COL1 = 'ASC',
|
|
COL2 = <strong>NULL</strong>,
|
|
COL3 = :FIELD3,
|
|
COL4 = <strong>CURRENT TIME</strong>,
|
|
COL5 = AMT - 6.00,
|
|
COL6 = COL7
|
|
<strong>WHERE</strong> EMPNO = :PGM-SERIAL</pre>
|
|
<p>To identify the rows to be updated, use the WHERE clause: </p>
|
|
<ul><li>To update a single row, use a WHERE clause that selects only one row.</li>
|
|
<li>To update several rows, use a WHERE clause that selects only the rows
|
|
you want to update.</li>
|
|
</ul>
|
|
<p>You can omit the WHERE clause. If you do, SQL updates each row in the table
|
|
or view with the values you supply.</p>
|
|
<p>If the database manager finds an error while running your UPDATE statement,
|
|
it stops updating and returns a negative SQLCODE. If you specify COMMIT(*ALL),
|
|
COMMIT(*CS), COMMIT(*CHG), or COMMIT(*RR), no rows in the table are changed
|
|
(rows already changed by this statement, if any, are restored to their previous
|
|
values). If COMMIT(*NONE) is specified, any rows already changed are <em>not</em> restored
|
|
to previous values.</p>
|
|
<p>If the database manager cannot find any rows that meet the search condition,
|
|
an SQLCODE of +100 is returned. </p>
|
|
<div class="note"><span class="notetitle">Note:</span> The UPDATE statement may have updated more than one row. The number
|
|
of rows updated is reflected in SQLERRD(3) of the SQLCA. This value is also
|
|
available from the ROW_COUNT diagnostics item in the GET DIAGNOSTICS statement.</div>
|
|
<p>The SET clause of an UPDATE statement can be used in many ways to determine
|
|
the actual values to be set in each row being updated. The following example
|
|
lists each column with its corresponding value: </p>
|
|
<pre><strong>UPDATE</strong> EMPLOYEE
|
|
<strong>SET</strong> WORKDEPT = 'D11',
|
|
PHONENO = '7213',
|
|
JOB = 'DESIGNER'
|
|
<strong>WHERE</strong> EMPNO = '000270'</pre>
|
|
<p>The previous update can also be written by specifying all of the columns
|
|
and then all of the values:</p>
|
|
<pre><strong>UPDATE</strong> EMPLOYEE
|
|
<strong>SET</strong> (WORKDEPT, PHONENO, JOB)
|
|
= ('D11', '7213', 'DESIGNER')
|
|
<strong>WHERE</strong> EMPNO = '000270'</pre>
|
|
</div>
|
|
<div>
|
|
<ul class="ullinks">
|
|
<li class="ulchildlink"><strong><a href="rbafyupdatesub.htm">Update a table using a scalar-subselect</a></strong><br />
|
|
Another way to select a value (or multiple values) for an update is to use a scalar-subselect. The scalar-subselect allows you to update one or more columns by setting them to one or more values selected from another table.</li>
|
|
<li class="ulchildlink"><strong><a href="rbafyupdatediftbl.htm">Update a table with rows from another table</a></strong><br />
|
|
It is also possible to update an entire row in one table with values from a row in another table.</li>
|
|
<li class="ulchildlink"><strong><a href="rbafyrfupdating.htm">Update tables with referential constraints</a></strong><br />
|
|
If you are updating a <em>parent</em> table, you cannot modify a
|
|
primary key for which dependent rows exist. </li>
|
|
<li class="ulchildlink"><strong><a href="rbafyupdateidentity.htm">Update an identity column</a></strong><br />
|
|
You can update the value in an identity column to a specified value or have the system generate a new value.</li>
|
|
<li class="ulchildlink"><strong><a href="rbafyupdatingasretrieved.htm">Update data as it is retrieved from a table</a></strong><br />
|
|
You can update rows of data as you retrieve them by using a cursor.</li>
|
|
</ul>
|
|
|
|
<div class="familylinks">
|
|
<div class="parentlink"><strong>Parent topic:</strong> <a href="rbafydml.htm" title="Data manipulation language (DML) describes the portion of SQL that allows you to manipulate or control your data.">Data manipulation language</a></div>
|
|
</div>
|
|
<div class="relinfo"><strong>Related information</strong><br />
|
|
<div><a href="../db2/rbafzmstupdt.htm">UPDATE statement</a></div>
|
|
</div>
|
|
</div>
|
|
</body>
|
|
</html> |