Re: Performance issue when we use policies for Row Level Security along with functions

Поиск
Список
Период
Сортировка
От Gopisetty, Ramesh
Тема Re: Performance issue when we use policies for Row Level Security along with functions
Дата
Msg-id BL0PR11MB3153F7CC866F21DC8D3C2216EE070@BL0PR11MB3153.namprd11.prod.outlook.com
обсуждение исходный текст
Ответ на Re: Performance issue when we use policies for Row Level Security along with functions  (Tom Lane <tgl@sss.pgh.pa.us>)
Ответы Performance issue when we use policies for Row Level Security along with functions
Список pgsql-performance
Hi,

Thanks for providing the details.  But things didn't work out even after changing the functions to STABLE/IMMUTABLE.   If i don't use the function it works for RLS.  If i use functions it doesn't work. 

I tried with both IMMUTABLE and STABLE.  Both didn't work.    Is there a way to use function in RLS to have the index scan rather than the seq scan.   Please help me out if that works or not.  

Currently, we are in the processes of converting oracle to postgres.  Under oracle we have used functions and there exists a lot of logic in it. 

Thank you.

Function

drop function f_sel_1;
CREATE OR REPLACE FUNCTION f_sel_1(key character varying)
 RETURNS character varying
 LANGUAGE plpgsql
 IMMUTABLE
AS $function$
Declare
    v_status boolean;
    key_ctx varchar(4000);
BEGIN

   SELECT INTO key_ctx current_setting('key_header' || '.'||'ctx_key_fil');
   
    if key = key_ctx then
        return key_ctx;
    end if;
    return '';  
    exception when undefined_object then
        return '';
    
END;
$function$
;



drop policy policy_sel on test1;
create policy policy_sel on test1 FOR
SELECT
    to sch USING  ( key = 
        f_sel_1(key)
    );

explain analyze select * from test1;
                                              QUERY PLAN
-------------------------------------------------------------------------------------------------------
 Seq Scan on test1  (cost=0.00..1555.61 rows=25 width=555) (actual time=35.124..35.124 rows=0 loops=1)
   Filter: ((key)::text = (f_sel_1(key))::text)
   Rows Removed by Filter4909
 Planning Time0.070 ms
 Execution Time35.142 ms
(5 rows)



drop policy policy_sel on test1;
create policy policy_sel on test1 FOR
SELECT
    to sch USING  (
     key = 
        (
            current_setting('key_header'|| '.' || 'ctx_key_fil')
        )
  );


explain analyze select * from test1;
                                                      QUERY PLAN
-----------------------------------------------------------------------------------------------------------------------
 Bitmap Heap Scan on test1  (cost=9.78..270.01 rows=193 width=555) (actual time=0.040..0.069 rows=193 loops=1)
   Recheck Cond: ((key)::text = current_setting('key_header.ctx_key_fil'::text))
   Heap Blocks: exact=13
   ->  Bitmap Index Scan on test1_pkey  (cost=0.00..9.73 rows=193 width=0) (actual time=0.030..0.030 rows=193 loops=1)
         Index Cond: ((key)::text = current_setting('key_header.ctx_key_fil'::text))
 Planning Time0.118 ms
 Execution Time0.094 ms
(7 rows)


CREATE TABLE sch.test1 (
    key varchar(50NOT NULL,
    id varchar(32NOT NULL,
    begin_date date NOT NULL,
    eff_date_end date NULL,
    code varchar(100NULL,
    CONSTRAINT test1_pkey PRIMARY KEY (vpd_key, id, begin_date)
);


Thank you.

Regards,
Ramesh G

From: Tom Lane <tgl@sss.pgh.pa.us>
Sent: Wednesday, September 16, 2020 10:17 AM
To: Gopisetty, Ramesh <rameshg2@illinois.edu>
Cc: pgsql-performance@lists.postgresql.org <pgsql-performance@lists.postgresql.org>
Subject: Re: Performance issue when we use policies for Row Level Security along with functions
 
"Gopisetty, Ramesh" <rameshg2@illinois.edu> writes:
> Policy
> create policy  policy_sel on test FOR SELECT to ram1 USING  (  testkey in (f_sel_policy_test(testkey))  );
> Going to a Sequential scan instead of index scan.  Hence, performance issue.

> If i replace the policy with stright forward without function then it chooses the index.   Not sure how i can implement with the function.
> create policy  policy_sel on test FOR SELECT to ram1 USING  ( testkey in ('COMMON',current_setting('ctx_ng'||'.'||'ctx_key_fil')));

" testkey in ('COMMON',current_setting('ctx_ng'||'.'||'ctx_key_fil')) "
is an indexable condition on testkey, because it compares testkey to
a constant (or at least, a value that's fixed for the life of the query).

" testkey in (f_sel_policy_test(testkey)) "
is not an indexable condition on anything, because there are variables
on both sides of the condition.  So there's no fixed value that the
index can search on.

If you intend f_sel_policy_test() to be equivalent to the other condition,
why are you passing it an argument it doesn't need?

As Luis noted, there's also the problem that an indexable condition
can't be volatile.  I gather that SYS_CONTEXT ends up being a probe
of some GUC setting, which means that marking the function IMMUTABLE
would be a lie, but you ought to be able to mark it STABLE.

                        regards, tom lane

В списке pgsql-performance по дате отправления:

Предыдущее
От: Pavel Stehule
Дата:
Сообщение: Re: Indexing an XMLTABLE query?
Следующее
От: "David G. Johnston"
Дата:
Сообщение: Performance issue when we use policies for Row Level Security along with functions