Skip to content

Commit 857b2e9

Browse files
committed
Add Parser::DBI::PostgreSQL support for proc / trigger
This adds support to the DBI parser for Postgres to read the user-defined stored procedures and triggers from the public namespace. It has been tested on only two versions of postgres so far...
1 parent 18be6d1 commit 857b2e9

File tree

2 files changed

+160
-0
lines changed

2 files changed

+160
-0
lines changed

lib/SQL/Translator/Parser/DBI/PostgreSQL.pm

Lines changed: 126 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -134,6 +134,61 @@ ORDER BY 1;
134134
/
135135
) or die "Can't prepare: $@";
136136

137+
my $trigger_select = $dbh->prepare(<<SQL) or die "Can't prepare trigger query: $@";
138+
SELECT
139+
t.tgname AS trigger_name,
140+
c.relname AS table_name,
141+
p.proname AS function_name,
142+
pg_get_triggerdef(t.oid) AS trigger_definition,
143+
CASE t.tgtype & 66
144+
WHEN 2 THEN 'before'
145+
WHEN 64 THEN 'instead of'
146+
ELSE 'after'
147+
END AS timing,
148+
(CASE WHEN (t.tgtype & 4) = 0 THEN '' ELSE 'insert,' END)
149+
|| (CASE WHEN (t.tgtype & 8) = 0 THEN '' ELSE 'delete,' END)
150+
|| (CASE WHEN (t.tgtype & 16) = 0 THEN '' ELSE 'update,' END)
151+
|| (CASE WHEN (t.tgtype & 32) = 0 THEN '' ELSE 'truncate,' END)
152+
AS events,
153+
CASE t.tgtype & 1
154+
WHEN 1 THEN 'row'
155+
ELSE 'statement'
156+
END AS scope,
157+
t.tgattr AS update_columns,
158+
pg_get_expr(t.tgqual, t.tgrelid) AS condition
159+
FROM pg_trigger t
160+
JOIN pg_class c ON t.tgrelid = c.oid
161+
JOIN pg_proc p ON t.tgfoid = p.oid
162+
JOIN pg_namespace n ON c.relnamespace = n.oid
163+
WHERE NOT t.tgisinternal
164+
AND n.nspname = 'public'
165+
ORDER BY c.relname, t.tgname;
166+
SQL
167+
168+
my $procedure_select = $dbh->prepare(<<SQL) or die "Can't prepare procedure query: $@";
169+
SELECT
170+
p.proname AS procedure_name,
171+
pg_get_functiondef(p.oid) AS procedure_definition,
172+
pg_catalog.pg_get_function_arguments(p.oid) AS parameters,
173+
pg_catalog.pg_get_function_result(p.oid) AS return_type,
174+
r.rolname AS owner,
175+
d.description AS comments,
176+
CASE p.prokind
177+
WHEN 'f' THEN 'function'
178+
WHEN 'p' THEN 'procedure'
179+
WHEN 'a' THEN 'aggregate'
180+
WHEN 'w' THEN 'window'
181+
ELSE 'unknown'
182+
END AS procedure_type
183+
FROM pg_proc p
184+
JOIN pg_namespace n ON p.pronamespace = n.oid
185+
LEFT JOIN pg_roles r ON p.proowner = r.oid
186+
LEFT JOIN pg_description d ON p.oid = d.objoid AND d.objsubid = 0
187+
WHERE n.nspname = 'public'
188+
AND p.prokind IN ('f', 'p') -- functions and procedures only
189+
ORDER BY p.proname;
190+
SQL
191+
137192
my %enum_types;
138193
if ($deconstruct_enum_types) {
139194
my $enum_select = $dbh->prepare('SELECT enumtypid, enumlabel FROM pg_enum ORDER BY oid, enumsortorder')
@@ -258,6 +313,77 @@ ORDER BY 1;
258313
}
259314
}
260315

316+
# Process triggers
317+
$trigger_select->execute() or die "Can't execute trigger query: $@";
318+
while (my $trigger_hash = $trigger_select->fetchrow_hashref) {
319+
my $trigger_name = $trigger_hash->{trigger_name};
320+
my $table_name = $trigger_hash->{table_name};
321+
my $timing = $trigger_hash->{timing};
322+
my $events = $trigger_hash->{events};
323+
my $scope = $trigger_hash->{scope};
324+
my $trigger_def = $trigger_hash->{trigger_definition};
325+
326+
# Get the table object
327+
my $table = $schema->get_table($table_name);
328+
next unless $table;
329+
330+
# Parse events into an array
331+
my @database_events = split /,/, $events;
332+
333+
# Handle update column specifications
334+
my @fields = ();
335+
if ($events =~ /update/ && $trigger_hash->{update_columns}) {
336+
# Parse update column list if present
337+
my $update_cols = $trigger_hash->{update_columns};
338+
if ($update_cols && $update_cols ne '') {
339+
@fields = split /\s+/, $update_cols;
340+
}
341+
}
342+
343+
# Extract just the EXECUTE FUNCTION/PROCEDURE part from the trigger definition
344+
my $action = '';
345+
if ($trigger_def =~ /\bEXECUTE\s+(FUNCTION|PROCEDURE)\s+(.+)$/i) {
346+
$action = "EXECUTE $1 $2";
347+
}
348+
# Fallback: capture everything from 'EXECUTE' onward
349+
elsif ($trigger_def =~ /\b(EXECUTE\b.*)$/i) {
350+
$action = $1;
351+
}
352+
else {
353+
die "Could not parse trigger action from '$trigger_def'";
354+
}
355+
356+
# Add trigger to schema
357+
my $trigger = $schema->add_trigger(
358+
name => $trigger_name,
359+
perform_action_when => $timing,
360+
database_events => \@database_events,
361+
on_table => $table_name,
362+
action => $action,
363+
scope => $scope,
364+
(@fields ? (fields => \@fields) : ()),
365+
) || die $schema->error;
366+
}
367+
368+
# Process stored procedures/functions
369+
$procedure_select->execute() or die "Can't execute procedure query: $@";
370+
while (my $proc_hash = $procedure_select->fetchrow_hashref) {
371+
my $proc_name = $proc_hash->{procedure_name};
372+
my $proc_sql = $proc_hash->{procedure_definition};
373+
my $parameters = $proc_hash->{parameters} || '';
374+
my $owner = $proc_hash->{owner};
375+
my $comments = $proc_hash->{comments};
376+
377+
# Add procedure to schema
378+
my $procedure = $schema->add_procedure(
379+
name => $proc_name,
380+
sql => $proc_sql,
381+
parameters => $parameters,
382+
($owner ? (owner => $owner) : ()),
383+
($comments ? (comments => $comments) : ()),
384+
) || die $schema->error;
385+
}
386+
261387
return 1;
262388
}
263389

t/66-postgres-dbi-parser.t

Lines changed: 34 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -69,6 +69,23 @@ my $sql = q[
6969
-- When the table t_test1 is created, f_text2 get id 5 but
7070
-- after this drop, there is only 4 columns.
7171
alter table sqlt_test1 drop column f_to_drop;
72+
73+
CREATE FUNCTION test_change_notify()
74+
RETURNS TRIGGER AS $$
75+
BEGIN
76+
IF old.f_varchar IS DISTINCT FROM new.f_varchar
77+
THEN
78+
PERFORM pg_notify('test_activity', new.f_serial::text);
79+
END IF;
80+
RETURN NEW;
81+
END;
82+
$$ LANGUAGE plpgsql;
83+
COMMENT ON function test_change_notify IS 'Testing Comment';
84+
85+
CREATE TRIGGER sqlt_test1_change_notify
86+
BEFORE UPDATE ON sqlt_test1
87+
FOR EACH ROW EXECUTE FUNCTION test_change_notify();
88+
7289
];
7390

7491
$| = 1;
@@ -207,6 +224,23 @@ is(scalar @t2_constraints, 1, "One constraint on table");
207224
my $t2_c1 = shift @t2_constraints;
208225
is($t2_c1->type, FOREIGN_KEY, "Constraint is a FK");
209226

227+
my @procs = $schema->get_procedures;
228+
is(scalar @procs, 1, 'one user-defined procedure');
229+
is($procs[0]->name, 'test_change_notify', 'proc[0]->name');
230+
like($procs[0]->sql, # Exact SQL syntax varies per server version
231+
qr/create or replace function.*?returns trigger.*IF old.f_varchar IS DISTINCT FROM new.f_varchar/si,
232+
'proc[0]->sql');
233+
is($procs[0]->comments, 'Testing Comment', 'proc[0]->comments');
234+
235+
my @triggers = $schema->get_triggers;
236+
is(scalar @triggers, 1, 'one trigger' );
237+
is($triggers[0]->name, 'sqlt_test1_change_notify', 'trigger[0]->name');
238+
is($triggers[0]->perform_action_when, 'before', 'trigger[0]->perform_action_when');
239+
is_deeply([ $triggers[0]->database_events ], ['update'], 'trigger[0]->database_events');
240+
is($triggers[0]->on_table, 'sqlt_test1', 'trigger[0]->on_table');
241+
is($triggers[0]->scope, 'row', 'trigger[0]->scope');
242+
like($triggers[0]->action, qr/test_change_notify/i, 'trigger[0]->action');
243+
210244
$dbh->rollback;
211245
$dbh->disconnect;
212246

0 commit comments

Comments
 (0)