PostgreSQL でパーテーションテーブルを使い、大量データの投入と削除を行い、その処理時間を計測してみます。
環境構築
こちらの手順で作成しました。
データベース構成
bkiban=# \l
List of databases
Name | Owner | Encoding | Locale Provider | Collate | Ctype | Locale | ICU Rules | Access privileges
-----------+----------+----------+-----------------+------------+------------+--------+-----------+-----------------------
bkiban | postgres | UTF8 | libc | en_US.utf8 | en_US.utf8 | | |
postgres | postgres | UTF8 | libc | en_US.utf8 | en_US.utf8 | | |
template0 | postgres | UTF8 | libc | en_US.utf8 | en_US.utf8 | | | =c/postgres +
| | | | | | | | postgres=CTc/postgres
template1 | postgres | UTF8 | libc | en_US.utf8 | en_US.utf8 | | | =c/postgres +
| | | | | | | | postgres=CTc/postgres
(4 rows)
bkiban=#
bkiban を使っていきます。
create table
bkiban=# \dt
Did not find any relations.
bkiban=#
bkiban データベースは空の状態です。
bkiban=# CREATE TABLE kihon (
id integer NOT NULL
, id1 varchar(8) NOT NULL
, id2 char(5) NOT NULL
, start_dt timestamp
, end_dt timestamp
, created_at timestamp NOT NULL
, updated_at timestamp NOT NULL
, CONSTRAINT kihon_pkey PRIMARY KEY(id, end_dt)
) PARTITION BY RANGE (end_dt);
CREATE TABLE
bkiban=#
bkiban=# \dt;
List of relations
Schema | Name | Type | Owner
--------+----------------+-------------------+----------
public | kihon | partitioned table | postgres
public | kihon_y2024m11 | table | postgres
public | kihon_y2024m12 | table | postgres
public | kihon_y2025m01 | table | postgres
public | kihon_y2025m02 | table | postgres
public | kihon_y2025m03 | table | postgres
public | kihon_y2025m04 | table | postgres
public | kihon_y2025m05 | table | postgres
public | kihon_y2025m06 | table | postgres
public | kihon_y2025m07 | table | postgres
public | kihon_y2025m08 | table | postgres
public | kihon_y2025m09 | table | postgres
public | kihon_y2025m10 | table | postgres
public | kihon_y2025m11 | table | postgres
public | kihon_y2025m12 | table | postgres
(15 rows)
bkiban=#
テーブルサイズ
bkiban=# SELECT pgn.nspname, relname, pg_size_pretty(relpages::bigint * 8 * 1024) AS size, CASE WHEN relkind =
't' THEN (SELECT pgd.relname FROM pg_class pgd WHERE pgd.reltoastrelid = pg.oid) WHEN nspname =
'pg_toast' AND relkind = 'i' THEN (SELECT pgt.relname FROM pg_class pgt WHERE SUBSTRING(pgt.relname
FROM 10) = REPLACE(SUBSTRING(pg.relname FROM 10), '_index', '')) ELSE (SELECT pgc.relname FROM
pg_class pgc WHERE pg.reltoastrelid = pgc.oid) END::varchar AS refrelname, CASE WHEN nspname =
'pg_toast' AND relkind = 'i' THEN (SELECT pgts.relname FROM pg_class pgts WHERE pgts.reltoastrelid =
(SELECT pgt.oid FROM pg_class pgt WHERE SUBSTRING(pgt.relname FROM 10) = REPLACE(SUBSTRING(pg.relname
FROM 10), '_index', ''))) END AS relidxrefrelname, relfilenode, relkind, reltuples::bigint, relpages
FROM pg_class pg, pg_namespace pgn WHERE relname LIKE 'kihon%' AND pg.relnamespace = pgn.oid AND pgn.nspname NOT IN
('information_schema', 'pg_catalog') ORDER BY relname, relpages DESC;
nspname | relname | size | refrelname | relidxrefrelname | relfilenode | relkind | reltuples | relpages
---------+---------------------+------------+------------+------------------+-------------+---------+-----------+----------
public | kihon | 0 bytes | | | 0 | p | -1 | 0
public | kihon_pkey | 0 bytes | | | 0 | I | 0 | 0
public | kihon_y2024m11 | 0 bytes | | | 16609 | r | -1 | 0
public | kihon_y2024m11_pkey | 8192 bytes | | | 16612 | i | 0 | 1
public | kihon_y2024m12 | 0 bytes | | | 16614 | r | -1 | 0
public | kihon_y2024m12_pkey | 8192 bytes | | | 16617 | i | 0 | 1
public | kihon_y2025m01 | 0 bytes | | | 16619 | r | -1 | 0
public | kihon_y2025m01_pkey | 8192 bytes | | | 16622 | i | 0 | 1
public | kihon_y2025m02 | 0 bytes | | | 16624 | r | -1 | 0
public | kihon_y2025m02_pkey | 8192 bytes | | | 16627 | i | 0 | 1
public | kihon_y2025m03 | 0 bytes | | | 16629 | r | -1 | 0
public | kihon_y2025m03_pkey | 8192 bytes | | | 16632 | i | 0 | 1
public | kihon_y2025m04 | 0 bytes | | | 16634 | r | -1 | 0
public | kihon_y2025m04_pkey | 8192 bytes | | | 16637 | i | 0 | 1
public | kihon_y2025m05 | 0 bytes | | | 16639 | r | -1 | 0
public | kihon_y2025m05_pkey | 8192 bytes | | | 16642 | i | 0 | 1
public | kihon_y2025m06 | 0 bytes | | | 16644 | r | -1 | 0
public | kihon_y2025m06_pkey | 8192 bytes | | | 16647 | i | 0 | 1
public | kihon_y2025m07 | 0 bytes | | | 16649 | r | -1 | 0
public | kihon_y2025m07_pkey | 8192 bytes | | | 16652 | i | 0 | 1
public | kihon_y2025m08 | 0 bytes | | | 16654 | r | -1 | 0
public | kihon_y2025m08_pkey | 8192 bytes | | | 16657 | i | 0 | 1
public | kihon_y2025m09 | 0 bytes | | | 16659 | r | -1 | 0
public | kihon_y2025m09_pkey | 8192 bytes | | | 16662 | i | 0 | 1
public | kihon_y2025m10 | 0 bytes | | | 16664 | r | -1 | 0
public | kihon_y2025m10_pkey | 8192 bytes | | | 16667 | i | 0 | 1
public | kihon_y2025m11 | 0 bytes | | | 16669 | r | -1 | 0
public | kihon_y2025m11_pkey | 8192 bytes | | | 16672 | i | 0 | 1
public | kihon_y2025m12 | 0 bytes | | | 16674 | r | -1 | 0
public | kihon_y2025m12_pkey | 8192 bytes | | | 16677 | i | 0 | 1
(30 rows)
bkiban=#
データ投入
以下のストアド・ファンクションで 1 か月分投入してみます。
create or replace function test() returns text AS $$
declare
myrow record;
i integer := 1;
j integer := 1;
id1 varchar(8) := 'A' || substring(to_char(j, '0000009'), 2, 100);
id2 char(5) := 'V' || substring(to_char(j, '0009'), 2, 100);
wk_id integer := 1;
wk_offset timestamp := '2024-11-01 00:00:00';
wk_current timestamp := wk_offset;
wk_current2 timestamp := wk_current + interval '6 hours';
begin
LOOP
EXIT WHEN i > 30;
LOOP
EXIT WHEN j > 50000;
INSERT INTO kihon VALUES (wk_id, id1, id2, wk_current, wk_current2, now(), now());
wk_id := wk_id + 1;
j := j + 1;
id1 := 'A' || substring(to_char(j, '0000009'), 2, 100);
id2 := 'V' || substring(to_char(j%10000, '0009'), 2, 100);
wk_current := wk_current + interval '1 second';
wk_current2 := wk_current2 + interval '1 second';
END LOOP;
i := i + 1;
j := 1;
wk_offset := wk_offset + interval '1 day';
wk_current := wk_offset;
wk_current2 := wk_current + interval '6 hours';
END LOOP;
return 'fine';
end;
$$ language plpgsql;
実行してみました。
bkiban=# select * from test();
test
------
fine
(1 row)
bkiban=#
bkiban=# select count(*) from kihon;
count
---------
1500000
(1 row)
bkiban=# select * from kihon order by id limit 5;
id | id1 | id2 | start_dt | end_dt | created_at | updated_at
----+----------+-------+---------------------+---------------------+----------------------------+----------------------------
1 | A0000001 | V0001 | 2024-11-01 00:00:00 | 2024-11-01 06:00:00 | 2024-11-17 03:53:36.024897 | 2024-11-17 03:53:36.024897
2 | A0000002 | V0002 | 2024-11-01 00:00:01 | 2024-11-01 06:00:01 | 2024-11-17 03:53:36.024897 | 2024-11-17 03:53:36.024897
3 | A0000003 | V0003 | 2024-11-01 00:00:02 | 2024-11-01 06:00:02 | 2024-11-17 03:53:36.024897 | 2024-11-17 03:53:36.024897
4 | A0000004 | V0004 | 2024-11-01 00:00:03 | 2024-11-01 06:00:03 | 2024-11-17 03:53:36.024897 | 2024-11-17 03:53:36.024897
5 | A0000005 | V0005 | 2024-11-01 00:00:04 | 2024-11-01 06:00:04 | 2024-11-17 03:53:36.024897 | 2024-11-17 03:53:36.024897
(5 rows)
bkiban=# select * from kihon order by id DESC limit 5;
id | id1 | id2 | start_dt | end_dt | created_at | updated_at
---------+----------+-------+---------------------+---------------------+----------------------------+----------------------------
1500000 | A0050000 | V0000 | 2024-11-30 13:53:19 | 2024-11-30 19:53:19 | 2024-11-17 03:53:36.024897 | 2024-11-17 03:53:36.024897
1499999 | A0049999 | V9999 | 2024-11-30 13:53:18 | 2024-11-30 19:53:18 | 2024-11-17 03:53:36.024897 | 2024-11-17 03:53:36.024897
1499998 | A0049998 | V9998 | 2024-11-30 13:53:17 | 2024-11-30 19:53:17 | 2024-11-17 03:53:36.024897 | 2024-11-17 03:53:36.024897
1499997 | A0049997 | V9997 | 2024-11-30 13:53:16 | 2024-11-30 19:53:16 | 2024-11-17 03:53:36.024897 | 2024-11-17 03:53:36.024897
1499996 | A0049996 | V9996 | 2024-11-30 13:53:15 | 2024-11-30 19:53:15 | 2024-11-17 03:53:36.024897 | 2024-11-17 03:53:36.024897
(5 rows)
bkiban=#
bkiban=# SELECT pgn.nspname, relname, pg_size_pretty(relpages::bigint * 8 * 1024) AS size, CASE WHEN relkind =
't' THEN (SELECT pgd.relname FROM pg_class pgd WHERE pgd.reltoastrelid = pg.oid) WHEN nspname =
'pg_toast' AND relkind = 'i' THEN (SELECT pgt.relname FROM pg_class pgt WHERE SUBSTRING(pgt.relname
FROM 10) = REPLACE(SUBSTRING(pg.relname FROM 10), '_index', '')) ELSE (SELECT pgc.relname FROM
pg_class pgc WHERE pg.reltoastrelid = pgc.oid) END::varchar AS refrelname, CASE WHEN nspname =
'pg_toast' AND relkind = 'i' THEN (SELECT pgts.relname FROM pg_class pgts WHERE pgts.reltoastrelid =
(SELECT pgt.oid FROM pg_class pgt WHERE SUBSTRING(pgt.relname FROM 10) = REPLACE(SUBSTRING(pg.relname
FROM 10), '_index', ''))) END AS relidxrefrelname, relfilenode, relkind, reltuples::bigint, relpages
FROM pg_class pg, pg_namespace pgn WHERE relname LIKE 'kihon%' AND pg.relnamespace = pgn.oid AND pgn.nspname NOT IN
('information_schema', 'pg_catalog') ORDER BY relname, relpages DESC;
nspname | relname | size | refrelname | relidxrefrelname | relfilenode | relkind | reltuples | relpages
---------+---------------------+------------+------------+------------------+-------------+---------+-----------+----------
public | kihon | 0 bytes | | | 0 | p | -1 | 0
public | kihon_pkey | 0 bytes | | | 0 | I | 0 | 0
public | kihon_y2024m11 | 121 MB | | | 16609 | r | 1500000 | 15464
public | kihon_y2024m11_pkey | 45 MB | | | 16612 | i | 1500000 | 5770
public | kihon_y2024m12 | 0 bytes | | | 16614 | r | -1 | 0
public | kihon_y2024m12_pkey | 8192 bytes | | | 16617 | i | 0 | 1
public | kihon_y2025m01 | 0 bytes | | | 16619 | r | -1 | 0
public | kihon_y2025m01_pkey | 8192 bytes | | | 16622 | i | 0 | 1
public | kihon_y2025m02 | 0 bytes | | | 16624 | r | -1 | 0
public | kihon_y2025m02_pkey | 8192 bytes | | | 16627 | i | 0 | 1
public | kihon_y2025m03 | 0 bytes | | | 16629 | r | -1 | 0
public | kihon_y2025m03_pkey | 8192 bytes | | | 16632 | i | 0 | 1
public | kihon_y2025m04 | 0 bytes | | | 16634 | r | -1 | 0
public | kihon_y2025m04_pkey | 8192 bytes | | | 16637 | i | 0 | 1
public | kihon_y2025m05 | 0 bytes | | | 16639 | r | -1 | 0
public | kihon_y2025m05_pkey | 8192 bytes | | | 16642 | i | 0 | 1
public | kihon_y2025m06 | 0 bytes | | | 16644 | r | -1 | 0
public | kihon_y2025m06_pkey | 8192 bytes | | | 16647 | i | 0 | 1
public | kihon_y2025m07 | 0 bytes | | | 16649 | r | -1 | 0
public | kihon_y2025m07_pkey | 8192 bytes | | | 16652 | i | 0 | 1
public | kihon_y2025m08 | 0 bytes | | | 16654 | r | -1 | 0
public | kihon_y2025m08_pkey | 8192 bytes | | | 16657 | i | 0 | 1
public | kihon_y2025m09 | 0 bytes | | | 16659 | r | -1 | 0
public | kihon_y2025m09_pkey | 8192 bytes | | | 16662 | i | 0 | 1
public | kihon_y2025m10 | 0 bytes | | | 16664 | r | -1 | 0
public | kihon_y2025m10_pkey | 8192 bytes | | | 16667 | i | 0 | 1
public | kihon_y2025m11 | 0 bytes | | | 16669 | r | -1 | 0
public | kihon_y2025m11_pkey | 8192 bytes | | | 16672 | i | 0 | 1
public | kihon_y2025m12 | 0 bytes | | | 16674 | r | -1 | 0
public | kihon_y2025m12_pkey | 8192 bytes | | | 16677 | i | 0 | 1
(30 rows)
bkiban=#
よさそうです。13か月分投入してみます。
bkiban=# select count(*) from kihon;
count
----------
21300000
(1 row)
bkiban=# select * from kihon order by id DESC limit 5;
id | id1 | id2 | start_dt | end_dt | created_at | updated_at
----------+----------+-------+---------------------+---------------------+----------------------------+----------------------------
21300000 | A0050000 | V0000 | 2025-12-31 13:53:19 | 2025-12-31 19:53:19 | 2024-11-17 04:32:23.808601 | 2024-11-17 04:32:23.808601
21299999 | A0049999 | V9999 | 2025-12-31 13:53:18 | 2025-12-31 19:53:18 | 2024-11-17 04:32:23.808601 | 2024-11-17 04:32:23.808601
21299998 | A0049998 | V9998 | 2025-12-31 13:53:17 | 2025-12-31 19:53:17 | 2024-11-17 04:32:23.808601 | 2024-11-17 04:32:23.808601
21299997 | A0049997 | V9997 | 2025-12-31 13:53:16 | 2025-12-31 19:53:16 | 2024-11-17 04:32:23.808601 | 2024-11-17 04:32:23.808601
21299996 | A0049996 | V9996 | 2025-12-31 13:53:15 | 2025-12-31 19:53:15 | 2024-11-17 04:32:23.808601 | 2024-11-17 04:32:23.808601
(5 rows)
bkiban=# SELECT pgn.nspname, relname, pg_size_pretty(relpages::bigint * 8 * 1024) AS size, CASE WHEN relkind =
't' THEN (SELECT pgd.relname FROM pg_class pgd WHERE pgd.reltoastrelid = pg.oid) WHEN nspname =
'pg_toast' AND relkind = 'i' THEN (SELECT pgt.relname FROM pg_class pgt WHERE SUBSTRING(pgt.relname
FROM 10) = REPLACE(SUBSTRING(pg.relname FROM 10), '_index', '')) ELSE (SELECT pgc.relname FROM
pg_class pgc WHERE pg.reltoastrelid = pgc.oid) END::varchar AS refrelname, CASE WHEN nspname =
'pg_toast' AND relkind = 'i' THEN (SELECT pgts.relname FROM pg_class pgts WHERE pgts.reltoastrelid =
(SELECT pgt.oid FROM pg_class pgt WHERE SUBSTRING(pgt.relname FROM 10) = REPLACE(SUBSTRING(pg.relname
FROM 10), '_index', ''))) END AS relidxrefrelname, relfilenode, relkind, reltuples::bigint, relpages
FROM pg_class pg, pg_namespace pgn WHERE relname LIKE 'kihon%' AND pg.relnamespace = pgn.oid AND pgn.nspname NOT IN
('information_schema', 'pg_catalog') ORDER BY relname, relpages DESC;
nspname | relname | size | refrelname | relidxrefrelname | relfilenode | relkind | reltuples | relpages
---------+---------------------+---------+------------+------------------+-------------+---------+-----------+----------
public | kihon | 0 bytes | | | 0 | p | -1 | 0
public | kihon_pkey | 0 bytes | | | 0 | I | 0 | 0
public | kihon_y2024m11 | 121 MB | | | 16685 | r | 1500000 | 15464
public | kihon_y2024m11_pkey | 45 MB | | | 16688 | i | 1500000 | 5770
public | kihon_y2024m12 | 125 MB | | | 16690 | r | 1550000 | 15980
public | kihon_y2024m12_pkey | 47 MB | | | 16693 | i | 1550000 | 5962
public | kihon_y2025m01 | 125 MB | | | 16695 | r | 1550000 | 15980
public | kihon_y2025m01_pkey | 47 MB | | | 16698 | i | 1550000 | 5962
public | kihon_y2025m02 | 113 MB | | | 16700 | r | 1400000 | 14433
public | kihon_y2025m02_pkey | 42 MB | | | 16703 | i | 1400000 | 5385
public | kihon_y2025m03 | 125 MB | | | 16705 | r | 1550000 | 15980
public | kihon_y2025m03_pkey | 47 MB | | | 16708 | i | 1550000 | 5962
public | kihon_y2025m04 | 121 MB | | | 16710 | r | 1500000 | 15464
public | kihon_y2025m04_pkey | 45 MB | | | 16713 | i | 1500000 | 5770
public | kihon_y2025m05 | 125 MB | | | 16715 | r | 1550000 | 15980
public | kihon_y2025m05_pkey | 47 MB | | | 16718 | i | 1550000 | 5962
public | kihon_y2025m06 | 121 MB | | | 16720 | r | 1500000 | 15464
public | kihon_y2025m06_pkey | 45 MB | | | 16723 | i | 1500000 | 5770
public | kihon_y2025m07 | 125 MB | | | 16725 | r | 1550000 | 15980
public | kihon_y2025m07_pkey | 47 MB | | | 16728 | i | 1550000 | 5962
public | kihon_y2025m08 | 125 MB | | | 16730 | r | 1550000 | 15980
public | kihon_y2025m08_pkey | 47 MB | | | 16733 | i | 1550000 | 5962
public | kihon_y2025m09 | 121 MB | | | 16735 | r | 1500000 | 15464
public | kihon_y2025m09_pkey | 45 MB | | | 16738 | i | 1500000 | 5770
public | kihon_y2025m10 | 125 MB | | | 16740 | r | 1550000 | 15980
public | kihon_y2025m10_pkey | 47 MB | | | 16743 | i | 1550000 | 5962
public | kihon_y2025m11 | 121 MB | | | 16745 | r | 1500000 | 15464
public | kihon_y2025m11_pkey | 45 MB | | | 16748 | i | 1500000 | 5770
public | kihon_y2025m12 | 125 MB | | | 16750 | r | 1550000 | 15980
public | kihon_y2025m12_pkey | 47 MB | | | 16753 | i | 1550000 | 5962
(30 rows)
bkiban=#
よさそうです。select count(*)
は 30 秒ほどかかりました。
1 日分のデータを消すのに何秒かかるのか?
やりたかったことは「1 日分のデータを消すのにかかる時間を知りたい」ということでした。さっそく確認していきます。
オートコミット停止
bkiban=# \echo :AUTOCOMMIT
on
bkiban=#
bkiban=# \set AUTOCOMMIT off
bkiban=# \echo :AUTOCOMMIT
off
bkiban=#
テスト
bkiban=# create table a (aa char(1));
CREATE TABLE
bkiban=*# insert into a values('z');
INSERT 0 1
bkiban=*# select * from a;
aa
----
z
(1 row)
bkiban=*# rollback;
ROLLBACK
bkiban=# select * from a;
ERROR: relation "a" does not exist
LINE 1: select * from a;
^
bkiban=!#
ここはちょっと意外な結果でしたが、posgre は create のような DDL (CREATE , DROP , ALTER , TRUNCATE) もトランザクション処理します。他の DB とはちょっと違う部分ですね。(TRUNCATE はさすがに rollback できないと思われますが、、、)
オートコミットを停止すると、プロンプトでいろいろ教えてくれるようです。
bkiban=#
トランザクションがクリアな状態
bkiban=*#
トランザクション処理中
bkiban=!#
なんでしょうか。今のところよくわからない状態
削除対象を抽出する処理時間を把握する
select id || ',' from kihon where end_dt >= '2024-11-01 00:00:00'::timestamp and end_dt < '2024-11-02 00:00:00'::timestamp;
これは即時で抽出できました。
1000 件単位で削除する
bkiban=!# delete from kihon where id in (
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,558,559,560,561,562,563,564,565,566,567,568,569,570,571,572,573,574,575,576,577,578,579,580,581,582,583,584,585,586,587,588,589,590,591,592,593,594,595,596,597,598,599,600,601,602,603,604,605,606,607,608,609,610,611,612,613,614,615,616,617,618,619,620,621,622,623,624,625,626,627,628,629,630,631,632,633,634,635,636,637,638,639,640,641,642,643,644,645,646,647,648,649,650,651,652,653,654,655,656,657,658,659,660,661,662,663,664,665,666,667,668,669,670,671,672,673,674,675,676,677,678,679,680,681,682,683,684,685,686,687,688,689,690,691,692,693,694,695,696,697,698,699,700,701,702,703,704,705,706,707,708,709,710,711,712,713,714,715,716,717,718,719,720,721,722,723,724,725,726,727,728,729,730,731,732,733,734,735,736,737,738,739,740,741,742,743,744,745,746,747,748,749,750,751,752,753,754,755,756,757,758,759,760,761,762,763,764,765,766,767,768,769,770,771,772,773,774,775,776,777,778,779,780,781,782,783,784,785,786,787,788,789,790,791,792,793,794,795,796,797,798,799,800,801,802,803,804,805,806,807,808,809,810,811,812,813,814,815,816,817,818,819,820,821,822,823,824,825,826,827,828,829,830,831,832,833,834,835,836,837,838,839,840,841,842,843,844,845,846,847,848,849,850,851,852,853,854,855,856,857,858,859,860,861,862,863,864,865,866,867,868,869,870,871,872,873,874,875,876,877,878,879,880,881,882,883,884,885,886,887,888,889,890,891,892,893,894,895,896,897,898,899,900,901,902,903,904,905,906,907,908,909,910,911,912,913,914,915,916,917,918,919,920,921,922,923,924,925,926,927,928,929,930,931,932,933,934,935,936,937,938,939,940,941,942,943,944,945,946,947,948,949,950,951,952,953,954,955,956,957,958,959,960,961,962,963,964,965,966,967,968,969,970,971,972,973,974,975,976,977,978,979,980,981,982,983,984,985,986,987,988,989,990,991,992,993,994,995,996,997,998,999,1000);
ERROR: current transaction is aborted, commands ignored until end of transaction block
bkiban=!# rollback;
ROLLBACK
bkiban=#
チューニングなしの状態では 1000 件削除できませんでしした。500 件で試してみます。
bkiban=# delete from kihon where id in (
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);
DELETE 500
bkiban=*#
即時復帰しました。commit してみます
bkiban=*# commit;
COMMIT
bkiban=#
これも即時復帰しました。