From d7e654ff79871605a175c64fcc71aeed01a14b02 Mon Sep 17 00:00:00 2001 From: Tom Lane Date: Thu, 5 Sep 2002 19:57:32 +0000 Subject: [PATCH] findoidjoins is updated for schemas, does not use libpgeasy. From Joe Conway. --- contrib/findoidjoins/Makefile | 9 +- contrib/findoidjoins/README.findoidjoins | 151 ++++++++-------- contrib/findoidjoins/findoidjoins.c | 212 +++++++++++++---------- contrib/findoidjoins/make_oidjoins_check | 15 +- 4 files changed, 216 insertions(+), 171 deletions(-) diff --git a/contrib/findoidjoins/Makefile b/contrib/findoidjoins/Makefile index d285abd5a6..cffe42e56b 100644 --- a/contrib/findoidjoins/Makefile +++ b/contrib/findoidjoins/Makefile @@ -1,4 +1,4 @@ -# $Header: /cvsroot/pgsql/contrib/findoidjoins/Attic/Makefile,v 1.13 2001/09/06 10:49:29 petere Exp $ +# $Header: /cvsroot/pgsql/contrib/findoidjoins/Attic/Makefile,v 1.14 2002/09/05 19:57:32 tgl Exp $ subdir = contrib/findoidjoins top_builddir = ../.. @@ -7,11 +7,8 @@ include $(top_builddir)/src/Makefile.global PROGRAM = findoidjoins OBJS = findoidjoins.o -libpgeasy_srcdir = $(top_srcdir)/src/interfaces/libpgeasy -libpgeasy_builddir = $(top_builddir)/src/interfaces/libpgeasy - -PG_CPPFLAGS = -I$(libpgeasy_srcdir) -I$(libpq_srcdir) -PG_LIBS = -L$(libpgeasy_builddir) -lpgeasy $(libpq) +PG_CPPFLAGS = -I$(libpq_srcdir) +PG_LIBS = $(libpq) SCRIPTS = make_oidjoins_check DOCS = README.findoidjoins diff --git a/contrib/findoidjoins/README.findoidjoins b/contrib/findoidjoins/README.findoidjoins index 14c17e1e0e..c455c99c90 100644 --- a/contrib/findoidjoins/README.findoidjoins +++ b/contrib/findoidjoins/README.findoidjoins @@ -1,24 +1,23 @@ findoidjoins -This program scans a database, and prints oid fields (also regproc, regclass -and regtype fields) and the tables they join to. CAUTION: it is ver-r-r-y -slow on a large database, or even a not-so-large one. We don't really -recommend running it on anything but an empty database, such as template1. - -Uses pgeasy library. +This program scans a database and prints oid fields (also reg* fields) +and the tables they join to. We don't really recommend running it on +anything but an empty database, such as template1; else it's likely to +be very slow. Run on an empty database, it returns the system join relationships (shown -below for 7.2). Note that unexpected matches may indicate bogus entries +below for 7.3). Note that unexpected matches may indicate bogus entries in system tables --- don't accept a peculiar match without question. In particular, a field shown as joining to more than one target table is -probably messed up. In 7.2, the *only* field that should join to more -than one target is pg_description.objoid. (Running make_oidjoins_check -is an easy way to spot fields joining to more than one table, BTW.) +probably messed up. In 7.3, the *only* fields that should join to more +than one target are pg_description.objoid, pg_depend.objid, and +pg_depend.refobjid. (Running make_oidjoins_check is an easy way to spot +fields joining to more than one table, BTW.) The shell script make_oidjoins_check converts findoidjoins' output into an SQL script that checks for dangling links (entries in an -OID or REGPROC column that don't match any row in the expected table). +OID or REG* column that don't match any row in the expected table). Note that fields joining to more than one table are NOT processed. The result of make_oidjoins_check should be installed as the "oidjoins" @@ -27,68 +26,82 @@ revision in the patterns of cross-links between system tables. (Ideally we'd just regenerate the script as part of the regression tests themselves, but that seems too slow...) -NOTE: in 7.2, make_oidjoins_check produces one bogus join check, for -pg_class.relfilenode => pg_class.oid. This is an artifact and should not -be added to the oidjoins regress test. +NOTE: in 7.3, make_oidjoins_check produces two bogus join checks: +Join pg_catalog.pg_class.relfilenode => pg_catalog.pg_class.oid +Join pg_catalog.pg_database.datlastsysoid => pg_catalog.pg_conversion.oid +These are artifacts and should not be added to the oidjoins regress test. --------------------------------------------------------------------------- -Join pg_aggregate.aggtransfn => pg_proc.oid -Join pg_aggregate.aggfinalfn => pg_proc.oid -Join pg_aggregate.aggbasetype => pg_type.oid -Join pg_aggregate.aggtranstype => pg_type.oid -Join pg_aggregate.aggfinaltype => pg_type.oid -Join pg_am.amgettuple => pg_proc.oid -Join pg_am.aminsert => pg_proc.oid -Join pg_am.ambeginscan => pg_proc.oid -Join pg_am.amrescan => pg_proc.oid -Join pg_am.amendscan => pg_proc.oid -Join pg_am.ammarkpos => pg_proc.oid -Join pg_am.amrestrpos => pg_proc.oid -Join pg_am.ambuild => pg_proc.oid -Join pg_am.ambulkdelete => pg_proc.oid -Join pg_am.amcostestimate => pg_proc.oid -Join pg_amop.amopclaid => pg_opclass.oid -Join pg_amop.amopopr => pg_operator.oid -Join pg_amproc.amopclaid => pg_opclass.oid -Join pg_amproc.amproc => pg_proc.oid -Join pg_attribute.attrelid => pg_class.oid -Join pg_attribute.atttypid => pg_type.oid -Join pg_class.reltype => pg_type.oid -Join pg_class.relam => pg_am.oid -Join pg_class.reltoastrelid => pg_class.oid -Join pg_class.reltoastidxid => pg_class.oid -Join pg_description.classoid => pg_class.oid -Join pg_index.indexrelid => pg_class.oid -Join pg_index.indrelid => pg_class.oid -Join pg_opclass.opcamid => pg_am.oid -Join pg_opclass.opcintype => pg_type.oid -Join pg_operator.oprleft => pg_type.oid -Join pg_operator.oprright => pg_type.oid -Join pg_operator.oprresult => pg_type.oid -Join pg_operator.oprcom => pg_operator.oid -Join pg_operator.oprnegate => pg_operator.oid -Join pg_operator.oprlsortop => pg_operator.oid -Join pg_operator.oprrsortop => pg_operator.oid -Join pg_operator.oprcode => pg_proc.oid -Join pg_operator.oprrest => pg_proc.oid -Join pg_operator.oprjoin => pg_proc.oid -Join pg_proc.prolang => pg_language.oid -Join pg_proc.prorettype => pg_type.oid -Join pg_rewrite.ev_class => pg_class.oid -Join pg_statistic.starelid => pg_class.oid -Join pg_statistic.staop1 => pg_operator.oid -Join pg_statistic.staop2 => pg_operator.oid -Join pg_statistic.staop3 => pg_operator.oid -Join pg_trigger.tgrelid => pg_class.oid -Join pg_trigger.tgfoid => pg_proc.oid -Join pg_type.typrelid => pg_class.oid -Join pg_type.typelem => pg_type.oid -Join pg_type.typinput => pg_proc.oid -Join pg_type.typoutput => pg_proc.oid -Join pg_type.typreceive => pg_proc.oid -Join pg_type.typsend => pg_proc.oid +Join pg_catalog.pg_aggregate.aggfnoid => pg_catalog.pg_proc.oid +Join pg_catalog.pg_aggregate.aggtransfn => pg_catalog.pg_proc.oid +Join pg_catalog.pg_aggregate.aggfinalfn => pg_catalog.pg_proc.oid +Join pg_catalog.pg_aggregate.aggtranstype => pg_catalog.pg_type.oid +Join pg_catalog.pg_am.amgettuple => pg_catalog.pg_proc.oid +Join pg_catalog.pg_am.aminsert => pg_catalog.pg_proc.oid +Join pg_catalog.pg_am.ambeginscan => pg_catalog.pg_proc.oid +Join pg_catalog.pg_am.amrescan => pg_catalog.pg_proc.oid +Join pg_catalog.pg_am.amendscan => pg_catalog.pg_proc.oid +Join pg_catalog.pg_am.ammarkpos => pg_catalog.pg_proc.oid +Join pg_catalog.pg_am.amrestrpos => pg_catalog.pg_proc.oid +Join pg_catalog.pg_am.ambuild => pg_catalog.pg_proc.oid +Join pg_catalog.pg_am.ambulkdelete => pg_catalog.pg_proc.oid +Join pg_catalog.pg_am.amcostestimate => pg_catalog.pg_proc.oid +Join pg_catalog.pg_amop.amopclaid => pg_catalog.pg_opclass.oid +Join pg_catalog.pg_amop.amopopr => pg_catalog.pg_operator.oid +Join pg_catalog.pg_amproc.amopclaid => pg_catalog.pg_opclass.oid +Join pg_catalog.pg_amproc.amproc => pg_catalog.pg_proc.oid +Join pg_catalog.pg_attribute.attrelid => pg_catalog.pg_class.oid +Join pg_catalog.pg_attribute.atttypid => pg_catalog.pg_type.oid +Join pg_catalog.pg_cast.castsource => pg_catalog.pg_type.oid +Join pg_catalog.pg_cast.casttarget => pg_catalog.pg_type.oid +Join pg_catalog.pg_cast.castfunc => pg_catalog.pg_proc.oid +Join pg_catalog.pg_class.relnamespace => pg_catalog.pg_namespace.oid +Join pg_catalog.pg_class.reltype => pg_catalog.pg_type.oid +Join pg_catalog.pg_class.relam => pg_catalog.pg_am.oid +Join pg_catalog.pg_class.reltoastrelid => pg_catalog.pg_class.oid +Join pg_catalog.pg_class.reltoastidxid => pg_catalog.pg_class.oid +Join pg_catalog.pg_conversion.connamespace => pg_catalog.pg_namespace.oid +Join pg_catalog.pg_conversion.conproc => pg_catalog.pg_proc.oid +Join pg_catalog.pg_depend.classid => pg_catalog.pg_class.oid +Join pg_catalog.pg_depend.refclassid => pg_catalog.pg_class.oid +Join pg_catalog.pg_description.classoid => pg_catalog.pg_class.oid +Join pg_catalog.pg_index.indexrelid => pg_catalog.pg_class.oid +Join pg_catalog.pg_index.indrelid => pg_catalog.pg_class.oid +Join pg_catalog.pg_language.lanvalidator => pg_catalog.pg_proc.oid +Join pg_catalog.pg_opclass.opcamid => pg_catalog.pg_am.oid +Join pg_catalog.pg_opclass.opcnamespace => pg_catalog.pg_namespace.oid +Join pg_catalog.pg_opclass.opcintype => pg_catalog.pg_type.oid +Join pg_catalog.pg_operator.oprnamespace => pg_catalog.pg_namespace.oid +Join pg_catalog.pg_operator.oprleft => pg_catalog.pg_type.oid +Join pg_catalog.pg_operator.oprright => pg_catalog.pg_type.oid +Join pg_catalog.pg_operator.oprresult => pg_catalog.pg_type.oid +Join pg_catalog.pg_operator.oprcom => pg_catalog.pg_operator.oid +Join pg_catalog.pg_operator.oprnegate => pg_catalog.pg_operator.oid +Join pg_catalog.pg_operator.oprlsortop => pg_catalog.pg_operator.oid +Join pg_catalog.pg_operator.oprrsortop => pg_catalog.pg_operator.oid +Join pg_catalog.pg_operator.oprltcmpop => pg_catalog.pg_operator.oid +Join pg_catalog.pg_operator.oprgtcmpop => pg_catalog.pg_operator.oid +Join pg_catalog.pg_operator.oprcode => pg_catalog.pg_proc.oid +Join pg_catalog.pg_operator.oprrest => pg_catalog.pg_proc.oid +Join pg_catalog.pg_operator.oprjoin => pg_catalog.pg_proc.oid +Join pg_catalog.pg_proc.pronamespace => pg_catalog.pg_namespace.oid +Join pg_catalog.pg_proc.prolang => pg_catalog.pg_language.oid +Join pg_catalog.pg_proc.prorettype => pg_catalog.pg_type.oid +Join pg_catalog.pg_rewrite.ev_class => pg_catalog.pg_class.oid +Join pg_catalog.pg_statistic.starelid => pg_catalog.pg_class.oid +Join pg_catalog.pg_statistic.staop1 => pg_catalog.pg_operator.oid +Join pg_catalog.pg_statistic.staop2 => pg_catalog.pg_operator.oid +Join pg_catalog.pg_statistic.staop3 => pg_catalog.pg_operator.oid +Join pg_catalog.pg_trigger.tgrelid => pg_catalog.pg_class.oid +Join pg_catalog.pg_trigger.tgfoid => pg_catalog.pg_proc.oid +Join pg_catalog.pg_type.typnamespace => pg_catalog.pg_namespace.oid +Join pg_catalog.pg_type.typrelid => pg_catalog.pg_class.oid +Join pg_catalog.pg_type.typelem => pg_catalog.pg_type.oid +Join pg_catalog.pg_type.typinput => pg_catalog.pg_proc.oid +Join pg_catalog.pg_type.typoutput => pg_catalog.pg_proc.oid --------------------------------------------------------------------------- Bruce Momjian (root@candle.pha.pa.us) +Updated for 7.3 by Joe Conway (mail@joeconway.com) diff --git a/contrib/findoidjoins/findoidjoins.c b/contrib/findoidjoins/findoidjoins.c index f83e5da189..a829a58190 100644 --- a/contrib/findoidjoins/findoidjoins.c +++ b/contrib/findoidjoins/findoidjoins.c @@ -1,109 +1,145 @@ /* - * findoidjoins.c, requires src/interfaces/libpgeasy + * findoidjoins.c * + * Copyright 2002 by PostgreSQL Global Development Group + * + * $Header: /cvsroot/pgsql/contrib/findoidjoins/Attic/findoidjoins.c,v 1.18 2002/09/05 19:57:32 tgl Exp $ */ #include "postgres_fe.h" #include "libpq-fe.h" -#include "halt.h" -#include "libpgeasy.h" +#include "pqexpbuffer.h" -PGresult *attres, - *relres; int main(int argc, char **argv) { - char query[4000]; - char relname[256]; - char relname2[256]; - char attname[256]; - char typname[256]; - int count; - char optstr[256]; + PGconn *conn; + PQExpBufferData sql; + PGresult *res; + PGresult *pkrel_res; + PGresult *fkrel_res; + char *fk_relname; + char *fk_nspname; + char *fk_attname; + char *pk_relname; + char *pk_nspname; + int fk, pk; /* loop counters */ if (argc != 2) - halt("Usage: %s database\n", argv[0]); - - snprintf(optstr, 256, "dbname=%s", argv[1]); - connectdb(optstr); - - on_error_continue(); - on_error_stop(); - - doquery("BEGIN WORK"); - doquery("\ - DECLARE c_attributes BINARY CURSOR FOR \ - SELECT typname, relname, a.attname \ - FROM pg_class c, pg_attribute a, pg_type t \ - WHERE a.attnum > 0 AND \ - relkind = 'r' AND \ - (typname = 'oid' OR \ - typname = 'regproc' OR \ - typname = 'regclass' OR \ - typname = 'regtype') AND \ - a.attrelid = c.oid AND \ - a.atttypid = t.oid \ - ORDER BY 2, a.attnum ; \ - "); - doquery("FETCH ALL IN c_attributes"); - attres = get_result(); - - doquery("\ - DECLARE c_relations BINARY CURSOR FOR \ - SELECT relname \ - FROM pg_class c \ - WHERE relkind = 'r' AND relhasoids \ - ORDER BY 1; \ - "); - doquery("FETCH ALL IN c_relations"); - relres = get_result(); - - set_result(attres); - while (fetch(typname, relname, attname) != END_OF_TUPLES) { - set_result(relres); - reset_fetch(); - while (fetch(relname2) != END_OF_TUPLES) - { - unset_result(relres); - if (strcmp(typname, "oid") == 0) - snprintf(query, 4000, "\ - DECLARE c_matches BINARY CURSOR FOR \ - SELECT count(*)::int4 \ - FROM \"%s\" t1, \"%s\" t2 \ - WHERE t1.\"%s\" = t2.oid ", - relname, relname2, attname); - else - sprintf(query, 4000, "\ - DECLARE c_matches BINARY CURSOR FOR \ - SELECT count(*)::int4 \ - FROM \"%s\" t1, \"%s\" t2 \ - WHERE t1.\"%s\"::oid = t2.oid ", - relname, relname2, attname); + fprintf(stderr, "Usage: %s database\n", argv[0]); + exit(EXIT_FAILURE); + } - doquery(query); - doquery("FETCH ALL IN c_matches"); - fetch(&count); - if (count != 0) - printf("Join %s.%s => %s.oid\n", relname, attname, relname2); - doquery("CLOSE c_matches"); - set_result(relres); - } - set_result(attres); + initPQExpBuffer(&sql); + + appendPQExpBuffer(&sql, "dbname=%s", argv[1]); + + conn = PQconnectdb(sql.data); + if (PQstatus(conn) == CONNECTION_BAD) + { + fprintf(stderr, "connection error: %s\n", PQerrorMessage(conn)); + exit(EXIT_FAILURE); } - set_result(relres); - doquery("CLOSE c_relations"); - PQclear(relres); + /* Get a list of relations that have OIDs */ - set_result(attres); - doquery("CLOSE c_attributes"); - PQclear(attres); - unset_result(attres); + resetPQExpBuffer(&sql); - doquery("COMMIT WORK"); + appendPQExpBuffer(&sql, "%s", + "SELECT c.relname, (SELECT nspname FROM " + "pg_catalog.pg_namespace n WHERE n.oid = c.relnamespace) AS nspname " + "FROM pg_catalog.pg_class c " + "WHERE c.relkind = 'r' " + "AND c.relhasoids " + "ORDER BY nspname, c.relname" + ); - disconnectdb(); - return 0; + res = PQexec(conn, sql.data); + if (!res || PQresultStatus(res) != PGRES_TUPLES_OK) + { + fprintf(stderr, "sql error: %s\n", PQerrorMessage(conn)); + exit(EXIT_FAILURE); + } + pkrel_res = res; + + /* Get a list of columns of OID type (or any OID-alias type) */ + + resetPQExpBuffer(&sql); + + appendPQExpBuffer(&sql, "%s", + "SELECT c.relname, " + "(SELECT nspname FROM pg_catalog.pg_namespace n WHERE n.oid = c.relnamespace) AS nspname, " + "a.attname " + "FROM pg_catalog.pg_class c, pg_catalog.pg_attribute a " + "WHERE a.attnum > 0 AND c.relkind = 'r' " + "AND a.attrelid = c.oid " + "AND a.atttypid IN ('pg_catalog.oid'::regtype, " + " 'pg_catalog.regclass'::regtype, " + " 'pg_catalog.regoper'::regtype, " + " 'pg_catalog.regoperator'::regtype, " + " 'pg_catalog.regproc'::regtype, " + " 'pg_catalog.regprocedure'::regtype, " + " 'pg_catalog.regtype'::regtype) " + "ORDER BY nspname, c.relname, a.attnum" + ); + + res = PQexec(conn, sql.data); + if (!res || PQresultStatus(res) != PGRES_TUPLES_OK) + { + fprintf(stderr, "sql error: %s\n", PQerrorMessage(conn)); + exit(EXIT_FAILURE); + } + fkrel_res = res; + + /* + * For each column and each relation-having-OIDs, look to see if + * the column contains any values matching entries in the relation. + */ + + for (fk = 0; fk < PQntuples(fkrel_res); fk++) + { + fk_relname = PQgetvalue(fkrel_res, fk, 0); + fk_nspname = PQgetvalue(fkrel_res, fk, 1); + fk_attname = PQgetvalue(fkrel_res, fk, 2); + + for (pk = 0; pk < PQntuples(pkrel_res); pk++) + { + pk_relname = PQgetvalue(pkrel_res, pk, 0); + pk_nspname = PQgetvalue(pkrel_res, pk, 1); + + resetPQExpBuffer(&sql); + + appendPQExpBuffer(&sql, + "SELECT 1 " + "FROM \"%s\".\"%s\" t1, " + "\"%s\".\"%s\" t2 " + "WHERE t1.\"%s\"::pg_catalog.oid = t2.oid " + "LIMIT 1", + fk_nspname, fk_relname, pk_nspname, pk_relname, fk_attname); + + res = PQexec(conn, sql.data); + if (!res || PQresultStatus(res) != PGRES_TUPLES_OK) + { + fprintf(stderr, "sql error: %s\n", PQerrorMessage(conn)); + exit(EXIT_FAILURE); + } + + if (PQntuples(res) != 0) + printf("Join %s.%s.%s => %s.%s.oid\n", + fk_nspname, fk_relname, fk_attname, + pk_nspname, pk_relname); + + PQclear(res); + } + } + + PQclear(pkrel_res); + PQclear(fkrel_res); + PQfinish(conn); + + termPQExpBuffer(&sql); + + exit(EXIT_SUCCESS); } diff --git a/contrib/findoidjoins/make_oidjoins_check b/contrib/findoidjoins/make_oidjoins_check index 72bb645251..74a2856778 100755 --- a/contrib/findoidjoins/make_oidjoins_check +++ b/contrib/findoidjoins/make_oidjoins_check @@ -26,7 +26,7 @@ fi cat /tmp/$$ | while read LINE do set -- $LINE - grep "$2" /tmp/$$a >/dev/null 2>&1 || echo $LINE + grep "^$2\$" /tmp/$$a >/dev/null 2>&1 || echo $LINE done >/tmp/$$b # Generate the output. @@ -41,13 +41,12 @@ $AWK -F'[ \.]' '\ } { printf "\ -SELECT ctid, %s.%s \n\ -FROM %s \n\ -WHERE %s.%s != 0 AND \n\ - NOT EXISTS(SELECT * FROM %s AS t1 WHERE t1.oid = %s.%s);\n", - $2, $3, $2, - $2, $3, - $5, $2, $3; +SELECT ctid, %s \n\ +FROM %s.%s fk \n\ +WHERE %s != 0 AND \n\ + NOT EXISTS(SELECT 1 FROM %s.%s pk WHERE pk.oid = fk.%s);\n", + $4, $2, $3, $4, + $6, $7, $4; }' exit 0