Skip to main content

UPDATE

Updates rows of a table.


Syntax

UPDATE [ ONLY ] <table_name> [ [ AS ] <alias> ]
SET { <column_name> = { <expression> | DEFAULT } |
( <column_name> [, ...] ) = [ ROW ] ( { <expression> | DEFAULT } [, ...] ) |
( <column_name> [, ...] ) = ( <sub-SELECT> )
} [, ...]
[ FROM <from_item> [, ...] ]
[ WHERE <condition> ]

Description

UPDATE changes the values of the specified columns in all rows that satisfy the condition. Only the columns to be modified need be mentioned in the SET clause. Columns not explicitly modified retain their previous values.

Important

Extreme DPS has some limitations on the use of the SET clause. For detailed restrictions of Extreme DPS on UPDATE ... SET, see Usage notes.

There are two ways to modify a table using information contained in other tables in the database: using sub-selects, or specifying additional tables in the FROM clause. Which technique is more appropriate depends on the specific circumstances.

You must have the UPDATE privilege on the table, or at least on the columns that are listed to be updated. You must also have the SELECT privilege on any column whose values are read in the expressions or condition.

note

As the default, Relyt acquires an EXCLUSIVE lock on tables for UPDATE operations on heap tables. When the Global Deadlock Detector is enabled, the lock mode for UPDATE operations on heap tables is ROW EXCLUSIVE.


Parameters

  • <table_name>

    The name (optionally schema-qualified) of the table to update. If ONLY is specified before the table name, matching rows are updated in the named table only. If ONLY is not specified, matching rows are also updated in any tables inheriting from the named table. Optionally, you can specify * after the table name to explicitly indicate that descendant tables are included.

  • <alias>

    A substitute name for the target table. When an alias is provided, it completely hides the actual name of the table. For example, given UPDATE foo AS f, the remainder of the UPDATE statement must refer to this table as f not foo.

  • <column_name>

    The name of a column in the table named by table_name. The column name can be qualified with a subfield name or array subscript, if needed. Do not include the table’s name in the specification of a target column; for example, UPDATE table_name SET table_name.col = 1 is invalid.

  • <expression>

    An expression to assign to the column. The expression may use the old values of this and other columns in the table.

  • DEFAULT

    Set the column to its default value (which will be NULL if no specific default expression has been assigned to it).

  • sub-SELECT

    A SELECT sub-query that produces as many output columns as are listed in the parenthesized column list preceding it. The sub-query must yield no more than one row when executed. If it yields one row, its column values are assigned to the target columns. If it yields no rows, NULL values are assigned to the target columns. The sub-query can refer to old values of the current row of the table being updated.

  • <from_item>

    A table expression allowing columns from other tables to appear in the WHERE condition and the update expressions. This uses the same syntax as the FROM clause of a SELECT statement. For example, you can specify an alias for the table name. Do not repeat the target table as a from_item unless you intend a self-join (in which case it must appear with an alias in the from_item).

  • <condition>

    An expression that returns a value of type boolean. Only rows for which this expression returns true will be updated.


Outputs

On successful completion, an UPDATE command returns a command tag of the form:

UPDATE <count>

The count is the number of rows updated, including matched rows whose values did not change. If count is 0, no rows were updated by the query (this is not considered an error).


Usage notes

The following operations are supported only by Hybrid DPS. If you want to perform any command that involves the following operation, set the DPS cluster to an Extreme DPS cluster:

  • SET DEFAULT

  • The SET clause is used to update multiple columns where parentheses (( )) are included, for example, UPDATE t1 SET (a1, a2) = (1, 2);

  • When UPDATE is used to on a table with an alias, for example:

    CREATE TABLE t1 (a1 bigint);

    UPDATE t1 d1 SET a1 = 1;

When a FROM clause is present, the target table is joined to the tables mentioned in the from_item list, and each output row of the join represents an update operation for the target table. When using FROM, ensure that the join produces at most one output row for each row to be modified. In other words, a target row should not join to more than one row from the other tables. If it does, then only one of the join rows will be used to update the target row, but which one will be used is not readily predictable.

Because of this indeterminacy, referencing other tables only within sub-selects is safer, though often harder to read and slower than using a join.


Examples

Change the word Drama to Dramatic in the column kind of the table films:

UPDATE films SET kind = 'Dramatic' WHERE kind = 'Drama';

Adjust temperature entries and reset precipitation to its default value in one row of the table weather:

UPDATE weather SET temp_lo = temp_lo+1, temp_hi = 
temp_lo+15, prcp = DEFAULT
WHERE city = 'San Francisco' AND date = '2016-07-03';

Perform the same operation and return the updated entries:

UPDATE weather SET temp_lo = temp_lo+1, temp_hi = temp_lo+15, prcp = DEFAULT
WHERE city = 'San Francisco' AND date = '2003-07-03'
RETURNING temp_lo, temp_hi, prcp;

Use the alternative column-list syntax to do the same update:

UPDATE weather SET (temp_lo, temp_hi, prcp) = (temp_lo+1, 
temp_lo+15, DEFAULT)
WHERE city = 'San Francisco' AND date = '2016-07-03';

Increment the sales count of the salesperson who manages the account for Acme Corporation, using the FROM clause syntax (assuming both tables being joined are distributed in Relyt on the id column):

UPDATE employees SET sales_count = sales_count + 1 FROM 
accounts
WHERE accounts.name = 'Acme Corporation'
AND employees.id = accounts.id;

Perform the same operation, using a sub-select in the WHERE clause:

UPDATE employees SET sales_count = sales_count + 1 WHERE id =
(SELECT id FROM accounts WHERE name = 'Acme Corporation');

Update contact names in an accounts table to match the currently assigned salesmen:

UPDATE accounts SET (contact_first_name, contact_last_name) =
(SELECT first_name, last_name FROM salesmen
WHERE salesmen.id = accounts.sales_id);

A similar result could be accomplished with a join:

UPDATE accounts SET contact_first_name = first_name,
contact_last_name = last_name
FROM salesmen WHERE salesmen.id = accounts.sales_id;

However, the second query may give unexpected results if salesmen.id is not a unique key, whereas the first query is guaranteed to raise an error if there are multiple id matches. Also, if there is no match for a particular accounts.sales_id entry, the first query will set the corresponding name fields to NULL, whereas the second query will not update that row at all.

Update statistics in a summary table to match the current data:

UPDATE summary s SET (sum_x, sum_y, avg_x, avg_y) =
(SELECT sum(x), sum(y), avg(x), avg(y) FROM data d
WHERE d.group_id = s.group_id);

Attempt to insert a new stock item along with the quantity of stock. If the item already exists, instead update the stock count of the existing item. To do this without failing the entire transaction, use savepoints.

BEGIN;
-- other operations
SAVEPOINT sp1;
INSERT INTO wines VALUES('Chateau Lafite 2003', '24');
-- Assume the above fails because of a unique key violation,
-- so now we issue these commands:
ROLLBACK TO sp1;
UPDATE wines SET stock = stock + 24 WHERE winename = 'Chateau
Lafite 2003';
-- continue with other operations, and eventually
COMMIT;

SQL standard compatibility

This command conforms to the SQL standard, except that the FROM clause is a Relyt extension.

Some other database systems offer a FROM option in which the target table is supposed to be listed again within FROM. That is not how Relyt interprets FROM. Be careful when porting applications that use this extension.

According to the standard, the source value for a parenthesized sub-list of target column names can be any row-valued expression yielding the correct number of columns. Relyt only allows the source value to be a row constructor or a sub-SELECT. You can specify an individual column’s updated value as DEFAULT in the row-constructor case, but not inside a sub-SELECT.