package SQL::Translator::Parser::DBI::PostgreSQL;
# -------------------------------------------------------------------
-# $Id: PostgreSQL.pm,v 1.7 2004-09-15 21:13:43 schiffbruechige Exp $
+# $Id: PostgreSQL.pm,v 1.8 2005-10-06 20:33:07 scottcain Exp $
# -------------------------------------------------------------------
# Copyright (C) 2002-4 SQLFairy Authors
#
=head1 DESCRIPTION
-Uses DBI methods to determine schema structure. DBI, of course,
-delegates to DBD::Pg, and versions < 1.31 of DBD::Pg don't return very
-useful information. It is recommended that you upgrade this module.
+Uses DBI to query PostgreSQL system tables to determine schema structure.
=cut
use SQL::Translator::Schema::Constants;
use vars qw[ $DEBUG $VERSION @EXPORT_OK ];
-$VERSION = sprintf "%d.%02d", q$Revision: 1.7 $ =~ /(\d+)\.(\d+)/;
+$VERSION = sprintf "%d.%02d", q$Revision: 1.8 $ =~ /(\d+)\.(\d+)/;
$DEBUG = 0 unless defined $DEBUG;
# -------------------------------------------------------------------
my $schema = $tr->schema;
- my ($sth, @tables, $columns);
- my $stuff;
-
- warn "DBD:Pg $DBD::Pg::VERSION is not likely to produce anything ".
- "useful. Upgrade to 1.31 or better if available.\n"
- unless ($DBD::Pg::VERSION ge '1.31');
-
- if ($dbh->{FetchHashKeyName} ne 'NAME_uc') {
- $dbh->{FetchHashKeyName} = 'NAME_uc';
- }
-
- if ($dbh->{ChopBlanks} != 1) {
- $dbh->{ChopBlanks} = 1;
- }
-
- $sth = $dbh->table_info();
-
- @tables = @{$sth->fetchall_arrayref({})};
-
- foreach my $table_info (@tables) {
- next
- unless (defined($table_info->{TABLE_TYPE}));
-
- if ($table_info->{TABLE_TYPE} eq 'TABLE'&&
- $table_info->{TABLE_SCHEM} eq 'public') {
- my $table = $schema->add_table(
- name => $table_info->{TABLE_NAME},
- type => $table_info->{TABLE_TYPE},
+ my $column_select = $dbh->prepare(
+ "SELECT a.attname, t.typname, a.attnum,a.atttypmod as length,
+ a.attnotnull, a.atthasdef, d.adsrc
+ FROM pg_type t,pg_attribute a
+ LEFT JOIN pg_attrdef d ON (d.adrelid = a.attrelid AND a.attnum = d.adnum)
+ WHERE a.attrelid=? AND attnum>0
+ AND a.atttypid=t.oid
+ ORDER BY a.attnum"
+ );
+
+ my $index_select = $dbh->prepare(
+ "SELECT oid, c.relname, i.indkey, i.indnatts, i.indisunique,
+ i.indisprimary, pg_get_indexdef(oid) AS create_string
+ FROM pg_class c,pg_index i
+ WHERE c.relnamespace=2200 AND c.relkind='i'
+ AND c.oid=i.indexrelid AND i.indrelid=?"
+ );
+
+ my $table_select = $dbh->prepare(
+ "SELECT oid,relname FROM pg_class WHERE relnamespace IN
+ (SELECT oid FROM pg_namespace WHERE nspname='public')
+ AND relkind='r';"
+ );
+ $table_select->execute();
+
+ while ( my $tablehash = $table_select->fetchrow_hashref ) {
+
+ my $table_name = $$tablehash{'relname'};
+ my $table_oid = $$tablehash{'oid'};
+
+ my $table = $schema->add_table(
+ name => $table_name,
+ #what is type? type => $table_info->{TABLE_TYPE},
) || die $schema->error;
+ $column_select->execute($table_oid);
+
+ while (my $columnhash = $column_select->fetchrow_hashref ) {
- my $cols = $dbh->column_info(undef,
- $table_info->{TABLE_SCHEM},
- $table_info->{TABLE_NAME},
- "%" )->fetchall_arrayref({});
+ $table->add_field(
+ name => $$columnhash{'attname'},
+ default_value => $$columnhash{'adsrc'},
+ data_type => $$columnhash{'typename'},
+ order => $$columnhash{'attnum'},
+ size => $$columnhash{'length'},
+ nullable => $$columnhash{'attnotnull'} eq 't'
+ ? 0 : 1,
+ ) || die $table->error;
+ }
- foreach my $c (@{$cols}) {
- print Dumper($c) if $DEBUG;
- my $f = $table->add_field(
- name => $c->{COLUMN_NAME},
- default_value => $c->{COLUMN_DEF},
- data_type => $c->{TYPE_NAME},
- order => $c->{ORDINAL_POSITION},
- size => $c->{COLUMN_SIZE},
- ) || die $table->error;
+ $index_select->execute($table_oid);
+
+ my @column_names = $table->field_names();
+ while (my $indexhash = $index_select->fetchrow_hashref ) {
+ #don't deal with function indexes at the moment
+ next if ($$indexhash{'indkey'} eq ''
+ or !defined($$indexhash{'indkey'}) );
+
+ my $type;
+ if ($$indexhash{'indisprimary'} eq 't') {
+ $type = PRIMARY_KEY;
+ } elsif ($$indexhash{'indisunique'} eq 't') {
+ $type = UNIQUE;
+ } else {
+ $type = NORMAL;
+ }
-
- $f->is_nullable($c->{NULLABLE} == 1);
+ my @column_ids = split /\s+/, $$indexhash{'indkey'};
+ my @columns;
+ foreach my $col (@column_ids) {
+ push @columns, $column_names[($col - 1)];
}
+
+ $table->add_index(
+ name => $$indexhash{'relname'},
+ type => $type,
+ fields => @columns,
+ ) || die $table->error;
}
}
=head1 AUTHOR
+Scott Cain E<lt>cain@cshl.eduE<gt>, previous author:
Paul Harrington E<lt>harringp@deshaw.comE<gt>.
=head1 SEE ALSO