CYBERTEC PostgreSQL Logo

Dealing with trigger recursion in PostgreSQL

10.2024 / Category: / Tags: |

A father tells his son to hit back the next time, but the son is afraid of trigger recursion.
© Laurenz Albe 2024

Many a beginner falls into the trap of trigger recursion at some point. Usually, the solution is to avoid recursion at all. But for some use cases, you may have to handle trigger recursion. This article tells you what you need to know about the topic. If you were ever troubled by the error message “stack depth limit exceeded”, here is the solution.

The beginner's mistake leading to trigger recursion

Triggers are the only good way to change data automatically. Constraints are the “policemen” that make sure rules are not voilated, but triggers are the workers that make the data stay in line. A beginner who has understood that may (quite correctly) wish to use a trigger to set the updated_at column in the following table:

The column default will set updated_at when the row is inserted, but won't change the value when you update the row. For that, our beginner writes a trigger:

But that won't work as intended:

The last four lines of the error context keep repeating and indicate a recursion problem.

Avoiding trigger recursion with a BEFORE trigger

The problem with the trigger is that it updates the same table whose update invoked the trigger in the first place. That triggers the same trigger again, and so on until there are so many recursive function calls on the stack that they exceed the limit. Different from most other cases, PostgreSQL's hint is not helpful here. Since the recursion is infinite, increasing the stack depth limit will only increase the time to the error message and the length on the error context.

Even if it didn't lead to infinite recursion, the above trigger would not be ideal. Owing to PostgreSQL's multi-version implementation, every update produces a “dead tuple”, which VACUUM has to clean up later. If the trigger performs a second update on the table row you just updated, that will generate a second dead tuple. That is inefficient, and you may need to tune autovacuum to cope with the additional workload.

The correct solution in PostgreSQL to avoid the second update and the infinite recursion is a BEFORE trigger that modifies the new row before it gets added to the table:

The “RETURN NEW;” is essential; read my article if you need an explanation.

A more serious trigger recursion example

The beginner's mistake above was easy to fix, and in most cases, it is easy to avoid such recursion with a little thought. But sometimes there are use cases for triggers where recursion is difficult to avoid. Imagine a public health database of working places and workers:

Each worker has a status “quarantined” (no, this article was not written during the pandemic).

Enforcing a data rule with a trigger that is prone to infinite recursion

Imagine law decrees that if one worker is quarantined, all people working at the same address be quarantined as well. It is best to implement data integrity rules like that with a trigger. Otherwise, data modifications performed outside the application could break the integrity of the data. Here is how such a trigger might look:

That looks fundamentally correct, but you get trigger recursion as soon as there are more workers at a single address. The first trigger invocation will update the other workers at the same address, which will again invoke the trigger, updating the original worker a second time, and so forth ad infinitum:

Avoiding infinite trigger recursion with a WHERE condition

In the above case, you could fix the infinite recursion by adding another WHERE condition that avoids updating a row a second time:

Now if I update the worker with id = 1, the trigger will update the worker with id = 2. This will call the trigger a second time, but all workers at that address are already quarantined, so the trigger won't update any row and recursion stops.

Avoiding infinite trigger recursion with the function pg_trigger_depth()

In our example, it was not difficult to avoid endless recursion with a WHERE condition. It may not always be that easy. There is another way to stop recursion: the function pg_trigger_depth(). This function is for use in trigger functions and returns the recursion level. We can use it as a safeguard to stop the recursion after the first level:

Using the trigger WHEN clause for better performance

With the above code, the trigger will still be called twice. The second time, the trigger funtion will return without doing anything, but we still have to pay the price of a second function call. The little-known WHEN clause in CREATE TRIGGER can make trigger invocation conditional and avoid that overhead:

With this definition, recursion is stopped before the trigger function is called a second time, which will improve performance significantly.

Conclusion

We have seen how to avoid a beginner's error that causes infinite trigger recursion by avoiding recursion at all. In cases where we cannot avoid trigger recursion, we have seen how to use pg_trigger_depth() or a carefully designed additional condition can stop recursion at the right moment. We have also seen the WHEN clause of CREATE TRIGGER that can simplify the code and boost performance.

Leave a Reply

Your email address will not be published. Required fields are marked *

CYBERTEC Logo white
CYBERTEC PostgreSQL International GmbH
Römerstraße 19
2752 Wöllersdorf
Austria

+43 (0) 2622 93022-0
office@cybertec.at

Get the newest PostgreSQL Info & Tools


    This site is protected by reCAPTCHA and the Google Privacy Policy & Terms of Service apply.

    ©
    2024
    CYBERTEC PostgreSQL International GmbH
    phone-handsetmagnifiercrosscross-circle
    linkedin facebook pinterest youtube rss twitter instagram facebook-blank rss-blank linkedin-blank pinterest youtube twitter instagram