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