Re: [HACKERS] delta relations in AFTER triggers - Mailing list pgsql-hackers
From | Kevin Grittner |
---|---|
Subject | Re: [HACKERS] delta relations in AFTER triggers |
Date | |
Msg-id | CACjxUsO=squN2XbYBM6qLfS9co=bfGqQFxMfY+pjyAGKP_jpwQ@mail.gmail.com Whole thread Raw |
In response to | Re: [HACKERS] delta relations in AFTER triggers (Thomas Munro <thomas.munro@enterprisedb.com>) |
Responses |
Re: [HACKERS] delta relations in AFTER triggers
Re: [HACKERS] delta relations in AFTER triggers |
List | pgsql-hackers |
On Sun, Mar 12, 2017 at 4:08 PM, Thomas Munro <thomas.munro@enterprisedb.com> wrote: > I found a new way to break it: run the trigger function so > that the plan is cached by plpgsql, then ALTER TABLE incompatibly, > then run the trigger function again. See attached. The first part doesn't seem so bad. Using the transition table in a FOR EACH STATEMENT trigger you get: test=# update hoge set name = (name::text || name::text)::integer; ERROR: attribute 2 has wrong type DETAIL: Table has type integer, but query expects text. CONTEXT: SQL statement "SELECT (SELECT string_agg(id || '=' || name, ',') FROM d)" PL/pgSQL function hoge_upd_func() line 3 at RAISE ... while putting each row on its own line from a FOR EACH ROW trigger you get: test=# update hoge set name = (name::text || name::text)::integer; ERROR: type of parameter 15 (integer) does not match that when preparing the plan (text) CONTEXT: SQL statement "SELECT (SELECT string_agg(old.id || '=' || old.name, ','))" PL/pgSQL function hoge_upd_func() line 3 at RAISE Does anyone think the first message needs improvement? If so, to what? Obviously the next part is a problem. With the transition table we get a segfault: test=# -- now drop column 'name' test=# alter table hoge drop column name; ALTER TABLE test=# update hoge set id = id; server closed the connection unexpectedly This probably means the server terminated abnormally before or whileprocessing the request. While the row-oriented query manages to dodge it: test=# alter table hoge drop column name; ALTER TABLE test=# update hoge set id = id; ERROR: record "old" has no field "name" CONTEXT: SQL statement "SELECT (SELECT string_agg(old.id || '=' || old.name, ','))" PL/pgSQL function hoge_upd_func() line 3 at RAISE I expected that existing mechanisms would have forced re-planning of a trigger function if the table the function was attached to was altered. Either that was a bit "optimistic", or the old TupleDesc is used for the new plan. Will track down which it is, and fix it. >> Do you suppose we should have all PLs that are part of the base >> distro covered? > > I vote for doing that in Postgres 11. My pl/python patch[1] may be a > useful starting point, but I haven't submitted it in this CF and > nobody has shown up with pl/tcl or pl/perl versions. OK, but we'd better add something to the docs saying that only C and plpgsql triggers are supported in v10. >> What is necessary to indicate an additional SQL feature covered? > > I assume you're talking about information_schema.sql_features I had forgotten we had that in a table. I was thinking more of the docs: https://www.postgresql.org/docs/current/static/features.html I guess if we change one, we had better change the other. (Or are they generated off a common source?) > a couple of thoughts occurred to me when looking for > references to transition tables in an old draft standard I have. > These are both cases where properties of the subject table should > probably also affect access to the derived transition tables: > > * What privileges implications are there for transition tables? I'm > wondering about column and row level privileges; for example, if you > can't see a column in the subject table, I'm guessing you shouldn't be > allowed to see it in the transition table either, but I'm not sure. I'll see how that works in FOR EACH ROW triggers. We should match that, I think. Keep in mind that not just anyone can put a trigger on a table. > * In future we could consider teaching it about functional > dependencies as required by the spec; if you can SELECT id, name FROM > <subject table> GROUP BY id, I believe you should be able to SELECT > id, name FROM <transition table> GROUP BY id, but currently you can't. Interesting idea. I'll post a new patch once I figure out the dropped column on the cached function plan. -- Kevin Grittner
pgsql-hackers by date: