Re: Is it possible to store the output of EXPLAIN into a table

From: Thomas Kellerer <spam_eater(at)gmx(dot)net>
To: pgsql-general(at)lists(dot)postgresql(dot)org
Subject: Re: Is it possible to store the output of EXPLAIN into a table
Date: 2019-04-22 16:01:13
Message-ID: 9378a90b-e03b-1477-e6b8-0efacd2613ad@gmx.net
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general

Souvik Bhattacherjee schrieb am 22.04.2019 um 17:27:
> Hi,
>
> I was just wondering if it is possible to store the output of EXPLAIN into a table.
>
> create temp table mytab as (select * from (explain select * from table1 where attr = 5) t);
>
>
> Unfortunately, the query above does not work.

You can't do that directly. You need to write a function that wraps the explain, and returns the plan as a result set.

Something like:

create or replace function show_plan(to_explain text)
returns table (line_nr integer, line text)
as
$$
declare
l_plan_line record;
l_line integer;
begin
l_line := 1;
for l_plan_line in execute 'explain (analyze, verbose, format xml)'||to_explain loop
return query select l_line, l_plan_line."QUERY PLAN"::text;
l_line := l_line + 1;
end loop;
end;
$$
language plpgsql;

The you can use:

create temp table mytab as
select *
from show_plan('select * from table1 where attr = 5');

In response to

Browse pgsql-general by date

  From Date Subject
Next Message Tom Lane 2019-04-22 16:02:01 Re: Is it possible to store the output of EXPLAIN into a table
Previous Message Thomas Kellerer 2019-04-22 16:01:01 Re: Is it possible to store the output of EXPLAIN into a table