Re: Need explanation on index size - Mailing list pgsql-general
From | Guillaume Lelarge |
---|---|
Subject | Re: Need explanation on index size |
Date | |
Msg-id | CAECtzeWXt=VmywJkfCzT9=vaEa9R+dEztBmSn1wSa0dhDFgBkg@mail.gmail.com Whole thread Raw |
In response to | Need explanation on index size (Guillaume Luchet <g.luchet@bilendi.com>) |
Responses |
Re: Need explanation on index size
|
List | pgsql-general |
Hi,
Le jeu. 24 sept. 2020 à 15:55, Guillaume Luchet <g.luchet@bilendi.com> a écrit :
Hi,I’m facing of a comportement I don’t understand on indexes, here a quick example to reproduce my problemtest=# select version();version----------------------------------------------------------------------------------------------------------------------------------PostgreSQL 12.4 (Debian 12.4-1.pgdg90+1) on x86_64-pc-linux-gnu, compiled by gcc (Debian 6.3.0-18+deb9u1) 6.3.0 20170516, 64-bit(1 row)test=# create table plop (col_a int, col_b int, col_c int);CREATE TABLEtest=# create unique index on plop (col_a);CREATE INDEXtest=# create index on plop(col_b);CREATE INDEXtest=# insert into plop (col_a, col_b) select generate_series(1, 10000), generate_series(1, 10000);INSERT 0 10000test=# SELECT schemaname, tablename,pg_size_pretty(SIZE) AS size_pretty,pg_size_pretty(total_size) AS total_size_prettyFROM (SELECT *, pg_relation_size(quote_ident(schemaname) || '.' || quote_ident(tablename)) AS SIZE,pg_total_relation_size(quote_ident(schemaname) || '.' || quote_ident(tablename)) AS total_sizeFROM pg_tables) AS TABLES where tablename = 'plop';schemaname | tablename | size_pretty | total_size_pretty------------+-----------+-------------+-------------------public | plop | 360 kB | 864 kB(1 row)test=# update plop set col_c = floor(random() * 10 + 1)::int;UPDATE 10000test=# SELECT schemaname, tablename,pg_size_pretty(SIZE) AS size_pretty,pg_size_pretty(total_size) AS total_size_prettyFROM (SELECT *, pg_relation_size(quote_ident(schemaname) || '.' || quote_ident(tablename)) AS SIZE,pg_total_relation_size(quote_ident(schemaname) || '.' || quote_ident(tablename)) AS total_sizeFROM pg_tables) AS TABLES where tablename = 'plop';schemaname | tablename | size_pretty | total_size_pretty------------+-----------+-------------+-------------------public | plop | 792 kB | 2160 kB(1 row)test=# reindex table plop;REINDEXtest=# SELECT schemaname, tablename,pg_size_pretty(SIZE) AS size_pretty,pg_size_pretty(total_size) AS total_size_prettyFROM (SELECT *, pg_relation_size(quote_ident(schemaname) || '.' || quote_ident(tablename)) AS SIZE,pg_total_relation_size(quote_ident(schemaname) || '.' || quote_ident(tablename)) AS total_sizeFROM pg_tables) AS TABLES where tablename = 'plop';schemaname | tablename | size_pretty | total_size_pretty------------+-----------+-------------+-------------------public | plop | 792 kB | 1304 kB(1 row)I don’t understand why after the update where I only update a non indexed column the indexes size is growing. Is it something someone can explain ?
Every tuple is now on a different location on the table (remember that update in PostgreSQL is more something like delete+insert). So even if the value of the column doesn't change, its tuple location changes, so the index needs to be updated to reflect that change.
--
Guillaume.
pgsql-general by date: