mirror of
https://github.com/postgres/postgres.git
synced 2025-04-22 23:02:54 +03:00
MVCC updates.
This commit is contained in:
parent
c0b4b42c92
commit
0e41fd57df
167
src/man/lock.l
167
src/man/lock.l
@ -1,47 +1,156 @@
|
|||||||
.\" This is -*-nroff-*-
|
.\" This is -*-nroff-*-
|
||||||
.\" XXX standard disclaimer belongs here....
|
.\" XXX standard disclaimer belongs here....
|
||||||
.\" $Header: /cvsroot/pgsql/src/man/Attic/lock.l,v 1.8 1999/06/04 04:28:54 momjian Exp $
|
.\" $Header: /cvsroot/pgsql/src/man/Attic/lock.l,v 1.9 1999/06/09 03:51:40 vadim Exp $
|
||||||
.TH FETCH SQL 01/23/93 PostgreSQL PostgreSQL
|
.TH LOCK SQL 01/23/93 PostgreSQL PostgreSQL
|
||||||
.SH NAME
|
.SH NAME
|
||||||
lock - exclusive lock a table
|
lock - Explicit lock of a table inside a transaction
|
||||||
.SH SYNOPSIS
|
.SH SYNOPSIS
|
||||||
.nf
|
.nf
|
||||||
\fBlock\fR [\fBtable\fR] classname
|
\fBlock\fR [\fBtable\fR] classname
|
||||||
[\fBin\fR [\fBrow\fR|\fBaccess\fR] [\fBshare\fR|\fBexclusive\fR] |
|
\fBlock\fR [\fBtable\fR] classname \fBin\fR [\fBrow\fR|\fBaccess\fR] {\fBshare\fR|\fBexclusive\fR} \fBmode\fR
|
||||||
[\fBshare row exclusive\fR] \fBmode\fR]
|
\fBlock\fR [\fBtable\fR] classname \fBin\fR \fBshare row exclusive\fR \fBmode\fR
|
||||||
.fi
|
.fi
|
||||||
.SH DESCRIPTION
|
.SH DESCRIPTION
|
||||||
By default,
|
Available lock modes from least restrictive to most restrictive:
|
||||||
.BR lock
|
|
||||||
exclusive locks an entire table inside a transaction.
|
|
||||||
Various options allow shared access, or row-level locking control.
|
|
||||||
.PP
|
.PP
|
||||||
The classic use for this
|
\fBACCESS SHARE MODE\fR
|
||||||
is the case where you want to \fBselect\fP some data, then update it
|
|
||||||
inside a transaction. If you don't exclusive lock the table before the
|
\fBNote\fR: this lock mode is acquired automatically over tables being
|
||||||
\fBselect\fP, some other user may also read the selected data, and try
|
\queried. \fBPostgres\fR releases automatically acquired
|
||||||
and do their own \fBupdate\fP, causing a deadlock while you both wait
|
ACCESS SHARE locks after statement is done.
|
||||||
for the other to release the \fBselect\fP-induced shared lock so you can
|
|
||||||
get an exclusive lock to do the \fBupdate.\fP
|
This is the least restrictive lock mode which conflicts with ACCESS EXCLUSIVE
|
||||||
|
mode only. It's intended to protect table being queried from concurrent
|
||||||
|
\fBALTER TABLE\fR, \fBDROP TABLE\fR and
|
||||||
|
\fBVACUUM\fR statements over the same table.
|
||||||
|
|
||||||
|
\fBROW SHARE MODE\fR
|
||||||
|
|
||||||
|
\fBNote\fR: Automatically acquired by SELECT FOR UPDATE statement.
|
||||||
|
|
||||||
|
Conflicts with EXCLUSIVE and ACCESS EXCLUSIVE lock modes.
|
||||||
|
|
||||||
|
\fBROW EXCLUSIVE MODE\fR
|
||||||
|
|
||||||
|
\fBNote\fR: Automatically acquired by UPDATE, DELETE, INSERT statements.
|
||||||
|
|
||||||
|
Conflicts with SHARE, SHARE ROW EXCLUSIVE, EXCLUSIVE and ACCESS EXCLUSIVE
|
||||||
|
modes. Generally means that a transaction updated/inserted some tuples in a
|
||||||
|
table.
|
||||||
|
|
||||||
|
\fBSHARE MODE\fR
|
||||||
|
|
||||||
|
\fBNote\fR: Automatically acquired by CREATE INDEX statement.
|
||||||
|
|
||||||
|
Conflicts with ROW EXCLUSIVE, SHARE ROW EXCLUSIVE, EXCLUSIVE and ACCESS
|
||||||
|
EXCLUSIVE modes. This mode protects a table against concurrent updates.
|
||||||
|
|
||||||
|
\fBSHARE ROW EXCLUSIVE MODE\fR
|
||||||
|
|
||||||
|
Conflicts with ROW EXCLUSIVE, SHARE, SHARE ROW EXCLUSIVE, EXCLUSIVE and
|
||||||
|
ACCESS EXCLUSIVE modes. This mode is more restrictive than SHARE mode
|
||||||
|
because of only one transaction at time can hold this lock.
|
||||||
|
|
||||||
|
\fBEXCLUSIVE MODE\fR
|
||||||
|
|
||||||
|
Conflicts with ROW SHARE, ROW EXCLUSIVE, SHARE, SHARE ROW EXCLUSIVE,
|
||||||
|
EXCLUSIVE and ACCESS EXCLUSIVE modes. This mode is yet more restrictive than
|
||||||
|
SHARE ROW EXCLUSIVE one - it blocks concurrent SELECT FOR UPDATE queries.
|
||||||
|
|
||||||
|
\fBACCESS EXCLUSIVE MODE\fR
|
||||||
|
|
||||||
|
\fBNote\fR: Automatically acquired by ALTER TABLE, DROP TABLE, VACUUM
|
||||||
|
statements.
|
||||||
|
|
||||||
|
This is the most restrictive lock mode which conflicts with all other
|
||||||
|
lock modes and protects locked table from any concurrent operations.
|
||||||
|
|
||||||
|
\fBNote\fR: This lock mode is also acquired by first form of LOCK TABLE
|
||||||
|
(i.e. without explicit lock mode option).
|
||||||
|
|
||||||
|
.SH USAGE
|
||||||
|
.BR Postgres
|
||||||
|
always uses less restrictive lock modes ever possible. LOCK TABLE statement
|
||||||
|
provided for cases when you might need in more restrictive locking.
|
||||||
.PP
|
.PP
|
||||||
Another example of deadlock is where one user locks one table, and
|
For example, application run transaction at READ COMMITTED isolation level
|
||||||
another user locks a second table. While both keep their existing
|
and need to ensure existance data in a table for duration of transaction. To
|
||||||
locks, the first user tries to lock the second user's table, and the
|
achieve this you could use SHARE lock mode over table before querying. This
|
||||||
second user tries to lock the first user's table. Both users deadlock
|
will protect data from concurrent changes and provide your further read
|
||||||
waiting for the tables to become available. The only solution to this
|
operations over table with data in their real current state, because of
|
||||||
is for both users to lock tables in the same order, so user's lock
|
SHARE lock mode conflicts with ROW EXCLUSIVE one, acquired by writers, and
|
||||||
aquisitions and requests to not form a deadlock.
|
your LOCK TABLE table IN SHARE MODE statement will wait untill concurrent
|
||||||
|
write operations (if any) commit/rollback. (Note that to read data in their
|
||||||
|
real current state running transaction at SERIALIZABLE isolation level you
|
||||||
|
have to execute LOCK TABLE statement before execution any DML statement,
|
||||||
|
when transaction defines what concurrent changes will be visible to
|
||||||
|
herself).
|
||||||
|
|
||||||
|
If, in addition to requirements above, transaction is going to change data
|
||||||
|
in a table then SHARE ROW EXCLUSIVE lock mode should be acquired to prevent
|
||||||
|
deadlock conditions when two concurrent transactions would lock table in
|
||||||
|
SHARE mode and than would try to change data in this table, both
|
||||||
|
(implicitly) acquiring ROW EXCLUSIVE lock mode that conflicts with
|
||||||
|
concurrent SHARE lock.
|
||||||
|
|
||||||
|
Following deadlock issue (when two transaction wait one another)
|
||||||
|
touched above, you should follow two general rules to prevent
|
||||||
|
deadlock conditions:
|
||||||
|
|
||||||
|
\fB1. Transactions have to acquire locks on the same objects in the same order.\fR
|
||||||
|
|
||||||
|
For example, if one application updates row R1 and than updates row R2 (in
|
||||||
|
the same transaction) then second application shouldn't update row R2 if
|
||||||
|
it's going update row R1 later (in single transaction). Instead, it should
|
||||||
|
update R1 and R2 rows in the same order as first application.
|
||||||
|
|
||||||
|
\fB2. Transactions should acquire two conflicting lock modes only if one of
|
||||||
|
them is self-conflicting (i.e. may be held by one transaction at time only)
|
||||||
|
and should acquire most restrictive mode first.\fR
|
||||||
|
|
||||||
|
Example for this rule is described above when told about using
|
||||||
|
SHARE ROW EXCLUSIVE mode instead of SHARE one.
|
||||||
|
|
||||||
|
\fBNote\fR: \fBPostgres\fR does detect deadlocks and will rollback one of
|
||||||
|
waiting transactions to resolve the deadlock.
|
||||||
|
|
||||||
|
.SH COMPATIBILITY
|
||||||
|
LOCK TABLE statement is a \fBPostgres\fR language extension.
|
||||||
|
|
||||||
|
Except for ACCESS SHARE/EXCLUSIVE lock modes, all other \fBPostgres\fR lock
|
||||||
|
modes and LOCK TABLE statement syntax are compatible with \fBOracle\fR
|
||||||
|
ones.
|
||||||
|
|
||||||
.SH EXAMPLES
|
.SH EXAMPLES
|
||||||
.nf
|
.nf
|
||||||
--
|
--
|
||||||
-- Proper locking to prevent deadlock
|
-- SHARE lock primary key table when going to perform
|
||||||
|
-- insert into foreign key table.
|
||||||
--
|
--
|
||||||
begin work;
|
BEGIN WORK;
|
||||||
lock table mytable;
|
LOCK TABLE films IN SHARE MODE;
|
||||||
select * from mytable;
|
SELECT id FROM films
|
||||||
update mytable set (x = 100);
|
WHERE name = 'Star Wars: Episode I - The Phantom Menace';
|
||||||
commit;
|
--
|
||||||
|
-- Do ROLLBACK if record was not returned
|
||||||
|
--
|
||||||
|
INSERT INTO films_user_comments VALUES
|
||||||
|
(_id_, 'GREAT! I was waiting it so long!');
|
||||||
|
COMMIT WORK;
|
||||||
|
|
||||||
|
--
|
||||||
|
-- SHARE ROW EXCLUSIVE lock primary key table when going to perform
|
||||||
|
-- delete operation.
|
||||||
|
--
|
||||||
|
BEGIN WORK;
|
||||||
|
LOCK TABLE films IN SHARE ROW EXCLUSIVE MODE;
|
||||||
|
DELETE FROM films_user_comments WHERE id IN
|
||||||
|
(SELECT id FROM films WHERE rating < 5);
|
||||||
|
DELETE FROM films WHERE rating < 5;
|
||||||
|
COMMIT WORK;
|
||||||
|
|
||||||
.SH "SEE ALSO"
|
.SH "SEE ALSO"
|
||||||
begin(l),
|
begin(l),
|
||||||
commit(l),
|
commit(l),
|
||||||
|
set(l),
|
||||||
select(l).
|
select(l).
|
||||||
|
@ -1,6 +1,6 @@
|
|||||||
.\" This is -*-nroff-*-
|
.\" This is -*-nroff-*-
|
||||||
.\" XXX standard disclaimer belongs here....
|
.\" XXX standard disclaimer belongs here....
|
||||||
.\" $Header: /cvsroot/pgsql/src/man/Attic/set.l,v 1.21 1999/06/04 03:44:42 momjian Exp $
|
.\" $Header: /cvsroot/pgsql/src/man/Attic/set.l,v 1.22 1999/06/09 03:51:40 vadim Exp $
|
||||||
.TH SET SQL 05/14/97 PostgreSQL PostgreSQL
|
.TH SET SQL 05/14/97 PostgreSQL PostgreSQL
|
||||||
.SH NAME
|
.SH NAME
|
||||||
set - set run-time parameters for session
|
set - set run-time parameters for session
|
||||||
@ -81,19 +81,14 @@ The default is unlimited.
|
|||||||
.IR TIMEZONE
|
.IR TIMEZONE
|
||||||
sets your timezone.
|
sets your timezone.
|
||||||
.PP
|
.PP
|
||||||
.I TRANSACTION ISOLATION LEVEL
|
\fITRANSACTION ISOLATION LEVEL\fR sets the current transaction's isolation
|
||||||
sets the current transaction's isolation level to
|
level to \fI SERIALIZABLE\fR or \fIREAD COMMITTED\fR. \fISERIALIZABLE\fR
|
||||||
.IR SERIALIZABLE
|
means that the current transaction queries will read only rows committed
|
||||||
or
|
before first DML statement (SELECT/INSERT/DELETE/UPDATE/FETCH/COPY_TO) was
|
||||||
.IR READ COMMITTED .
|
executed in this transaction. \fIREAD COMMITTED\fR means that the current
|
||||||
.IR SERIALIZABLE
|
transaction queries will read only rows committed before a query began.
|
||||||
means that the current transaction will place a lock on every row read,
|
\fIREAD COMMITTED\fR is the default. \fBNote\fR: SQL92 standard requires
|
||||||
so later reads in that transaction see the rows unmodified by
|
\fISERIALIZABLE\fR to be the default isolation level.
|
||||||
other transactions.
|
|
||||||
.IR READ COMMITTED
|
|
||||||
means that the current transaction reads only committed rows.
|
|
||||||
.IR READ COMMITTED
|
|
||||||
is the default.
|
|
||||||
.PP
|
.PP
|
||||||
.IR CLIENT_ENCODING|NAMES
|
.IR CLIENT_ENCODING|NAMES
|
||||||
sets the character set encoding of the client. Only available if multi-byte
|
sets the character set encoding of the client. Only available if multi-byte
|
||||||
|
Loading…
x
Reference in New Issue
Block a user