RE: BUG #16481: Stored Procedure Triggered by Logical Replication isUnable to use Notification Events

Поиск
Список
Период
Сортировка
От Vianello Fabio
Тема RE: BUG #16481: Stored Procedure Triggered by Logical Replication isUnable to use Notification Events
Дата
Msg-id AM6PR06MB6168A03388FAA53050611E3593810@AM6PR06MB6168.eurprd06.prod.outlook.com
обсуждение исходный текст
Ответ на RE: BUG #16481: Stored Procedure Triggered by Logical Replication isUnable to use Notification Events  (Vianello Fabio <fabio.vianello@salvagninigroup.com>)
Список pgsql-bugs
Just to help those who find themselves in the same situation, there is a simple application-level workaround which
consistsin listening to the notifications in the replica when they are issued by the master and vice versa.
 

We are programming in .NET and we use a code like this:

Code in the replica side:

           var csb = new NpgsqlConnectionStringBuilder
            {
                Host = "master",
                Database = "MasterDB",
                Port = 5432,
                Username = "postgres",
                Password = "XXXXXXX",

            };
            var connection = new NpgsqlConnection(csb.ConnectionString);
            connection.Open();
            using (var command = new NpgsqlCommand("listen \"Table\"", connection))
            {
                command.ExecuteNonQuery();
            }
            connection.Notification += PostgresNotification;

So you can listen from the replica every changed raised by a trigger on the master from the replica side on the table
"Table".

CREATE TRIGGER master_trigger
    AFTER INSERT OR DELETE OR UPDATE
    ON public."TABLE"
    FOR EACH ROW
    EXECUTE PROCEDURE public.master_notice();

ALTER TABLE public."Tabele"
    ENABLE ALWAYS TRIGGER master_trigger;

CREATE FUNCTION public. master_notice ()
    RETURNS trigger
    LANGUAGE 'plpgsql'
    COST 100
    VOLATILE NOT LEAKPROOF
AS $BODY$
  BEGIN
  PERFORM  pg_notify('Table', Cast(NEW."ID"  as text));
  RETURN NEW;
  END;
  $BODY$;

ALTER FUNCTION public.incupdate1_notice()
    OWNER TO postgres;

I hope that help someone, because the bug last from "years". I tried in version 10 11 and 12, so it is present since
2017-10-05and I can't see any solution on 13 beta.
 

Best Regards.
Fabio.


-----Original Message-----
From: Vianello Fabio
Sent: lunedì 8 giugno 2020 11:14
To: Kyotaro Horiguchi <horikyota.ntt@gmail.com>
Cc: pgsql-bugs@lists.postgresql.org; pgsql-hackers@lists.postgresql.org
Subject: RE: BUG #16481: Stored Procedure Triggered by Logical Replication is Unable to use Notification Events

Hi Kyotaro Horiguchi, thanks for you helps.
We have a question about the bug. Why there isn't any solution in the HEAD?

This bug last since 10.4 version and I can't understand why it is not fixed in the HEAD  yet.

BR.
Fabio Vianello.


-----Original Message-----
From: Kyotaro Horiguchi [mailto:horikyota.ntt@gmail.com]
Sent: lunedì 8 giugno 2020 10:28
To: Vianello Fabio <fabio.vianello@salvagninigroup.com>; pgsql-bugs@lists.postgresql.org;
pgsql-hackers@lists.postgresql.org
Subject: Re: BUG #16481: Stored Procedure Triggered by Logical Replication is Unable to use Notification Events

Hello.

It seems to me a bug.

At Fri, 05 Jun 2020 11:05:14 +0000, PG Bug reporting form <noreply@postgresql.org> wrote in
> The following bug has been logged on the website:
>
> Bug reference:      16481
> Logged by:          Fabio Vianello
> Email address:      fabio.vianello@salvagninigroup.com
> PostgreSQL version: 12.3
> Operating system:   Windows 10
> Description:
>
> About the bug BUG #15293, on PostgreSQL version 10.4 and 11.2 as
> describe below, we found the same issue on the PostgreSQL version 12.3.

The HEAD behaves the same way.

> Is it a feature?
> Becasue in the documentation we didn't found any constraint that says
> that we can not use NOTIFY/LISTEN on logical replication tables.
>
> "When using logical replication a stored procedure executed on the
> replica is unable to use NOTIFY to send messages to other listeners.
> The stored procedure does execute as expected but the pg_notify()
> doesn't appear to have any effect. If an insert is run on the replica
> side the trigger executes the stored procedure as expected and the
> NOTIFY correctly notifies listeners.

The message is actually queued, but logical replication worker doesn't signal that to listener backends. If any
ordinarysession sent a message to the same listener after that, both messages would be shown at once.
 

That can be fixed by calling ProcessCompletedNotifies() in apply_handle_commit. The function has a code to write out
notificationsto connected clients but it doesn't nothing on logical replication workers.
 

regards.

--
Kyotaro Horiguchi
NTT Open Source Software Center
SALVAGNINI ITALIA S.p.A.
Via Guido Salvagnini, 51 - IT - 36040 Sarego (VI)
T. +39 0444 725111 | F. +39 0444 43 6404
Società a socio unico - Attività direz. e coord.: Salvagnini Holding S.p.A.
Clicca qui<https://www.salvagninigroup.com/company-information> per le informazioni societarie
salvagninigroup.com<https://www.salvagninigroup.com> | salvagnini.it<http://www.salvagnini.it>


Le informazioni trasmesse sono destinate esclusivamente alla persona o alla società in indirizzo e sono da intendersi
confidenzialie riservate. Ogni trasmissione, inoltro, diffusione o altro uso di queste informazioni a persone o società
differentidal destinatario è proibita. Se avete ricevuto questa comunicazione per errore, per favore contattate il
mittentee cancellate le informazioni da ogni computer. Questa casella di posta elettronica è riservata esclusivamente
all’invioed alla ricezione di messaggi aziendali inerenti all’attività lavorativa e non è previsto né autorizzato
l’utilizzoper fini personali. Pertanto i messaggi in uscita e quelli di risposta in entrata verranno trattati quali
messaggiaziendali e soggetti alla ordinaria gestione disposta con proprio disciplinare dall’azienda e, di conseguenza,
eventualmenteanche alla lettura da parte di persone diverse dall’intestatario della casella.
 

Any information herein transmitted only concerns the person or the company named in the address and is deemed to be
confidential.It is strictly forbidden to transmit, post, forward or otherwise use said information to anyone other than
therecipient. If you have received this message by mistake, please contact the sender and delete any relevant
informationfrom your computer. This mailbox is only meant for sending and receiving messages pertaining business
mattersand any other use for personal purposes is forbidden and unauthorized. Therefore, any email sent and received
willbe handled as ordinary business messages and subject to the company's own rules, and may thus be read also by
peopleother than the user named in the mailbox address.
 

В списке pgsql-bugs по дате отправления:

Предыдущее
От: Kyotaro Horiguchi
Дата:
Сообщение: Re: BUG #16476: pgp_sym_encrypt_bytea with compress-level=6 :Wrong key or corrupt data
Следующее
От: Kyle Kingsbury
Дата:
Сообщение: Re: Potential G2-item cycles under serializable isolation