Skip to content

Instantly share code, notes, and snippets.

@thiago-vieira
Created August 22, 2022 15:59
Show Gist options
  • Star 0 You must be signed in to star a gist
  • Fork 0 You must be signed in to fork a gist
  • Save thiago-vieira/f90ef2e3ebf62e17cc0171754316d339 to your computer and use it in GitHub Desktop.
Save thiago-vieira/f90ef2e3ebf62e17cc0171754316d339 to your computer and use it in GitHub Desktop.
PostgreSQL - procurar em todas as tabelas de um schema por um determinado valor:
CREATE OR REPLACE FUNCTION search_columns(
needle text,
haystack_tables name[] default '{}',
haystack_schema name[] default '{public}'
)
RETURNS table(schemaname text, tablename text, columnname text, rowctid text)
AS $$
begin
FOR schemaname,tablename,columnname IN
SELECT c.table_schema,c.table_name,c.column_name
FROM information_schema.columns c
JOIN information_schema.tables t ON
(t.table_name=c.table_name AND t.table_schema=c.table_schema)
WHERE (c.table_name=ANY(haystack_tables) OR haystack_tables='{}')
AND c.table_schema=ANY(haystack_schema)
AND t.table_type='BASE TABLE'
LOOP
EXECUTE format('SELECT ctid FROM %I.%I WHERE cast(%I as text)=%L',
schemaname,
tablename,
columnname,
needle
) INTO rowctid;
IF rowctid is not null THEN
RETURN NEXT;
END IF;
END LOOP;
END;
$$ language plpgsql;
select * from search_columns('foo');
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment