Sign In Start Free Trial
Account

Add to playlist

Create a Playlist

Modal Close icon
You need to login to use this feature.
  • Book Overview & Buying Mastering PostgreSQL 15
  • Table Of Contents Toc
  • Feedback & Rating feedback
Mastering PostgreSQL 15

Mastering PostgreSQL 15

By : Hans-Jürgen Schönig
4.9 (7)
close
close
Mastering PostgreSQL 15

Mastering PostgreSQL 15

4.9 (7)
By: Hans-Jürgen Schönig

Overview of this book

Starting with an introduction to the newly released features of PostgreSQL 15, this updated fifth edition will help you get to grips with PostgreSQL administration and how to build dynamic database solutions for enterprise apps, including designing both physical and technical aspects of the system. You'll explore advanced PostgreSQL features, such as logical replication, database clusters, advanced indexing, and user management to manage and maintain your database. You'll then work with the PostgreSQL optimizer, configure PostgreSQL for high speed, and move from Oracle to PostgreSQL. Among the other skills that the book will help you build, you’ll cover transactions, handling recursions, working with JSON and JSONB data, and setting up a Patroni cluster. It will show you how to improve performance with query optimization. You'll also focus on managing network security and work with backups and replication while exploring useful PostgreSQL extensions that optimize the performance of large databases. By the end of this PostgreSQL book, you’ll be able to use your database to its utmost capacity by implementing advanced administrative tasks with ease.
Table of Contents (16 chapters)
close
close

Observing deadlocks and similar issues

Deadlocks are an important issue and can happen in every database. Basically, a deadlock will happen if two transactions have to wait on each other.

In this section, you will see how this can happen. Let’s suppose we have a table containing two rows:

CREATE TABLE t_deadlock (id int);
INSERT INTO t_deadlock VALUES (1), (2);

The following example shows what can happen:

Transaction 1

Transaction 2

BEGIN;

BEGIN;

UPDATE t_deadlock

SET id = id * 10

WHERE id = 1;

UPDATE t_deadlock

SET id = id * 10

WHERE id = 2;

UPDATE t_deadlock

SET id = id * 10

WHERE id = 2;

Waiting on transaction 2

UPDATE t_deadlock

SET id = id * 10

WHERE id = 1;

Waiting on transaction 2

Waiting on transaction 1

Deadlock will be resolved after 1 second

(deadlock_timeout)

COMMIT;

ROLLBACK;

Table 2.10 – Understanding deadlocks

As soon as the deadlock is detected, the following error message will show up:

psql: ERROR: deadlock detected
DETAIL: Process 91521 waits for ShareLock on transaction 903;
   blocked by process 77185.
 Process 77185 waits for ShareLock on transaction 905;
 blocked by process 91521.
 HINT: See server log for query details.
 CONTEXT: while updating tuple (0,1) in relation "t_deadlock"

PostgreSQL is even kind enough to tell us which row has caused the conflict. In my example, the root of all evil is a tuple, (0, 1). What you can see here is ctid, which is a unique identifier of a row in a table. It tells us about the physical position of a row inside a table. In this example, it is the first row in the first block (0).

It is even possible to query this row if it is still visible in your transaction. Here’s how it works:

test=# SELECT ctid, * FROM t_deadlock WHERE ctid = '(0, 1)';
ctid   | id
-------+-----
(0,1)  |  10
 (1 row)

Keep in mind that this query might not return a row if it has already been deleted or modified.

However, this isn’t the only case where deadlocks can lead to potentially failing transactions. Transactions also cannot be serialized for various reasons. The following example shows what can happen. To make this example work, I assume that you’ve still got the two rows, id = 1 and id = 2:

Transaction 1

Transaction 2

BEGIN ISOLATION LEVEL REPEATABLE READ;

SELECT * FROM t_deadlock;

Two rows will be returned

DELETE FROM t_deadlock;

SELECT * FROM t_deadlock;

Two rows will be returned

DELETE FROM t_deadlock;

The transaction will error out

ROLLBACK; - we cannot COMMIT anymore

Table 2.11 – Transaction isolation and DELETE

In this example, two concurrent transactions are at work. As long as the first transaction is just selecting data, everything is fine because PostgreSQL can easily preserve the illusion of static data. But what happens if the second transaction commits a DELETE command? As long as there are only reads, there is still no problem. The trouble begins when the first transaction tries to delete or modify data that is already dead at this point. The only solution for PostgreSQL is to error out due to a conflict caused by our transactions:

test=# DELETE FROM t_deadlock;
psql: ERROR: could not serialize access due to concurrent update

Practically, this means that end users have to be prepared to handle erroneous transactions. If something goes wrong, properly written applications must be able to try again.

Create a Note

Modal Close icon
You need to login to use this feature.
notes
bookmark search playlist download font-size

Change the font size

margin-width

Change margin width

day-mode

Change background colour

Close icon Search
Country selected

Close icon Your notes and bookmarks

Delete Bookmark

Modal Close icon
Are you sure you want to delete it?
Cancel
Yes, Delete

Delete Note

Modal Close icon
Are you sure you want to delete it?
Cancel
Yes, Delete

Edit Note

Modal Close icon
Write a note (max 255 characters)
Cancel
Update Note

Confirmation

Modal Close icon
claim successful

Buy this book with your credits?

Modal Close icon
Are you sure you want to buy this book with one of your credits?
Close
YES, BUY