Обсуждение: Querying an index's btree version

Поиск
Список
Период
Сортировка

Querying an index's btree version

От
Darren Lafreniere
Дата:
Hello,

We've read that PG 12 has improved btree index support, and that the latest internal btree version was bumped from 3 to 4. Is it possible to query the btree version that a particular index is using? We'd like to automatically start a concurrent re-index if we detect any btree indexes are still on version 3.

Thank you,
Darren Lafreniere

Re: Querying an index's btree version

От
Peter Geoghegan
Дата:
On Wed, Mar 11, 2020 at 1:26 PM Darren Lafreniere
<dlafreniere@onezero.com> wrote:
> We've read that PG 12 has improved btree index support, and that the latest internal btree version was bumped from 3
to4. Is it possible to query the btree version that a particular index is using? We'd like to automatically start a
concurrentre-index if we detect any btree indexes are still on version 3. 

It's possible, but you have to install the superuser-only pageinspect
extension. Here is how you'd determine that an index called
'pg_aggregate_fnoid_index' is on version 4:

regression=# create extension pageinspect;
CREATE EXTENSION
regression=# select version from bt_metap('pg_aggregate_fnoid_index');
 version
---------
       4
(1 row)

--
Peter Geoghegan



Re: Querying an index's btree version

От
Darren Lafreniere
Дата:
Thank you for the info, Peter.

Separate but related follow-up question: when you restore a DB from a backup, does the restored index use the old format or the latest one?

Thank you,
Darren Lafreniere



On Wed, Mar 11, 2020 at 4:30 PM Peter Geoghegan <pg@bowt.ie> wrote:
On Wed, Mar 11, 2020 at 1:26 PM Darren Lafreniere
<dlafreniere@onezero.com> wrote:
> We've read that PG 12 has improved btree index support, and that the latest internal btree version was bumped from 3 to 4. Is it possible to query the btree version that a particular index is using? We'd like to automatically start a concurrent re-index if we detect any btree indexes are still on version 3.

It's possible, but you have to install the superuser-only pageinspect
extension. Here is how you'd determine that an index called
'pg_aggregate_fnoid_index' is on version 4:

regression=# create extension pageinspect;
CREATE EXTENSION
regression=# select version from bt_metap('pg_aggregate_fnoid_index');
 version
---------
       4
(1 row)

--
Peter Geoghegan


--
Darren Lafreniere
Senior Software Engineer | oneZero Financial Systems

site: www.onezero.com
email: dlafreniere@onezero.com


Re: Querying an index's btree version

От
Peter Geoghegan
Дата:
On Wed, Mar 11, 2020 at 2:13 PM Darren Lafreniere
<dlafreniere@onezero.com> wrote:
> when you restore a DB from a backup, does the restored index use the old format or the latest one?

If you use pg_restore, it uses the latest index format.

If you're using pg_upgrade, the version won't change unless and until
you REINDEX. This includes cases where you're running pg_upgrade
against a restored physical backup.

-- 
Peter Geoghegan



Re: Querying an index's btree version

От
Laurenz Albe
Дата:
On Wed, 2020-03-11 at 17:12 -0400, Darren Lafreniere wrote:
> Separate but related follow-up question: when you restore a DB from a backup, does the restored index use the old
formator the latest one?
 

If you restore a pg_dump, you will have the latest version.

If you restore a file system backup, you will have what you had before.

Yours,
Laurenz Albe
-- 
Cybertec | https://www.cybertec-postgresql.com