Using some of the rules from the PG grammar to make mine better, cleaned
[dbsrgits/SQL-Translator.git] / lib / SQL / Translator / Parser / PostgreSQL.pm
CommitLineData
84012a55 1package SQL::Translator::Parser::PostgreSQL;
4422e22a 2
3# -------------------------------------------------------------------
3022f45b 4# $Id: PostgreSQL.pm,v 1.13 2003-05-03 04:09:50 kycl4rk Exp $
4422e22a 5# -------------------------------------------------------------------
6# Copyright (C) 2003 Ken Y. Clark <kclark@cpan.org>,
0efb6e1b 7# Allen Day <allenday@users.sourceforge.net>,
4422e22a 8# darren chamberlain <darren@cpan.org>,
9# Chris Mungall <cjm@fruitfly.org>
10#
11# This program is free software; you can redistribute it and/or
12# modify it under the terms of the GNU General Public License as
13# published by the Free Software Foundation; version 2.
14#
15# This program is distributed in the hope that it will be useful, but
16# WITHOUT ANY WARRANTY; without even the implied warranty of
17# MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the GNU
18# General Public License for more details.
19#
20# You should have received a copy of the GNU General Public License
21# along with this program; if not, write to the Free Software
0efb6e1b 22# Foundation, Inc., 59 Temple Place, Suite 330, Boston, MA
4422e22a 23# 02111-1307 USA
24# -------------------------------------------------------------------
25
26=head1 NAME
27
84012a55 28SQL::Translator::Parser::PostgreSQL - parser for PostgreSQL
4422e22a 29
30=head1 SYNOPSIS
31
32 use SQL::Translator;
84012a55 33 use SQL::Translator::Parser::PostgreSQL;
4422e22a 34
35 my $translator = SQL::Translator->new;
84012a55 36 $translator->parser("SQL::Translator::Parser::PostgreSQL");
4422e22a 37
38=head1 DESCRIPTION
39
0efb6e1b 40The grammar was started from the MySQL parsers. Here is the description
41from PostgreSQL:
42
43Table:
629b76f9 44(http://www.postgresql.org/docs/view.php?version=7.3&idoc=1&file=sql-createtable.html)
45
46 CREATE [ [ LOCAL ] { TEMPORARY | TEMP } ] TABLE table_name (
47 { column_name data_type [ DEFAULT default_expr ]
48 [ column_constraint [, ... ] ]
49 | table_constraint } [, ... ]
50 )
51 [ INHERITS ( parent_table [, ... ] ) ]
52 [ WITH OIDS | WITHOUT OIDS ]
53
54 where column_constraint is:
55
56 [ CONSTRAINT constraint_name ]
57 { NOT NULL | NULL | UNIQUE | PRIMARY KEY |
58 CHECK (expression) |
59 REFERENCES reftable [ ( refcolumn ) ] [ MATCH FULL | MATCH PARTIAL ]
60 [ ON DELETE action ] [ ON UPDATE action ] }
61 [ DEFERRABLE | NOT DEFERRABLE ]
62 [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
63
64 and table_constraint is:
65
66 [ CONSTRAINT constraint_name ]
67 { UNIQUE ( column_name [, ... ] ) |
68 PRIMARY KEY ( column_name [, ... ] ) |
69 CHECK ( expression ) |
70 FOREIGN KEY ( column_name [, ... ] )
71 REFERENCES reftable [ ( refcolumn [, ... ] ) ]
72 [ MATCH FULL | MATCH PARTIAL ]
73 [ ON DELETE action ] [ ON UPDATE action ] }
74 [ DEFERRABLE | NOT DEFERRABLE ]
75 [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
0efb6e1b 76
77Index:
629b76f9 78(http://www.postgresql.org/docs/view.php?version=7.3&idoc=1&file=sql-createindex.html)
0efb6e1b 79
629b76f9 80 CREATE [ UNIQUE ] INDEX index_name ON table
81 [ USING acc_method ] ( column [ ops_name ] [, ...] )
82 [ WHERE predicate ]
83 CREATE [ UNIQUE ] INDEX index_name ON table
84 [ USING acc_method ] ( func_name( column [, ... ]) [ ops_name ] )
85 [ WHERE predicate ]
4422e22a 86
0012a163 87Alter table:
88
89 ALTER TABLE [ ONLY ] table [ * ]
90 ADD [ COLUMN ] column type [ column_constraint [ ... ] ]
91 ALTER TABLE [ ONLY ] table [ * ]
92 ALTER [ COLUMN ] column { SET DEFAULT value | DROP DEFAULT }
93 ALTER TABLE [ ONLY ] table [ * ]
94 ALTER [ COLUMN ] column SET STATISTICS integer
95 ALTER TABLE [ ONLY ] table [ * ]
96 RENAME [ COLUMN ] column TO newcolumn
97 ALTER TABLE table
98 RENAME TO new_table
99 ALTER TABLE table
100 ADD table_constraint_definition
101 ALTER TABLE [ ONLY ] table
102 DROP CONSTRAINT constraint { RESTRICT | CASCADE }
103 ALTER TABLE table
104 OWNER TO new_owner
105
3022f45b 106View table:
107
108 CREATE [ OR REPLACE ] VIEW view [ ( column name list ) ] AS SELECT query
109
4422e22a 110=cut
111
112use strict;
113use vars qw[ $DEBUG $VERSION $GRAMMAR @EXPORT_OK ];
3022f45b 114$VERSION = sprintf "%d.%02d", q$Revision: 1.13 $ =~ /(\d+)\.(\d+)/;
4422e22a 115$DEBUG = 0 unless defined $DEBUG;
116
117use Data::Dumper;
118use Parse::RecDescent;
119use Exporter;
120use base qw(Exporter);
121
122@EXPORT_OK = qw(parse);
123
124# Enable warnings within the Parse::RecDescent module.
125$::RD_ERRORS = 1; # Make sure the parser dies when it encounters an error
126$::RD_WARN = 1; # Enable warnings. This will warn on unused rules &c.
127$::RD_HINT = 1; # Give out hints to help fix problems.
128
129my $parser; # should we do this? There's no programmic way to
130 # change the grammar, so I think this is safe.
131
132$GRAMMAR = q!
133
0efb6e1b 134{ our ( %tables, $table_order ) }
4422e22a 135
629b76f9 136#
137# The "eofile" rule makes the parser fail if any "statement" rule
138# fails. Otherwise, the first successful match by a "statement"
139# won't cause the failure needed to know that the parse, as a whole,
140# failed. -ky
141#
0efb6e1b 142startrule : statement(s) eofile { \%tables }
4422e22a 143
0efb6e1b 144eofile : /^\Z/
145
146statement : create
147 | comment
0012a163 148 | alter
0efb6e1b 149 | grant
150 | revoke
4422e22a 151 | drop
0efb6e1b 152 | connect
0012a163 153 | set
4422e22a 154 | <error>
155
0efb6e1b 156connect : /^\s*\\\connect.*\n/
157
0012a163 158set : /SET/ /[^;]*/ ';'
159
0efb6e1b 160revoke : /revoke/i WORD(s /,/) /on/i table_name /from/i name_with_opt_quotes(s /,/) ';'
161 {
162 my $table_name = $item{'table_name'};
163 push @{ $tables{ $table_name }{'permissions'} }, {
164 type => 'revoke',
165 actions => $item[2],
166 users => $item[6],
167 }
168 }
169
170grant : /grant/i WORD(s /,/) /on/i table_name /to/i name_with_opt_quotes(s /,/) ';'
171 {
172 my $table_name = $item{'table_name'};
173 push @{ $tables{ $table_name }{'permissions'} }, {
174 type => 'grant',
175 actions => $item[2],
176 users => $item[6],
177 }
178 }
179
180drop : /drop/i /[^;]*/ ';'
4422e22a 181
0012a163 182#
183# Create table.
184#
ba1a1626 185create : create_table table_name '(' create_definition(s /,/) ')' table_option(s?) ';'
0efb6e1b 186 {
187 my $table_name = $item{'table_name'};
188 $tables{ $table_name }{'order'} = ++$table_order;
189 $tables{ $table_name }{'table_name'} = $table_name;
190
191 my $i = 1;
192 my @constraints;
193 for my $definition ( @{ $item[4] } ) {
194 if ( $definition->{'type'} eq 'field' ) {
195 my $field_name = $definition->{'name'};
196 $tables{ $table_name }{'fields'}{ $field_name } =
197 { %$definition, order => $i };
198 $i++;
4422e22a 199
0138f7bb 200 for my $constraint ( @{ $definition->{'constraints'} || [] } ) {
201 $constraint->{'fields'} = [ $field_name ];
7d5bcab8 202 push @{ $tables{ $table_name }{'constraints'} },
0138f7bb 203 $constraint;
0efb6e1b 204 }
205 }
206 elsif ( $definition->{'type'} eq 'constraint' ) {
207 $definition->{'type'} = $definition->{'constraint_type'};
0138f7bb 208 # group FKs at the field level
209 if ( $definition->{'type'} eq 'foreign_key' ) {
210 for my $fld ( @{ $definition->{'fields'} || [] } ) {
211 push @{
212 $tables{$table_name}{'fields'}{$fld}{'constraints'}
213 }, $definition;
214 }
215 }
216 else {
217 push @{ $tables{ $table_name }{'constraints'} },
218 $definition;
219 }
0efb6e1b 220 }
221 else {
222 push @{ $tables{ $table_name }{'indices'} }, $definition;
223 }
224 }
225
226 for my $option ( @{ $item[6] } ) {
3022f45b 227 $tables{ $table_name }{'table_options(s?)'}{ $option->{'type'} } =
0efb6e1b 228 $option;
229 }
230
231 1;
232 }
233
0012a163 234#
235# Create index.
236#
0efb6e1b 237create : /create/i unique(?) /(index|key)/i index_name /on/i table_name using_method(?) '(' field_name(s /,/) ')' where_predicate(?) ';'
4422e22a 238 {
239 push @{ $tables{ $item{'table_name'} }{'indices'} },
240 {
0efb6e1b 241 name => $item{'index_name'},
242 type => $item{'unique'}[0] ? 'unique' : 'normal',
243 fields => $item[9],
244 method => $item{'using_method'}[0],
4422e22a 245 }
246 ;
247 }
248
0012a163 249#
250# Create anything else (e.g., domain, function, etc.)
251#
252create : /create/i WORD /[^;]+/ ';'
253
0efb6e1b 254using_method : /using/i WORD { $item[2] }
255
256where_predicate : /where/i /[^;]+/
257
258create_definition : field
0efb6e1b 259 | table_constraint
4422e22a 260 | <error>
261
262comment : /^\s*(?:#|-{2}).*\n/
263
f2f71b8e 264field : comment(s?) field_name data_type field_meta(s?) comment(s?)
4422e22a 265 {
3022f45b 266 my ( $default, @constraints, $is_pk );
41fc9cb3 267 for my $meta ( @{ $item[4] } ) {
0efb6e1b 268 $default = $meta if $meta->{'meta_type'} eq 'default';
269 push @constraints, $meta if $meta->{'meta_type'} eq 'constraint';
3022f45b 270 $is_pk = $meta->{'type'} eq 'primary_key';
4422e22a 271 }
272
0efb6e1b 273 my $null = ( grep { $_->{'type'} eq 'not_null' } @constraints ) ? 0 : 1;
274
f2f71b8e 275 my @comments = ( @{ $item[1] }, @{ $item[5] } );
276
0a7fc605 277 $return = {
4422e22a 278 type => 'field',
279 name => $item{'field_name'},
280 data_type => $item{'data_type'}{'type'},
281 size => $item{'data_type'}{'size'},
282 list => $item{'data_type'}{'list'},
283 null => $null,
0efb6e1b 284 default => $default->{'value'},
285 constraints => [ @constraints ],
f2f71b8e 286 comments => [ @comments ],
3022f45b 287 is_primary_key => $is_pk || 0,
4422e22a 288 }
289 }
290 | <error>
291
0efb6e1b 292field_meta : default_val
293 |
294 column_constraint
4422e22a 295
0efb6e1b 296column_constraint : constraint_name(?) column_constraint_type deferrable(?) deferred(?)
297 {
298 my $desc = $item{'column_constraint_type'};
299 my $type = $desc->{'type'};
300 my $fields = $desc->{'fields'} || [];
301 my $expression = $desc->{'expression'} || '';
302
303 $return = {
304 meta_type => 'constraint',
305 name => $item{'constraint_name'}[0] || '',
306 type => $type,
307 expression => $type eq 'check' ? $expression : '',
308 deferreable => $item{'deferrable'},
309 deferred => $item{'deferred'},
310 reference_table => $desc->{'reference_table'},
311 reference_fields => $desc->{'reference_fields'},
312 match_type => $desc->{'match_type'},
313 on_delete_do => $desc->{'on_delete_do'},
314 on_update_do => $desc->{'on_update_do'},
4422e22a 315 }
316 }
317
0efb6e1b 318constraint_name : /constraint/i name_with_opt_quotes { $item[2] }
319
320column_constraint_type : /not null/i { $return = { type => 'not_null' } }
321 |
322 /null/
323 { $return = { type => 'null' } }
324 |
325 /unique/
326 { $return = { type => 'unique' } }
327 |
328 /primary key/i
329 { $return = { type => 'primary_key' } }
330 |
331 /check/i '(' /[^)]+/ ')'
332 { $return = { type => 'check', expression => $item[2] } }
333 |
3022f45b 334 /references/i table_name parens_word_list(?) match_type(?) key_action(s?)
0efb6e1b 335 {
3022f45b 336 my ( $on_delete, $on_update );
337 for my $action ( @{ $item[5] || [] } ) {
338 $on_delete = $action->{'action'} if $action->{'type'} eq 'delete';
339 $on_update = $action->{'action'} if $action->{'type'} eq 'update';
340 }
341
0efb6e1b 342 $return = {
343 type => 'foreign_key',
344 reference_table => $item[2],
0138f7bb 345 reference_fields => $item[3][0],
0efb6e1b 346 match_type => $item[4][0],
3022f45b 347 on_delete_do => $on_delete,
348 on_update_do => $on_update,
ba1a1626 349 }
4422e22a 350 }
351
0efb6e1b 352table_name : name_with_opt_quotes
4422e22a 353
0efb6e1b 354field_name : name_with_opt_quotes
4422e22a 355
0012a163 356name_with_opt_quotes : double_quote(?) NAME double_quote(?) { $item[2] }
4422e22a 357
0efb6e1b 358double_quote: /"/
4422e22a 359
0efb6e1b 360index_name : WORD
4422e22a 361
0efb6e1b 362data_type : pg_data_type parens_value_list(?)
4422e22a 363 {
3022f45b 364 my $data_type = $item[1];
ba1a1626 365
0efb6e1b 366 #
367 # We can deduce some sizes from the data type's name.
368 #
3022f45b 369 $data_type->{'size'} ||= $item[2][0];
4422e22a 370
3022f45b 371 $return = $data_type;
4422e22a 372 }
373
0efb6e1b 374pg_data_type :
3022f45b 375 /(bigint|int8|bigserial|serial8)/
376 {
377 $return = {
378 type => 'integer',
379 size => 8,
380 auto_increment => 1,
381 };
382 }
0efb6e1b 383 |
3022f45b 384 /(smallint|int2)/
385 {
386 $return = {
387 type => 'integer',
388 size => 2,
389 };
390 }
0efb6e1b 391 |
3022f45b 392 /int(eger)?|int4/
393 {
394 $return = {
395 type => 'integer',
396 size => 4,
397 };
398 }
0efb6e1b 399 |
3022f45b 400 /(double precision|float8?)/
401 {
402 $return = {
403 type => 'float',
404 size => 8,
405 };
406 }
0efb6e1b 407 |
3022f45b 408 /(real|float4)/
409 {
410 $return = {
411 type => 'real',
412 size => 4,
413 };
414 }
0efb6e1b 415 |
3022f45b 416 /serial4?/
417 {
418 $return = {
419 type => 'integer',
420 size => 4,
421 auto_increment => 1,
422 };
423 }
0efb6e1b 424 |
3022f45b 425 /bigserial/
426 {
427 $return = {
428 type => 'integer',
429 size => 8,
430 auto_increment => 1,
431 };
432 }
0efb6e1b 433 |
3022f45b 434 /(bit varying|varbit)/
435 {
436 $return = { type => 'varbit' };
437 }
0efb6e1b 438 |
3022f45b 439 /character varying/
440 {
441 $return = { type => 'varchar' };
442 }
0efb6e1b 443 |
3022f45b 444 /char(acter)?/
445 {
446 $return = { type => 'char' };
447 }
0efb6e1b 448 |
3022f45b 449 /bool(ean)?/
450 {
451 $return = { type => 'boolean' };
452 }
0efb6e1b 453 |
3022f45b 454 /(bytea|binary data)/
455 {
456 $return = { type => 'binary' };
457 }
0efb6e1b 458 |
3022f45b 459 /timestampz?/
460 {
461 $return = { type => 'timestamp' };
462 }
0efb6e1b 463 |
464 /(bit|box|cidr|circle|date|inet|interval|line|lseg|macaddr|money|numeric|decimal|path|point|polygon|text|time|varchar)/
3022f45b 465 {
466 $return = { type => $item[1] };
467 }
0efb6e1b 468
4422e22a 469parens_value_list : '(' VALUE(s /,/) ')'
470 { $item[2] }
471
0efb6e1b 472parens_word_list : '(' WORD(s /,/) ')'
473 { $item[2] }
4422e22a 474
0efb6e1b 475field_size : '(' num_range ')' { $item{'num_range'} }
4422e22a 476
0efb6e1b 477num_range : DIGITS ',' DIGITS
4422e22a 478 { $return = $item[1].','.$item[3] }
479 | DIGITS
480 { $return = $item[1] }
481
f2f71b8e 482table_constraint : comment(s?) constraint_name(?) table_constraint_type deferrable(?) deferred(?) comment(s?)
0efb6e1b 483 {
484 my $desc = $item{'table_constraint_type'};
485 my $type = $desc->{'type'};
486 my $fields = $desc->{'fields'};
487 my $expression = $desc->{'expression'};
f2f71b8e 488 my @comments = ( @{ $item[1] }, @{ $item[-1] } );
0efb6e1b 489
490 $return = {
491 name => $item{'constraint_name'}[0] || '',
492 type => 'constraint',
493 constraint_type => $type,
494 fields => $type ne 'check' ? $fields : [],
495 expression => $type eq 'check' ? $expression : '',
496 deferreable => $item{'deferrable'},
497 deferred => $item{'deferred'},
498 reference_table => $desc->{'reference_table'},
499 reference_fields => $desc->{'reference_fields'},
500 match_type => $desc->{'match_type'}[0],
0012a163 501 on_delete_do => $desc->{'on_delete_do'},
502 on_update_do => $desc->{'on_update_do'},
f2f71b8e 503 comments => [ @comments ],
0efb6e1b 504 }
505 }
4422e22a 506
0efb6e1b 507table_constraint_type : /primary key/i '(' name_with_opt_quotes(s /,/) ')'
508 {
509 $return = {
510 type => 'primary_key',
511 fields => $item[3],
512 }
513 }
514 |
515 /unique/i '(' name_with_opt_quotes(s /,/) ')'
516 {
517 $return = {
518 type => 'unique',
519 fields => $item[3],
520 }
521 }
522 |
523 /check/ '(' /(.+)/ ')'
524 {
525 $return = {
526 type => 'check',
527 expression => $item[3],
528 }
529 }
530 |
3022f45b 531 /foreign key/i '(' name_with_opt_quotes(s /,/) ')' /references/i table_name parens_word_list(?) match_type(?) key_action(s?)
0efb6e1b 532 {
3022f45b 533 my ( $on_delete, $on_update );
534 for my $action ( @{ $item[9] || [] } ) {
535 $on_delete = $action->{'action'} if $action->{'type'} eq 'delete';
536 $on_update = $action->{'action'} if $action->{'type'} eq 'update';
537 }
538
0efb6e1b 539 $return = {
540 type => 'foreign_key',
541 fields => $item[3],
542 reference_table => $item[6],
543 reference_fields => $item[7][0],
544 match_type => $item[8][0],
3022f45b 545 on_delete_do => $on_delete || '',
546 on_update_do => $on_update || '',
0efb6e1b 547 }
548 }
549
550deferrable : /not/i /deferrable/i
551 {
552 $return = ( $item[1] =~ /not/i ) ? 0 : 1;
553 }
4422e22a 554
0efb6e1b 555deferred : /initially/i /(deferred|immediate)/i { $item[2] }
4422e22a 556
0efb6e1b 557match_type : /match full/i { 'match_full' }
558 |
559 /match partial/i { 'match_partial' }
560
3022f45b 561key_action : key_delete
562 |
563 key_update
0efb6e1b 564
3022f45b 565key_delete : /on delete/i key_mutation
566 {
567 $return => {
568 type => 'delete',
569 action => $item[2],
570 };
571 }
572
573key_update : /on update/i key_mutation
574 {
575 $return => {
576 type => 'update',
577 action => $item[2],
578 };
579 }
580
581key_mutation : /no action/i { $return = 'no_action' }
582 |
583 /restrict/i { $return = 'restrict' }
584 |
585 /cascade/i { $return = 'cascade' }
586 |
587 /set null/i { $return = 'set_null' }
588 |
589 /set default/i { $return = 'set_default' }
0efb6e1b 590
0012a163 591alter : alter_table table_name /add/i table_constraint ';'
592 {
593 my $table_name = $item[2];
594 my $constraint = $item[4];
595 $constraint->{'type'} = $constraint->{'constraint_type'};
596 push @{ $tables{ $table_name }{'constraints'} }, $constraint;
597 }
598
599alter_table : /alter/i /table/i only(?)
600
601only : /only/i
602
0efb6e1b 603create_table : /create/i /table/i
604
605create_index : /create/i /index/i
4422e22a 606
607default_val : /default/i /(?:')?[\w\d.-]*(?:')?/
608 {
0efb6e1b 609 my $val = $item[2] || '';
610 $val =~ s/'//g;
611 $return = {
612 meta_type => 'default',
613 value => $val,
614 }
4422e22a 615 }
616
4422e22a 617name_with_opt_paren : NAME parens_value_list(s?)
0efb6e1b 618 { $item[2][0] ? "$item[1]($item[2][0][0])" : $item[1] }
4422e22a 619
620unique : /unique/i { 1 }
621
622key : /key/i | /index/i
623
0efb6e1b 624table_option : /inherits/i '(' name_with_opt_quotes(s /,/) ')'
4422e22a 625 {
0efb6e1b 626 $return = { type => 'inherits', table_name => $item[3] }
627 }
628 |
629 /with(out)? oids/i
630 {
631 $return = { type => $item[1] =~ /out/i ? 'without_oids' : 'with_oids' }
4422e22a 632 }
633
0efb6e1b 634SEMICOLON : /\s*;\n?/
635
4422e22a 636WORD : /\w+/
637
638DIGITS : /\d+/
639
640COMMA : ','
641
642NAME : "`" /\w+/ "`"
643 { $item[2] }
644 | /\w+/
645 { $item[1] }
0012a163 646 | /[\$\w]+/
647 { $item[1] }
4422e22a 648
649VALUE : /[-+]?\.?\d+(?:[eE]\d+)?/
650 { $item[1] }
651 | /'.*?'/ # XXX doesn't handle embedded quotes
652 { $item[1] }
653 | /NULL/
654 { 'NULL' }
655
656!;
657
658# -------------------------------------------------------------------
659sub parse {
660 my ( $translator, $data ) = @_;
661 $parser ||= Parse::RecDescent->new($GRAMMAR);
662
663 $::RD_TRACE = $translator->trace ? 1 : undef;
664 $DEBUG = $translator->debug;
665
666 unless (defined $parser) {
667 return $translator->error("Error instantiating Parse::RecDescent ".
668 "instance: Bad grammer");
669 }
670
671 my $result = $parser->startrule($data);
672 die "Parse failed.\n" unless defined $result;
673 warn Dumper($result) if $DEBUG;
674 return $result;
675}
676
6771;
678
679#-----------------------------------------------------
680# Where man is not nature is barren.
681# William Blake
682#-----------------------------------------------------
683
684=pod
685
0efb6e1b 686=head1 AUTHORS
4422e22a 687
688Ken Y. Clark E<lt>kclark@cpan.orgE<gt>,
0a7fc605 689Allen Day <allenday@ucla.edu>.
4422e22a 690
691=head1 SEE ALSO
692
693perl(1), Parse::RecDescent.
694
695=cut