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