Skip to content

Instantly share code, notes, and snippets.

@tallpeak
Last active December 11, 2023 04:17
Show Gist options
  • Save tallpeak/bd6b3b3fbb979c478378f7bb3290e22c to your computer and use it in GitHub Desktop.
Save tallpeak/bd6b3b3fbb979c478378f7bb3290e22c to your computer and use it in GitHub Desktop.
All empty tables in a Postgresql database
drop FUNCTION empty_tables;
CREATE OR REPLACE FUNCTION empty_tables()
RETURNS TABLE(name text) AS
$BODY$
DECLARE
t record;
v_sql text;
hasdata bool;
BEGIN
DROP TABLE IF EXISTS tmp_emptytables;
CREATE TEMP TABLE tmp_emptytables (name text);
FOR t in (SELECT table_schema, table_name
FROM INFORMATION_SCHEMA.tables
WHERE table_schema NOT IN('information_schema','pg_catalog')
AND table_name <> 'tmp_emptytables')
LOOP
v_sql := 'SELECT true as hasdata FROM '||quote_ident(t.table_schema)||'.'||quote_ident(t.table_name)||' LIMIT 1';
--RAISE INFO 'v_sql:%',v_sql;
EXECUTE v_sql INTO hasdata;
IF hasdata IS NULL THEN
insert into tmp_emptytables SELECT quote_ident(t.table_schema)||'.'||quote_ident(t.table_name);
END IF;
END LOOP;
RETURN QUERY (SELECT * FROM tmp_emptytables ORDER BY 1);
END
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
select * from empty_tables();
/* --or just this query:
SELECT nspname || '.' || relname AS "relation"
FROM pg_class C LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
WHERE nspname NOT IN ('pg_catalog', 'information_schema','pg_toast') AND pg_relation_size(C.oid)=0
ORDER BY 1;
*/
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment