1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 508 509 510 511 512 513 514 515 516 517 518 519 520 521 522 523 524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 593 594 595 596 597 598 599 600 601 602 603 604 605 606 607 608 609 610 611 612 613 614 615 616 617 618 619 620 621 622 623 624 625 626 627 628 629 630 631 632 633 634 635 636 637 638 639 640 641 642 643 644 645 646 647 648 649 650 651 652 653 654 655 656 657 658 659 660 661 662 663 664 665 666 667 668 669 670 671 672 673 674 675 676 677 678 679 680 681 682 683 684 685 686 687 688 689 690 691 692 693 694 695 696 697 698 699 700 701 702 703 704 705 706 707 708 709 710 711 712 713 714 715 716 717 718 719 720 721 722 723 724 725 726 727 728 729 730 731 732 733 734 735 736 737 738 739 740 741 742 743 744 745 746 747 748 749 750 751 752 753 754 755 756 757 758 759 760 761 762 763 764 765 766 767 768 769 770 771 772 773 774 775 776 777 778 779 780 781 782 783 784 785 786 787 788 789 790 791 792 793 794 795 796 797 798 799 800 801 802 803 804 805 806 807 808 809 810 811 812 813 814 815 816 817 818 819 820 821 822 823 824 825 826 827 828 829 830 831 832 833 834 835 836 837 838 839 840 841 842 843 844 845 846 847 848 849 850 851 852 853 854 855 856 857 858 859 860 861 862 863 864 865 866 867 868 869 870 871 872 873 874 875 876 877 878 879 880 881 882 883 884 885
|
package DBIx::Admin::CreateTable;
use strict;
use warnings;
use Moo;
has db_vendor =>
(
is => 'rw',
default => sub{return ''},
required => 0,
);
has dbh =>
(
is => 'rw',
isa => sub{die "The 'dbh' parameter to new() is mandatory\n" if (! $_[0])},
default => sub{return ''},
required => 0,
);
has primary_index_name =>
(
is => 'rw',
default => sub{return {} },
required => 0,
);
has sequence_name =>
(
is => 'rw',
default => sub{return {} },
required => 0,
);
has verbose =>
(
is => 'rw',
default => sub{return 0},
required => 0,
);
our $VERSION = '2.11';
# -----------------------------------------------
sub BUILD
{
my($self) = @_;
$self -> db_vendor(uc $self -> dbh -> get_info(17) ); # SQL_DBMS_NAME.
print STDERR __PACKAGE__, '. Db vendor ' . $self -> db_vendor . ". \n" if ($self -> verbose);
} # End of BUILD.
# --------------------------------------------------
sub create_table
{
my($self, $sql, $arg) = @_;
my($table_name) = $sql;
$table_name =~ s/^\s*create\s+table\s+([a-z_0-9]+).+$/$1/is;
$arg = {} if (! defined $arg);
$$arg{$table_name} = {} if (! defined $$arg{$table_name});
$$arg{$table_name}{no_sequence} = 0 if (! defined $$arg{$table_name}{no_sequence});
if (! $$arg{$table_name}{no_sequence})
{
my($sequence_name) = $self -> generate_primary_sequence_name($table_name);
if ($sequence_name)
{
my($sql) = "create sequence $sequence_name";
$self -> dbh -> do($sql);
print STDERR __PACKAGE__, ". SQL: $sql. \n" if ($self -> verbose);
if ($self -> dbh -> errstr() )
{
return $self -> dbh -> errstr(); # Failure.
}
print STDERR __PACKAGE__, ". Created sequence '$sequence_name'. \n" if ($self -> verbose);
}
}
$self -> dbh -> do($sql);
print STDERR __PACKAGE__, ". SQL: $sql. \n" if ($self -> verbose);
if ($self -> dbh -> errstr() )
{
return $self -> dbh -> errstr(); # Failure.
}
print STDERR __PACKAGE__, ". Created table '$table_name'. \n" if ($self -> verbose);
return ''; # Success.
} # End of create_table.
# --------------------------------------------------
sub drop_table
{
my($self, $table_name, $arg) = @_;
my($sequence_name) = $self -> generate_primary_sequence_name($table_name);
# Turn off RaiseError so we don't error if the sequence and table being deleted do not exist.
# We do this by emulating local $$dbh{RaiseError}.
my($dbh) = $self -> dbh;
my($raise_error) = $$dbh{RaiseError};
$$dbh{RaiseError} = 0;
$self -> dbh($dbh);
$arg = {} if (! defined $arg);
$$arg{$table_name} = {} if (! defined $$arg{$table_name});
$$arg{$table_name}{no_sequence} = 0 if (! defined $$arg{$table_name}{no_sequence});
my($sql);
# For Oracle, drop the sequence before dropping the table.
if ( ($self -> db_vendor eq 'ORACLE') && ! $$arg{$table_name}{no_sequence})
{
$sql = "drop sequence $sequence_name";
$self -> dbh -> do($sql);
print STDERR __PACKAGE__, ". SQL: $sql. \n" if ($self -> verbose);
print STDERR __PACKAGE__, ". Dropped sequence '$sequence_name'. \n" if ($self -> verbose);
}
$sql = "drop table $table_name";
$self -> dbh -> do($sql);
print STDERR __PACKAGE__, ". SQL: $sql. \n" if ($self -> verbose);
print STDERR __PACKAGE__, ". Dropped table '$table_name'. \n" if ($self -> verbose);
# For Postgres, drop the sequence after dropping the table.
if ( ($self -> db_vendor eq 'POSTGRESQL') && ! $$arg{$table_name}{no_sequence})
{
$sql = "drop sequence $sequence_name";
$self -> dbh -> do($sql);
print STDERR __PACKAGE__, ". SQL: $sql. \n" if ($self -> verbose);
print STDERR __PACKAGE__, ". Dropped sequence '$sequence_name'. \n" if ($self -> verbose);
}
# Undo local $$dbh{RaiseError}.
$$dbh{RaiseError} = $raise_error;
$self -> dbh($dbh);
return '';
} # End of drop_table.
# --------------------------------------------------
sub generate_primary_index_name
{
my($self, $table_name) = @_;
my($hashref) = $self -> primary_index_name;
if (! $$hashref{$table_name})
{
$$hashref{$table_name} = $self -> db_vendor eq 'POSTGRESQL'
? "${table_name}_pkey"
: ''; # MySQL, Oracle, SQLite.
$self -> primary_index_name($hashref);
}
return $$hashref{$table_name};
} # End of generate_primary_index_name.
# --------------------------------------------------
sub generate_primary_key_sql
{
my($self, $table_name) = @_;
my($sequence_name) = $self -> generate_primary_sequence_name($table_name);
my($primary_key) =
($self -> db_vendor eq 'MYSQL')
? 'integer primary key auto_increment'
: ($self -> db_vendor eq 'SQLITE')
? 'integer primary key autoincrement'
: $self -> db_vendor eq 'ORACLE'
? 'integer primary key'
: "integer primary key default nextval('$sequence_name')"; # Postgres.
return $primary_key;
} # End of generate_primary_key_sql.
# --------------------------------------------------
sub generate_primary_sequence_name
{
my($self, $table_name) = @_;
my($hashref) = $self -> sequence_name;
if (! $$hashref{$table_name})
{
$$hashref{$table_name} = $self -> db_vendor =~ /(?:MYSQL|SQLITE)/
? ''
: "${table_name}_id_seq"; # Oracle, Postgres.
$self -> sequence_name($hashref);
}
return $$hashref{$table_name};
} # End of generate_primary_sequence_name.
# -----------------------------------------------
# Assumption: This code is only called in the case
# of Oracle and Postgres, and after importing data
# for all tables from a XML file (say).
# The mechanism used to import from XML does not
# activate the sequences because the primary keys
# are included in the data being imported.
# So, we have to reset the current values of the
# sequences up from their default values of 1 to
# the number of records in the corresponding table.
# If not, then the next call to nextval() would
# return a value of 2, which is already in use.
sub reset_all_sequences
{
my($self, $arg) = @_;
if ($self -> db_vendor ne 'MYSQL')
{
$self -> reset_sequence($_, $arg) for keys %{$self -> sequence_name};
}
} # End of reset_all_sequences.
# -----------------------------------------------
sub reset_sequence
{
my($self, $table_name, $arg) = @_;
$arg = {} if (! defined $arg);
$$arg{$table_name} = {} if (! defined $$arg{$table_name});
$$arg{$table_name}{no_sequence} = 0 if (! defined $$arg{$table_name}{no_sequence});
if (! $$arg{$table_name}{no_sequence})
{
my($sequence_name) = $self -> generate_primary_sequence_name($table_name);
my($sth) = $self -> dbh -> prepare("select count(*) from $table_name");
$sth -> execute();
my($max) = $sth -> fetch();
$max = $$max[0] || 0;
my($sql) = "select setval('$sequence_name', $max)";
$sth -> finish();
$self -> dbh -> do($sql);
print STDERR __PACKAGE__, ". SQL: $sql. \n" if ($self -> verbose);
print STDERR __PACKAGE__, ". Reset table '$table_name', sequence '$sequence_name' to $max. \n" if ($self -> verbose);
}
} # End of reset_sequence.
# --------------------------------------------------
1;
=head1 NAME
DBIx::Admin::CreateTable - Create and drop tables, primary indexes, and sequences
=head1 Synopsis
#!/usr/bin/env perl
use strict;
use warnings;
use DBI;
use DBIx::Admin::CreateTable;
# ----------------
my($dbh) = DBI -> connect(...);
my($creator) = DBIx::Admin::CreateTable -> new(dbh => $dbh, verbose => 1);
my($table_name) = 'test';
$creator -> drop_table($table_name);
my($primary_key) = $creator -> generate_primary_key_sql($table_name);
$creator -> create_table(<<SQL);
create table $table_name
(
id $primary_key,
data varchar(255)
)
SQL
See also xt/author/fk.t in L<DBIx::Admin::TableInfo>.
=head1 Description
C<DBIx::Admin::CreateTable> is a pure Perl module.
Database vendors supported: MySQL, Oracle, Postgres, SQLite.
Assumptions:
=over 4
=item Every table has a primary key
=item The primary key is a unique, non-null, integer
=item The primary key is a single column
=item The primary key column is called 'id'
=item If a primary key has a corresponding auto-created index, the index is called 't_pkey'
This is true for Postgres, where declaring a column as a primary key automatically results in the creation
of an associated index for that column. The index is named after the table, not after the column.
=item If a table 't' (with primary key 'id') has an associated sequence, the sequence is called 't_id_seq'
This is true for both Oracle and Postgres, which use sequences to populate primary key columns. The sequences
are named after both the table and the column.
=back
=head1 Constructor and initialization
new(...) returns an object of type C<DBIx::Admin::CreateTable>.
This is the class constructor.
Usage: DBIx::Admin::CreateTable -> new().
This method takes a set of parameters. Only the dbh parameter is mandatory.
For each parameter you wish to use, call new as new(param_1 => value_1, ...).
=over 4
=item dbh
This is a database handle, returned from the DBI connect() call.
This parameter is mandatory.
There is no default.
=item verbose
This is 0 or 1, to turn off or on printing of progress statements to STDERR.
This parameter is optional.
The default is 0.
=back
=head1 Method: create_table($sql, $arg)
Returns '' (empty string) if successful and DBI errstr() if there is an error.
$sql is the SQL to create the table.
$arg is an optional hash ref of options per table.
The keys are table names. The only sub-key at the moment is...
=over 4
=item no_sequence
$arg = {$table_name_1 => {no_sequence => 1}, $table_name_2 => {no_sequence => 1} };
can be used to tell create_table not to create a sequence for the given table.
You would use this on a CGI::Session-type table called 'sessions', for example,
when using Oracle or Postgres. With MySQL there would be no sequence anyway.
You would also normally use this on a table called 'log'.
The reason for this syntax is so you can use the same hash ref in a call to reset_all_sequences.
=back
Usage with CGI::Session:
my($creator) = DBIx::Admin::CreateTable -> new(dbh => $dbh, verbose => 1);
my($table_name) = 'sessions';
my($type) = $creator -> db_vendor() eq 'ORACLE' ? 'long' : 'text';
$creator -> drop_table($table_name);
$creator -> create_table(<<SQL, {$table_name => {no_sequence => 1} });
create table $table_name
(
id char(32) primary key,
a_session $type not null
)
SQL
Typical usage:
my($creator) = DBIx::Admin::CreateTable -> new(dbh => $dbh, verbose => 1);
my($table_name) = 'test';
my($primary_key) = $creator -> generate_primary_key_sql($table_name);
$creator -> drop_table($table_name);
$creator -> create_table(<<SQL);
create table $table_name
(
id $primary_key,
data varchar(255)
)
SQL
The SQL generated by this call to create_table() is spelled-out in the (SQL) table below.
Action:
Method: create_table($table_name, $arg).
Comment: Creation of tables and sequences.
Sequence: See generate_primary_sequence_name($table_name).
+----------|---------------------------------------------------+
| | Action for $$arg{$table_name} |
| Vendor | {no_sequence => 0} | {no_sequence => 1} |
+----------|------------------------------|--------------------+
| MySQL | Create table | Create table |
+----------|------------------------------|--------------------+
| Oracle | Create sequence before table | Create table |
+----------|------------------------------|--------------------+
| Postgres | Create sequence before table | Create table |
+----------|------------------------------|--------------------+
| SQLite | Create table | Create table |
+----------|------------------------------|--------------------+
SQL:
Method: create_table($table_name, $arg).
Comment: SQL generated.
Sequence: See generate_primary_sequence_name($table_name).
+----------|-------------------------------------------------------------------------------------+
| | SQL for $$arg{$table_name} |
| Vendor | {no_sequence => 0} | {no_sequence => 1} |
+----------|------------------------------------------|------------------------------------------+
| MySQL | create table $table_name | create table $table_name |
| | (id integer primary key | (id integer auto_increment |
| | auto_increment, | primary key, |
| | data varchar(255) ) | data varchar(255) ) |
+----------|------------------------------------------|------------------------------------------+
| Oracle | create sequence ${table_name}_id_seq & | |
| | create table $table_name | create table $table_name |
| | (id integer primary key, | (id integer primary key, |
| | data varchar(255) ) | data varchar(255) ) |
+----------|------------------------------------------|------------------------------------------+
| Postgres | create sequence ${table_name}_id_seq & | |
| | create table $table_name | create table $table_name |
| | (id integer primary key | (id integer primary key |
| | default nextval("${table_name}_id_seq"), | default nextval("${table_name}_id_seq"), |
| | data varchar(255) ) | data varchar(255) ) |
+----------|------------------------------------------|------------------------------------------+
| SQLite | create table $table_name | create table $table_name |
| | (id integer primary key | (id integer autoincrement |
| | autoincrement, | primary key, |
| | data varchar(255) ) | data varchar(255) ) |
+----------|------------------------------------------|------------------------------------------+
=head1 Method: db_vendor()
Returns an upper-case string identifying the database vendor.
Return string:
Method: db_vendor(db_vendor).
Comment: Value returned.
+----------|------------+
| Vendor | String |
+----------|------------+
| MySQL | MYSQL |
+----------|------------+
| Oracle | ORACLE |
+----------|------------+
| Postgres | POSTGRESQL |
+----------|------------+
| SQLite | SQLITE |
+----------|------------+
=head1 Method: drop_table($table_name, $arg)
Returns '' (empty string).
$table_name is the name of the table to drop.
$arg is an optional hash ref of options, the same as for C<create_table()>.
Action:
Method: drop_table($table_name, $arg).
Comment: Deletion of tables and sequences.
Sequence: See generate_primary_sequence_name($table_name).
+----------|-------------------------------------------------+
| | Action for $$arg{$table_name} |
| Vendor | {no_sequence => 0} | {no_sequence => 1} |
+----------|----------------------------|--------------------+
| MySQL | Drop table | Drop table |
+----------|----------------------------|--------------------+
| Oracle | Drop sequence before table | Drop table |
+----------|----------------------------|--------------------+
| Postgres | Drop sequence after table | Drop table |
+----------|----------------------------|--------------------+
| SQLite | Drop table | Drop table |
+----------|----------------------------|--------------------+
SQL:
Method: drop_table($table_name, $arg).
Comment: SQL generated.
Sequence: See generate_primary_sequence_name($table_name).
+----------|---------------------------------------------------------------+
| | SQL for $$arg{$table_name} |
| Vendor | {no_sequence => 0} | {no_sequence => 1} |
+----------|--------------------------------------|------------------------+
| MySQL | drop table $table_name | drop table $table_name |
+----------|--------------------------------------|------------------------+
| Oracle | drop sequence ${table_name}_id_seq & | |
| | drop table $table_name | drop table $table_name |
+----------|--------------------------------------|------------------------+
| Postgres | drop table $table_name & | drop table $table_name |
| | drop sequence ${table_name}_id_seq | |
+----------|--------------------------------------|------------------------+
| SQLite | drop table $table_name | drop table $table_name |
+----------|--------------------------------------|------------------------+
Note: drop_table() turns off RaiseError so we do not error if the sequence and table being deleted do not exist.
This is new in V 2.00.
=head1 Method: generate_primary_index_name($table_name)
Returns the name of the index corresponding to the primary key for the given table.
The module does not call this method.
SQL:
Method: generate_primary_index_name($table_name).
Comment: Generation of name of the index for the primary key.
+----------|--------------------+
| Vendor | SQL |
+----------|--------------------+
| MySQL | |
+----------|--------------------+
| Oracle | |
+----------|--------------------+
| Postgres | ${table_name}_pkey |
+----------|--------------------+
| SQLite | |
+----------|--------------------+
=head1 Method: generate_primary_key_sql($table_name)
Returns partial SQL for declaring the primary key for the given table.
See the Synopsis for how to use this method.
SQL:
Method: generate_primary_key_sql($table_name).
Comment: Generation of partial SQL for primary key.
Sequence: See generate_primary_sequence_name($table_name).
+----------|-----------------------------------------------------+
| Vendor | SQL |
+----------|-----------------------------------------------------+
| MySQL | integer primary key auto_increment |
+----------|-----------------------------------------------------+
| Oracle | integer primary key |
+----------|-----------------------------------------------------+
| Postgres | integer primary key default nextval($sequence_name) |
+----------|-----------------------------------------------------+
| SQLite | integer primary key autoincrement |
+----------|-----------------------------------------------------+
=head1 Method: generate_primary_sequence_name($table_name)
Returns the name of the sequence used to populate the primary key of the given table.
SQL:
Method: generate_primary_sequence_name($table_name).
Comment: Generation of name for sequence.
+----------|----------------------+
| Vendor | SQL |
+----------|----------------------+
| MySQL | |
+----------|----------------------+
| Oracle | ${table_name}_id_seq |
+----------|----------------------+
| Postgres | ${table_name}_id_seq |
+----------|----------------------+
| SQLite | |
+----------|----------------------+
=head1 Method: reset_all_sequences($arg)
Returns nothing.
Resets the primary key sequence for all tables, except those marked by $arg as not having a sequence.
Note: This method only works if called against an object which knows the names of all tables and sequences.
This means you must have called at least one of these, for each table:
=over
=item create_table
=item drop_table
=item generate_primary_key_sql
=item generate_primary_sequence_name
=back
$arg is an optional hash ref of options, the same as for C<create_table()>.
Summary:
Method: reset_all_sequences($arg).
Comment: Reset all sequences.
+----------|-------------------------------------------------------+
| Vendor | Action |
+----------|-------------------------------------------------------+
| MySQL | Do nothing |
+----------|-------------------------------------------------------+
| Oracle | Call reset_sequence($table_name, $arg) for all tables |
+----------|-------------------------------------------------------+
| Postgres | Call reset_sequence($table_name, $arg) for all tables |
+----------|-------------------------------------------------------+
| SQLite | Do nothing |
+----------|-------------------------------------------------------+
=head1 Method: reset_sequence($table_name, $arg)
Returns nothing.
Resets the primary key sequence for the given table, except if it is marked by $arg as not having a sequence.
$arg is an optional hash ref of options, the same as for C<create_table()>.
Summary:
Method: reset_sequence($table_name, $arg).
Comment: Reset one sequence.
Sequence: The value of the sequence is set to the number of records in the table.
+----------|-----------------------------------------+
| | Action for $$arg{$table_name} |
| Vendor | {no_sequence => 0} | {no_sequence => 1} |
+----------|--------------------|--------------------+
| MySQL | Do nothing | Do nothing |
+----------|--------------------|--------------------+
| Oracle | Set sequence value | Do nothing |
+----------|--------------------|--------------------+
| Postgres | Set sequence value | Do nothing |
+----------|--------------------|--------------------+
| SQLite | Do nothing | Do nothing |
+----------|--------------------|--------------------+
=head1 FAQ
=head2 Which versions of the servers did you test?
Versions as at 2014-03-07
+----------|------------+
| Vendor | V |
+----------|------------+
| MariaDB | 5.5.36 |
+----------|------------+
| Oracle | 10.2.0.1.0 | (Not tested for years)
+----------|------------+
| Postgres | 9.1.12 |
+----------|------------+
| SQLite | 3.7.17 |
+----------|------------+
=head2 Do all database servers accept the same 'create table' commands?
No. You have been warned.
References for 'Create table':
L<MySQL|https://dev.mysql.com/doc/refman/5.7/en/create-table.html>.
L<Postgres|http://www.postgresql.org/docs/9.3/interactive/sql-createtable.html>.
L<SQLite|https://sqlite.org/lang_createtable.html>.
Consider these:
create table one
(
id integer primary key autoincrement,
data varchar(255)
) $engine
create table two
(
id integer primary key autoincrement,
one_id integer not null,
data varchar(255),
foreign key(one_id) references one(id)
) $engine
Putting the 'foreign key' clause at the end makes it a table constraint. Some database servers, e.g. MySQL and Postgres,
allow you to attach it to a particular column, as explained next.
=over 4
=item o MySQL
The creates work as given, where $engine eq 'engine = innodb'.
Further, you can re-order the clauses in the 2nd create:
create table two
(
id integer primary key autoincrement,
one_id integer not null,
foreign key(one_id) references one(id),
data varchar(255)
) $engine
This also works, where $engine eq 'engine = innodb'.
However, if you use:
create table two
(
id integer primary key autoincrement,
one_id integer not null references one(id),
data varchar(255)
) $engine
Then the 'references' (foreign key) clause is parsed but discarded, even with 'engine = innodb'.
=item o Postgres
The creates work as given, where $engine = ''.
And you can re-order the clauses, as in the first example for MySQL.
=item o SQLite
The creates work as given, where $engine = ''.
But if you re-order the clauses:
create table two
(
id integer primary key autoincrement,
one_id integer not null,
foreign key(one_id) references one(id),
data varchar(255)
) $engine
Then you get a syntax error.
However, if you use:
create table two
(
id integer primary key autoincrement,
one_id integer not null references one(id),
data varchar(255)
) $engine
Then the 'references' (foreign key) clause is parsed, and it does create a foreign key relationship.
=back
Do not forget this when using SQLite:
$dbh -> do('pragma foreign_keys = on') if ($dsn =~ /SQLite/i);
=head2 Do I include the name of an auto-populated column in an insert statement?
Depends on the server. Some databases, e.g. Postgres, do I<not> want the name of the primary key
in the insert statement if the server is to generate a value for a column.
SQL for insert:
Comment: SQL for insertion of rows containing auto-populated values.
Sequence: See generate_primary_sequence_name($table_name).
+----------|-----------------------------------------------------------------------+
| Vendor | SQL |
+----------|-----------------------------------------------------------------------+
| MySQL | insert into $table_name (data) values (?) |
+----------|-----------------------------------------------------------------------+
| Oracle | insert into $table_name (id, data) values ($sequence_name.nextval, ?) |
+----------|-----------------------------------------------------------------------+
| Postgres | insert into $table_name (data) values (?) |
+----------|-----------------------------------------------------------------------+
| SQLite | insert into $table_name (id, data) values (undef, ?) |
+----------|-----------------------------------------------------------------------+
=head2 Do I have to use a sequence to populate a primary key?
Well, no, actually. See next question.
=head2 How to I override the auto-populated value for a primary key column?
By including the name and the value in the insert statement.
SQL for insert:
Comment: SQL for insertion of rows overriding auto-populated values.
+----------|--------------------------------------------------+
| Vendor | SQL |
+----------|--------------------------------------------------+
| MySQL | insert into $table_name (id, data) values (?, ?) |
+----------|--------------------------------------------------+
| Oracle | insert into $table_name (id, data) values (?, ?) |
+----------|--------------------------------------------------+
| Postgres | insert into $table_name (id, data) values (?, ?) |
+----------|--------------------------------------------------+
| SQLite | insert into $table_name (id, data) values (?, ?) |
+----------|--------------------------------------------------+
=head2 Are primary keys always not null and unique?
Yes. All servers document primary key as meaning both non null and unique.
=head2 See Also
L<DBIx::Admin::DSNManager>.
L<DBIx::Admin::TableInfo>.
=head1 Version Numbers
Version numbers < 1.00 represent development versions. From 1.00 up, they are production versions.
=head1 Repository
L<https://github.com/ronsavage/DBIx-Admin-CreateTable>
=head1 Support
Bugs should be reported via the CPAN bug tracker at
L<https://github.com/ronsavage/DBIx-Admin-CreateTable/issues>
=head1 Author
C<DBIx::Admin::CreateTable> was written by Ron Savage I<E<lt>ron@savage.net.auE<gt>> in 2006.
L<http://savage.net.au/>
=head1 Copyright
Australian copyright (c) 2006, Ron Savage.
All Programs of mine are 'OSI Certified Open Source Software';
you can redistribute them and/or modify them under the terms of
the Artistic or the GPL licences, copies of which is available at:
http://www.opensource.org/licenses/index.html
=cut
|