-
Notifications
You must be signed in to change notification settings - Fork 24
/
postgresql_autodoc.pl
executable file
·1930 lines (1679 loc) · 70.6 KB
/
postgresql_autodoc.pl
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
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
#!/usr/bin/env perl
# -- # -*- Perl -*-w
# $Header: /cvsroot/autodoc/autodoc/postgresql_autodoc.pl,v 1.30 2012/01/05 15:30:33 rbt Exp $
# Imported 1.22 2002/02/08 17:09:48 into sourceforge
# Postgres Auto-Doc Version 1.41
# License
# -------
# Copyright (c) 2001-2009, Rod Taylor
# All rights reserved.
#
# Redistribution and use in source and binary forms, with or without
# modification, are permitted provided that the following conditions
# are met:
#
# 1. Redistributions of source code must retain the above copyright
# notice, this list of conditions and the following disclaimer.
#
# 2. Redistributions in binary form must reproduce the above
# copyright notice, this list of conditions and the following
# disclaimer in the documentation and/or other materials provided
# with the distribution.
#
# 3. Neither the name of the InQuent Technologies Inc. nor the names
# of its contributors may be used to endorse or promote products
# derived from this software without specific prior written
# permission.
#
# THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS
# ``AS IS'' AND ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT
# LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR
# A PARTICULAR PURPOSE ARE DISCLAIMED. IN NO EVENT SHALL THE FREEBSD
# PROJECT OR CONTRIBUTORS BE LIABLE FOR ANY DIRECT, INDIRECT, INCIDENTAL,
# SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES (INCLUDING, BUT NOT
# LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES; LOSS OF USE,
# DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON ANY
# THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT
# (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE
# OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE.
# About Project
# -------------
# Various details about the project and related items can be found at
# the website
#
# http://www.rbt.ca/autodoc/
use strict;
use warnings;
use DBI;
use Fcntl;
# Allows file templates
use HTML::Template;
# Allow reading a password from stdin
use Term::ReadKey;
# Used for storing comments when external processor is used
use File::Temp qw{ tempfile };
sub main($) {
my ($ARGV) = @_;
my %db;
# The templates path
# @@TEMPLATE-DIR@@ will be replaced by make in the build phase
my $template_path = '@@TEMPLATE-DIR@@';
# Setup the default connection variables based on the environment
my $dbuser = $ENV{'PGUSER'};
$dbuser ||= $ENV{'USER'};
my $database = $ENV{'PGDATABASE'};
$database ||= $dbuser;
my $dbhost = $ENV{'PGHOST'};
$dbhost ||= "";
my $dbport = $ENV{'PGPORT'};
$dbport ||= "";
# Determine whether we need a password to connect
my $needpass = 0;
my $dbpass = "";
my $output_filename_base = $database;
# Tracking variables
my $dbisset = 0;
my $fileisset = 0;
my $only_schema;
my $only_matching;
my $table_out;
my $wanted_output = undef; # means all types
my $statistics = 0;
my $filter_prog;
# Fetch base and dirnames. Useful for Usage()
my $basename = $0;
my $dirname = $0;
$basename =~ s|^.*/([^/]+)$|$1|;
$dirname =~ s|^(.*)/[^/]+$|$1|;
# If template_path isn't defined, lets set it ourselves
$template_path = $dirname if ( !defined($template_path) );
for ( my $i = 0 ; $i <= $#ARGV ; $i++ ) {
ARGPARSE: for ( $ARGV[$i] ) {
# Set the database
/^-d$/ && do {
$database = $ARGV[ ++$i ];
$dbisset = 1;
if ( !$fileisset ) {
$output_filename_base = $database;
}
last;
};
# Set the user
/^-[uU]$/ && do {
$dbuser = $ARGV[ ++$i ];
if ( !$dbisset ) {
$database = $dbuser;
if ( !$fileisset ) {
$output_filename_base = $database;
}
}
last;
};
# Set the hostname
/^-h$/ && do { $dbhost = $ARGV[ ++$i ]; last; };
# Set the Port
/^-p$/ && do { $dbport = $ARGV[ ++$i ]; last; };
# Set the users password
/^--password=/ && do {
$dbpass = $ARGV[$i];
$dbpass =~ s/^--password=//g;
last;
};
# Make sure we get a password before attempting to conenct
/^--password$/ && do {
$needpass = 1;
last;
};
# Read from .pgpass (override all other password options)
/^-w$/ && do {
$dbpass = undef;
$dbuser = undef;
$needpass = 0;
last;
};
# Set the base of the filename. The extensions pulled
# from the templates will be appended to this name
/^-f$/ && do {
$output_filename_base = $ARGV[ ++$i ];
$fileisset = 1;
last;
};
# Set the template directory explicitly
/^(-l|--library)$/ && do {
$template_path = $ARGV[ ++$i ];
last;
};
# Set the output type
/^(-t|--type)$/ && do {
$wanted_output = $ARGV[ ++$i ];
last;
};
# User has requested a single schema dump and provided a pattern
/^(-s|--schema)$/ && do {
$only_schema = $ARGV[ ++$i ];
last;
};
# User has requested only tables/objects matching a pattern
/^(-m|--matching)$/ && do {
$only_matching = $ARGV[ ++$i ];
last;
};
# One might dump a table's set (comma-separated) or just one
# If dumping a set of specific tables do NOT dump out the functions
# in this database. Generates noise in the output
# that most likely isn't wanted. Check for $table_out around the
# function gathering location.
/^--table=/ && do {
my $some_table = $ARGV[$i];
$some_table =~ s/^--table=//g;
my @tables_in = split( ',', $some_table );
sub single_quote;
$table_out = join( ',', map( single_quote, @tables_in ) );
last;
};
# Check to see if Statistics have been requested
/^--statistics$/ && do {
$statistics = 1;
last;
};
/^--comment-filter=/ && do {
my $some_filter_prog = $ARGV[$i];
$some_filter_prog =~ s/^--comment-filter=//g;
$filter_prog = $some_filter_prog;
last;
};
# Help is wanted, redirect user to usage()
/^-\?$/ && do { usage( $basename, $database, $dbuser ); last; };
/^--help$/ && do { usage( $basename, $database, $dbuser ); last; };
}
}
# If no arguments have been provided, connect to the database anyway but
# inform the user of what we're doing.
if ( $#ARGV <= 0 ) {
print <<Msg
No arguments set. Use '$basename --help' for help
Connecting to database '$database' as user '$dbuser'
Msg
;
}
# If needpass has been set but no password was provided, prompt the user
# for a password.
if ( $needpass and not $dbpass ) {
print "Password: ";
ReadMode 'noecho';
$dbpass = ReadLine 0;
chomp $dbpass;
ReadMode 'normal';
print "\n";
}
# Database Connection
my $dsn = "dbi:Pg:dbname=$database";
$dsn .= ";host=$dbhost" if ( "$dbhost" ne "" );
$dsn .= ";port=$dbport" if ( "$dbport" ne "" );
info_collect( [ $dsn, $dbuser, $dbpass ],
\%db, $database, $only_schema, $only_matching, $statistics,
$table_out );
# Write out *ALL* templates
write_using_templates( \%db, $database, $statistics, $template_path,
$output_filename_base, $wanted_output, $filter_prog );
}
##
# info_collect
#
# Pull out all of the applicable information about a specific database
sub info_collect {
my ( $dbConnect, $db, $database, $only_schema, $only_matching, $statistics,
$table_out )
= @_;
my $dbh = DBI->connect( @{$dbConnect} )
or triggerError("Unable to connect due to: $DBI::errstr");
$dbh->do("set client_encoding to 'UTF-8'")
or triggerError("could not set client_encoding to UTF-8: $DBI::errstr");
my %struct;
$db->{$database}{'STRUCT'} = \%struct;
my $struct = $db->{$database}{'STRUCT'};
# PostgreSQL's version is used to determine what queries are required
# to retrieve a given information set.
if ( $dbh->{pg_server_version} < 70300 ) {
die("PostgreSQL 7.3 and later are supported");
}
# Ensure we only retrieve information for the requested schemas.
#
# system_schema -> The primary system schema for a database.
# Public is used for verions prior to 7.3
#
# system_schema_list -> The list of schemas which we are not supposed
# to gather information for.
# TODO: Merge with system_schema in array form.
#
# schemapattern -> The schema the user provided as a command
# line option.
my $schemapattern = '^';
my $system_schema = 'pg_catalog';
my $system_schema_list =
'pg_catalog|pg_toast|pg_temp_[0-9]+|information_schema';
if ( defined($only_schema) ) {
$schemapattern = '^' . $only_schema . '$';
}
# and only objects matching the specified pattern, if any
my $matchpattern = '';
if ( defined($only_matching) ) {
$matchpattern = $only_matching;
}
#
# List of queries which are used to gather information from the
# database. The queries differ based on version but should
# provide similar output. At some point it should be safe to remove
# support for older database versions.
#
# Fetch the description of the database
my $sql_Database = q{
SELECT pg_catalog.obj_description(oid, 'pg_database') as comment
FROM pg_catalog.pg_database
WHERE datname = '$database';
};
# Pull out a list of tables, views and special structures.
my $sql_Tables = qq{
SELECT nspname as namespace
, relname as tablename
, pg_catalog.pg_get_userbyid(relowner) AS tableowner
, pg_class.oid
, pg_catalog.obj_description(pg_class.oid, 'pg_class') as table_description
, relacl
, CASE
WHEN relkind = 'r' THEN
'table'
WHEN relkind = 's' THEN
'special'
ELSE
'view'
END as reltype
, CASE
WHEN relkind = 'v' THEN
pg_get_viewdef(pg_class.oid)
ELSE
NULL
END as view_definition
FROM pg_catalog.pg_class
JOIN pg_catalog.pg_namespace ON (relnamespace = pg_namespace.oid)
WHERE relkind IN ('r', 's', 'v')
AND relname ~ '$matchpattern'
AND nspname !~ '$system_schema_list'
AND nspname ~ '$schemapattern'
};
$sql_Tables .= qq{ AND relname IN ($table_out)} if defined($table_out);
# - uses pg_class.oid
my $sql_Columns = q{
SELECT attname as column_name
, attlen as column_length
, CASE
WHEN pg_type.typname = 'int4'
AND EXISTS (SELECT TRUE
FROM pg_catalog.pg_depend
JOIN pg_catalog.pg_class ON (pg_class.oid = objid)
WHERE refobjsubid = attnum
AND refobjid = attrelid
AND relkind = 'S') THEN
'serial'
WHEN pg_type.typname = 'int8'
AND EXISTS (SELECT TRUE
FROM pg_catalog.pg_depend
JOIN pg_catalog.pg_class ON (pg_class.oid = objid)
WHERE refobjsubid = attnum
AND refobjid = attrelid
AND relkind = 'S') THEN
'bigserial'
ELSE
pg_catalog.format_type(atttypid, atttypmod)
END as column_type
, CASE
WHEN attnotnull THEN
cast('NOT NULL' as text)
ELSE
cast('' as text)
END as column_null
, CASE
WHEN pg_type.typname IN ('int4', 'int8')
AND EXISTS (SELECT TRUE
FROM pg_catalog.pg_depend
JOIN pg_catalog.pg_class ON (pg_class.oid = objid)
WHERE refobjsubid = attnum
AND refobjid = attrelid
AND relkind = 'S') THEN
NULL
ELSE
pg_get_expr(adbin, adrelid)
END as column_default
, pg_catalog.col_description(attrelid, attnum) as column_description
, attnum
FROM pg_catalog.pg_attribute
JOIN pg_catalog.pg_type ON (pg_type.oid = atttypid)
LEFT JOIN pg_catalog.pg_attrdef ON ( attrelid = adrelid
AND attnum = adnum)
WHERE attnum > 0
AND attisdropped IS FALSE
AND attrelid = ?;
};
my $sql_Table_Statistics;
if ( $statistics == 1 ) {
if ( $dbh->{pg_server_version} <= 70300 ) {
triggerError(
"Table statistics supported on PostgreSQL 7.4 and later.\n"
. "Remove --statistics flag and try again." );
}
$sql_Table_Statistics = q{
SELECT table_len
, tuple_count
, tuple_len
, CAST(tuple_percent AS numeric(20,2)) AS tuple_percent
, dead_tuple_count
, dead_tuple_len
, CAST(dead_tuple_percent AS numeric(20,2)) AS dead_tuple_percent
, CAST(free_space AS numeric(20,2)) AS free_space
, CAST(free_percent AS numeric(20,2)) AS free_percent
FROM pgstattuple(CAST(? AS oid));
};
}
my $sql_Indexes = q{
SELECT schemaname
, tablename
, indexname
, substring( indexdef
FROM position('(' IN indexdef) + 1
FOR length(indexdef) - position('(' IN indexdef) - 1
) AS indexdef
FROM pg_catalog.pg_indexes
WHERE substring(indexdef FROM 8 FOR 6) != 'UNIQUE'
AND schemaname = ?
AND tablename = ?;
};
my $sql_Inheritance = qq{
SELECT parnsp.nspname AS par_schemaname
, parcla.relname AS par_tablename
, chlnsp.nspname AS chl_schemaname
, chlcla.relname AS chl_tablename
FROM pg_catalog.pg_inherits
JOIN pg_catalog.pg_class AS chlcla ON (chlcla.oid = inhrelid)
JOIN pg_catalog.pg_namespace AS chlnsp ON (chlnsp.oid = chlcla.relnamespace)
JOIN pg_catalog.pg_class AS parcla ON (parcla.oid = inhparent)
JOIN pg_catalog.pg_namespace AS parnsp ON (parnsp.oid = parcla.relnamespace)
WHERE chlnsp.nspname = ?
AND chlcla.relname = ?
AND chlnsp.nspname ~ '$schemapattern'
AND parnsp.nspname ~ '$schemapattern';
};
# Fetch the list of PRIMARY and UNIQUE keys
my $sql_Primary_Keys = q{
SELECT conname AS constraint_name
, pg_catalog.pg_get_indexdef(d.objid) AS constraint_definition
, CASE
WHEN contype = 'p' THEN
'PRIMARY KEY'
ELSE
'UNIQUE'
END as constraint_type
FROM pg_catalog.pg_constraint AS c
JOIN pg_catalog.pg_depend AS d ON (d.refobjid = c.oid)
WHERE contype IN ('p', 'u')
AND deptype = 'i'
AND conrelid = ?;
};
# FOREIGN KEY fetch
#
# Don't return the constraint name if it was automatically generated by
# PostgreSQL. The $N (where N is an integer) is not a descriptive enough
# piece of information to be worth while including in the various outputs.
my $sql_Foreign_Keys = qq{
SELECT pg_constraint.oid
, pg_namespace.nspname AS namespace
, CASE WHEN substring(pg_constraint.conname FROM 1 FOR 1) = '\$' THEN ''
ELSE pg_constraint.conname
END AS constraint_name
, conkey AS constraint_key
, confkey AS constraint_fkey
, confrelid AS foreignrelid
FROM pg_catalog.pg_constraint
JOIN pg_catalog.pg_class ON (pg_class.oid = conrelid)
JOIN pg_catalog.pg_class AS pc ON (pc.oid = confrelid)
JOIN pg_catalog.pg_namespace ON (pg_class.relnamespace = pg_namespace.oid)
JOIN pg_catalog.pg_namespace AS pn ON (pn.oid = pc.relnamespace)
WHERE contype = 'f'
AND conrelid = ?
AND pg_namespace.nspname ~ '$schemapattern'
AND pn.nspname ~ '$schemapattern';
};
my $sql_Foreign_Key_Arg = q{
SELECT attname AS attribute_name
, relname AS relation_name
, nspname AS namespace
FROM pg_catalog.pg_attribute
JOIN pg_catalog.pg_class ON (pg_class.oid = attrelid)
JOIN pg_catalog.pg_namespace ON (relnamespace = pg_namespace.oid)
WHERE attrelid = ?
AND attnum = ?;
};
# Fetch CHECK constraints
my $sql_Constraint;
$sql_Constraint = q{
SELECT pg_get_constraintdef(oid) AS constraint_source
, conname AS constraint_name
FROM pg_constraint
WHERE conrelid = ?
AND contype = 'c';
};
# Query for function information
my $sql_Function;
my $sql_FunctionArg;
$sql_Function = qq{
SELECT proname AS function_name
, nspname AS namespace
, lanname AS language_name
, pg_catalog.obj_description(pg_proc.oid, 'pg_proc') AS comment
, proargtypes AS function_args
, proargnames AS function_arg_names
, prosrc AS source_code
, proretset AS returns_set
, prorettype AS return_type
FROM pg_catalog.pg_proc
JOIN pg_catalog.pg_language ON (pg_language.oid = prolang)
JOIN pg_catalog.pg_namespace ON (pronamespace = pg_namespace.oid)
JOIN pg_catalog.pg_type ON (prorettype = pg_type.oid)
WHERE pg_namespace.nspname !~ '$system_schema_list'
AND pg_namespace.nspname ~ '$schemapattern'
AND proname ~ '$matchpattern'
AND proname != 'plpgsql_call_handler';
};
$sql_FunctionArg = q{
SELECT nspname AS namespace
, replace( pg_catalog.format_type(pg_type.oid, typtypmod)
, nspname ||'.'
, '') AS type_name
FROM pg_catalog.pg_type
JOIN pg_catalog.pg_namespace ON (pg_namespace.oid = typnamespace)
WHERE pg_type.oid = ?;
};
# Fetch schema information.
my $sql_Schema = qq{
SELECT pg_catalog.obj_description(oid, 'pg_namespace') AS comment
, nspname as namespace
FROM pg_catalog.pg_namespace
WHERE pg_namespace.nspname !~ '$system_schema_list'
AND pg_namespace.nspname ~ '$schemapattern';
};
my $sth_Columns = $dbh->prepare($sql_Columns);
my $sth_Constraint = $dbh->prepare($sql_Constraint);
my $sth_Database = $dbh->prepare($sql_Database);
my $sth_Foreign_Keys = $dbh->prepare($sql_Foreign_Keys);
my $sth_Foreign_Key_Arg = $dbh->prepare($sql_Foreign_Key_Arg);
my $sth_Function = $dbh->prepare($sql_Function);
my $sth_FunctionArg = $dbh->prepare($sql_FunctionArg);
my $sth_Indexes = $dbh->prepare($sql_Indexes);
my $sth_Inheritance = $dbh->prepare($sql_Inheritance);
my $sth_Primary_Keys = $dbh->prepare($sql_Primary_Keys);
my $sth_Schema = $dbh->prepare($sql_Schema);
my $sth_Tables = $dbh->prepare($sql_Tables);
my $sth_Table_Statistics = $dbh->prepare($sql_Table_Statistics)
if ( $statistics == 1 );
# Fetch Database info
$sth_Database->execute();
my $dbinfo = $sth_Database->fetchrow_hashref;
if ( defined($dbinfo) ) {
$db->{$database}{'COMMENT'} = $dbinfo->{'comment'};
}
# Fetch tables and all things bound to tables
$sth_Tables->execute();
while ( my $tables = $sth_Tables->fetchrow_hashref ) {
my $reloid = $tables->{'oid'};
my $relname = $tables->{'tablename'};
my $schema = $tables->{'namespace'};
EXPRESSIONFOUND:
# Store permissions
my $acl = $tables->{'relacl'};
# Empty acl groups cause serious issues.
$acl ||= '';
# Strip array forming 'junk'.
$acl =~ s/^{//g;
$acl =~ s/}$//g;
$acl =~ s/"//g;
# Foreach acl
foreach ( split( /\,/, $acl ) ) {
my ( $user, $raw_permissions ) = split( /=/, $_ );
if ( defined($raw_permissions) ) {
if ( $user eq '' ) {
$user = 'PUBLIC';
}
# The section after the / is the user who granted the permissions
my ( $permissions, $granting_user ) =
split( /\//, $raw_permissions );
# Break down permissions to individual flags
if ( $permissions =~ /a/ ) {
$struct->{$schema}{'TABLE'}{$relname}{'ACL'}{$user}
{'INSERT'} = 1;
}
if ( $permissions =~ /r/ ) {
$struct->{$schema}{'TABLE'}{$relname}{'ACL'}{$user}
{'SELECT'} = 1;
}
if ( $permissions =~ /w/ ) {
$struct->{$schema}{'TABLE'}{$relname}{'ACL'}{$user}
{'UPDATE'} = 1;
}
if ( $permissions =~ /d/ ) {
$struct->{$schema}{'TABLE'}{$relname}{'ACL'}{$user}
{'DELETE'} = 1;
}
if ( $permissions =~ /R/ ) {
$struct->{$schema}{'TABLE'}{$relname}{'ACL'}{$user}
{'RULE'} = 1;
}
if ( $permissions =~ /x/ ) {
$struct->{$schema}{'TABLE'}{$relname}{'ACL'}{$user}
{'REFERENCES'} = 1;
}
if ( $permissions =~ /t/ ) {
$struct->{$schema}{'TABLE'}{$relname}{'ACL'}{$user}
{'TRIGGER'} = 1;
}
}
}
# Primitive Stats, but only if requested
if ( $statistics == 1 and $tables->{'reltype'} eq 'table' ) {
$sth_Table_Statistics->execute($reloid);
my $stats = $sth_Table_Statistics->fetchrow_hashref;
$struct->{$schema}{'TABLE'}{$relname}{'TABLELEN'} =
$stats->{'table_len'};
$struct->{$schema}{'TABLE'}{$relname}{'TUPLECOUNT'} =
$stats->{'tuple_count'};
$struct->{$schema}{'TABLE'}{$relname}{'TUPLELEN'} =
$stats->{'tuple_len'};
$struct->{$schema}{'TABLE'}{$relname}{'DEADTUPLELEN'} =
$stats->{'dead_tuple_len'};
$struct->{$schema}{'TABLE'}{$relname}{'FREELEN'} =
$stats->{'free_space'};
}
# Store the relation type
$struct->{$schema}{'TABLE'}{$relname}{'TYPE'} = $tables->{'reltype'};
# Store table description
$struct->{$schema}{'TABLE'}{$relname}{'DESCRIPTION'} =
$tables->{'table_description'};
# Store the view definition
$struct->{$schema}{'TABLE'}{$relname}{'VIEW_DEF'} =
$tables->{'view_definition'};
# Store constraints
$sth_Constraint->execute($reloid);
while ( my $cols = $sth_Constraint->fetchrow_hashref ) {
my $constraint_name = $cols->{'constraint_name'};
$struct->{$schema}{'TABLE'}{$relname}{'CONSTRAINT'}
{$constraint_name} = $cols->{'constraint_source'};
}
$sth_Columns->execute($reloid);
my $i = 1;
while ( my $cols = $sth_Columns->fetchrow_hashref ) {
my $column_name = $cols->{'column_name'};
$struct->{$schema}{'TABLE'}{$relname}{'COLUMN'}{$column_name}
{'ORDER'} = $cols->{'attnum'};
$struct->{$schema}{'TABLE'}{$relname}{'COLUMN'}{$column_name}
{'PRIMARY KEY'} = 0;
$struct->{$schema}{'TABLE'}{$relname}{'COLUMN'}{$column_name}
{'FKTABLE'} = '';
$struct->{$schema}{'TABLE'}{$relname}{'COLUMN'}{$column_name}
{'TYPE'} = $cols->{'column_type'};
$struct->{$schema}{'TABLE'}{$relname}{'COLUMN'}{$column_name}
{'NULL'} = $cols->{'column_null'};
$struct->{$schema}{'TABLE'}{$relname}{'COLUMN'}{$column_name}
{'DESCRIPTION'} = $cols->{'column_description'};
$struct->{$schema}{'TABLE'}{$relname}{'COLUMN'}{$column_name}
{'DEFAULT'} = $cols->{'column_default'};
}
# Pull out both PRIMARY and UNIQUE keys based on the supplied query
# and the relation OID.
#
# Since there may be multiple UNIQUE indexes on a table, we append a
# number to the end of the the UNIQUE keyword which shows that they
# are a part of a related definition. I.e UNIQUE_1 goes with UNIQUE_1
#
$sth_Primary_Keys->execute($reloid);
my $unqgroup = 0;
while ( my $pricols = $sth_Primary_Keys->fetchrow_hashref ) {
my $index_type = $pricols->{'constraint_type'};
my $con = $pricols->{'constraint_name'};
my $indexdef = $pricols->{'constraint_definition'};
# Fetch the column list
my $column_list = $indexdef;
$column_list =~ s/.*\(([^)]+)\).*/$1/g;
# Split our column list and deal with all PRIMARY KEY fields
my @collist = split( ',', $column_list );
# Store the column number in the indextype field. Anything > 0
# indicates the column has this type of constraint applied to it.
my $column;
my $currentcol = $#collist + 1;
my $numcols = $#collist + 1;
# Bump group number if there are two or more columns
if ( $numcols >= 2 && $index_type eq 'UNIQUE' ) {
$unqgroup++;
}
# Record the data to the structure.
while ( $column = pop(@collist) ) {
$column =~ s/\s$//;
$column =~ s/^\s//;
$column =~ s/^"//;
$column =~ s/"$//;
$struct->{$schema}{'TABLE'}{$relname}{'COLUMN'}{$column}{'CON'}
{$con}{'TYPE'} = $index_type;
$struct->{$schema}{'TABLE'}{$relname}{'COLUMN'}{$column}{'CON'}
{$con}{'COLNUM'} = $currentcol--;
# Record group number only when a multi-column
# constraint is involved
if ( $numcols >= 2 && $index_type eq 'UNIQUE' ) {
$struct->{$schema}{'TABLE'}{$relname}{'COLUMN'}{$column}
{'CON'}{$con}{'KEYGROUP'} = $unqgroup;
}
}
}
# FOREIGN KEYS like UNIQUE indexes can appear several times in
# a table in multi-column format. We use the same trick to
# record a numeric association to the foreign key reference.
$sth_Foreign_Keys->execute($reloid);
my $fkgroup = 0;
while ( my $forcols = $sth_Foreign_Keys->fetchrow_hashref ) {
my $column_oid = $forcols->{'oid'};
my $con = $forcols->{'constraint_name'};
# Declare variables for dataload
my @keylist;
my @fkeylist;
my $fschema;
my $ftable;
my $fkey = $forcols->{'constraint_fkey'};
my $keys = $forcols->{'constraint_key'};
my $frelid = $forcols->{'foreignrelid'};
# Since decent array support was not added until 7.4, and
# we want to support 7.3 as well, we parse the text version
# of the array by hand rather than combining this and
# Foreign_Key_Arg query into a single query.
my @fkeyset;
if ( ref $fkey eq 'ARRAY' ) {
@fkeyset = @{$fkey};
}
else { # DEPRECATED: DBD::Pg 1.49 and earlier
$fkey =~ s/^{//g;
$fkey =~ s/}$//g;
$fkey =~ s/"//g;
@fkeyset = split( /,/, $fkey );
}
my @keyset;
if ( ref $keys eq 'ARRAY' ) {
@keyset = @{$keys};
}
else { # DEPRECATED: DBD::Pg 1.49 and earlier
$keys =~ s/^{//g;
$keys =~ s/}$//g;
$keys =~ s/"//g;
@keyset = split( /,/, $keys );
}
# Convert the list of column numbers into column names for the
# local side.
foreach my $k (@keyset) {
$sth_Foreign_Key_Arg->execute( $reloid, $k );
my $row = $sth_Foreign_Key_Arg->fetchrow_hashref;
push( @keylist, $row->{'attribute_name'} );
}
# Convert the list of columns numbers into column names
# for the referenced side. Grab the table and namespace
# while we're here.
foreach my $k (@fkeyset) {
$sth_Foreign_Key_Arg->execute( $frelid, $k );
my $row = $sth_Foreign_Key_Arg->fetchrow_hashref;
push( @fkeylist, $row->{'attribute_name'} );
$fschema = $row->{'namespace'};
$ftable = $row->{'relation_name'};
}
# Deal with common catalog issues.
die "FKEY $con Broken -- fix your PostgreSQL installation"
if $#keylist != $#fkeylist;
# Load up the array based on the information discovered
# using the information retrieval methods above.
my $numcols = $#keylist + 1;
my $currentcol = $#keylist + 1;
# Bump group number if there are two or more columns involved
if ( $numcols >= 2 ) {
$fkgroup++;
}
# Record the foreign key to structure
while ( my $column = pop(@keylist)
and my $fkey = pop(@fkeylist) )
{
$struct->{$schema}{'TABLE'}{$relname}{'COLUMN'}{$column}{'CON'}
{$con}{'TYPE'} = 'FOREIGN KEY';
$struct->{$schema}{'TABLE'}{$relname}{'COLUMN'}{$column}{'CON'}
{$con}{'COLNUM'} = $currentcol--;
$struct->{$schema}{'TABLE'}{$relname}{'COLUMN'}{$column}{'CON'}
{$con}{'FKTABLE'} = $ftable;
$struct->{$schema}{'TABLE'}{$relname}{'COLUMN'}{$column}{'CON'}
{$con}{'FKSCHEMA'} = $fschema;
$struct->{$schema}{'TABLE'}{$relname}{'COLUMN'}{$column}{'CON'}
{$con}{'FK-COL NAME'} = $fkey;
# Record group number only when a multi-column
# constraint is involved
if ( $numcols >= 2 ) {
$struct->{$schema}{'TABLE'}{$relname}{'COLUMN'}{$column}
{'CON'}{$con}{'KEYGROUP'} = $fkgroup;
}
}
}
# Pull out index information
$sth_Indexes->execute( $schema, $relname );
while ( my $idx = $sth_Indexes->fetchrow_hashref ) {
$struct->{$schema}{'TABLE'}{$relname}{'INDEX'}
{ $idx->{'indexname'} } = $idx->{'indexdef'};
}
# Extract Inheritance information
$sth_Inheritance->execute( $schema, $relname );
while ( my $inherit = $sth_Inheritance->fetchrow_hashref ) {
my $parSch = $inherit->{'par_schemaname'};
my $parTab = $inherit->{'par_tablename'};
$struct->{$schema}{'TABLE'}{$relname}{'INHERIT'}{$parSch}{$parTab} =
1;
}
}
# Function Handling
$sth_Function->execute();
while ( my $functions = $sth_Function->fetchrow_hashref and not $table_out )
{
my $schema = $functions->{'namespace'};
my $comment = $functions->{'comment'};
my $functionargs = $functions->{'function_args'};
my @types = split( ' ', $functionargs );
my $count = 0;
# Pre-setup argument names when available.
my $argnames = $functions->{'function_arg_names'};
# Setup full argument types including the parameter name
my @parameters;
for my $type (@types) {
$sth_FunctionArg->execute($type);
my $hash = $sth_FunctionArg->fetchrow_hashref;
my $parameter = '';
if ($argnames) {
$parameter .= sprintf( '%s ', shift( @{$argnames} ) );
}
if ( $hash->{'namespace'} ne $system_schema ) {
$parameter .= $hash->{'namespace'} . '.';
}
$parameter .= $hash->{'type_name'};
push( @parameters, $parameter );
}
my $functionname = sprintf( '%s(%s)',
$functions->{'function_name'},
join( ', ', @parameters ) );
my $ret_type = $functions->{'returns_set'} ? 'SET OF ' : '';
$sth_FunctionArg->execute( $functions->{'return_type'} );
my $rhash = $sth_FunctionArg->fetchrow_hashref;
$ret_type .= $rhash->{'type_name'};
$struct->{$schema}{'FUNCTION'}{$functionname}{'COMMENT'} = $comment;
$struct->{$schema}{'FUNCTION'}{$functionname}{'SOURCE'} =
$functions->{'source_code'};
$struct->{$schema}{'FUNCTION'}{$functionname}{'LANGUAGE'} =
$functions->{'language_name'};
$struct->{$schema}{'FUNCTION'}{$functionname}{'RETURNS'} = $ret_type;
}
# Deal with the Schema
$sth_Schema->execute();
while ( my $schema = $sth_Schema->fetchrow_hashref ) {
my $comment = $schema->{'comment'};
my $namespace = $schema->{'namespace'};
$struct->{$namespace}{'SCHEMA'}{'COMMENT'} = $comment;
}
$sth_Columns->finish();
$sth_Constraint->finish();
$sth_Database->finish();
$sth_Foreign_Keys->finish();
$sth_Foreign_Key_Arg->finish();
$sth_Function->finish();
$sth_FunctionArg->finish();
$sth_Indexes->finish();
$sth_Inheritance->finish();
$sth_Primary_Keys->finish();
$sth_Schema->finish();
$sth_Tables->finish();
$sth_Table_Statistics->finish()
if ( $statistics == 1 );
$dbh->disconnect;
}
#####
# write_using_templates
#
# Generate structure that HTML::Template requires out of the
# $struct for table related information, and $struct for
# the schema and function information
sub write_using_templates($$$$$$) {
my ( $db, $database, $statistics, $template_path, $output_filename_base,
$wanted_output, $filter_prog )
= @_;
my $struct = $db->{$database}{'STRUCT'};
my @schemas;
# Start at 0, increment to 1 prior to use.
my $object_id = 0;