Bumping version to 1.61
[dbsrgits/SQL-Translator.git] / lib / SQL / Translator / Parser / DBI / PostgreSQL.pm
CommitLineData
80ae061a 1package SQL::Translator::Parser::DBI::PostgreSQL;
2
80ae061a 3=head1 NAME
4
5SQL::Translator::Parser::DBI::PostgreSQL - parser for DBD::Pg
6
7=head1 SYNOPSIS
8
9See SQL::Translator::Parser::DBI.
10
11=head1 DESCRIPTION
12
ea93df61 13Uses DBI to query PostgreSQL system tables to determine schema structure.
80ae061a 14
15=cut
16
17use strict;
f27f9229 18use warnings;
80ae061a 19use DBI;
80ae061a 20use Data::Dumper;
21use SQL::Translator::Schema::Constants;
22
0c04c5a2 23our ( $DEBUG, @EXPORT_OK );
752a0ffc 24our $VERSION = '1.61';
80ae061a 25$DEBUG = 0 unless defined $DEBUG;
26
cfeaa28f 27my $actions = {c => 'cascade',
28 r => 'restrict',
29 a => 'no action',
30 n => 'set null',
31 d => 'set default',
32 };
33
80ae061a 34sub parse {
35 my ( $tr, $dbh ) = @_;
36
638e82c2 37 my $schema = $tr->schema;
80ae061a 38
d2522b19 39 my $column_select = $dbh->prepare(
a23f9a9d 40 "SELECT a.attname, format_type(t.oid, a.atttypmod) as typname, a.attnum,
fd52d7dd 41 a.atttypmod as length, a.attnotnull, a.atthasdef, ad.adsrc,
42 d.description
43 FROM pg_type t, pg_attribute a
44 LEFT JOIN pg_attrdef ad ON (ad.adrelid = a.attrelid AND a.attnum = ad.adnum)
45 LEFT JOIN pg_description d ON (a.attrelid=d.objoid AND a.attnum=d.objsubid)
d2522b19 46 WHERE a.attrelid=? AND attnum>0
47 AND a.atttypid=t.oid
48 ORDER BY a.attnum"
ea93df61 49 );
d2522b19 50
51 my $index_select = $dbh->prepare(
52 "SELECT oid, c.relname, i.indkey, i.indnatts, i.indisunique,
53 i.indisprimary, pg_get_indexdef(oid) AS create_string
54 FROM pg_class c,pg_index i
122353c5 55 WHERE c.relnamespace IN (SELECT oid FROM pg_namespace WHERE nspname='public') AND c.relkind='i'
d2522b19 56 AND c.oid=i.indexrelid AND i.indrelid=?"
57 );
58
59 my $table_select = $dbh->prepare(
fd52d7dd 60 "SELECT c.oid, c.relname, d.description
61 FROM pg_class c
62 LEFT JOIN pg_description d ON c.oid=d.objoid AND d.objsubid=0
63 WHERE relnamespace IN
d2522b19 64 (SELECT oid FROM pg_namespace WHERE nspname='public')
65 AND relkind='r';"
66 );
cfeaa28f 67
68 my $fk_select = $dbh->prepare(
69 q/
70SELECT r.conname,
71 c.relname,
72 d.relname AS frelname,
73 r.conkey,
74 ARRAY(SELECT column_name::varchar
75 FROM information_schema.columns
76 WHERE ordinal_position = ANY (r.conkey)
77 AND table_schema = n.nspname
78 AND table_name = c.relname ) AS fields,
79 r.confkey,
80 ARRAY(SELECT column_name::varchar
81 FROM information_schema.columns
82 WHERE ordinal_position = ANY (r.confkey)
83 AND table_schema = n.nspname
84 AND table_name = d.relname ) AS reference_fields,
85 r.confupdtype,
86 r.confdeltype,
87 r.confmatchtype
88
89FROM pg_catalog.pg_constraint r
90
91JOIN pg_catalog.pg_class c
92 ON c.oid = r.conrelid
93 AND r.contype = 'f'
94
95JOIN pg_catalog.pg_class d
96 ON d.oid = r.confrelid
97
98JOIN pg_catalog.pg_namespace n
99 ON n.oid = c.relnamespace
100
101WHERE pg_catalog.pg_table_is_visible(c.oid)
102 AND n.nspname = ?
103 AND c.relname = ?
104ORDER BY 1;
105 /) or die "Can't prepare: $@";
ea93df61 106
d2522b19 107 $table_select->execute();
108
109 while ( my $tablehash = $table_select->fetchrow_hashref ) {
110
111 my $table_name = $$tablehash{'relname'};
ea93df61 112 my $table_oid = $$tablehash{'oid'};
d2522b19 113 my $table = $schema->add_table(
114 name => $table_name,
115 #what is type? type => $table_info->{TABLE_TYPE},
638e82c2 116 ) || die $schema->error;
80ae061a 117
fd52d7dd 118 $table->comments($$tablehash{'description'}) if $$tablehash{'description'};
119
d2522b19 120 $column_select->execute($table_oid);
121
122 while (my $columnhash = $column_select->fetchrow_hashref ) {
638e82c2 123
ea93df61 124 #data_type seems to not be populated; perhaps there needs to
31f10179 125 #be a mapping of query output to reserved constants in sqlt?
126
127 my $col = $table->add_field(
d2522b19 128 name => $$columnhash{'attname'},
129 default_value => $$columnhash{'adsrc'},
7ed7402c 130 data_type => $$columnhash{'typname'},
d2522b19 131 order => $$columnhash{'attnum'},
d2522b19 132 ) || die $table->error;
31f10179 133
a23f9a9d 134 $col->{size} = [$$columnhash{'length'}]
135 if $$columnhash{'length'}>0 && $$columnhash{'length'}<=0xFFFF;
7ed7402c 136 $col->{is_nullable} = $$columnhash{'attnotnull'} ? 0 : 1;
fd52d7dd 137 $col->comments($$columnhash{'description'}) if $$columnhash{'description'};
d2522b19 138 }
638e82c2 139
d2522b19 140 $index_select->execute($table_oid);
141
142 my @column_names = $table->field_names();
143 while (my $indexhash = $index_select->fetchrow_hashref ) {
144 #don't deal with function indexes at the moment
ea93df61 145 next if ($$indexhash{'indkey'} eq ''
d2522b19 146 or !defined($$indexhash{'indkey'}) );
147
db195df8 148 my @columns = map $column_names[$_ - 1], split /\s+/, $$indexhash{'indkey'};
149
d2522b19 150 my $type;
31f10179 151 if ($$indexhash{'indisprimary'}) {
152 $type = UNIQUE; #PRIMARY_KEY;
153
154 #tell sqlt that this is the primary key:
db195df8 155 for my $column (@columns) {
156 $table->get_field($column)->{is_primary_key}=1;
157 }
31f10179 158
159 } elsif ($$indexhash{'indisunique'}) {
cfeaa28f 160 $type = UNIQUE;
d2522b19 161 } else {
162 $type = NORMAL;
163 }
638e82c2 164
c601ca5d 165
d2522b19 166 $table->add_index(
167 name => $$indexhash{'relname'},
168 type => $type,
31f10179 169 fields => \@columns,
d2522b19 170 ) || die $table->error;
638e82c2 171 }
ea93df61 172
cfeaa28f 173 $fk_select->execute('public',$table_name) or die "Can't execute: $@";
174 my $fkeys = $fk_select->fetchall_arrayref({});
1f5b2625 175 $DEBUG and print Dumper $fkeys;
cfeaa28f 176 for my $con (@$fkeys){
177 my $con_name = $con->{conname};
178 my $fields = $con->{fields};
179 my $reference_fields = $con->{reference_fields};
180 my $reference_table = $con->{frelname};
181 my $on_upd = $con->{confupdtype};
182 my $on_del = $con->{confdeltype};
183 $table->add_constraint(
184 name => $con_name,
185 type => 'foreign_key',
186 fields => $fields,
187 reference_fields => $reference_fields,
188 reference_table => $reference_table,
189 on_delete => $actions->{$on_upd},
190 on_update => $actions->{$on_del},
191 );
192 }
80ae061a 193 }
ea93df61 194
80ae061a 195
196 return 1;
197}
198
1991;
200
201# -------------------------------------------------------------------
13b0b70f 202# Time is a waste of money.
203# Oscar Wilde
80ae061a 204# -------------------------------------------------------------------
205
206=pod
207
208=head1 AUTHOR
209
ea93df61 210Scott Cain E<lt>cain@cshl.eduE<gt>, previous author:
13b0b70f 211Paul Harrington E<lt>harringp@deshaw.comE<gt>.
80ae061a 212
213=head1 SEE ALSO
214
13b0b70f 215SQL::Translator, DBD::Pg.
80ae061a 216
217=cut