Search Postgresql Archives

Re: Refresh Publication takes hours and doesn´t finish

[Date Prev][Date Next][Thread Prev][Thread Next][Date Index][Thread Index]

 




Em seg, 20 de mai de 2019 às 17:18, PegoraroF10 <marcos@xxxxxxxxxx> escreveu:
>
> I tried sometime ago ... but with no responses, I ask you again.
> pg_publication_tables is a view that is used to refresh publication, but as
> we have 15.000 tables, it takes hours and doesn´t complete. If I change that
> view I can have an immediate result. The question is: Can I change that view
> ? There is some trouble changing those system views ?
>

You really need a publication with a lot of relations??? If you can split it in several publications your life should be easy.
 
>
> Original View is ...
> create view pg_catalog.pg_publication_tables as
> SELECT p.pubname, n.nspname AS schemaname, c.relname AS tablename FROM
> pg_publication p,
> (pg_class c JOIN pg_namespace n ON ((n.oid = c.relnamespace)))
> WHERE (c.oid IN (SELECT pg_get_publication_tables.relid FROM
> pg_get_publication_tables((p.pubname)::text)
> pg_get_publication_tables(relid)));
> This way it takes 45 minutes to respond.
>

I really don't know why we did it... because pg_get_publication_tables doesn't have any special behavior different than get relations assigned to publications.

 
>
> I changed it to ...
> create or replace pg_catalog.view pg_publication_tables as SELECT p.pubname,
> n.nspname AS schemaname, c.relname AS tablename from pg_publication p inner
> join pg_get_publication_tables(p.pubname) pt on true inner join pg_class c
> on pt.relid = c.oid inner join pg_namespace n ON (n.oid = c.relnamespace);
> This one takes just one or two seconds.
>

Even better, you can go direct by system catalogs:

 SELECT p.pubname,
    n.nspname AS schemaname,
    c.relname AS tablename
   FROM pg_publication p
     JOIN pg_publication_rel pr ON pr.prpubid = p.oid
     JOIN pg_class c ON c.oid = pr.prrelid
     JOIN pg_namespace n ON n.oid = c.relnamespace;

To change it, before you'll need to set "allow_system_table_mods=on" and restart PostgreSQL.

Regards,

--
   Fabrízio de Royes Mello         Timbira - http://www.timbira.com.br/
   PostgreSQL: Consultoria, Desenvolvimento, Suporte 24x7 e Treinamento

[Date Prev][Date Next][Thread Prev][Thread Next][Date Index][Thread Index]
[Index of Archives]     [Postgresql Jobs]     [Postgresql Admin]     [Postgresql Performance]     [Linux Clusters]     [PHP Home]     [PHP on Windows]     [Kernel Newbies]     [PHP Classes]     [PHP Books]     [PHP Databases]     [Postgresql & PHP]     [Yosemite]

  Powered by Linux