Use this statement to modify existing rows in database tables.
UPDATE [ row-limitation ] table-list ] SET set-item, ... [ FROM table-expression [,...] ] [ WHERE search-condition ] [ ORDER BY expression [ ASC | DESC ] , ... ] [ OPTION( query-hint, ... ) ]
table-list : table-name [,...]
table-name : [ owner.]table-name [ [ AS ] correlation-name ] | [ owner.]view-name [ [ AS ] correlation-name ] | derived-table
derived-table : ( select-statement ) [ AS ] correlation-name [ ( column-name [,... ] ) ]
table-expression : A full table expression that can include joins. See FROM clause.
UPDATE table-name SET set-item, ... VERIFY ( column-name, ... ) VALUES ( expression, ... ) [ WHERE search-condition ] [ ORDER BY expression [ ASC | DESC ], ... ] [ OPTION( query-hint, ... ) ]
UPDATE [ owner.]table-name PUBLICATION publication { SUBSCRIBE BY expression | OLD SUBSCRIBE BY expression NEW SUBSCRIBE BY expression } WHERE search-condition
row-limitation : FIRST | TOP n [ START AT m ]
set-item : [ correlation-name.]column-name = { expression | DEFAULT } | [owner-name.]table-name.column-name = { expression | DEFAULT } | @variable-name = expression
query-hint : MATERIALIZED VIEW OPTIMIZATION option-value | FORCE OPTIMIZATION | FORCE NO OPTIMIZATION | option-name = option-value
table-name : [ owner.]base-table-name | temporary-table-name | derived-table-name | [ owner.]view-name
option-name : identifier
option-value : hostvar (indicator allowed), string, identifier, or number
UPDATE clause For Syntax 1, table-list can include temporary tables, derived tables, or views. Views and derived tables can be updated unless they are non-updatable. For Syntax 2 and 3, table-name must be a base table.
UPDATES can be performed on views only if the query specification defining the view is updatable. For more information about identifying views that are inherently non-updatable, see Working with views.
row-limitation clause The row limiting clause allows you to return only a subset of the rows that satisfy the WHERE clause. The TOP and START AT values can be a host variable, integer constant, or integer variable. The TOP value must be greater than or equal to 0. The START AT value must be greater than 0. Normally, when specifying these clauses, an ORDER BY clause is specified as well to order the rows in a meaningful manner. See Explicitly limiting the number of rows returned by a query.
SET clause The set clause specifies the columns and how the values are changed.
You can use the SET clause to set the column to a computed column value using this format:
SET column-name = expression, ... |
Each named column is set to the value of the expression on the right-hand side of the equal sign. There are no restrictions on the expression. If the expression is a column-name, the old value is used.
If a column has a default defined, you can use the SET clause to set a column to its default value. See the Examples section for an example of this.
You can also use the SET clause to assign a variable using this format:
SET @variable-name = expression, ... |
When assigning a variable, the variable must already be declared, and its name must begin with the "at" sign (@). Variable and column assignments can be mixed together, and any number can be used. If a name on the left side of an assignment in the SET list matches a column in the updated table and the variable name, the statement updates the column.
Following is an example of part of an UPDATE statement. It assigns a variable in addition to updating the table:
UPDATE T SET @var = expression1, col1 = expression2 WHERE... |
This is equivalent to:
SELECT @var = expression1 FROM T WHERE... ; UPDATE T SET col1 = expression2 WHERE... |
FROM clause If the FROM clause is present, the WHERE clause qualifies the rows of the FROM clause.
The FROM table-expression clause allows tables to be updated based on joins. table-expression can contain arbitrary complex table expressions, such as KEY and NATURAL joins. For a full description of the FROM clause and joins, see FROM clause.
If a FROM clause is used, it is important to qualify the table name the same way in both parts of the statement. If a correlation name is used in one place, the same correlation name must be used elsewhere. Otherwise, an error is generated.
The following statement illustrates a potential ambiguity in table names in UPDATE statements with two FROM clauses that use correlation names:UPDATE FROM table_1 FROM table_1 AS alias_1, table_2 AS alias_2 WHERE ... |
table table_1 doesn't have a correlation name in the first FROM clause but does in the second FROM clause. In this case, table_1 in the first clause is identified with alias_1 in the second clause—there is only one instance of table_1 in this statement. This is allowed as an exception to the general rule that where a table is identified with a correlation name and without a correlation name in the same statement, two instances of the table are considered.
However, in the following example, there are two instances of table_1 in the second FROM clause. The statement fails with a syntax error because it is not clear which instance of the table_1 from the second FROM clause matches the first instance of table_1 in the first FROM clause.
UPDATE FROM table_1 FROM table_1 AS alias_1, table_1 AS alias_2 WHERE ... |
This clause is allowed only if ansi_update_constraints is set to Off. See ansi_update_constraints option [compatibility].
For a full description of joins, see Joins: Retrieving data from several tables.
For more information, see FROM clause.
WHERE clause If a WHERE clause is specified, only rows satisfying the search condition are updated. If no WHERE clause is specified, every row is updated.
ORDER BY clause Normally, the order in which rows are updated does not matter. However, in conjunction with the FIRST or TOP clause the order can be significant.
You cannot use ordinal column numbers in the ORDER BY clause.
You must not update columns that appear in the ORDER BY clause unless you set the ansi_update_constraints option to Off. See ansi_update_constraints option [compatibility].
OPTION clause Use this clause to specify hints for executing the statement. The following hints are supported:
Character strings inserted into tables are always stored in the same case as they are entered, regardless of whether the database is case sensitive or not. A CHAR data type column updated with the string Street is always held in the database with an uppercase S and the remainder of the letters lowercase. SELECT statements return the string as Street. If the database is not case sensitive, however, all comparisons make Street the same as street, STREET, and so on. Further, if a single-column primary key already contains an entry Street, an INSERT of street is rejected, as it would make the primary key not unique.
If the new value does not differ from the old value, no change is made to the data. However, BEFORE UPDATE triggers fire any time an UPDATE occurs on a row, whether the new value differs from the old value. AFTER UPDATE triggers fire only if the new value is different from the old value.
Syntax 1 of the UPDATE statement modifies values in rows of one or more tables. Syntax 2 and 3 are applicable only to SQL Remote.
Syntax 2 is intended for use with SQL Remote only, in single-row updates of a single table executed by the Message Agent. The VERIFY clause contains a set of values that are expected to be present in the row being updated. If the values do not match, any RESOLVE UPDATE triggers are fired before the UPDATE proceeds. The UPDATE does not fail simply because the VERIFY clause fails to match.
Syntax 3 of the UPDATE statement is used to implement a specific SQL Remote feature, and is to be used inside a BEFORE trigger. It provides a full list of SUBSCRIBE BY values any time the list changes. It is placed in SQL Remote triggers so that the database server can compute the current list of SUBSCRIBE BY values. Both lists are placed in the transaction log.
The Message Agent uses the two lists to make sure that the row moves to any remote database that did not have the row and now needs it. The Message Agent also removes the row from any remote database that has the row and no longer needs it. A remote database that has the row and still needs it is not affected by the UPDATE statement.
For publications created using a subquery in a SUBSCRIBE BY clause, you must write a trigger containing syntax 3 of the UPDATE statement to ensure that the rows are kept in their proper subscriptions.
Syntax 3 of the UPDATE statement allows the old SUBSCRIBE BY list and the new SUBSCRIBE BY list to be explicitly specified, which can make SQL Remote triggers more efficient. In the absence of these lists, the database server computes the old SUBSCRIBE BY list from the publication definition. Since the new SUBSCRIBE BY list is commonly only slightly different from the old SUBSCRIBE BY list, the work to compute the old list may be done twice. By specifying both the old and new lists, you can avoid this extra work.
The SUBSCRIBE BY expression is either a value or a subquery.
Syntax 3 of the UPDATE statement makes an entry in the transaction log, but does not change the database table.
Updating a significant amount of data using the UPDATE statement also updates column statistics.
Must have UPDATE permission for the columns being modified.
Column statistics are updated.
SQL/2003 Syntax 1 is a core feature, except for the FROM and ORDER BY clauses, which are vendor extensions. Syntax 2 and 3 are vendor extensions for use only with SQL Remote.
To enforce SQL/2003 compatibility, ensure that the ansi_update_constraints option is set to Strict. See ansi_update_constraints option [compatibility].
Using the sample database, this example transfers employee Philip Chin (employee 129) from the sales department to the marketing department.
UPDATE Employees SET DepartmentID = 400 WHERE EmployeeID = 129; |
Using the sample database, this example renumbers all existing sales orders by subtracting 2000 from the ID.
UPDATE SalesOrders AS orders SET orders.ID = orders.ID - 2000 ORDER BY orders.ID ASC; |
This update is possible only if the foreign key of the SalesOrderItems table (referencing the primary key SalesOrders.ID) is defined with the action ON UPDATE CASCADE. The SalesOrderItems table is then updated as well.
For more information about foreign key properties, see ALTER TABLE statement and CREATE TABLE statement.
Using the sample database, this example changes the price of a product at isolation level 2, rather than using the current isolation level setting of the database.
UPDATE Products SET UnitPrice = 7.00 WHERE ID = 501 OPTION( isolation_level = 2 ); |
The following example shows how to update a table to set a column to its default value. In this example, you create a table, MyTable, populate it with data, and then execute an UPDATE statement specifying the SET clause to change the column values to their defaults.
CREATE TABLE MyTable( PK INT PRIMARY KEY DEFAULT AUTOINCREMENT, TableName CHAR(128) NOT NULL, TableNameLen INT DEFAULT 20, LastUser CHAR(10) DEFAULT last user, LastTime TIMESTAMP DEFAULT TIMESTAMP, LastTimestamp TIMESTAMP DEFAULT @@dbts ); INSERT INTO MyTable WITH AUTO NAME SELECT LENGTH(t.table_name) AS TableNameLen, t.table_name AS TableName FROM SYS.SYSTAB t WHERE table_id<=10; UPDATE MyTable SET LastTime = DEFAULT, LastTimestamp = DEFAULT WHERE TableName LIKE '%sys%'; |
Discuss this page in DocCommentXchange. Send feedback about this page using email. |
Copyright © 2009, iAnywhere Solutions, Inc. - SQL Anywhere 11.0.1 |