1 package SQL::Translator::Parser::PostgreSQL;
3 # -------------------------------------------------------------------
4 # $Id: PostgreSQL.pm,v 1.39 2004-08-11 22:00:39 kycl4rk Exp $
5 # -------------------------------------------------------------------
6 # Copyright (C) 2002-4 SQLFairy Authors
8 # This program is free software; you can redistribute it and/or
9 # modify it under the terms of the GNU General Public License as
10 # published by the Free Software Foundation; version 2.
12 # This program is distributed in the hope that it will be useful, but
13 # WITHOUT ANY WARRANTY; without even the implied warranty of
14 # MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the GNU
15 # General Public License for more details.
17 # You should have received a copy of the GNU General Public License
18 # along with this program; if not, write to the Free Software
19 # Foundation, Inc., 59 Temple Place, Suite 330, Boston, MA
21 # -------------------------------------------------------------------
25 SQL::Translator::Parser::PostgreSQL - parser for PostgreSQL
30 use SQL::Translator::Parser::PostgreSQL;
32 my $translator = SQL::Translator->new;
33 $translator->parser("SQL::Translator::Parser::PostgreSQL");
37 The grammar was started from the MySQL parsers. Here is the description
41 (http://www.postgresql.org/docs/view.php?version=7.3&idoc=1&file=sql-createtable.html)
43 CREATE [ [ LOCAL ] { TEMPORARY | TEMP } ] TABLE table_name (
44 { column_name data_type [ DEFAULT default_expr ]
45 [ column_constraint [, ... ] ]
46 | table_constraint } [, ... ]
48 [ INHERITS ( parent_table [, ... ] ) ]
49 [ WITH OIDS | WITHOUT OIDS ]
51 where column_constraint is:
53 [ CONSTRAINT constraint_name ]
54 { NOT NULL | NULL | UNIQUE | PRIMARY KEY |
56 REFERENCES reftable [ ( refcolumn ) ] [ MATCH FULL | MATCH PARTIAL ]
57 [ ON DELETE action ] [ ON UPDATE action ] }
58 [ DEFERRABLE | NOT DEFERRABLE ]
59 [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
61 and table_constraint is:
63 [ CONSTRAINT constraint_name ]
64 { UNIQUE ( column_name [, ... ] ) |
65 PRIMARY KEY ( column_name [, ... ] ) |
66 CHECK ( expression ) |
67 FOREIGN KEY ( column_name [, ... ] )
68 REFERENCES reftable [ ( refcolumn [, ... ] ) ]
69 [ MATCH FULL | MATCH PARTIAL ]
70 [ ON DELETE action ] [ ON UPDATE action ] }
71 [ DEFERRABLE | NOT DEFERRABLE ]
72 [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
75 (http://www.postgresql.org/docs/view.php?version=7.3&idoc=1&file=sql-createindex.html)
77 CREATE [ UNIQUE ] INDEX index_name ON table
78 [ USING acc_method ] ( column [ ops_name ] [, ...] )
80 CREATE [ UNIQUE ] INDEX index_name ON table
81 [ USING acc_method ] ( func_name( column [, ... ]) [ ops_name ] )
86 ALTER TABLE [ ONLY ] table [ * ]
87 ADD [ COLUMN ] column type [ column_constraint [ ... ] ]
88 ALTER TABLE [ ONLY ] table [ * ]
89 ALTER [ COLUMN ] column { SET DEFAULT value | DROP DEFAULT }
90 ALTER TABLE [ ONLY ] table [ * ]
91 ALTER [ COLUMN ] column SET STATISTICS integer
92 ALTER TABLE [ ONLY ] table [ * ]
93 RENAME [ COLUMN ] column TO newcolumn
97 ADD table_constraint_definition
98 ALTER TABLE [ ONLY ] table
99 DROP CONSTRAINT constraint { RESTRICT | CASCADE }
105 CREATE [ OR REPLACE ] VIEW view [ ( column name list ) ] AS SELECT query
110 use vars qw[ $DEBUG $VERSION $GRAMMAR @EXPORT_OK ];
111 $VERSION = sprintf "%d.%02d", q$Revision: 1.39 $ =~ /(\d+)\.(\d+)/;
112 $DEBUG = 0 unless defined $DEBUG;
115 use Parse::RecDescent;
117 use base qw(Exporter);
119 @EXPORT_OK = qw(parse);
121 # Enable warnings within the Parse::RecDescent module.
122 $::RD_ERRORS = 1; # Make sure the parser dies when it encounters an error
123 $::RD_WARN = 1; # Enable warnings. This will warn on unused rules &c.
124 $::RD_HINT = 1; # Give out hints to help fix problems.
126 my $parser; # should we do this? There's no programmic way to
127 # change the grammar, so I think this is safe.
131 { my ( %tables, $table_order, $field_order, @table_comments) }
134 # The "eofile" rule makes the parser fail if any "statement" rule
135 # fails. Otherwise, the first successful match by a "statement"
136 # won't cause the failure needed to know that the parse, as a whole,
139 startrule : statement(s) eofile { \%tables }
157 connect : /^\s*\\\connect.*\n/
159 set : /set/i /[^;]*/ ';'
161 revoke : /revoke/i WORD(s /,/) /on/i TABLE(?) table_name /from/i name_with_opt_quotes(s /,/) ';'
163 my $table_name = $item{'table_name'};
164 push @{ $tables{ $table_name }{'permissions'} }, {
171 grant : /grant/i WORD(s /,/) /on/i TABLE(?) table_name /to/i name_with_opt_quotes(s /,/) ';'
173 my $table_name = $item{'table_name'};
174 push @{ $tables{ $table_name }{'permissions'} }, {
181 drop : /drop/i /[^;]*/ ';'
183 insert : /insert/i /[^;]*/ ';'
185 update : /update/i /[^;]*/ ';'
190 create : create_table table_name '(' create_definition(s /,/) ')' table_option(s?) ';'
192 my $table_name = $item{'table_name'};
193 $tables{ $table_name }{'order'} = ++$table_order;
194 $tables{ $table_name }{'table_name'} = $table_name;
196 if ( @table_comments ) {
197 $tables{ $table_name }{'comments'} = [ @table_comments ];
198 @table_comments = ();
202 for my $definition ( @{ $item[4] } ) {
203 if ( $definition->{'supertype'} eq 'field' ) {
204 my $field_name = $definition->{'name'};
205 $tables{ $table_name }{'fields'}{ $field_name } =
206 { %$definition, order => $field_order++ };
208 for my $constraint ( @{ $definition->{'constraints'} || [] } ) {
209 $constraint->{'fields'} = [ $field_name ];
210 push @{ $tables{ $table_name }{'constraints'} },
214 elsif ( $definition->{'supertype'} eq 'constraint' ) {
215 push @{ $tables{ $table_name }{'constraints'} }, $definition;
217 elsif ( $definition->{'supertype'} eq 'index' ) {
218 push @{ $tables{ $table_name }{'indices'} }, $definition;
222 for my $option ( @{ $item[6] } ) {
223 $tables{ $table_name }{'table_options(s?)'}{ $option->{'type'} } =
230 create : CREATE unique(?) /(index|key)/i index_name /on/i table_name using_method(?) '(' field_name(s /,/) ')' where_predicate(?) ';'
232 push @{ $tables{ $item{'table_name'} }{'indices'} },
234 name => $item{'index_name'},
235 supertype => $item{'unique'}[0] ? 'constraint' : 'index',
236 type => $item{'unique'}[0] ? 'unique' : 'normal',
238 method => $item{'using_method'}[0],
245 # Create anything else (e.g., domain, etc.)
247 create : CREATE WORD /[^;]+/ ';'
248 { @table_comments = (); }
250 using_method : /using/i WORD { $item[2] }
252 where_predicate : /where/i /[^;]+/
254 create_definition : field
258 comment : /^\s*(?:#|-{2})(.*)\n/
260 my $comment = $item[1];
261 $comment =~ s/^\s*(#|-*)\s*//;
262 $comment =~ s/\s*$//;
264 push @table_comments, $comment;
267 comment_on_table : /comment/i /on/i /table/i table_name /is/i comment_phrase ';'
269 push @{ $tables{ $item{'table_name'} }{'comments'} }, $item{'comment_phrase'};
272 comment_on_column : /comment/i /on/i /column/i column_name /is/i comment_phrase ';'
274 my $table_name = $item[4]->{'table'};
275 my $field_name = $item[4]->{'field'};
276 push @{ $tables{ $table_name }{'fields'}{ $field_name }{'comments'} },
277 $item{'comment_phrase'};
280 column_name : NAME '.' NAME
281 { $return = { table => $item[1], field => $item[3] } }
283 comment_phrase : /'.*?'|NULL/
285 my $val = $item[1] || '';
290 field : field_comment(s?) field_name data_type field_meta(s?) field_comment(s?)
292 my ( $default, @constraints, $is_pk );
294 for my $meta ( @{ $item[4] } ) {
295 if ( $meta->{'type'} eq 'default' ) {
299 elsif ( $meta->{'type'} eq 'not_null' ) {
302 elsif ( $meta->{'type'} eq 'primary_key' ) {
306 push @constraints, $meta if $meta->{'supertype'} eq 'constraint';
309 my @comments = ( @{ $item[1] }, @{ $item[5] } );
312 supertype => 'field',
313 name => $item{'field_name'},
314 data_type => $item{'data_type'}{'type'},
315 size => $item{'data_type'}{'size'},
316 is_nullable => $is_nullable,
317 default => $default->{'value'},
318 constraints => [ @constraints ],
319 comments => [ @comments ],
320 is_primary_key => $is_pk || 0,
321 is_auto_increment => $item{'data_type'}{'is_auto_increment'},
326 field_comment : /^\s*(?:#|-{2})(.*)\n/
328 my $comment = $item[1];
329 $comment =~ s/^\s*(#|-*)\s*//;
330 $comment =~ s/\s*$//;
334 field_meta : default_val
337 column_constraint : constraint_name(?) column_constraint_type deferrable(?) deferred(?)
339 my $desc = $item{'column_constraint_type'};
340 my $type = $desc->{'type'};
341 my $fields = $desc->{'fields'} || [];
342 my $expression = $desc->{'expression'} || '';
345 supertype => 'constraint',
346 name => $item{'constraint_name'}[0] || '',
348 expression => $type eq 'check' ? $expression : '',
349 deferrable => $item{'deferrable'},
350 deferred => $item{'deferred'},
351 reference_table => $desc->{'reference_table'},
352 reference_fields => $desc->{'reference_fields'},
353 match_type => $desc->{'match_type'},
354 on_delete_do => $desc->{'on_delete_do'},
355 on_update_do => $desc->{'on_update_do'},
359 constraint_name : /constraint/i name_with_opt_quotes { $item[2] }
361 column_constraint_type : /not null/i { $return = { type => 'not_null' } }
364 { $return = { type => 'null' } }
367 { $return = { type => 'unique' } }
370 { $return = { type => 'primary_key' } }
372 /check/i '(' /[^)]+/ ')'
373 { $return = { type => 'check', expression => $item[3] } }
375 /references/i table_name parens_word_list(?) match_type(?) key_action(s?)
377 my ( $on_delete, $on_update );
378 for my $action ( @{ $item[5] || [] } ) {
379 $on_delete = $action->{'action'} if $action->{'type'} eq 'delete';
380 $on_update = $action->{'action'} if $action->{'type'} eq 'update';
384 type => 'foreign_key',
385 reference_table => $item[2],
386 reference_fields => $item[3][0],
387 match_type => $item[4][0],
388 on_delete_do => $on_delete,
389 on_update_do => $on_update,
393 table_name : name_with_opt_quotes
395 field_name : name_with_opt_quotes
397 name_with_opt_quotes : double_quote(?) NAME double_quote(?) { $item[2] }
403 data_type : pg_data_type parens_value_list(?)
405 my $data_type = $item[1];
408 # We can deduce some sizes from the data type's name.
410 if ( my $size = $item[2][0] ) {
411 $data_type->{'size'} = $size;
414 $return = $data_type;
434 /(integer|int4?)/i # interval must come before this
450 /(double precision|float8?)/i
458 /(bigserial|serial8)/i
463 is_auto_increment => 1,
472 is_auto_increment => 1,
476 /(bit varying|varbit)/i
478 $return = { type => 'varbit' };
483 $return = { type => 'varchar' };
488 $return = { type => 'char' };
493 $return = { type => 'boolean' };
498 $return = { type => 'bytea' };
501 /(timestamptz|timestamp)/i
503 $return = { type => 'timestamp' };
514 /(bit|box|cidr|circle|date|inet|interval|line|lseg|macaddr|money|numeric|decimal|path|point|polygon|timetz|time|varchar)/i
516 $return = { type => $item[1] };
519 parens_value_list : '(' VALUE(s /,/) ')'
522 parens_word_list : '(' WORD(s /,/) ')'
525 field_size : '(' num_range ')' { $item{'num_range'} }
527 num_range : DIGITS ',' DIGITS
528 { $return = $item[1].','.$item[3] }
530 { $return = $item[1] }
532 table_constraint : comment(s?) constraint_name(?) table_constraint_type deferrable(?) deferred(?) comment(s?)
534 my $desc = $item{'table_constraint_type'};
535 my $type = $desc->{'type'};
536 my $fields = $desc->{'fields'};
537 my $expression = $desc->{'expression'};
538 my @comments = ( @{ $item[1] }, @{ $item[-1] } );
541 name => $item{'constraint_name'}[0] || '',
542 supertype => 'constraint',
544 fields => $type ne 'check' ? $fields : [],
545 expression => $type eq 'check' ? $expression : '',
546 deferrable => $item{'deferrable'},
547 deferred => $item{'deferred'},
548 reference_table => $desc->{'reference_table'},
549 reference_fields => $desc->{'reference_fields'},
550 match_type => $desc->{'match_type'}[0],
551 on_delete_do => $desc->{'on_delete_do'},
552 on_update_do => $desc->{'on_update_do'},
553 comments => [ @comments ],
557 table_constraint_type : /primary key/i '(' name_with_opt_quotes(s /,/) ')'
560 type => 'primary_key',
565 /unique/i '(' name_with_opt_quotes(s /,/) ')'
573 /check/i '(' /[^)]+/ ')'
577 expression => $item[3],
581 /foreign key/i '(' name_with_opt_quotes(s /,/) ')' /references/i table_name parens_word_list(?) match_type(?) key_action(s?)
583 my ( $on_delete, $on_update );
584 for my $action ( @{ $item[9] || [] } ) {
585 $on_delete = $action->{'action'} if $action->{'type'} eq 'delete';
586 $on_update = $action->{'action'} if $action->{'type'} eq 'update';
590 supertype => 'constraint',
591 type => 'foreign_key',
593 reference_table => $item[6],
594 reference_fields => $item[7][0],
595 match_type => $item[8][0],
596 on_delete_do => $on_delete || '',
597 on_update_do => $on_update || '',
601 deferrable : /not/i /deferrable/i
603 $return = ( $item[1] =~ /not/i ) ? 0 : 1;
606 deferred : /initially/i /(deferred|immediate)/i { $item[2] }
608 match_type : /match full/i { 'match_full' }
610 /match partial/i { 'match_partial' }
612 key_action : key_delete
616 key_delete : /on delete/i key_mutation
624 key_update : /on update/i key_mutation
632 key_mutation : /no action/i { $return = 'no_action' }
634 /restrict/i { $return = 'restrict' }
636 /cascade/i { $return = 'cascade' }
638 /set null/i { $return = 'set null' }
640 /set default/i { $return = 'set default' }
642 alter : alter_table table_name add_column field ';'
644 my $field_def = $item[4];
645 $tables{ $item[2] }{'fields'}{ $field_def->{'name'} } = {
646 %$field_def, order => $field_order++
651 alter : alter_table table_name ADD table_constraint ';'
653 my $table_name = $item[2];
654 my $constraint = $item[4];
655 push @{ $tables{ $table_name }{'constraints'} }, $constraint;
659 alter : alter_table table_name drop_column NAME restrict_or_cascade(?) ';'
661 $tables{ $item[2] }{'fields'}{ $item[4] }{'drop'} = 1;
665 alter : alter_table table_name alter_column NAME alter_default_val ';'
667 $tables{ $item[2] }{'fields'}{ $item[4] }{'default'} =
673 # These will just parse for now but won't affect the structure. - ky
675 alter : alter_table table_name /rename/i /to/i NAME ';'
678 alter : alter_table table_name alter_column NAME SET /statistics/i INTEGER ';'
681 alter : alter_table table_name alter_column NAME SET /storage/i storage_type ';'
684 alter : alter_table table_name rename_column NAME /to/i NAME ';'
687 alter : alter_table table_name DROP /constraint/i NAME restrict_or_cascade ';'
690 alter : alter_table table_name /owner/i /to/i NAME ';'
693 storage_type : /(plain|external|extended|main)/i
695 alter_default_val : SET default_val
697 $return = { value => $item[2]->{'value'} }
701 $return = { value => undef }
705 # This is a little tricky to get right, at least WRT to making the
706 # tests pass. The problem is that the constraints are stored just as
707 # a list (no name access), and the tests expect the constraints in a
708 # particular order. I'm going to leave the rule but disable the code
711 alter : alter_table table_name alter_column NAME alter_nullable ';'
713 # my $table_name = $item[2];
714 # my $field_name = $item[4];
715 # my $is_nullable = $item[5]->{'is_nullable'};
717 # $tables{ $table_name }{'fields'}{ $field_name }{'is_nullable'} =
720 # if ( $is_nullable ) {
722 # push @{ $tables{ $table_name }{'constraints'} }, {
723 # type => 'not_null',
724 # fields => [ $field_name ],
729 # 0 .. $#{ $tables{ $table_name }{'constraints'} || [] }
731 # my $c = $tables{ $table_name }{'constraints'}[ $i ] or next;
732 # my $fields = join( '', @{ $c->{'fields'} || [] } ) or next;
733 # if ( $c->{'type'} eq 'not_null' && $fields eq $field_name ) {
734 # delete $tables{ $table_name }{'constraints'}[ $i ];
743 alter_nullable : SET not_null
745 $return = { is_nullable => 0 }
749 $return = { is_nullable => 1 }
752 not_null : /not/i /null/i
754 add_column : ADD COLUMN(?)
756 alter_table : ALTER TABLE ONLY(?)
758 drop_column : DROP COLUMN(?)
760 alter_column : ALTER COLUMN(?)
762 rename_column : /rename/i COLUMN(?)
764 restrict_or_cascade : /restrict/i |
768 # End basically useless stuff. - ky
771 create_table : CREATE TABLE
773 create_index : CREATE /index/i
775 default_val : DEFAULT /(\d+|'[^']*'|\w+\(.*?\))|\w+/
777 my $val = defined $item[2] ? $item[2] : '';
780 supertype => 'constraint',
788 supertype => 'constraint',
794 name_with_opt_paren : NAME parens_value_list(s?)
795 { $item[2][0] ? "$item[1]($item[2][0][0])" : $item[1] }
797 unique : /unique/i { 1 }
799 key : /key/i | /index/i
801 table_option : /inherits/i '(' name_with_opt_quotes(s /,/) ')'
803 $return = { type => 'inherits', table_name => $item[3] }
808 $return = { type => $item[1] =~ /out/i ? 'without_oids' : 'with_oids' }
827 SEMICOLON : /\s*;\n?/
846 VALUE : /[-+]?\.?\d+(?:[eE]\d+)?/
848 | /'.*?'/ # XXX doesn't handle embedded quotes
855 # -------------------------------------------------------------------
857 my ( $translator, $data ) = @_;
858 $parser ||= Parse::RecDescent->new($GRAMMAR);
860 $::RD_TRACE = $translator->trace ? 1 : undef;
861 $DEBUG = $translator->debug;
863 unless (defined $parser) {
864 return $translator->error("Error instantiating Parse::RecDescent ".
865 "instance: Bad grammer");
868 my $result = $parser->startrule($data);
869 die "Parse failed.\n" unless defined $result;
870 warn Dumper($result) if $DEBUG;
872 my $schema = $translator->schema;
874 $result->{ $a }->{'order'} <=> $result->{ $b }->{'order'}
877 for my $table_name ( @tables ) {
878 my $tdata = $result->{ $table_name };
879 my $table = $schema->add_table(
880 name => $tdata->{'table_name'},
881 ) or die "Couldn't create table '$table_name': " . $schema->error;
883 $table->comments( $tdata->{'comments'} );
886 $tdata->{'fields'}->{ $a }->{'order'}
888 $tdata->{'fields'}->{ $b }->{'order'}
889 } keys %{ $tdata->{'fields'} };
891 for my $fname ( @fields ) {
892 my $fdata = $tdata->{'fields'}{ $fname };
893 next if $fdata->{'drop'};
894 my $field = $table->add_field(
895 name => $fdata->{'name'},
896 data_type => $fdata->{'data_type'},
897 size => $fdata->{'size'},
898 default_value => $fdata->{'default'},
899 is_auto_increment => $fdata->{'is_auto_increment'},
900 is_nullable => $fdata->{'is_nullable'},
901 comments => $fdata->{'comments'},
902 ) or die $table->error;
904 $table->primary_key( $field->name ) if $fdata->{'is_primary_key'};
906 for my $cdata ( @{ $fdata->{'constraints'} } ) {
907 next unless $cdata->{'type'} eq 'foreign_key';
908 $cdata->{'fields'} ||= [ $field->name ];
909 push @{ $tdata->{'constraints'} }, $cdata;
913 for my $idata ( @{ $tdata->{'indices'} || [] } ) {
914 my $index = $table->add_index(
915 name => $idata->{'name'},
916 type => uc $idata->{'type'},
917 fields => $idata->{'fields'},
918 ) or die $table->error;
921 for my $cdata ( @{ $tdata->{'constraints'} || [] } ) {
922 my $constraint = $table->add_constraint(
923 name => $cdata->{'name'},
924 type => $cdata->{'type'},
925 fields => $cdata->{'fields'},
926 reference_table => $cdata->{'reference_table'},
927 reference_fields => $cdata->{'reference_fields'},
928 match_type => $cdata->{'match_type'} || '',
929 on_delete => $cdata->{'on_delete_do'},
930 on_update => $cdata->{'on_update_do'},
931 expression => $cdata->{'expression'},
932 ) or die "Can't add constraint of type '" .
933 $cdata->{'type'} . "' to table '" . $table->name .
934 "': " . $table->error;
943 # -------------------------------------------------------------------
944 # Rescue the drowning and tie your shoestrings.
945 # Henry David Thoreau
946 # -------------------------------------------------------------------
952 Ken Y. Clark E<lt>kclark@cpan.orgE<gt>,
953 Allen Day E<lt>allenday@ucla.eduE<gt>.
957 perl(1), Parse::RecDescent.