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