File: Pg.pm

package info (click to toggle)
libdbix-dbschema-perl 0.47-1
  • links: PTS, VCS
  • area: main
  • in suites: bookworm, forky, sid, trixie
  • size: 244 kB
  • sloc: perl: 1,686; makefile: 2
file content (411 lines) | stat: -rw-r--r-- 11,322 bytes parent folder | download
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
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
package DBIx::DBSchema::DBD::Pg;
use base qw(DBIx::DBSchema::DBD);

use strict;
use DBD::Pg 1.41;

our $VERSION = '0.21';

our %typemap = (
  'BLOB'           => 'BYTEA',
  'LONG VARBINARY' => 'BYTEA',
  'TIMESTAMP'      => 'TIMESTAMP WITH TIME ZONE',
);

=head1 NAME

DBIx::DBSchema::DBD::Pg - PostgreSQL native driver for DBIx::DBSchema

=head1 SYNOPSIS

use DBI;
use DBIx::DBSchema;

$dbh = DBI->connect('dbi:Pg:dbname=database', 'user', 'pass');
$schema = new_native DBIx::DBSchema $dbh;

=head1 DESCRIPTION

This module implements a PostgreSQL-native driver for DBIx::DBSchema.

=cut

sub default_db_schema  { 'public'; }

sub columns {
  my($proto, $dbh, $table) = @_;
  my $sth = $dbh->prepare(<<END) or die $dbh->errstr;
    SELECT a.attname, t.typname, a.attlen, a.atttypmod, a.attnotnull,
           a.atthasdef, a.attnum
    FROM pg_class c, pg_attribute a, pg_type t
    WHERE c.relname = '$table'
      AND a.attnum > 0 AND a.attrelid = c.oid AND a.atttypid = t.oid
    ORDER BY a.attnum
END
  $sth->execute or die $sth->errstr;

  map {

    my $type = $_->{'typname'};
    $type = 'char' if $type eq 'bpchar';

    my $len = '';
    if ( $_->{attlen} == -1 && $_->{atttypmod} != -1 
         && $_->{typname} ne 'text'                  ) {
      $len = $_->{atttypmod} - 4;
      if ( $_->{typname} eq 'numeric' ) {
        $len = ($len >> 16). ','. ($len & 0xffff);
      }
    }

    my $default = '';
    if ( $_->{atthasdef} ) {
      my $attnum = $_->{attnum};
      my $d_sth = $dbh->prepare(<<END) or die $dbh->errstr;
        SELECT pg_get_expr(d.adbin, d.adrelid) FROM pg_attrdef d, pg_class c
        WHERE c.relname = '$table' AND c.oid = d.adrelid AND d.adnum = $attnum
END
      $d_sth->execute or die $d_sth->errstr;

      $default = $d_sth->fetchrow_arrayref->[0];

      if ( _type_needs_quoting($type) ) {
        $default =~ s/::([\w ]+)$//; #save typecast info?
        if ( $default =~ /^'(.*)'$/ ) {
          $default = $1;
          $default = \"''" if $default eq '';
        } else {
          my $value = $default;
          $default = \$value;
        }
      } elsif ( $default =~ /^[a-z]/i ) { #sloppy, but it'll do
        my $value = $default;
        $default = \$value;
      }

    }

    [
      $_->{'attname'},
      $type,
      ! $_->{'attnotnull'},
      $len,
      $default,
      ''  #local
    ];

  } @{ $sth->fetchall_arrayref({}) };
}

sub primary_key {
  my($proto, $dbh, $table) = @_;
  my $sth = $dbh->prepare(<<END) or die $dbh->errstr;
    SELECT a.attname, a.attnum
    FROM pg_class c, pg_attribute a, pg_type t
    WHERE c.relname = '${table}_pkey'
      AND a.attnum > 0 AND a.attrelid = c.oid AND a.atttypid = t.oid
END
  $sth->execute or die $sth->errstr;
  my $row = $sth->fetchrow_hashref or return '';
  $row->{'attname'};
}

sub unique {
  my($proto, $dbh, $table) = @_;
  my $gratuitous = { map { $_ => [ $proto->_index_fields($dbh, $_ ) ] }
      grep { $proto->_is_unique($dbh, $_ ) }
        $proto->_all_indices($dbh, $table)
  };
}

sub index {
  my($proto, $dbh, $table) = @_;
  my $gratuitous = { map { $_ => [ $proto->_index_fields($dbh, $_ ) ] }
      grep { ! $proto->_is_unique($dbh, $_ ) }
        $proto->_all_indices($dbh, $table)
  };
}

sub _all_indices {
  my($proto, $dbh, $table) = @_;
  my $sth = $dbh->prepare(<<END) or die $dbh->errstr;
    SELECT c2.relname
    FROM pg_class c, pg_class c2, pg_index i
    WHERE c.relname = '$table' AND c.oid = i.indrelid AND i.indexrelid = c2.oid
END
  $sth->execute or die $sth->errstr;
  map { $_->{'relname'} }
    grep { $_->{'relname'} !~ /_pkey$/ }
      @{ $sth->fetchall_arrayref({}) };
}

sub _index_fields {
  my($proto, $dbh, $index) = @_;
  my $sth = $dbh->prepare(<<END) or die $dbh->errstr;
    SELECT a.attname, a.attnum
    FROM pg_class c, pg_attribute a, pg_type t
    WHERE c.relname = '$index'
      AND a.attnum > 0 AND a.attrelid = c.oid AND a.atttypid = t.oid
    ORDER BY a.attnum
END
  $sth->execute or die $sth->errstr;
  map { $_->{'attname'} } @{ $sth->fetchall_arrayref({}) };
}

sub _is_unique {
  my($proto, $dbh, $index) = @_;
  my $sth = $dbh->prepare(<<END) or die $dbh->errstr;
    SELECT i.indisunique
    FROM pg_index i, pg_class c, pg_am a
    WHERE i.indexrelid = c.oid AND c.relname = '$index' AND c.relam = a.oid
END
  $sth->execute or die $sth->errstr;
  my $row = $sth->fetchrow_hashref or die 'guru meditation #420';
  $row->{'indisunique'};
}

#using this
#******** QUERY **********
#SELECT conname,
#  pg_catalog.pg_get_constraintdef(r.oid, true) as condef
#FROM pg_catalog.pg_constraint r
#WHERE r.conrelid = '16457' AND r.contype = 'f' ORDER BY 1;
#**************************

# what's this do?
#********* QUERY **********
#SELECT conname, conrelid::pg_catalog.regclass,
#  pg_catalog.pg_get_constraintdef(c.oid, true) as condef
#FROM pg_catalog.pg_constraint c
#WHERE c.confrelid = '16457' AND c.contype = 'f' ORDER BY 1;
#**************************

sub constraints {
  my($proto, $dbh, $table) = @_;
  my $sth = $dbh->prepare(<<END) or die $dbh->errstr;
    SELECT conname, pg_catalog.pg_get_constraintdef(r.oid, true) as condef
      FROM pg_catalog.pg_constraint r
        WHERE r.conrelid = ( SELECT oid FROM pg_class
                               WHERE relname = '$table'
                                 AND pg_catalog.pg_table_is_visible(oid)
                           )
          AND r.contype = 'f'
END
  $sth->execute;

  map { $_->{condef}
        =~ /^FOREIGN KEY \(([\w\, ]+)\) REFERENCES (\w+)\(([\w\, ]+)\)\s*(.*)$/i
            or die "unparsable constraint: ". $_->{condef};
        my($columns, $table, $references, $etc ) = ($1, $2, $3, $4);
        my $match = ( $etc =~ /MATCH (\w+)/i ) ? "MATCH $1" : '';
        my $on_delete = ( $etc =~ /ON DELETE ((NO |SET )?\w+)/i ) ? $1 : '';
        my $on_update = ( $etc =~ /ON UPDATE ((NO |SET )?\w+)/i ) ? $1 : '';
        +{ 'constraint' => $_->{conname},
           'columns'    => [ split(/,\s*/, $columns) ],
           'table'      => $table,
           'references' => [ split(/,\s*/, $references) ],
           'match'      => $match,
           'on_delete'  => $on_delete,
           'on_update'  => $on_update,
         };
      }
    grep $_->{condef} =~ /^\s*FOREIGN\s+KEY/,
      @{ $sth->fetchall_arrayref( {} ) };
}

sub add_column_callback {
  my( $proto, $dbh, $table, $column_obj ) = @_;
  my $name = $column_obj->name;

  my $pg_server_version = $dbh->{'pg_server_version'};
  my $warning = '';
  unless ( $pg_server_version =~ /\d/ ) {
    $warning = "WARNING: no pg_server_version!  Assuming >= 7.3\n";
    $pg_server_version = 70300;
  }

  my $hashref = { 'sql_after' => [], };

  if ( $column_obj->type =~ /^(\w*)SERIAL$/i ) {

    $hashref->{'effective_type'} = uc($1).'INT';

    #needs more work for old Pg?
      
    my $nextval;
    warn $warning if $warning;
    if ( $pg_server_version >= 70300 ) {
      my $db_schema  = default_db_schema();
      $nextval = "nextval('$db_schema.${table}_${name}_seq'::text)";
    } else {
      $nextval = "nextval('${table}_${name}_seq'::text)";
    }

    push @{ $hashref->{'sql_after'} }, 
      "ALTER TABLE $table ALTER COLUMN $name SET DEFAULT $nextval",
      "CREATE SEQUENCE ${table}_${name}_seq",
      "UPDATE $table SET $name = $nextval WHERE $name IS NULL",
    ;

  }

  if ( ! $column_obj->null ) {
    $hashref->{'effective_null'} = 'NULL';

    warn $warning if $warning;
    if ( $pg_server_version >= 70300 ) {

      push @{ $hashref->{'sql_after'} },
        "ALTER TABLE $table ALTER $name SET NOT NULL";

    } else {

      push @{ $hashref->{'sql_after'} },
        "UPDATE pg_attribute SET attnotnull = TRUE ".
        " WHERE attname = '$name' ".
        " AND attrelid = ( SELECT oid FROM pg_class WHERE relname = '$table' )";

    }

  }

  $hashref;

}

sub alter_column_callback {
  my( $proto, $dbh, $table, $old_column, $new_column ) = @_;
  my $name = $old_column->name;

  my %canonical = (
    'SMALLINT'         => 'INT2',
    'INT'              => 'INT4',
    'BIGINT'           => 'INT8',
    'SERIAL'           => 'INT4',
    'BIGSERIAL'        => 'INT8',
    'DECIMAL'          => 'NUMERIC',
    'REAL'             => 'FLOAT4',
    'DOUBLE PRECISION' => 'FLOAT8',
    'BLOB'             => 'BYTEA',
    'TIMESTAMP'        => 'TIMESTAMPTZ',
  );
  foreach ($old_column, $new_column) {
    $_->type($canonical{uc($_->type)}) if $canonical{uc($_->type)};
  }

  my $pg_server_version = $dbh->{'pg_server_version'};
  my $warning = '';
  unless ( $pg_server_version =~ /\d/ ) {
    $warning = "WARNING: no pg_server_version!  Assuming >= 7.3\n";
    $pg_server_version = 70300;
  }

  my $hashref = {};

  #change type
  if ( ( $canonical{uc($old_column->type)} || uc($old_column->type) )
         ne ( $canonical{uc($new_column->type)} || uc($new_column->type) )
       || $old_column->length ne $new_column->length
     )
  {

    warn $warning if $warning;
    if ( $pg_server_version >= 80000 ) {

      $hashref->{'sql_alter_type'} =
        "ALTER COLUMN ". $new_column->name.
        " TYPE ". $new_column->type.
        ( ( defined($new_column->length) && $new_column->length )
              ? '('.$new_column->length.')'
              : ''
        )

    } else {
      warn "WARNING: can't yet change column types for Pg < version 8\n";
    }

  }

  # change nullability from NOT NULL to NULL
  if ( ! $old_column->null && $new_column->null ) {

    warn $warning if $warning;
    if ( $pg_server_version < 70300 ) {
      $hashref->{'sql_alter_null'} =
        "UPDATE pg_attribute SET attnotnull = FALSE
          WHERE attname = '$name'
            AND attrelid = ( SELECT oid FROM pg_class
                               WHERE relname = '$table'
                           )";
    }

  }

  # change nullability from NULL to NOT NULL...
  # this one could be more complicated, need to set a DEFAULT value and update
  # the table first...
  if ( $old_column->null && ! $new_column->null ) {

    warn $warning if $warning;
    if ( $pg_server_version < 70300 ) {
      $hashref->{'sql_alter_null'} =
        "UPDATE pg_attribute SET attnotnull = TRUE
           WHERE attname = '$name'
             AND attrelid = ( SELECT oid FROM pg_class
                                WHERE relname = '$table'
                            )";
    }

  }

  $hashref;

}

sub column_value_needs_quoting {
  my($proto, $col) = @_;
  _type_needs_quoting($col->type);
}

sub _type_needs_quoting {
  my $type = shift;
  $type !~ m{^(
               int(?:2|4|8)?
             | smallint
             | integer
             | bigint
             | (?:numeric|decimal)(?:\(\d+(?:\s*\,\s*\d+\))?)?
             | real
             | double\s+precision
             | float(?:\(\d+\))?
             | serial(?:4|8)?
             | bigserial
             )$}ix;
}


=head1 AUTHOR

Ivan Kohler <ivan-dbix-dbschema@420.am>

=head1 COPYRIGHT

Copyright (c) 2000 Ivan Kohler
Copyright (c) 2000 Mail Abuse Prevention System LLC
Copyright (c) 2009-2013 Freeside Internet Services, Inc.
All rights reserved.
This program is free software; you can redistribute it and/or modify it under
the same terms as Perl itself.

=head1 BUGS

columns doesn't return column default information.

=head1 SEE ALSO

L<DBIx::DBSchema>, L<DBIx::DBSchema::DBD>, L<DBI>, L<DBI::DBD>

=cut 

1;