Re: Does PostgreSQL check database integrity at startup?

From: Stephen Frost <sfrost(at)snowman(dot)net>
To: Melvin Davidson <melvin6925(at)gmail(dot)com>
Cc: Alban Hertroys <haramrae(at)gmail(dot)com>, Jan Wieck <jan(at)wi3ck(dot)info>, Edson Carlos Ericksson Richter <richter(at)simkorp(dot)com(dot)br>, pgsql-general(at)lists(dot)postgresql(dot)org
Subject: Re: Does PostgreSQL check database integrity at startup?
Date: 2017-12-30 22:06:52
Message-ID: 20171230220652.GK2416@tamriel.snowman.net
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general

Greetings,

* Melvin Davidson (melvin6925(at)gmail(dot)com) wrote:
> My query works as designed and has done so
> for two years. It shows the filenames for schemas and tables in the
> database.

I'm glad to hear that it works in your specific use-case.
Unfortunately, it doesn't work in the general case and therefore isn't a
good example. A proper query to return the filename for each user table
in the current database is:

SELECT
quote_ident(nsp.nspname) || '.' || quote_ident(c.relname),
s.setting || '/base/' || db.oid || '/' || c.relfilenode
FROM
pg_settings s
JOIN pg_database db on (s.name = 'data_directory')
JOIN pg_class c on (datname = current_database())
JOIN pg_namespace nsp on (c.relnamespace = nsp.oid)
WHERE
relfilenode <> 0
AND nsp.nspname !~ '^pg_'
AND nsp.nspname <> 'information_schema';

Note that, as discussed earlier in this thread, this doesn't actually
answer what Edson was asking for. Here's the query that would answer
his original request:

SELECT
quote_ident(nsp.nspname) || '.' || quote_ident(c.relname),
s.setting || '/base/' || db.oid || '/' || c.relfilenode,
(pg_stat_file(s.setting || '/base/' || db.oid || '/' || c.relfilenode)).size as size
FROM
pg_settings s
JOIN pg_database db on (s.name = 'data_directory')
JOIN pg_class c on (datname = current_database())
JOIN pg_namespace nsp on (c.relnamespace = nsp.oid)
WHERE
relfilenode <> 0
AND nsp.nspname !~ '^pg_'
AND nsp.nspname <> 'information_schema';

Technically speaking, while these queries are correct for PG10, in prior
versions of PostgreSQL it's possible to have user schemas that begin
with 'pg_' and therefore the filtering in the WHERE clause would have to
be more specific.

Note that both of these need to be run as a superuser in older versions
of PG. In PostgreSQL 10, a user could be GRANT'd 'pg_read_all_settings'
and be able to run the first query. We don't currently support being
able to GRANT a non-superuser the ability to run pg_stat_file(), but
that will likely be coming in PG 11.

Thanks!

Stephen

In response to

Responses

Browse pgsql-general by date

  From Date Subject
Next Message Andreas Joseph Krogh 2017-12-30 23:43:40 Sv: Re: Does PostgreSQL check database integrity at startup?
Previous Message GPT 2017-12-30 21:36:07 Re: Adding an extra boolean column to "information_schema.columns" or "pg_attribute"