Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Fix postgres dialect delete expired #367

Merged
merged 3 commits into from
Dec 19, 2022

Conversation

kzkvv
Copy link
Contributor

@kzkvv kzkvv commented Dec 15, 2022

The DELETE SQL of POSTGRESQL_9 dialect ends up slowly executing and producing excessive CPU load.

Quoted from PostgreSQL - System Columns:

ctid: The physical location of the row version within its table. Note that although the ctid can be used to locate the row version very quickly, a row's ctid will change each time it is updated or moved by VACUUM FULL. Therefore ctid is useless as a long-term row identifier. The OID, or even better a user-defined serial number, should be used to identify logical rows.

The original uses "ctid" system value, but the modified uses the "id" primary key column. Here are explain plans of the original query and of modified query, showing that the modified one doesn't have that unexplainably high cost.

original:

explain DELETE FROM TXNO_OUTBOX WHERE ctid IN (SELECT ctid FROM TXNO_OUTBOX WHERE nextAttemptTime < now() AND processed = true AND blocked = false LIMIT 100);                                                        
--------------------------------------------------------------------------------------------------------------------------
Delete on txno_outbox  (cost=0.13..750420.75 rows=1 width=36)
  ->  Nested Loop Semi Join  (cost=0.13..750420.75 rows=1 width=36)
        Join Filter: (txno_outbox.ctid = "ANY_subquery".ctid)
        ->  Seq Scan on txno_outbox  (cost=0.00..750419.00 rows=1 width=6)
        ->  Subquery Scan on "ANY_subquery"  (cost=0.13..1.74 rows=1 width=36)
              ->  Limit  (cost=0.13..1.73 rows=1 width=6)
                    ->  Index Scan using ix_txno_outbox_1 on txno_outbox txno_outbox_1  (cost=0.13..1.73 rows=1 width=6)
                          Index Cond: ((processed = true) AND (blocked = false) AND (nextattempttime < now()))
                          Filter: (processed AND (NOT blocked))

modified:

explain DELETE FROM TXNO_OUTBOX WHERE id IN (SELECT id FROM TXNO_OUTBOX WHERE nextAttemptTime < now() AND processed = true AND blocked = false LIMIT 100);                                                           
---------------------------------------------------------------------------------------------------------------------------------
Delete on txno_outbox  (cost=2.98..5.21 rows=1 width=67)
   ->  Nested Loop  (cost=2.98..5.21 rows=1 width=67)
         ->  HashAggregate  (cost=1.74..1.75 rows=1 width=98)
               Group Key: ("ANY_subquery".id)::text
               ->  Subquery Scan on "ANY_subquery"  (cost=0.13..1.74 rows=1 width=98)
                     ->  Limit  (cost=0.13..1.73 rows=1 width=37)
                           ->  Index Scan using ix_txno_outbox_1 on txno_outbox txno_outbox_1  (cost=0.13..1.73 rows=1 width=37)
                                 Index Cond: ((processed = true) AND (blocked = false) AND (nextattempttime < now()))
                                 Filter: (processed AND (NOT blocked))
         ->  Bitmap Heap Scan on txno_outbox  (cost=1.23..2.35 rows=1 width=43)
               Recheck Cond: ((id)::text = ("ANY_subquery".id)::text)
               ->  Bitmap Index Scan on txno_outbox_pkey  (cost=0.00..1.23 rows=1 width=0)
                     Index Cond: ((id)::text = ("ANY_subquery".id)::text)

The modification is only "ctid" --> "id". Functionally, the query is equivalent.

@badgerwithagun
Copy link
Member

Thanks @kzkvv !

The query change looks fine.

Could you remove the parameterisation though? It'll cause problems with schema management and it seems odd to parameterise that one column and not the others.

I'm quite happy if this change is simply a one-liner, ctid --> id.

@kzkvv kzkvv force-pushed the fix-postgres-delete-expired branch from 198d813 to 29cecf0 Compare December 19, 2022 07:42
@kzkvv
Copy link
Contributor Author

kzkvv commented Dec 19, 2022

Done! Only the postgres DELETE query has been updated, other changes have been reverted

@badgerwithagun badgerwithagun merged commit 79442ab into gruelbox:master Dec 19, 2022
@badgerwithagun
Copy link
Member

Merged! Thanks again.

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Projects
None yet
Development

Successfully merging this pull request may close these issues.

2 participants