Add trigger support to PostgreSQL producer and parser (including trigger scope)
[dbsrgits/SQL-Translator.git] / lib / SQL / Translator / Parser / PostgreSQL.pm
CommitLineData
84012a55 1package SQL::Translator::Parser::PostgreSQL;
4422e22a 2
4422e22a 3=head1 NAME
4
84012a55 5SQL::Translator::Parser::PostgreSQL - parser for PostgreSQL
4422e22a 6
7=head1 SYNOPSIS
8
9 use SQL::Translator;
84012a55 10 use SQL::Translator::Parser::PostgreSQL;
4422e22a 11
12 my $translator = SQL::Translator->new;
84012a55 13 $translator->parser("SQL::Translator::Parser::PostgreSQL");
4422e22a 14
15=head1 DESCRIPTION
16
ea93df61 17The grammar was started from the MySQL parsers. Here is the description
0efb6e1b 18from PostgreSQL:
19
20Table:
629b76f9 21(http://www.postgresql.org/docs/view.php?version=7.3&idoc=1&file=sql-createtable.html)
22
23 CREATE [ [ LOCAL ] { TEMPORARY | TEMP } ] TABLE table_name (
ea93df61 24 { column_name data_type [ DEFAULT default_expr ]
629b76f9 25 [ column_constraint [, ... ] ]
26 | table_constraint } [, ... ]
27 )
28 [ INHERITS ( parent_table [, ... ] ) ]
29 [ WITH OIDS | WITHOUT OIDS ]
ea93df61 30
629b76f9 31 where column_constraint is:
ea93df61 32
629b76f9 33 [ CONSTRAINT constraint_name ]
34 { NOT NULL | NULL | UNIQUE | PRIMARY KEY |
35 CHECK (expression) |
36 REFERENCES reftable [ ( refcolumn ) ] [ MATCH FULL | MATCH PARTIAL ]
37 [ ON DELETE action ] [ ON UPDATE action ] }
ea93df61 38 [ DEFERRABLE | NOT DEFERRABLE ]
629b76f9 39 [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
ea93df61 40
629b76f9 41 and table_constraint is:
ea93df61 42
629b76f9 43 [ CONSTRAINT constraint_name ]
44 { UNIQUE ( column_name [, ... ] ) |
45 PRIMARY KEY ( column_name [, ... ] ) |
46 CHECK ( expression ) |
ea93df61 47 FOREIGN KEY ( column_name [, ... ] )
629b76f9 48 REFERENCES reftable [ ( refcolumn [, ... ] ) ]
ea93df61 49 [ MATCH FULL | MATCH PARTIAL ]
629b76f9 50 [ ON DELETE action ] [ ON UPDATE action ] }
ea93df61 51 [ DEFERRABLE | NOT DEFERRABLE ]
629b76f9 52 [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
0efb6e1b 53
54Index:
629b76f9 55(http://www.postgresql.org/docs/view.php?version=7.3&idoc=1&file=sql-createindex.html)
0efb6e1b 56
629b76f9 57 CREATE [ UNIQUE ] INDEX index_name ON table
58 [ USING acc_method ] ( column [ ops_name ] [, ...] )
59 [ WHERE predicate ]
60 CREATE [ UNIQUE ] INDEX index_name ON table
61 [ USING acc_method ] ( func_name( column [, ... ]) [ ops_name ] )
62 [ WHERE predicate ]
4422e22a 63
0012a163 64Alter table:
65
66 ALTER TABLE [ ONLY ] table [ * ]
67 ADD [ COLUMN ] column type [ column_constraint [ ... ] ]
68 ALTER TABLE [ ONLY ] table [ * ]
69 ALTER [ COLUMN ] column { SET DEFAULT value | DROP DEFAULT }
70 ALTER TABLE [ ONLY ] table [ * ]
71 ALTER [ COLUMN ] column SET STATISTICS integer
72 ALTER TABLE [ ONLY ] table [ * ]
73 RENAME [ COLUMN ] column TO newcolumn
74 ALTER TABLE table
75 RENAME TO new_table
76 ALTER TABLE table
77 ADD table_constraint_definition
ea93df61 78 ALTER TABLE [ ONLY ] table
0012a163 79 DROP CONSTRAINT constraint { RESTRICT | CASCADE }
80 ALTER TABLE table
ea93df61 81 OWNER TO new_owner
0012a163 82
3022f45b 83View table:
84
85 CREATE [ OR REPLACE ] VIEW view [ ( column name list ) ] AS SELECT query
86
4422e22a 87=cut
88
89use strict;
f27f9229 90use warnings;
0c04c5a2 91our ( $DEBUG, $GRAMMAR, @EXPORT_OK );
92our $VERSION = '1.59';
4422e22a 93$DEBUG = 0 unless defined $DEBUG;
94
95use Data::Dumper;
96use Parse::RecDescent;
97use Exporter;
98use base qw(Exporter);
99
100@EXPORT_OK = qw(parse);
101
102# Enable warnings within the Parse::RecDescent module.
103$::RD_ERRORS = 1; # Make sure the parser dies when it encounters an error
104$::RD_WARN = 1; # Enable warnings. This will warn on unused rules &c.
105$::RD_HINT = 1; # Give out hints to help fix problems.
106
4422e22a 107$GRAMMAR = q!
108
c96cd4a8 109{ my ( %tables, @views, @triggers, $table_order, $field_order, @table_comments) }
4422e22a 110
629b76f9 111#
112# The "eofile" rule makes the parser fail if any "statement" rule
ea93df61 113# fails. Otherwise, the first successful match by a "statement"
629b76f9 114# won't cause the failure needed to know that the parse, as a whole,
115# failed. -ky
116#
c96cd4a8 117startrule : statement(s) eofile {
118 {
119 tables => \%tables,
120 views => \@views,
121 triggers => \@triggers,
122 }
123}
4422e22a 124
0efb6e1b 125eofile : /^\Z/
ea93df61 126
0efb6e1b 127
128statement : create
ac397a49 129 | comment_on_table
130 | comment_on_column
e4a9818d 131 | comment_on_other
0efb6e1b 132 | comment
0012a163 133 | alter
0efb6e1b 134 | grant
135 | revoke
4422e22a 136 | drop
4d2da1f7 137 | insert
0efb6e1b 138 | connect
4d2da1f7 139 | update
0012a163 140 | set
34338cb2 141 | select
142 | copy
143 | readin_symbol
1f5b2625 144 | commit
4422e22a 145 | <error>
146
1f5b2625 147commit : /commit/i ';'
148
0efb6e1b 149connect : /^\s*\\\connect.*\n/
150
f04713db 151set : /set/i /[^;]*/ ';'
0012a163 152
330e4686 153revoke : /revoke/i WORD(s /,/) /on/i TABLE(?) table_id /from/i name_with_opt_quotes(s /,/) ';'
0efb6e1b 154 {
330e4686 155 my $table_info = $item{'table_id'};
a20abbda 156 my $schema_name = $table_info->{'schema_name'};
157 my $table_name = $table_info->{'table_name'};
0efb6e1b 158 push @{ $tables{ $table_name }{'permissions'} }, {
159 type => 'revoke',
160 actions => $item[2],
91c75eab 161 users => $item[7],
0efb6e1b 162 }
163 }
164
34338cb2 165revoke : /revoke/i WORD(s /,/) /on/i SCHEMA(?) schema_name /from/i name_with_opt_quotes(s /,/) ';'
166 { 1 }
167
330e4686 168grant : /grant/i WORD(s /,/) /on/i TABLE(?) table_id /to/i name_with_opt_quotes(s /,/) ';'
0efb6e1b 169 {
330e4686 170 my $table_info = $item{'table_id'};
a20abbda 171 my $schema_name = $table_info->{'schema_name'};
172 my $table_name = $table_info->{'table_name'};
0efb6e1b 173 push @{ $tables{ $table_name }{'permissions'} }, {
174 type => 'grant',
175 actions => $item[2],
91c75eab 176 users => $item[7],
0efb6e1b 177 }
178 }
179
34338cb2 180grant : /grant/i WORD(s /,/) /on/i SCHEMA(?) schema_name /to/i name_with_opt_quotes(s /,/) ';'
181 { 1 }
182
0efb6e1b 183drop : /drop/i /[^;]*/ ';'
4422e22a 184
9bf756df 185string :
ea93df61 186 /'(\\.|''|[^\\\'])*'/
4d2da1f7 187
9bf756df 188nonstring : /[^;\'"]+/
189
9644fab3 190statement_body : string | nonstring
9bf756df 191
9644fab3 192insert : /insert/i statement_body(s?) ';'
9bf756df 193
9644fab3 194update : /update/i statement_body(s?) ';'
4d2da1f7 195
0012a163 196#
197# Create table.
198#
330e4686 199create : CREATE temporary(?) TABLE table_id '(' create_definition(s? /,/) ')' table_option(s?) ';'
0efb6e1b 200 {
330e4686 201 my $table_info = $item{'table_id'};
a20abbda 202 my $schema_name = $table_info->{'schema_name'};
203 my $table_name = $table_info->{'table_name'};
204 $tables{ $table_name }{'order'} = ++$table_order;
205 $tables{ $table_name }{'schema_name'} = $schema_name;
206 $tables{ $table_name }{'table_name'} = $table_name;
0efb6e1b 207
330e4686 208 $tables{ $table_name }{'temporary'} = $item[2][0];
3e98f7d9 209
ac397a49 210 if ( @table_comments ) {
211 $tables{ $table_name }{'comments'} = [ @table_comments ];
212 @table_comments = ();
213 }
214
0efb6e1b 215 my @constraints;
3e98f7d9 216 for my $definition ( @{ $item[6] } ) {
b3384294 217 if ( $definition->{'supertype'} eq 'field' ) {
0efb6e1b 218 my $field_name = $definition->{'name'};
ea93df61 219 $tables{ $table_name }{'fields'}{ $field_name } =
00ef67ea 220 { %$definition, order => $field_order++ };
ea93df61 221
0138f7bb 222 for my $constraint ( @{ $definition->{'constraints'} || [] } ) {
223 $constraint->{'fields'} = [ $field_name ];
7d5bcab8 224 push @{ $tables{ $table_name }{'constraints'} },
0138f7bb 225 $constraint;
0efb6e1b 226 }
227 }
b3384294 228 elsif ( $definition->{'supertype'} eq 'constraint' ) {
229 push @{ $tables{ $table_name }{'constraints'} }, $definition;
0efb6e1b 230 }
b3384294 231 elsif ( $definition->{'supertype'} eq 'index' ) {
0efb6e1b 232 push @{ $tables{ $table_name }{'indices'} }, $definition;
233 }
234 }
235
3e98f7d9 236 for my $option ( @{ $item[8] } ) {
ea93df61 237 $tables{ $table_name }{'table_options(s?)'}{ $option->{'type'} } =
0efb6e1b 238 $option;
239 }
240
241 1;
242 }
243
330e4686 244create : CREATE unique(?) /(index|key)/i index_name /on/i table_id using_method(?) '(' field_name(s /,/) ')' where_predicate(?) ';'
4422e22a 245 {
330e4686 246 my $table_info = $item{'table_id'};
a20abbda 247 my $schema_name = $table_info->{'schema_name'};
248 my $table_name = $table_info->{'table_name'};
249 push @{ $tables{ $table_name }{'indices'} },
4422e22a 250 {
b3384294 251 name => $item{'index_name'},
252 supertype => $item{'unique'}[0] ? 'constraint' : 'index',
253 type => $item{'unique'}[0] ? 'unique' : 'normal',
254 fields => $item[9],
255 method => $item{'using_method'}[0],
4422e22a 256 }
257 ;
258 }
259
330e4686 260create : CREATE or_replace(?) temporary(?) VIEW view_id view_fields(?) /AS/i view_target ';'
261 {
262 push @views, {
263 schema_name => $item{view_id}{schema_name},
264 view_name => $item{view_id}{view_name},
265 sql => $item{view_target},
266 fields => $item[6],
267 is_temporary => $item[3][0],
268 }
269 }
270
c96cd4a8 271trigger_name : name_with_opt_quotes
272
273trigger_scope : /FOR/i /EACH/i /(ROW|STATEMENT)/i { $return = lc $1 }
274
275before_or_after : /(before|after)/i { $return = lc $1 }
276
277trigger_action : /.+/
278
279database_event : /insert|update|delete/i
280database_events : database_event(s /OR/)
281
282create : CREATE /TRIGGER/i trigger_name before_or_after database_events /ON/i table_id trigger_scope(?) trigger_action
283 {
284 # Hack to pass roundtrip tests which have trigger statements terminated by double semicolon
285 # and expect the returned data to have the same
286 my $action = $item{trigger_action};
287 $action =~ s/;$//;
288
289 push @triggers, {
290 name => $item{trigger_name},
291 perform_action_when => $item{before_or_after},
292 database_events => $item{database_events},
293 on_table => $item{table_id}{table_name},
294 scope => $item{'trigger_scope(?)'}[0],
295 action => $action,
296 }
297 }
298
0012a163 299#
211e2e90 300# Create anything else (e.g., domain, etc.)
0012a163 301#
211e2e90 302create : CREATE WORD /[^;]+/ ';'
ac397a49 303 { @table_comments = (); }
0012a163 304
0efb6e1b 305using_method : /using/i WORD { $item[2] }
306
307where_predicate : /where/i /[^;]+/
308
309create_definition : field
0efb6e1b 310 | table_constraint
4422e22a 311 | <error>
312
ea93df61 313comment : /^\s*(?:#|-{2})(.*)\n/
314 {
a82fa2cb 315 my $comment = $item[1];
316 $comment =~ s/^\s*(#|-*)\s*//;
317 $comment =~ s/\s*$//;
ac397a49 318 $return = $comment;
319 push @table_comments, $comment;
320 }
321
330e4686 322comment_on_table : /comment/i /on/i /table/i table_id /is/i comment_phrase ';'
ac397a49 323 {
330e4686 324 my $table_info = $item{'table_id'};
a20abbda 325 my $schema_name = $table_info->{'schema_name'};
326 my $table_name = $table_info->{'table_name'};
327 push @{ $tables{ $table_name }{'comments'} }, $item{'comment_phrase'};
ac397a49 328 }
329
330comment_on_column : /comment/i /on/i /column/i column_name /is/i comment_phrase ';'
331 {
332 my $table_name = $item[4]->{'table'};
333 my $field_name = $item[4]->{'field'};
e1fa2c52 334 if ($tables{ $table_name }{'fields'}{ $field_name } ) {
ea93df61 335 push @{ $tables{ $table_name }{'fields'}{ $field_name }{'comments'} },
e1fa2c52 336 $item{'comment_phrase'};
337 }
338 else {
339 die "No such column as $table_name.$field_name";
340 }
ac397a49 341 }
342
e4a9818d 343comment_on_other : /comment/i /on/i /\w+/ /\w+/ /is/i comment_phrase ';'
344 {
345 push(@table_comments, $item{'comment_phrase'});
346 }
347
348# [added by cjm 20041019]
349# [TODO: other comment-on types]
350# for now we just have a general mechanism for handling other
351# kinds of comments than table/column; I'm not sure of the best
352# way to incorporate these into the datamodel
353#
354# this is the exhaustive list of types of comment:
355#COMMENT ON DATABASE my_database IS 'Development Database';
356#COMMENT ON INDEX my_index IS 'Enforces uniqueness on employee id';
357#COMMENT ON RULE my_rule IS 'Logs UPDATES of employee records';
358#COMMENT ON SEQUENCE my_sequence IS 'Used to generate primary keys';
359#COMMENT ON TABLE my_table IS 'Employee Information';
360#COMMENT ON TYPE my_type IS 'Complex Number support';
361#COMMENT ON VIEW my_view IS 'View of departmental costs';
362#COMMENT ON COLUMN my_table.my_field IS 'Employee ID number';
363#COMMENT ON TRIGGER my_trigger ON my_table IS 'Used for R.I.';
364#
365# this is tested by test 08
366
ac397a49 367column_name : NAME '.' NAME
368 { $return = { table => $item[1], field => $item[3] } }
369
e4a9818d 370comment_phrase : /null/i
371 { $return = 'NULL' }
372
373comment_phrase : /'/ comment_phrase_unquoted(s) /'/
374 { my $phrase = join(' ', @{ $item[2] });
375 $return = $phrase}
376
377# [cjm TODO: double-single quotes in a comment_phrase]
378comment_phrase_unquoted : /[^\']*/
379 { $return = $item[1] }
380
381
ea93df61 382xxxcomment_phrase : /'.*?'|NULL/
383 {
8e9e79dc 384 my $val = $item[1] || '';
ac397a49 385 $val =~ s/^'|'$//g;
386 $return = $val;
387 }
388
a82fa2cb 389field : field_comment(s?) field_name data_type field_meta(s?) field_comment(s?)
4422e22a 390 {
3022f45b 391 my ( $default, @constraints, $is_pk );
00ef67ea 392 my $is_nullable = 1;
41fc9cb3 393 for my $meta ( @{ $item[4] } ) {
82968eb9 394 if ( $meta->{'type'} eq 'default' ) {
395 $default = $meta;
396 next;
397 }
398 elsif ( $meta->{'type'} eq 'not_null' ) {
00ef67ea 399 $is_nullable = 0;
82968eb9 400 }
401 elsif ( $meta->{'type'} eq 'primary_key' ) {
402 $is_pk = 1;
403 }
4422e22a 404
82968eb9 405 push @constraints, $meta if $meta->{'supertype'} eq 'constraint';
406 }
0efb6e1b 407
f2f71b8e 408 my @comments = ( @{ $item[1] }, @{ $item[5] } );
409
0a7fc605 410 $return = {
b3384294 411 supertype => 'field',
ea93df61 412 name => $item{'field_name'},
7eac5e12 413 data_type => $item{'data_type'}{'type'},
414 size => $item{'data_type'}{'size'},
00ef67ea 415 is_nullable => $is_nullable,
7eac5e12 416 default => $default->{'value'},
417 constraints => [ @constraints ],
418 comments => [ @comments ],
419 is_primary_key => $is_pk || 0,
420 is_auto_increment => $item{'data_type'}{'is_auto_increment'},
ea93df61 421 }
4422e22a 422 }
423 | <error>
424
ea93df61 425field_comment : /^\s*(?:#|-{2})(.*)\n/
426 {
a82fa2cb 427 my $comment = $item[1];
428 $comment =~ s/^\s*(#|-*)\s*//;
429 $comment =~ s/\s*$//;
430 $return = $comment;
431 }
432
0efb6e1b 433field_meta : default_val
82968eb9 434 | column_constraint
4422e22a 435
330e4686 436view_fields : '(' field_name(s /,/) ')'
437 { $return = join (',', @{$item[2]} ) }
438
0efb6e1b 439column_constraint : constraint_name(?) column_constraint_type deferrable(?) deferred(?)
440 {
441 my $desc = $item{'column_constraint_type'};
442 my $type = $desc->{'type'};
443 my $fields = $desc->{'fields'} || [];
444 my $expression = $desc->{'expression'} || '';
445
446 $return = {
82968eb9 447 supertype => 'constraint',
0efb6e1b 448 name => $item{'constraint_name'}[0] || '',
449 type => $type,
450 expression => $type eq 'check' ? $expression : '',
f04713db 451 deferrable => $item{'deferrable'},
0efb6e1b 452 deferred => $item{'deferred'},
453 reference_table => $desc->{'reference_table'},
454 reference_fields => $desc->{'reference_fields'},
455 match_type => $desc->{'match_type'},
100684f3 456 on_delete => $desc->{'on_delete'} || $desc->{'on_delete_do'},
457 on_update => $desc->{'on_update'} || $desc->{'on_update_do'},
ea93df61 458 }
4422e22a 459 }
460
0efb6e1b 461constraint_name : /constraint/i name_with_opt_quotes { $item[2] }
462
463column_constraint_type : /not null/i { $return = { type => 'not_null' } }
464 |
f04713db 465 /null/i
0efb6e1b 466 { $return = { type => 'null' } }
467 |
f04713db 468 /unique/i
0efb6e1b 469 { $return = { type => 'unique' } }
470 |
ea93df61 471 /primary key/i
0efb6e1b 472 { $return = { type => 'primary_key' } }
473 |
ea93df61 474 /check/i '(' /[^)]+/ ')'
b3384294 475 { $return = { type => 'check', expression => $item[3] } }
0efb6e1b 476 |
330e4686 477 /references/i table_id parens_word_list(?) match_type(?) key_action(s?)
0efb6e1b 478 {
330e4686 479 my $table_info = $item{'table_id'};
a20abbda 480 my $schema_name = $table_info->{'schema_name'};
481 my $table_name = $table_info->{'table_name'};
3022f45b 482 my ( $on_delete, $on_update );
483 for my $action ( @{ $item[5] || [] } ) {
484 $on_delete = $action->{'action'} if $action->{'type'} eq 'delete';
485 $on_update = $action->{'action'} if $action->{'type'} eq 'update';
486 }
487
0efb6e1b 488 $return = {
489 type => 'foreign_key',
a20abbda 490 reference_table => $table_name,
0138f7bb 491 reference_fields => $item[3][0],
0efb6e1b 492 match_type => $item[4][0],
100684f3 493 on_delete => $on_delete,
494 on_update => $on_update,
ba1a1626 495 }
4422e22a 496 }
497
330e4686 498table_id : schema_qualification(?) name_with_opt_quotes {
499 $return = { schema_name => $item[1][0], table_name => $item[2] }
a20abbda 500}
501
330e4686 502view_id : schema_qualification(?) name_with_opt_quotes {
503 $return = { schema_name => $item[1][0], view_name => $item[2] }
504}
505
506view_target : /select|with/i /[^;]+/ {
507 $return = "$item[1] $item[2]";
508}
509
510# SELECT views _may_ support outer parens, and we used to produce
511# such sql, although non-standard. Use ugly lookeahead to parse
512view_target : '(' /select/i / [^;]+ (?= \) ) /x ')' {
513 $return = "$item[2] $item[3]"
514}
515
ea93df61 516view_target_spec :
330e4686 517
518schema_qualification : name_with_opt_quotes '.'
4422e22a 519
34338cb2 520schema_name : name_with_opt_quotes
521
0efb6e1b 522field_name : name_with_opt_quotes
4422e22a 523
0012a163 524name_with_opt_quotes : double_quote(?) NAME double_quote(?) { $item[2] }
4422e22a 525
0efb6e1b 526double_quote: /"/
4422e22a 527
d4056aa7 528index_name : name_with_opt_quotes
4422e22a 529
c96cd4a8 530
0efb6e1b 531data_type : pg_data_type parens_value_list(?)
ea93df61 532 {
3022f45b 533 my $data_type = $item[1];
ba1a1626 534
0efb6e1b 535 #
536 # We can deduce some sizes from the data type's name.
537 #
44ffdb73 538 if ( my $size = $item[2][0] ) {
539 $data_type->{'size'} = $size;
540 }
4422e22a 541
3022f45b 542 $return = $data_type;
4422e22a 543 }
544
0efb6e1b 545pg_data_type :
50840472 546 /(bigint|int8)/i
ea93df61 547 {
548 $return = {
50840472 549 type => 'integer',
b8ea6076 550 size => 20,
3022f45b 551 };
552 }
0efb6e1b 553 |
1bbd4a2b 554 /(smallint|int2)/i
ea93df61 555 {
3022f45b 556 $return = {
ea93df61 557 type => 'integer',
b8ea6076 558 size => 5,
3022f45b 559 };
560 }
0efb6e1b 561 |
c4c363bb 562 /interval/i
563 {
564 $return = { type => 'interval' };
565 }
566 |
50840472 567 /(integer|int4?)/i # interval must come before this
ea93df61 568 {
3022f45b 569 $return = {
ea93df61 570 type => 'integer',
b8ea6076 571 size => 10,
3022f45b 572 };
573 }
ea93df61 574 |
50840472 575 /(real|float4)/i
ea93df61 576 {
50840472 577 $return = {
ea93df61 578 type => 'real',
b8ea6076 579 size => 10,
50840472 580 };
581 }
0efb6e1b 582 |
1bbd4a2b 583 /(double precision|float8?)/i
ea93df61 584 {
3022f45b 585 $return = {
ea93df61 586 type => 'float',
b8ea6076 587 size => 20,
ea93df61 588 };
3022f45b 589 }
0efb6e1b 590 |
50840472 591 /(bigserial|serial8)/i
ea93df61 592 {
593 $return = {
594 type => 'integer',
595 size => 20,
7eac5e12 596 is_auto_increment => 1,
3022f45b 597 };
598 }
0efb6e1b 599 |
1bbd4a2b 600 /serial4?/i
ea93df61 601 {
602 $return = {
7eac5e12 603 type => 'integer',
ea93df61 604 size => 11,
7eac5e12 605 is_auto_increment => 1,
3022f45b 606 };
607 }
0efb6e1b 608 |
1bbd4a2b 609 /(bit varying|varbit)/i
ea93df61 610 {
3022f45b 611 $return = { type => 'varbit' };
612 }
0efb6e1b 613 |
1bbd4a2b 614 /character varying/i
ea93df61 615 {
3022f45b 616 $return = { type => 'varchar' };
617 }
0efb6e1b 618 |
1bbd4a2b 619 /char(acter)?/i
ea93df61 620 {
3022f45b 621 $return = { type => 'char' };
622 }
0efb6e1b 623 |
1bbd4a2b 624 /bool(ean)?/i
ea93df61 625 {
3022f45b 626 $return = { type => 'boolean' };
627 }
0efb6e1b 628 |
1bbd4a2b 629 /bytea/i
ea93df61 630 {
82968eb9 631 $return = { type => 'bytea' };
3022f45b 632 }
0efb6e1b 633 |
b5a782a0 634 /(timestamptz|timestamp)(?:\(\d\))?( with(?:out)? time zone)?/i
ea93df61 635 {
b5a782a0 636 $return = { type => 'timestamp' . ($2||'') };
3022f45b 637 }
0efb6e1b 638 |
38a6a4f9 639 /text/i
ea93df61 640 {
641 $return = {
38a6a4f9 642 type => 'text',
643 size => 64_000,
644 };
645 }
646 |
c4c363bb 647 /(bit|box|cidr|circle|date|inet|line|lseg|macaddr|money|numeric|decimal|path|point|polygon|timetz|time|varchar)/i
ea93df61 648 {
3022f45b 649 $return = { type => $item[1] };
650 }
0efb6e1b 651
4422e22a 652parens_value_list : '(' VALUE(s /,/) ')'
653 { $item[2] }
654
efd0c9ec 655
656parens_word_list : '(' name_with_opt_quotes(s /,/) ')'
0efb6e1b 657 { $item[2] }
4422e22a 658
0efb6e1b 659field_size : '(' num_range ')' { $item{'num_range'} }
4422e22a 660
0efb6e1b 661num_range : DIGITS ',' DIGITS
4422e22a 662 { $return = $item[1].','.$item[3] }
663 | DIGITS
664 { $return = $item[1] }
665
f2f71b8e 666table_constraint : comment(s?) constraint_name(?) table_constraint_type deferrable(?) deferred(?) comment(s?)
0efb6e1b 667 {
668 my $desc = $item{'table_constraint_type'};
669 my $type = $desc->{'type'};
670 my $fields = $desc->{'fields'};
671 my $expression = $desc->{'expression'};
f2f71b8e 672 my @comments = ( @{ $item[1] }, @{ $item[-1] } );
0efb6e1b 673
674 $return = {
d4056aa7 675 name => $item[2][0] || '',
b3384294 676 supertype => 'constraint',
677 type => $type,
0efb6e1b 678 fields => $type ne 'check' ? $fields : [],
679 expression => $type eq 'check' ? $expression : '',
f04713db 680 deferrable => $item{'deferrable'},
0efb6e1b 681 deferred => $item{'deferred'},
682 reference_table => $desc->{'reference_table'},
683 reference_fields => $desc->{'reference_fields'},
840447a5 684 match_type => $desc->{'match_type'},
100684f3 685 on_delete => $desc->{'on_delete'} || $desc->{'on_delete_do'},
686 on_update => $desc->{'on_update'} || $desc->{'on_update_do'},
f2f71b8e 687 comments => [ @comments ],
ea93df61 688 }
0efb6e1b 689 }
4422e22a 690
ea93df61 691table_constraint_type : /primary key/i '(' name_with_opt_quotes(s /,/) ')'
692 {
0efb6e1b 693 $return = {
694 type => 'primary_key',
695 fields => $item[3],
696 }
697 }
698 |
ea93df61 699 /unique/i '(' name_with_opt_quotes(s /,/) ')'
700 {
0efb6e1b 701 $return = {
702 type => 'unique',
703 fields => $item[3],
704 }
705 }
706 |
ea93df61 707 /check/i '(' /[^)]+/ ')'
0efb6e1b 708 {
709 $return = {
710 type => 'check',
711 expression => $item[3],
712 }
713 }
714 |
330e4686 715 /foreign key/i '(' name_with_opt_quotes(s /,/) ')' /references/i table_id parens_word_list(?) match_type(?) key_action(s?)
0efb6e1b 716 {
3022f45b 717 my ( $on_delete, $on_update );
718 for my $action ( @{ $item[9] || [] } ) {
719 $on_delete = $action->{'action'} if $action->{'type'} eq 'delete';
720 $on_update = $action->{'action'} if $action->{'type'} eq 'update';
721 }
ea93df61 722
0efb6e1b 723 $return = {
b3384294 724 supertype => 'constraint',
0efb6e1b 725 type => 'foreign_key',
726 fields => $item[3],
a20abbda 727 reference_table => $item[6]->{'table_name'},
0efb6e1b 728 reference_fields => $item[7][0],
729 match_type => $item[8][0],
100684f3 730 on_delete => $on_delete || '',
731 on_update => $on_update || '',
0efb6e1b 732 }
733 }
734
ea93df61 735deferrable : not(?) /deferrable/i
736 {
0efb6e1b 737 $return = ( $item[1] =~ /not/i ) ? 0 : 1;
738 }
4422e22a 739
0efb6e1b 740deferred : /initially/i /(deferred|immediate)/i { $item[2] }
4422e22a 741
840447a5 742match_type : /match/i /partial|full|simple/i { $item[2] }
0efb6e1b 743
ea93df61 744key_action : key_delete
3022f45b 745 |
746 key_update
0efb6e1b 747
3022f45b 748key_delete : /on delete/i key_mutation
ea93df61 749 {
750 $return = {
3022f45b 751 type => 'delete',
752 action => $item[2],
753 };
754 }
755
756key_update : /on update/i key_mutation
ea93df61 757 {
758 $return = {
3022f45b 759 type => 'update',
760 action => $item[2],
761 };
762 }
763
764key_mutation : /no action/i { $return = 'no_action' }
765 |
766 /restrict/i { $return = 'restrict' }
767 |
768 /cascade/i { $return = 'cascade' }
769 |
38a6a4f9 770 /set null/i { $return = 'set null' }
3022f45b 771 |
38a6a4f9 772 /set default/i { $return = 'set default' }
0efb6e1b 773
ea93df61 774alter : alter_table table_id add_column field ';'
775 {
00ef67ea 776 my $field_def = $item[4];
a20abbda 777 $tables{ $item[2]->{'table_name'} }{'fields'}{ $field_def->{'name'} } = {
00ef67ea 778 %$field_def, order => $field_order++
779 };
780 1;
781 }
782
ea93df61 783alter : alter_table table_id ADD table_constraint ';'
784 {
a20abbda 785 my $table_name = $item[2]->{'table_name'};
0012a163 786 my $constraint = $item[4];
0012a163 787 push @{ $tables{ $table_name }{'constraints'} }, $constraint;
00ef67ea 788 1;
0012a163 789 }
790
ea93df61 791alter : alter_table table_id drop_column NAME restrict_or_cascade(?) ';'
00ef67ea 792 {
a20abbda 793 $tables{ $item[2]->{'table_name'} }{'fields'}{ $item[4] }{'drop'} = 1;
00ef67ea 794 1;
795 }
0012a163 796
ea93df61 797alter : alter_table table_id alter_column NAME alter_default_val ';'
00ef67ea 798 {
ea93df61 799 $tables{ $item[2]->{'table_name'} }{'fields'}{ $item[4] }{'default'} =
00ef67ea 800 $item[5]->{'value'};
801 1;
802 }
803
804#
805# These will just parse for now but won't affect the structure. - ky
806#
330e4686 807alter : alter_table table_id /rename/i /to/i NAME ';'
00ef67ea 808 { 1 }
809
ea93df61 810alter : alter_table table_id alter_column NAME SET /statistics/i INTEGER ';'
00ef67ea 811 { 1 }
812
330e4686 813alter : alter_table table_id alter_column NAME SET /storage/i storage_type ';'
00ef67ea 814 { 1 }
815
330e4686 816alter : alter_table table_id rename_column NAME /to/i NAME ';'
00ef67ea 817 { 1 }
818
330e4686 819alter : alter_table table_id DROP /constraint/i NAME restrict_or_cascade ';'
00ef67ea 820 { 1 }
821
330e4686 822alter : alter_table table_id /owner/i /to/i NAME ';'
00ef67ea 823 { 1 }
824
6f28e7ac 825alter : alter_sequence NAME /owned/i /by/i column_name ';'
826 { 1 }
827
00ef67ea 828storage_type : /(plain|external|extended|main)/i
829
330e4686 830temporary : /temp(orary)?\\b/i
831 {
832 1;
833 }
3e98f7d9 834
330e4686 835or_replace : /or replace/i
3e98f7d9 836
ea93df61 837alter_default_val : SET default_val
838 {
839 $return = { value => $item[2]->{'value'} }
840 }
841 | DROP DEFAULT
842 {
843 $return = { value => undef }
00ef67ea 844 }
00ef67ea 845
846#
ea93df61 847# This is a little tricky to get right, at least WRT to making the
00ef67ea 848# tests pass. The problem is that the constraints are stored just as
849# a list (no name access), and the tests expect the constraints in a
ea93df61 850# particular order. I'm going to leave the rule but disable the code
00ef67ea 851# for now. - ky
852#
330e4686 853alter : alter_table table_id alter_column NAME alter_nullable ';'
00ef67ea 854 {
a20abbda 855# my $table_name = $item[2]->{'table_name'};
00ef67ea 856# my $field_name = $item[4];
857# my $is_nullable = $item[5]->{'is_nullable'};
858#
ea93df61 859# $tables{ $table_name }{'fields'}{ $field_name }{'is_nullable'} =
00ef67ea 860# $is_nullable;
861#
862# if ( $is_nullable ) {
863# 1;
864# push @{ $tables{ $table_name }{'constraints'} }, {
865# type => 'not_null',
866# fields => [ $field_name ],
867# };
868# }
869# else {
ea93df61 870# for my $i (
871# 0 .. $#{ $tables{ $table_name }{'constraints'} || [] }
00ef67ea 872# ) {
873# my $c = $tables{ $table_name }{'constraints'}[ $i ] or next;
874# my $fields = join( '', @{ $c->{'fields'} || [] } ) or next;
875# if ( $c->{'type'} eq 'not_null' && $fields eq $field_name ) {
876# delete $tables{ $table_name }{'constraints'}[ $i ];
877# last;
878# }
879# }
880# }
881
882 1;
883 }
884
ea93df61 885alter_nullable : SET not_null
886 {
887 $return = { is_nullable => 0 }
00ef67ea 888 }
889 | DROP not_null
ea93df61 890 {
891 $return = { is_nullable => 1 }
00ef67ea 892 }
893
894not_null : /not/i /null/i
895
99f3fab6 896not : /not/i
897
00ef67ea 898add_column : ADD COLUMN(?)
899
900alter_table : ALTER TABLE ONLY(?)
901
ea93df61 902alter_sequence : ALTER SEQUENCE
6f28e7ac 903
00ef67ea 904drop_column : DROP COLUMN(?)
905
906alter_column : ALTER COLUMN(?)
907
908rename_column : /rename/i COLUMN(?)
909
ea93df61 910restrict_or_cascade : /restrict/i |
00ef67ea 911 /cascade/i
912
34338cb2 913# Handle functions that can be called
ea93df61 914select : SELECT select_function ';'
34338cb2 915 { 1 }
916
917# Read the setval function but don't do anything with it because this parser
918# isn't handling sequences
ea93df61 919select_function : schema_qualification(?) /setval/i '(' VALUE /,/ VALUE /,/ /(true|false)/i ')'
34338cb2 920 { 1 }
921
922# Skipping all COPY commands
923copy : COPY WORD /[^;]+/ ';' { 1 }
924 { 1 }
925
926# The "\." allows reading in from STDIN but this isn't needed for schema
927# creation, so it is skipped.
928readin_symbol : '\.'
929 {1}
930
00ef67ea 931#
932# End basically useless stuff. - ky
933#
0012a163 934
211e2e90 935create_table : CREATE TABLE
0efb6e1b 936
211e2e90 937create_index : CREATE /index/i
4422e22a 938
37e74f25 939default_val : DEFAULT /(\d+|'[^']*'|\w+\(.*\))|\w+/
ea93df61 940 {
f04713db 941 my $val = defined $item[2] ? $item[2] : '';
ea93df61 942 $val =~ s/^'|'$//g;
0efb6e1b 943 $return = {
82968eb9 944 supertype => 'constraint',
945 type => 'default',
0efb6e1b 946 value => $val,
947 }
4422e22a 948 }
f27085c9 949 | /null/i
ea93df61 950 {
f27085c9 951 $return = {
952 supertype => 'constraint',
953 type => 'default',
954 value => 'NULL',
955 }
956 }
4422e22a 957
4422e22a 958name_with_opt_paren : NAME parens_value_list(s?)
0efb6e1b 959 { $item[2][0] ? "$item[1]($item[2][0][0])" : $item[1] }
4422e22a 960
961unique : /unique/i { 1 }
962
963key : /key/i | /index/i
964
0efb6e1b 965table_option : /inherits/i '(' name_with_opt_quotes(s /,/) ')'
ea93df61 966 {
0efb6e1b 967 $return = { type => 'inherits', table_name => $item[3] }
968 }
969 |
970 /with(out)? oids/i
971 {
972 $return = { type => $item[1] =~ /out/i ? 'without_oids' : 'with_oids' }
4422e22a 973 }
974
00ef67ea 975ADD : /add/i
976
977ALTER : /alter/i
978
211e2e90 979CREATE : /create/i
980
00ef67ea 981ONLY : /only/i
982
983DEFAULT : /default/i
984
985DROP : /drop/i
986
987COLUMN : /column/i
988
0d51cd9e 989TABLE : /table/i
990
330e4686 991VIEW : /view/i
992
34338cb2 993SCHEMA : /schema/i
994
0efb6e1b 995SEMICOLON : /\s*;\n?/
996
6f28e7ac 997SEQUENCE : /sequence/i
998
34338cb2 999SELECT : /select/i
1000
1001COPY : /copy/i
1002
00ef67ea 1003INTEGER : /\d+/
1004
4422e22a 1005WORD : /\w+/
1006
1007DIGITS : /\d+/
1008
1009COMMA : ','
1010
00ef67ea 1011SET : /set/i
1012
4422e22a 1013NAME : "`" /\w+/ "`"
1014 { $item[2] }
1015 | /\w+/
1016 { $item[1] }
0012a163 1017 | /[\$\w]+/
1018 { $item[1] }
4422e22a 1019
1020VALUE : /[-+]?\.?\d+(?:[eE]\d+)?/
1021 { $item[1] }
1022 | /'.*?'/ # XXX doesn't handle embedded quotes
1023 { $item[1] }
f04713db 1024 | /null/i
4422e22a 1025 { 'NULL' }
1026
1027!;
1028
4422e22a 1029sub parse {
1030 my ( $translator, $data ) = @_;
9fa2a755 1031 my $parser = Parse::RecDescent->new($GRAMMAR);
4422e22a 1032
1033 $::RD_TRACE = $translator->trace ? 1 : undef;
1034 $DEBUG = $translator->debug;
1035
1036 unless (defined $parser) {
1037 return $translator->error("Error instantiating Parse::RecDescent ".
1038 "instance: Bad grammer");
1039 }
1040
1041 my $result = $parser->startrule($data);
1042 die "Parse failed.\n" unless defined $result;
1043 warn Dumper($result) if $DEBUG;
82968eb9 1044
1045 my $schema = $translator->schema;
ea93df61 1046 my @tables = sort {
330e4686 1047 ( $result->{tables}{ $a }{'order'} || 0 ) <=> ( $result->{tables}{ $b }{'order'} || 0 )
1048 } keys %{ $result->{tables} };
82968eb9 1049
1050 for my $table_name ( @tables ) {
330e4686 1051 my $tdata = $result->{tables}{ $table_name };
ea93df61 1052 my $table = $schema->add_table(
a20abbda 1053 #schema => $tdata->{'schema_name'},
1054 name => $tdata->{'table_name'},
d7fcc1d6 1055 ) or die "Couldn't create table '$table_name': " . $schema->error;
82968eb9 1056
3e98f7d9 1057 $table->extra(temporary => 1) if $tdata->{'temporary'};
1058
a82fa2cb 1059 $table->comments( $tdata->{'comments'} );
1060
ea93df61 1061 my @fields = sort {
1062 $tdata->{'fields'}{ $a }{'order'}
82968eb9 1063 <=>
429f639c 1064 $tdata->{'fields'}{ $b }{'order'}
82968eb9 1065 } keys %{ $tdata->{'fields'} };
1066
1067 for my $fname ( @fields ) {
1068 my $fdata = $tdata->{'fields'}{ $fname };
00ef67ea 1069 next if $fdata->{'drop'};
82968eb9 1070 my $field = $table->add_field(
1071 name => $fdata->{'name'},
1072 data_type => $fdata->{'data_type'},
1073 size => $fdata->{'size'},
1074 default_value => $fdata->{'default'},
7eac5e12 1075 is_auto_increment => $fdata->{'is_auto_increment'},
00ef67ea 1076 is_nullable => $fdata->{'is_nullable'},
a82fa2cb 1077 comments => $fdata->{'comments'},
82968eb9 1078 ) or die $table->error;
1079
1080 $table->primary_key( $field->name ) if $fdata->{'is_primary_key'};
1081
1082 for my $cdata ( @{ $fdata->{'constraints'} } ) {
1083 next unless $cdata->{'type'} eq 'foreign_key';
1084 $cdata->{'fields'} ||= [ $field->name ];
1085 push @{ $tdata->{'constraints'} }, $cdata;
1086 }
1087 }
1088
1089 for my $idata ( @{ $tdata->{'indices'} || [] } ) {
1090 my $index = $table->add_index(
1091 name => $idata->{'name'},
1092 type => uc $idata->{'type'},
1093 fields => $idata->{'fields'},
3406fd5b 1094 ) or die $table->error . ' ' . $table->name;
82968eb9 1095 }
1096
1097 for my $cdata ( @{ $tdata->{'constraints'} || [] } ) {
1098 my $constraint = $table->add_constraint(
1099 name => $cdata->{'name'},
1100 type => $cdata->{'type'},
1101 fields => $cdata->{'fields'},
1102 reference_table => $cdata->{'reference_table'},
1103 reference_fields => $cdata->{'reference_fields'},
1104 match_type => $cdata->{'match_type'} || '',
100684f3 1105 on_delete => $cdata->{'on_delete'} || $cdata->{'on_delete_do'},
1106 on_update => $cdata->{'on_update'} || $cdata->{'on_update_do'},
b3384294 1107 expression => $cdata->{'expression'},
1108 ) or die "Can't add constraint of type '" .
ea93df61 1109 $cdata->{'type'} . "' to table '" . $table->name .
b3384294 1110 "': " . $table->error;
82968eb9 1111 }
1112 }
1113
330e4686 1114 for my $vinfo (@{$result->{views}}) {
1115 my $sql = $vinfo->{sql};
1116 $sql =~ s/\A\s+|\s+\z//g;
1117 my $view = $schema->add_view (
1118 name => $vinfo->{view_name},
1119 sql => $sql,
1120 fields => $vinfo->{fields},
1121 );
1122
1123 $view->extra ( temporary => 1 ) if $vinfo->{is_temporary};
1124 }
1125
c96cd4a8 1126 for my $trigger (@{ $result->{triggers} }) {
1127 $schema->add_trigger( %$trigger );
1128 }
1129
f62bd16c 1130 return 1;
4422e22a 1131}
1132
11331;
1134
82968eb9 1135# -------------------------------------------------------------------
1136# Rescue the drowning and tie your shoestrings.
ea93df61 1137# Henry David Thoreau
82968eb9 1138# -------------------------------------------------------------------
4422e22a 1139
1140=pod
1141
0efb6e1b 1142=head1 AUTHORS
4422e22a 1143
11ad2df9 1144Ken Y. Clark E<lt>kclark@cpan.orgE<gt>,
b8ea6076 1145Allen Day E<lt>allenday@ucla.eduE<gt>.
4422e22a 1146
1147=head1 SEE ALSO
1148
1149perl(1), Parse::RecDescent.
1150
1151=cut