Does updating a row with the same value actually update the row?
Due to the MVCC model of Postgres, and according to the rules of SQL, an UPDATE
writes a new row version for every row that is not excluded in the WHERE
clause.
This does have a more or less substantial impact on performance, directly and indirectly. "Empty updates" have the same cost per row as any other update. They fire triggers (if present) like any other update, they have to be WAL-logged and they produce dead rows bloating the table and causing more work for VACUUM
later like any other update.
Indexes entries and TOASTed columns where none of the involved columns are changed can stay the same, but that is true for any updated row. Related:
- PostgreSQL Initial Database Size
- Redundant data in update statements
It's almost always a good idea to exclude such empty updates (when there is an actual chance it may happen). You did not provide a table definition in your question (which is always a good idea). We have to assume first_name
can be NULL (which wouldn't be surprising for a "first name"), hence the query has to use NULL-safe comparison:
UPDATE users
SET first_name = 'Michael'
WHERE id = 123
AND first_name IS DISTINCT FROM 'Michael';
If first_name IS NULL
before the update, a test with just first_name <> 'Michael'
would evaluate to NULL and as such exclude the row from the update. Sneaky error. If the column is defined NOT NULL
, use the simple equality check, though, because that's a bit cheaper.
Related:
- How do I (or can I) SELECT DISTINCT on multiple columns?
- Update column with data from another table
ORM's like Ruby on Rail's offer deferred execution which mark a record as changed (or not) and then when needed or called, then submit the change to the database.
PostgreSQL is a database and not an ORM. It would have decreased performance if it took the time to check if a new value was the same as the updated value in your query.
It will therefore update the value regardless of whether it is the same as the new value or not.
If you wish to prevent this, you could use code like Max Vernon suggested in his answer.
You could simply add to the where
clause:
UPDATE users
SET first_name = 'Michael'
WHERE users.id = 123
AND (first_name <> 'Michael' OR first_name IS NULL);
If first_name
is defined as NOT NULL
, the OR first_name IS NULL
part can be removed.
The condition:
(first_name <> 'Michael' OR first_name IS NULL)
can also be written more elegantly as (in Erwin's answer):
first_name IS DISTINCT FROM 'Michael'