1 ---------------------------------------------------------------------------
4 -- sample queries to the system catalogs
7 -- Portions Copyright (c) 1996-2009, PostgreSQL Global Development Group
8 -- Portions Copyright (c) 1994, Regents of the University of California
12 ---------------------------------------------------------------------------
15 -- Sets the schema search path to pg_catalog first, so that we do not
16 -- need to qualify every system object
18 SET SEARCH_PATH TO pg_catalog;
21 -- lists the names of all database owners and the name of their database(s)
23 SELECT rolname, datname
24 FROM pg_roles, pg_database
25 WHERE pg_roles.oid = datdba
26 ORDER BY rolname, datname;
29 -- lists all user-defined classes
31 SELECT n.nspname, c.relname
32 FROM pg_class c, pg_namespace n
33 WHERE c.relnamespace=n.oid
34 and c.relkind = 'r' -- not indices, views, etc
35 and n.nspname not like 'pg\\_%' -- not catalogs
36 and n.nspname != 'information_schema' -- not information_schema
37 ORDER BY nspname, relname;
41 -- lists all simple indices (ie. those that are defined over one simple
44 SELECT n.nspname AS schema_name,
45 bc.relname AS class_name,
46 ic.relname AS index_name,
49 pg_class bc, -- base class
50 pg_class ic, -- index class
52 pg_attribute a -- att in base
53 WHERE bc.relnamespace = n.oid
54 and i.indrelid = bc.oid
55 and i.indexrelid = ic.oid
56 and i.indkey[0] = a.attnum
58 and a.attrelid = bc.oid
59 ORDER BY schema_name, class_name, index_name, attname;
63 -- lists the user-defined attributes and their types for all user-defined
66 SELECT n.nspname, c.relname, a.attname, format_type(t.oid, null) as typname
67 FROM pg_namespace n, pg_class c,
68 pg_attribute a, pg_type t
69 WHERE n.oid = c.relnamespace
70 and c.relkind = 'r' -- no indices
71 and n.nspname not like 'pg\\_%' -- no catalogs
72 and n.nspname != 'information_schema' -- no information_schema
73 and a.attnum > 0 -- no system att's
74 and not a.attisdropped -- no dropped columns
75 and a.attrelid = c.oid
76 and a.atttypid = t.oid
77 ORDER BY nspname, relname, attname;
81 -- lists all user-defined base types (not including array types)
83 SELECT n.nspname, r.rolname, format_type(t.oid, null) as typname
84 FROM pg_type t, pg_roles r, pg_namespace n
85 WHERE r.oid = t.typowner
86 and t.typnamespace = n.oid
87 and t.typrelid = 0 -- no complex types
88 and t.typelem = 0 -- no arrays
89 and n.nspname not like 'pg\\_%' -- no built-in types
90 and n.nspname != 'information_schema' -- no information_schema
91 ORDER BY nspname, rolname, typname;
95 -- lists all left unary operators
97 SELECT n.nspname, o.oprname AS left_unary,
98 format_type(right_type.oid, null) AS operand,
99 format_type(result.oid, null) AS return_type
100 FROM pg_namespace n, pg_operator o,
101 pg_type right_type, pg_type result
102 WHERE o.oprnamespace = n.oid
103 and o.oprkind = 'l' -- left unary
104 and o.oprright = right_type.oid
105 and o.oprresult = result.oid
106 ORDER BY nspname, operand;
110 -- lists all right unary operators
112 SELECT n.nspname, o.oprname AS right_unary,
113 format_type(left_type.oid, null) AS operand,
114 format_type(result.oid, null) AS return_type
115 FROM pg_namespace n, pg_operator o,
116 pg_type left_type, pg_type result
117 WHERE o.oprnamespace = n.oid
118 and o.oprkind = 'r' -- right unary
119 and o.oprleft = left_type.oid
120 and o.oprresult = result.oid
121 ORDER BY nspname, operand;
124 -- lists all binary operators
126 SELECT n.nspname, o.oprname AS binary_op,
127 format_type(left_type.oid, null) AS left_opr,
128 format_type(right_type.oid, null) AS right_opr,
129 format_type(result.oid, null) AS return_type
130 FROM pg_namespace n, pg_operator o, pg_type left_type,
131 pg_type right_type, pg_type result
132 WHERE o.oprnamespace = n.oid
133 and o.oprkind = 'b' -- binary
134 and o.oprleft = left_type.oid
135 and o.oprright = right_type.oid
136 and o.oprresult = result.oid
137 ORDER BY nspname, left_opr, right_opr;
141 -- lists the name, number of arguments and the return type of all user-defined
144 SELECT n.nspname, p.proname, p.pronargs, format_type(t.oid, null) as return_type
145 FROM pg_namespace n, pg_proc p,
146 pg_language l, pg_type t
147 WHERE p.pronamespace = n.oid
148 and n.nspname not like 'pg\\_%' -- no catalogs
149 and n.nspname != 'information_schema' -- no information_schema
150 and p.prolang = l.oid
151 and p.prorettype = t.oid
153 ORDER BY nspname, proname, pronargs, return_type;
156 -- lists all aggregate functions and the types to which they can be applied
158 SELECT n.nspname, p.proname, format_type(t.oid, null) as typname
159 FROM pg_namespace n, pg_aggregate a,
161 WHERE p.pronamespace = n.oid
162 and a.aggfnoid = p.oid
163 and p.proargtypes[0] = t.oid
164 ORDER BY nspname, proname, typname;
168 -- lists all the operator families that can be used with each access method
169 -- as well as the operators that can be used with the respective operator
172 SELECT am.amname, n.nspname, opf.opfname, opr.oprname
173 FROM pg_namespace n, pg_am am, pg_opfamily opf,
174 pg_amop amop, pg_operator opr
175 WHERE opf.opfnamespace = n.oid
176 and opf.opfmethod = am.oid
177 and amop.amopfamily = opf.oid
178 and amop.amopopr = opr.oid
179 ORDER BY nspname, amname, opfname, oprname;
182 -- Reset the search path