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