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
|
package SQL::Translator::Parser::DBI::PostgreSQL;
=head1 NAME
SQL::Translator::Parser::DBI::PostgreSQL - parser for DBD::Pg
=head1 SYNOPSIS
See SQL::Translator::Parser::DBI.
=head1 DESCRIPTION
Uses DBI to query PostgreSQL system tables to determine schema structure.
=cut
use strict;
use warnings;
use DBI;
use Data::Dumper;
use SQL::Translator::Schema::Constants;
our ( $DEBUG, @EXPORT_OK );
our $VERSION = '1.59';
$DEBUG = 0 unless defined $DEBUG;
my $actions = {c => 'cascade',
r => 'restrict',
a => 'no action',
n => 'set null',
d => 'set default',
};
sub parse {
my ( $tr, $dbh ) = @_;
my $schema = $tr->schema;
my $column_select = $dbh->prepare(
"SELECT a.attname, format_type(t.oid, a.atttypmod) as typname, a.attnum,
a.atttypmod as length, a.attnotnull, a.atthasdef, ad.adsrc,
d.description
FROM pg_type t, pg_attribute a
LEFT JOIN pg_attrdef ad ON (ad.adrelid = a.attrelid AND a.attnum = ad.adnum)
LEFT JOIN pg_description d ON (a.attrelid=d.objoid AND a.attnum=d.objsubid)
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,
ARRAY(SELECT a.attname
FROM pg_attribute a
WHERE a.attrelid=i.indrelid AND a.attnum = ANY(i.indkey)
) AS attname,
i.indisprimary, pg_get_indexdef(oid) AS create_string
FROM pg_class c,pg_index i
WHERE c.relnamespace IN (SELECT oid FROM pg_namespace WHERE nspname='public') AND c.relkind='i'
AND c.oid=i.indexrelid AND i.indrelid=?"
);
my $table_select = $dbh->prepare(
"SELECT c.oid, c.relname, d.description
FROM pg_class c
LEFT JOIN pg_description d ON c.oid=d.objoid AND d.objsubid=0
WHERE relnamespace IN
(SELECT oid FROM pg_namespace WHERE nspname='public')
AND relkind='r';"
);
my $fk_select = $dbh->prepare(
q/
SELECT r.conname,
c.relname,
d.relname AS frelname,
r.conkey,
ARRAY(SELECT column_name::varchar
FROM information_schema.columns
WHERE ordinal_position = ANY (r.conkey)
AND table_schema = n.nspname
AND table_name = c.relname ) AS fields,
r.confkey,
ARRAY(SELECT column_name::varchar
FROM information_schema.columns
WHERE ordinal_position = ANY (r.confkey)
AND table_schema = n.nspname
AND table_name = d.relname ) AS reference_fields,
r.confupdtype,
r.confdeltype,
r.confmatchtype
FROM pg_catalog.pg_constraint r
JOIN pg_catalog.pg_class c
ON c.oid = r.conrelid
AND r.contype = 'f'
JOIN pg_catalog.pg_class d
ON d.oid = r.confrelid
JOIN pg_catalog.pg_namespace n
ON n.oid = c.relnamespace
WHERE pg_catalog.pg_table_is_visible(c.oid)
AND n.nspname = ?
AND c.relname = ?
ORDER BY 1;
/) or die "Can't prepare: $@";
$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;
$table->comments($$tablehash{'description'}) if $$tablehash{'description'};
$column_select->execute($table_oid);
while (my $columnhash = $column_select->fetchrow_hashref ) {
#data_type seems to not be populated; perhaps there needs to
#be a mapping of query output to reserved constants in sqlt?
my $col = $table->add_field(
name => $$columnhash{'attname'},
default_value => $$columnhash{'adsrc'},
data_type => $$columnhash{'typname'},
order => $$columnhash{'attnum'},
) || die $table->error;
$col->{size} = [$$columnhash{'length'}]
if $$columnhash{'length'}>0 && $$columnhash{'length'}<=0xFFFF;
$col->{is_nullable} = $$columnhash{'attnotnull'} ? 0 : 1;
$col->comments($$columnhash{'description'}) if $$columnhash{'description'};
}
$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'}) {
$type = UNIQUE; #PRIMARY_KEY;
#tell sqlt that this is the primary key:
my $col_name=$column_names[($$indexhash{'indkey'} - 1)];
$table->get_field($col_name)->{is_primary_key}=1;
} elsif ($$indexhash{'indisunique'}) {
$type = UNIQUE;
} else {
$type = NORMAL;
}
my @column_ids = split /\s+/, $$indexhash{'indkey'};
my @columns = split /\s+/, $$indexhash{'attname'};
$table->add_index(
name => $$indexhash{'relname'},
type => $type,
fields => \@columns,
) || die $table->error;
}
$fk_select->execute('public',$table_name) or die "Can't execute: $@";
my $fkeys = $fk_select->fetchall_arrayref({});
$DEBUG and print Dumper $fkeys;
for my $con (@$fkeys){
my $con_name = $con->{conname};
my $fields = $con->{fields};
my $reference_fields = $con->{reference_fields};
my $reference_table = $con->{frelname};
my $on_upd = $con->{confupdtype};
my $on_del = $con->{confdeltype};
$table->add_constraint(
name => $con_name,
type => 'foreign_key',
fields => $fields,
reference_fields => $reference_fields,
reference_table => $reference_table,
on_delete => $actions->{$on_upd},
on_update => $actions->{$on_del},
);
}
}
return 1;
}
1;
# -------------------------------------------------------------------
# Time is a waste of money.
# Oscar Wilde
# -------------------------------------------------------------------
=pod
=head1 AUTHOR
Scott Cain E<lt>cain@cshl.eduE<gt>, previous author:
Paul Harrington E<lt>harringp@deshaw.comE<gt>.
=head1 SEE ALSO
SQL::Translator, DBD::Pg.
=cut
|