Index: contrib/findoidjoins/Makefile =================================================================== RCS file: /opt/src/cvs/pgsql-server/contrib/findoidjoins/Makefile,v retrieving revision 1.13 diff -c -r1.13 Makefile *** contrib/findoidjoins/Makefile 6 Sep 2001 10:49:29 -0000 1.13 --- contrib/findoidjoins/Makefile 4 Sep 2002 23:36:27 -0000 *************** *** 1,5 **** - # $Header: /opt/src/cvs/pgsql-server/contrib/findoidjoins/Makefile,v 1.13 2001/09/06 10:49:29 petere Exp $ - subdir = contrib/findoidjoins top_builddir = ../.. include $(top_builddir)/src/Makefile.global --- 1,3 ---- *************** *** 7,17 **** 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) SCRIPTS = make_oidjoins_check DOCS = README.findoidjoins --- 5,12 ---- PROGRAM = findoidjoins OBJS = findoidjoins.o ! PG_CPPFLAGS = -I$(libpq_srcdir) ! PG_LIBS = $(libpq) SCRIPTS = make_oidjoins_check DOCS = README.findoidjoins Index: contrib/findoidjoins/README.findoidjoins =================================================================== RCS file: /opt/src/cvs/pgsql-server/contrib/findoidjoins/README.findoidjoins,v retrieving revision 1.5 diff -c -r1.5 README.findoidjoins *** contrib/findoidjoins/README.findoidjoins 25 Apr 2002 02:56:55 -0000 1.5 --- contrib/findoidjoins/README.findoidjoins 5 Sep 2002 04:42:21 -0000 *************** *** 1,24 **** 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. Run on an empty database, it returns the system join relationships (shown ! below for 7.2). 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.) 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). Note that fields joining to more than one table are NOT processed. The result of make_oidjoins_check should be installed as the "oidjoins" --- 1,22 ---- findoidjoins ! 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. Run on an empty database, it returns the system join relationships (shown ! 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.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 REG* columns 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,43 **** (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. --------------------------------------------------------------------------- ! 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 --- 25,39 ---- (Ideally we'd just regenerate the script as part of the regression tests themselves, but that seems too slow...) ! NOTE: in 7.3, 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. --------------------------------------------------------------------------- ! Join pg_aggregate.aggfnoid => pg_proc.oid Join pg_aggregate.aggtransfn => pg_proc.oid Join pg_aggregate.aggfinalfn => pg_proc.oid Join pg_aggregate.aggtranstype => pg_type.oid Join pg_am.amgettuple => pg_proc.oid Join pg_am.aminsert => pg_proc.oid Join pg_am.ambeginscan => pg_proc.oid *************** *** 54,68 **** --- 50,95 ---- Join pg_amproc.amproc => pg_proc.oid Join pg_attribute.attrelid => pg_class.oid Join pg_attribute.atttypid => pg_type.oid + Join pg_cast.castsource => pg_type.oid + Join pg_cast.casttarget => pg_type.oid + Join pg_cast.castfunc => pg_proc.oid + Join pg_class.relnamespace => pg_namespace.oid Join pg_class.reltype => pg_type.oid Join pg_class.relam => pg_am.oid + Join pg_class.relfilenode => pg_class.oid Join pg_class.reltoastrelid => pg_class.oid Join pg_class.reltoastidxid => pg_class.oid + Join pg_conversion.connamespace => pg_namespace.oid + Join pg_conversion.conproc => pg_proc.oid + Join pg_database.datlastsysoid => pg_conversion.oid + Join pg_depend.classid => pg_class.oid + Join pg_depend.objid => pg_conversion.oid + Join pg_depend.objid => pg_rewrite.oid + Join pg_depend.objid => pg_type.oid + Join pg_depend.refclassid => pg_class.oid + Join pg_depend.refobjid => pg_cast.oid + Join pg_depend.refobjid => pg_class.oid + Join pg_depend.refobjid => pg_language.oid + Join pg_depend.refobjid => pg_namespace.oid + Join pg_depend.refobjid => pg_opclass.oid + Join pg_depend.refobjid => pg_operator.oid + Join pg_depend.refobjid => pg_proc.oid + Join pg_depend.refobjid => pg_trigger.oid + Join pg_depend.refobjid => pg_type.oid + Join pg_description.objoid => pg_am.oid + Join pg_description.objoid => pg_database.oid + Join pg_description.objoid => pg_language.oid + Join pg_description.objoid => pg_namespace.oid + Join pg_description.objoid => pg_proc.oid + Join pg_description.objoid => pg_type.oid Join pg_description.classoid => pg_class.oid Join pg_index.indexrelid => pg_class.oid Join pg_index.indrelid => pg_class.oid + Join pg_language.lanvalidator => pg_proc.oid Join pg_opclass.opcamid => pg_am.oid + Join pg_opclass.opcnamespace => pg_namespace.oid Join pg_opclass.opcintype => pg_type.oid + Join pg_operator.oprnamespace => pg_namespace.oid Join pg_operator.oprleft => pg_type.oid Join pg_operator.oprright => pg_type.oid Join pg_operator.oprresult => pg_type.oid *************** *** 70,94 **** 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 - --------------------------------------------------------------------------- Bruce Momjian (root@candle.pha.pa.us) --- 97,119 ---- Join pg_operator.oprnegate => pg_operator.oid Join pg_operator.oprlsortop => pg_operator.oid Join pg_operator.oprrsortop => pg_operator.oid + Join pg_operator.oprltcmpop => pg_operator.oid + Join pg_operator.oprgtcmpop => 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.pronamespace => pg_namespace.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_trigger.tgrelid => pg_class.oid Join pg_trigger.tgfoid => pg_proc.oid + Join pg_type.typnamespace => pg_namespace.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 --------------------------------------------------------------------------- Bruce Momjian (root@candle.pha.pa.us) + Updated for 7.3 by Joe Conway (mail@joeconway.com) Index: contrib/findoidjoins/findoidjoins.c =================================================================== RCS file: /opt/src/cvs/pgsql-server/contrib/findoidjoins/findoidjoins.c,v retrieving revision 1.17 diff -c -r1.17 findoidjoins.c *** contrib/findoidjoins/findoidjoins.c 4 Sep 2002 20:31:06 -0000 1.17 --- contrib/findoidjoins/findoidjoins.c 5 Sep 2002 04:51:16 -0000 *************** *** 1,109 **** /* ! * findoidjoins.c, requires src/interfaces/libpgeasy * */ - #include "postgres_fe.h" ! #include "libpq-fe.h" ! #include "halt.h" ! #include "libpgeasy.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]; 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); ! ! 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); } ! set_result(relres); ! doquery("CLOSE c_relations"); ! PQclear(relres); ! ! set_result(attres); ! doquery("CLOSE c_attributes"); ! PQclear(attres); ! unset_result(attres); ! doquery("COMMIT WORK"); ! disconnectdb(); ! return 0; } --- 1,152 ---- /* ! * findoidjoins ! * ! * Copyright 2002 by PostgreSQL Global Development Group ! * ! * Permission to use, copy, modify, and distribute this software and its ! * documentation for any purpose, without fee, and without a written agreement ! * is hereby granted, provided that the above copyright notice and this ! * paragraph and the following two paragraphs appear in all copies. ! * ! * IN NO EVENT SHALL THE AUTHORS OR DISTRIBUTORS BE LIABLE TO ANY PARTY FOR ! * DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING ! * LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS ! * DOCUMENTATION, EVEN IF THE AUTHOR OR DISTRIBUTORS HAVE BEEN ADVISED OF THE ! * POSSIBILITY OF SUCH DAMAGE. ! * ! * THE AUTHORS AND DISTRIBUTORS SPECIFICALLY DISCLAIM ANY WARRANTIES, ! * INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY ! * AND FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS ! * ON AN "AS IS" BASIS, AND THE AUTHOR AND DISTRIBUTORS HAS NO OBLIGATIONS TO ! * PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS. * */ ! #include ! #include "postgres_fe.h" ! #include "libpq-fe.h" ! #include "pqexpbuffer.h" int main(int argc, char **argv) { ! PGconn *conn; ! PQExpBufferData sql; ! PGresult *res; ! PGresult *pkrel_res; ! PGresult *fkrel_res; ! char *fk_relname; ! char *fk_nspname; ! char *fk_attname; ! char *fk_typname; ! char *pk_relname; ! char *pk_nspname; ! int fk, pk; /* loop counters */ if (argc != 2) ! { ! fprintf(stderr, "Usage: %s database\n", argv[0]); ! exit(EXIT_FAILURE); ! } ! 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); ! } ! ! termPQExpBuffer(&sql); ! initPQExpBuffer(&sql); ! 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" ! ); ! 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; + + termPQExpBuffer(&sql); + initPQExpBuffer(&sql); ! appendPQExpBuffer(&sql, "%s", ! "SELECT c.relname, " ! "(SELECT nspname FROM pg_catalog.pg_namespace n WHERE n.oid = c.relnamespace) AS nspname, " ! "a.attname, " ! "t.typname " ! "FROM pg_catalog.pg_class c, pg_catalog.pg_attribute a, pg_catalog.pg_type t " ! "WHERE a.attnum > 0 AND c.relkind = 'r' " ! "AND t.typnamespace IN (SELECT n.oid FROM pg_catalog.pg_namespace n WHERE nspname LIKE 'pg\\_%') " ! "AND (t.typname = 'oid' OR t.typname LIKE 'reg%') " ! "AND a.attrelid = c.oid " ! "AND a.atttypid = t.oid " ! "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; ! ! termPQExpBuffer(&sql); ! initPQExpBuffer(&sql); ! ! 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); ! fk_typname = PQgetvalue(fkrel_res, fk, 3); ! ! for (pk = 0; pk < PQntuples(pkrel_res); pk++) ! { ! pk_relname = PQgetvalue(pkrel_res, pk, 0); ! pk_nspname = PQgetvalue(pkrel_res, pk, 1); ! ! appendPQExpBuffer(&sql, ! "SELECT 1 " ! "FROM \"%s\".\"%s\" t1, " ! "\"%s\".\"%s\" t2 " ! "WHERE t1.\"%s\"::oid = t2.oid", ! 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.oid\n", ! fk_relname, fk_attname, pk_relname); ! ! PQclear(res); ! ! termPQExpBuffer(&sql); ! initPQExpBuffer(&sql); ! } ! } ! PQclear(pkrel_res); ! PQclear(fkrel_res); ! PQfinish(conn); ! exit(EXIT_SUCCESS); }