public

Global search in PostgreSQL

Sometimes you need to find something in tables of the database but you don't know where to start? This function can help you.

17 days ago

Latest Post Workaround for crashing Cloud Director console proxy service by Alexey Koznov public

This SQL function helps you to find anything in the database using PostgreSQL:

CREATE OR REPLACE FUNCTION global_search(
search_term text,
param_tables text[] default '{}',
param_schemas text[] default '{public}',
progress text default null -- 'tables','hits','all'
)
RETURNS table(schemaname text, tablename text, columnname text, rowctid tid)
AS $$
declare
query text;
hit boolean;
begin
FOR schemaname,tablename IN
SELECT table_schema, table_name
FROM information_schema.tables t
WHERE (t.table_name=ANY(param_tables) OR param_tables='{}')
AND t.table_schema=ANY(param_schemas)
AND t.table_type='BASE TABLE'
LOOP
IF (progress in ('tables','all')) THEN
raise info '%', format('Searching globally in table: %I.%I',
schemaname, tablename);
END IF;
query := format('SELECT ctid FROM %I.%I AS t WHERE strpos(cast(t.* as text), %L) > 0',
schemaname,
tablename,
search_term);
FOR rowctid IN EXECUTE query
LOOP
FOR columnname IN
SELECT column_name
FROM information_schema.columns
WHERE table_name=tablename
AND table_schema=schemaname
LOOP
query := format('SELECT true FROM %I.%I WHERE cast(%I as text)=%L AND ctid=%L',
schemaname, tablename, columnname, search_term, rowctid);
EXECUTE query INTO hit;
IF hit THEN
IF (progress in ('hits', 'all')) THEN
raise info '%', format('Found in %I.%I.%I at ctid %s',
schemaname, tablename, columnname, rowctid);
END IF;
RETURN NEXT;
END IF;
END LOOP; -- for columnname
END LOOP; -- for rowctid
END LOOP; -- for table
END;
$$ language plpgsql;

The syntax for using this function:

select * from global_search('192.168.100.238')
select * from global_search('00:50:56:01:d1:6f')

I hope this article will be useful for you.

Alexey Koznov

Published 17 days ago

Comments?

Leave us your opinion.