aboutsummaryrefslogtreecommitdiff
path: root/doc/src/sgml/mvcc.sgml
blob: 2ce81ace1ac2b711d7e6192a39a91fab286f560b (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
 <chapter id="mvcc">
  <title>Multi-Version Concurrency Control</title>

  <abstract>
   <para>
    Multi-Version Concurrency Control
    (MVCC)
    is an advanced technique for improving database performance in a
    multi-user environment. 
    <ulink url="mailto:vadim@krs.ru">Vadim Mikheev</ulink> provided
    the implementation for <productname>Postgres</productname>.
   </para>
  </abstract>

  <sect1>
   <title>Introduction</title>

   <para>
    Unlike most other database systems which use locks for concurrency control,
    <productname>Postgres</productname>
    maintains data consistency by using a multiversion model. 
    This means that while querying a database each transaction sees
    a snapshot of data (a <firstterm>database version</firstterm>)
    as it was some
    time ago, regardless of the current state of the underlying data.
    This protects the transaction from viewing inconsistent data that
    could be caused by (other) concurrent transaction updates on the same
    data rows, providing <firstterm>transaction isolation</firstterm>
    for each database session.
   </para>

   <para>
    The main difference between multiversion and lock models is that
    in MVCC locks acquired for querying (reading) data don't conflict
    with locks acquired for writing data and so reading never blocks
    writing and writing never blocks reading.
   </para>
  </sect1>

  <sect1>
   <title>Transaction Isolation</title>

   <para>
    The <acronym>ANSI</acronym>/<acronym>ISO</acronym> <acronym>SQL</acronym>
    standard defines four levels of transaction
    isolation in terms of three phenomena that must be prevented 
    between concurrent transactions.
    These undesirable phenomena are:

    <variablelist>
     <varlistentry>
      <term>
       dirty reads
      </term>
     <listitem>
      <para>
	A transaction reads data written by concurrent uncommitted transaction.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>
       non-repeatable reads
      </term>
     <listitem>
      <para>
	A transaction re-reads data it has previously read and finds that data
	has been modified by another committed transaction.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>
       phantom read
      </term>
     <listitem>
      <para>
	A transaction re-executes a query returning a set of rows that satisfy a
	search condition and finds that additional rows satisfying the condition
	has been inserted by another committed transaction.
       </para>
      </listitem>
     </varlistentry>
    </variablelist>
   </para>

   <para>
    The four isolation levels and the corresponding behaviors are described below.

    <table tocentry="1">
     <title><productname>Postgres</productname> Isolation Levels</title>
     <titleabbrev>Isolation Levels</titleabbrev>
     <tgroup cols="4">
      <thead>
       <row>
	<entry>
	 Dirty Read
	</entry>
	<entry>
	 Non-Repeatable Read
	</entry>
	<entry>
	 Phantom Read
	</entry>
       </row>
      </thead>
      <tbody>
       <row>
	<entry>
	 Read uncommitted
	</entry>
	<entry>
	 Possible
	</entry>
	<entry>
	 Possible
	</entry>
	<entry>
	 Possible
	</entry>
       </row>

       <row>
	<entry>
	 Read committed
	</entry>
	<entry>
	 Not possible
	</entry>
	<entry>
	 Possible
	</entry>
	<entry>
	 Possible
	</entry>
       </row>

       <row>
	<entry>
	 Repeatable read
	</entry>
	<entry>
	 Not possible
	</entry>
	<entry>
	 Not possible
	</entry>
	<entry>
	 Possible
	</entry>
       </row>

       <row>
	<entry>
	 Serializable
	</entry>
	<entry>
	 Not possible
	</entry>
	<entry>
	 Not possible
	</entry>
	<entry>
	 Not possible
	</entry>
       </row>
      </tbody>
     </tgroup>
    </table>

    <productname>Postgres</productname>
    offers the read committed and serializable isolation levels.
   </para>
  </sect1>

  <sect1>
   <title>Read Committed Isolation Level</title>

   <para>
    <firstterm>Read Committed</firstterm>
    is the default isolation level in <productname>Postgres</productname>. 
    When a transaction runs on this isolation level, a query sees only
    data committed before the query began and never sees either dirty data or
    concurrent transaction changes committed during query execution.
   </para>

   <para>
    If a row returned by a query while executing an
    <command>UPDATE</command> statement
    (or <command>DELETE</command>
    or <command>SELECT FOR UPDATE</command>)
    is being updated by a
    concurrent uncommitted transaction then the second transaction
    that tries to update this row will wait for the other transaction to
    commit or rollback. In the case of rollback, the waiting transaction
    can proceed to change the row. In the case of commit (and if the
    row still exists; i.e. was not deleted by the other transaction), the
    query will be re-executed for this row to check that new row
    version satisfies query search condition. If the new row version
    satisfies the query search condition then row will be
    updated (or deleted or marked for update).
   </para>

   <para>
    Note that the results of execution of <command>SELECT</command>
    or <command>INSERT</command> (with a query) 
    statements will not be affected by concurrent transactions.
   </para>
  </sect1>

  <sect1>
   <title>Serializable Isolation Level</title>

   <para>
    <firstterm>Serializable</firstterm> provides the highest transaction isolation.
    When a
    transaction is on the serializable level,
    a query sees only data
    committed before the transaction began and never see either dirty data
    or concurrent transaction changes committed during transaction
    execution. So, this level emulates serial transaction execution,
    as if transactions would be executed one after another, serially,
    rather than concurrently.
   </para>

   <para>
    If a row returned by query while executing a
    <command>UPDATE</command>
    (or <command>DELETE</command> or <command>SELECT FOR UPDATE</command>)
    statement is being updated by
    a concurrent uncommitted transaction then the second transaction
    that tries to update this row will wait for the other transaction to
    commit or rollback. In the case of rollback, the waiting transaction
    can proceed to change the row. In the case of a concurrent
    transaction commit, a serializable transaction will be rolled back
    with the message

    <programlisting>
ERROR:  Can't serialize access due to concurrent update
    </programlisting>

    because a serializable transaction cannot modify rows changed by
    other transactions after the serializable transaction began.
   </para>

   <note>
    <para>
     Note that results of execution of <command>SELECT</command>
     or <command>INSERT</command> (with a query) 
     will not be affected by concurrent transactions.
    </para>
   </note>
  </sect1>

  <sect1>
   <title>Locking and Tables</title>

   <para>
    <productname>Postgres</productname>
    provides various lock modes to control concurrent
    access to data in tables. Some of these lock modes are acquired by
    <productname>Postgres</productname>
    automatically before statement execution, while others are
    provided to be used by applications. All lock modes (except for
    AccessShareLock) acquired in a transaction are held for the duration
    of the transaction.
   </para>

   <para>
    In addition to locks, short-term share/exclusive latches are used
    to control read/write access to table pages in shared buffer pool.
    Latches are released immediately after a tuple is fetched or updated.
   </para>

   <sect2>
    <title>Table-level locks</title>

    <para>
     <variablelist>
      <varlistentry>
       <term>
	AccessShareLock
       </term>
       <listitem>
	<para>
	 An internal lock mode acquiring automatically over tables
	 being queried. <productname>Postgres</productname>
	 releases these locks after statement is
	 done.
	</para>

	<para>
	 Conflicts with AccessExclusiveLock only.
	</para>
       </listitem>
      </varlistentry>

      <varlistentry>
       <term>
	RowShareLock
       </term>
       <listitem>
	<para>
	 Acquired by <command>SELECT FOR UPDATE</command>
	 and <command>LOCK TABLE</command>
	 for <option>IN ROW SHARE MODE</option> statements.
	</para>

	<para>
	 Conflicts with ExclusiveLock and AccessExclusiveLock modes.
	</para>
       </listitem>
      </varlistentry>

      <varlistentry>
       <term>
	RowExclusiveLock
       </term>
       <listitem>
	<para>
	 Acquired by <command>UPDATE</command>, <command>DELETE</command>,
	 <command>INSERT</command> and <command>LOCK TABLE</command>
	 for <option>IN ROW EXCLUSIVE MODE</option> statements.
	</para>

	<para>
	 Conflicts with ShareLock, ShareRowExclusiveLock, ExclusiveLock and
	 AccessExclusiveLock modes.
	</para>
       </listitem>
      </varlistentry>

      <varlistentry>
       <term>
	ShareLock
       </term>
       <listitem>
	<para>
	 Acquired by <command>CREATE INDEX</command>
	 and <command>LOCK TABLE</command> table
	 for <option>IN SHARE MODE</option>
	 statements.
	</para>

	<para>
	 Conflicts with RowExclusiveLock, ShareRowExclusiveLock,
	 ExclusiveLock and AccessExclusiveLock modes.
	</para>
       </listitem>
      </varlistentry>

      <varlistentry>
       <term>
	ShareRowExclusiveLock
       </term>
       <listitem>
	<para>
	 Acquired by <command>LOCK TABLE</command> for
	 <option>IN SHARE ROW EXCLUSIVE MODE</option> statements.
	</para>

	<para>
	 Conflicts with RowExclusiveLock, ShareLock, ShareRowExclusiveLock,
	 ExclusiveLock and AccessExclusiveLock modes.
	</para>
       </listitem>
      </varlistentry>

      <varlistentry>
       <term>
	ExclusiveLock
       </term>
       <listitem>
	<para>
	 Acquired by <command>LOCK TABLE</command> table 
	 for <option>IN EXCLUSIVE MODE</option> statements.
	</para>

	<para>
	 Conflicts with RowShareLock, RowExclusiveLock, ShareLock,
	 ShareRowExclusiveLock, ExclusiveLock and AccessExclusiveLock
	 modes.
	</para>
       </listitem>
      </varlistentry>

      <varlistentry>
       <term>
	AccessExclusiveLock
       </term>
       <listitem>
	<para>
	 Acquired by <command>ALTER TABLE</command>,
	 <command>DROP TABLE</command>,
	 <command>VACUUM</command> and <command>LOCK TABLE</command>
	 statements.
	</para>

	<para>
	 Conflicts with RowShareLock, RowExclusiveLock, ShareLock,
	 ShareRowExclusiveLock, ExclusiveLock and AccessExclusiveLock
	 modes.

	 <note>
	  <para>
	   Only AccessExclusiveLock blocks <command>SELECT</command> (without
	   <option>FOR UPDATE</option>) statement.
	  </para>
	 </note>
	</para>
       </listitem>
      </varlistentry>
     </variablelist>
    </para>
   </sect2>

   <sect2>
    <title>Row-level locks</title>

    <para>
     These locks are acquired when internal
     fields of a row are being updated (or deleted or marked for update).
     <productname>Postgres</productname>
     doesn't remember any information about modified rows in memory and
     so has no limit to the number of rows locked without lock escalation.
    </para>

    <para>
     However, take into account that <command>SELECT FOR UPDATE</command> will modify
     selected rows to mark them and so will results in disk writes.
    </para>

    <para>
     Row-level locks don't affect data querying. They are used to block
     writers to <emphasis>the same row</emphasis> only.
    </para>
   </sect2>
  </sect1>

  <sect1>
   <title>Locking and Indices</title>

   <para>
    Though <productname>Postgres</productname>
    provides unblocking read/write access to table
    data, unblocked read/write access is not provided for every
    index access methods implemented
    in <productname>Postgres</productname>.
   </para>

   <para>
    The various index types are handled as follows:

    <variablelist>
     <varlistentry>
      <term>
       GiST and R-Tree indices
      </term>
      <listitem>
       <para>
	Share/exclusive index-level locks are used for read/write access.
	Locks are released after statement is done.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>
       Hash indices
      </term>
      <listitem>
       <para>
	Share/exclusive page-level locks are used for read/write access.
	Locks are released after page is processed.
       </para>

       <para>
	Page-level locks produces better concurrency than index-level ones
	but are subject to deadlocks.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>
       Btree
      </term>
      <listitem>
       <para>
	Short-term share/exclusive page-level latches are used for
	read/write access. Latches are released immediately after the index
	tuple is inserted/fetched.
       </para>

       <para>
	Btree indices provide the highest concurrency without deadlock
	conditions.
       </para>
      </listitem>
     </varlistentry>
    </variablelist>
   </para>
  </sect1>

  <sect1>
   <title>Data consistency checks at the application level</title>

   <para>
    Because readers in <productname>Postgres</productname>
    don't lock data, regardless of
    transaction isolation level, data read by one transaction can be
    overwritten by another. In the other words, if a row is returned
    by <command>SELECT</command> it doesn't mean that this row really
    exists at the time it is returned (i.e. sometime after the
    statement or transaction began) nor
    that the row is protected from deletion or update by concurrent
    transactions before the current transaction does a commit or rollback. 
   </para>

   <para>
    To ensure the actual existance of a row and protect it against
    concurrent updates one must use <command>SELECT FOR UPDATE</command> or
    an appropriate <command>LOCK TABLE</command> statement.
    This should be taken into account when porting applications using
    serializable mode to <productname>Postgres</productname> from other environments.

    <note>
     <para>
      Before version 6.5 <productname>Postgres</productname>
      used read-locks and so the
      above consideration is also the case
      when upgrading to 6.5 (or higher) from previous
      <productname>Postgres</productname> versions.
     </para>
    </note>
   </para>
  </sect1>
 </chapter>

<!-- Keep this comment at the end of the file
Local variables:
mode: sgml
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"./reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:"/usr/lib/sgml/catalog"
sgml-local-ecat-files:nil
End:
-->