Re: ***SPAM*** Re: Help with large delete - Mailing list pgsql-general

From Tom Lane
Subject Re: ***SPAM*** Re: Help with large delete
Date
Msg-id 1958274.1650129333@sss.pgh.pa.us
Whole thread Raw
In response to Re: ***SPAM*** Re: Help with large delete  (Perry Smith <pedz@easesoftware.com>)
List pgsql-general
Perry Smith <pedz@easesoftware.com> writes:
> On Apr 16, 2022, at 10:33, Tom Lane <tgl@sss.pgh.pa.us> wrote:
>> The most obvious question is do you have an index on the referencing
>> column.  PG doesn't require one to exist to create an FK; but if you
>> don't, deletes of referenced rows had better be uninteresting to you
>> performance-wise, because each one will cause a seqscan.

> For Tom’s question, here is the description of the table:

> psql -c '\d dateien' find_dups
>                                           Table "public.dateien"
>    Column   |              Type              | Collation | Nullable |               Default
> ------------+--------------------------------+-----------+----------+-------------------------------------
>  id         | bigint                         |           | not null | nextval('dateien_id_seq'::regclass)
>  basename   | character varying              |           | not null |
>  parent_id  | bigint                         |           |          |
>  dev        | bigint                         |           | not null |
>  ftype      | character varying              |           | not null |
>  uid        | bigint                         |           | not null |
>  gid        | bigint                         |           | not null |
>  ino        | bigint                         |           | not null |
>  mode       | bigint                         |           | not null |
>  mtime      | timestamp without time zone    |           | not null |
>  nlink      | bigint                         |           | not null |
>  size       | bigint                         |           | not null |
>  sha1       | character varying              |           |          |
>  created_at | timestamp(6) without time zone |           | not null |
>  updated_at | timestamp(6) without time zone |           | not null |
> Indexes:
>     "dateien_pkey" PRIMARY KEY, btree (id)
>     "unique_dev_ino_for_dirs" UNIQUE, btree (dev, ino) WHERE ftype::text = 'directory'::text
>     "unique_parent_basename" UNIQUE, btree (COALESCE(parent_id, '-1'::integer::bigint), basename)
> Foreign-key constraints:
>     "fk_rails_c01ebbd0bf" FOREIGN KEY (parent_id) REFERENCES dateien(id) ON DELETE CASCADE
> Referenced by:
>     TABLE "dateien" CONSTRAINT "fk_rails_c01ebbd0bf" FOREIGN KEY (parent_id) REFERENCES dateien(id) ON DELETE CASCADE

Yeah.  So if you want to make deletes on this table not be unpleasantly
slow, you need an index on the parent_id column, and you don't have one.

(unique_parent_basename doesn't help, because with that definition it's
useless for looking up rows by parent_id.)

            regards, tom lane



pgsql-general by date:

Previous
From: Perry Smith
Date:
Subject: Re: ***SPAM*** Re: Help with large delete
Next
From: Jan Wieck
Date:
Subject: Re: Help with large delete