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