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