Re: thousands of CachedPlan entry per backend

2023-06-02 Thread Jeff Janes
On Thu, Jun 1, 2023 at 4:51 AM James Pang (chaolpan) 
wrote:

>   2) from  this line, we saw total 42 blocks ,215 chunks
> CacheMemoryContext: 8737352 total in 42 blocks; 1021944 free (215 chunks);
> 7715408 used,
>
>   But from sum of it’s child level entrys,  total sum(child lines)
> block ,trunks show much more than “CacheMemoryContext,  is expected to see
> that?
>

Yes, that is expected.  The parent context reports only its own direct
memory usage and blocks.  It does not include the sum of memory usage of
its child contexts.

Cheers,

Jeff

>


RE: thousands of CachedPlan entry per backend

2023-06-02 Thread James Pang (chaolpan)
these lines about "SPI Plan" are these PL/PGSQL functions related through 
SPI_prepare plan entry, right?


SPI Plan: 1024 total in 1 blocks; 600 free (0 chunks); 424 used

CachedPlan: 2048 total in 2 blocks; 304 free (1 chunks); 1744 used: xxx

CachedPlanSource: 2048 total in 2 blocks; 200 free (0 chunks); 1848 used: 
xxx

  CachedPlanQuery: 2048 total in 2 blocks; 704 free (0 chunks); 1344 used

From: Pavel Stehule 
Sent: Friday, June 2, 2023 12:57 PM
To: James Pang (chaolpan) 
Cc: Laurenz Albe ; 
pgsql-performance@lists.postgresql.org
Subject: Re: thousands of CachedPlan entry per backend



pá 2. 6. 2023 v 3:45 odesílatel James Pang (chaolpan) 
mailto:chaol...@cisco.com>> napsal:
   these lines about "SPI Plan" are these PL/PGSQL functions related 
SPI_prepare plan entry, right?   Possible to set a GUC to max(cached plan) per 
backend ?

There is no limit for size of system cache. You can use pgbouncer that 
implicitly refresh session after 1 hour (and this limit can be reduced)

Regards

Pavel




SPI Plan: 1024 total in 1 blocks; 600 free (0 chunks); 424 used
CachedPlan: 2048 total in 2 blocks; 304 free (1 chunks); 1744 used: xxx
CachedPlanSource: 2048 total in 2 blocks; 200 free (0 chunks); 1848 used: 
xxx
  CachedPlanQuery: 2048 total in 2 blocks; 704 free (0 chunks); 1344 used

Thanks,

James

-Original Message-
From: Laurenz Albe mailto:laurenz.a...@cybertec.at>>
Sent: Thursday, June 1, 2023 8:48 PM
To: James Pang (chaolpan) mailto:chaol...@cisco.com>>; 
Pavel Stehule mailto:pavel.steh...@gmail.com>>
Cc: 
pgsql-performance@lists.postgresql.org<mailto:pgsql-performance@lists.postgresql.org>
Subject: Re: thousands of CachedPlan entry per backend

On Thu, 2023-06-01 at 08:50 +, James Pang (chaolpan) wrote:
> we found thousands of cached plan , since JDBC driver only allow max
> 256 cached prepared statements, how backend cache so many sql plans.
> If we have one function, when application call that function will make
> backend to cache  every SQL statement plan in that function too?   and for 
> table triggers, have similar caching behavior ?

Yes, as long as the functions are written in PL/pgSQL.
It only affects static SQL, that is, nothing that is run with EXECUTE.

Yours,
Laurenz Albe


Re: thousands of CachedPlan entry per backend

2023-06-01 Thread Pavel Stehule
pá 2. 6. 2023 v 3:45 odesílatel James Pang (chaolpan) 
napsal:

>these lines about "SPI Plan" are these PL/PGSQL functions related
> SPI_prepare plan entry, right?   Possible to set a GUC to max(cached plan)
> per backend ?
>

There is no limit for size of system cache. You can use pgbouncer that
implicitly refresh session after 1 hour (and this limit can be reduced)

Regards

Pavel




>
> SPI Plan: 1024 total in 1 blocks; 600 free (0 chunks); 424 used
> CachedPlan: 2048 total in 2 blocks; 304 free (1 chunks); 1744 used:
> xxx
> CachedPlanSource: 2048 total in 2 blocks; 200 free (0 chunks); 1848
> used: xxx
>   CachedPlanQuery: 2048 total in 2 blocks; 704 free (0 chunks); 1344
> used
>
> Thanks,
>
> James
>
> -Original Message-
> From: Laurenz Albe 
> Sent: Thursday, June 1, 2023 8:48 PM
> To: James Pang (chaolpan) ; Pavel Stehule <
> pavel.steh...@gmail.com>
> Cc: pgsql-performance@lists.postgresql.org
> Subject: Re: thousands of CachedPlan entry per backend
>
> On Thu, 2023-06-01 at 08:50 +, James Pang (chaolpan) wrote:
> > we found thousands of cached plan , since JDBC driver only allow max
> > 256 cached prepared statements, how backend cache so many sql plans.
> > If we have one function, when application call that function will make
> > backend to cache  every SQL statement plan in that function too?   and
> for table triggers, have similar caching behavior ?
>
> Yes, as long as the functions are written in PL/pgSQL.
> It only affects static SQL, that is, nothing that is run with EXECUTE.
>
> Yours,
> Laurenz Albe
>


RE: thousands of CachedPlan entry per backend

2023-06-01 Thread James Pang (chaolpan)
   these lines about "SPI Plan" are these PL/PGSQL functions related 
SPI_prepare plan entry, right?   Possible to set a GUC to max(cached plan) per 
backend ? 

SPI Plan: 1024 total in 1 blocks; 600 free (0 chunks); 424 used
CachedPlan: 2048 total in 2 blocks; 304 free (1 chunks); 1744 used: xxx
CachedPlanSource: 2048 total in 2 blocks; 200 free (0 chunks); 1848 used: 
xxx
  CachedPlanQuery: 2048 total in 2 blocks; 704 free (0 chunks); 1344 used

Thanks,

James

-Original Message-
From: Laurenz Albe  
Sent: Thursday, June 1, 2023 8:48 PM
To: James Pang (chaolpan) ; Pavel Stehule 

Cc: pgsql-performance@lists.postgresql.org
Subject: Re: thousands of CachedPlan entry per backend

On Thu, 2023-06-01 at 08:50 +, James Pang (chaolpan) wrote:
> we found thousands of cached plan , since JDBC driver only allow max 
> 256 cached prepared statements, how backend cache so many sql plans. 
> If we have one function, when application call that function will make 
> backend to cache  every SQL statement plan in that function too?   and for 
> table triggers, have similar caching behavior ?

Yes, as long as the functions are written in PL/pgSQL.
It only affects static SQL, that is, nothing that is run with EXECUTE.

Yours,
Laurenz Albe


Re: thousands of CachedPlan entry per backend

2023-06-01 Thread Laurenz Albe
On Thu, 2023-06-01 at 08:50 +, James Pang (chaolpan) wrote:
> we found thousands of cached plan , since JDBC driver only allow max 256 
> cached
> prepared statements, how backend cache so many sql plans. If we have one 
> function,
> when application call that function will make backend to cache  every SQL 
> statement
> plan in that function too?   and for table triggers, have similar caching 
> behavior ?

Yes, as long as the functions are written in PL/pgSQL.
It only affects static SQL, that is, nothing that is run with EXECUTE.

Yours,
Laurenz Albe




RE: thousands of CachedPlan entry per backend

2023-06-01 Thread James Pang (chaolpan)
Yes, too many cached metadata and we are thinking of a workaround to 
disconnect the sessions timely.
In addition, based on the dumped memory context, I have questions
   1) we found thousands of cached plan , since JDBC driver only allow max 256 
cached prepared statements, how backend cache so many sql plans. If we have one 
function,  when application call that function will make backend to cache  
every SQL statement plan in that function too?   and for table triggers, have 
similar caching behavior ?
  2) from  this line, we saw total 42 blocks ,215 chunks  
CacheMemoryContext: 8737352 total in 42 blocks; 1021944 free (215 chunks); 
7715408 used,
  But from sum of it’s child level entrys,  total sum(child lines) block 
,trunks show much more than “CacheMemoryContext,  is expected to see that?


Thanks,

James




From: Pavel Stehule 
Sent: Thursday, June 1, 2023 3:19 PM
To: Laurenz Albe 
Cc: James Pang (chaolpan) ; 
pgsql-performance@lists.postgresql.org
Subject: Re: thousands of CachedPlan entry per backend

Hi

čt 1. 6. 2023 v 8:53 odesílatel Laurenz Albe 
mailto:laurenz.a...@cybertec.at>> napsal:
On Thu, 2023-06-01 at 03:36 +, James Pang (chaolpan) wrote:
> PG V14.8-1 , client using Postgresql JDBC driver we found 40MB process memory 
> per
> backend, from Operating system and memorycontext dump “Grand total:”, both 
> mached.
> But from details, we found almost of entry belong to  “CacheMemoryContext”,
> from this line  CacheMemoryContext: 8737352 total in 42 blocks; 1021944 free 
> (215 chunks); 7715408 used,
> but there are thousands of lines of it’s child, the sum of blocks much more 
> than “8737352” total in 42 blocks
>
> Our application use Postgresql JDBC driver with default 
> parameters(maxprepared statement 256),
> there are many triggers, functions in this database, and a few functions run 
> sql by an extension
> pg_background.  We have thousands of connections and have big concern why 
> have thousands of entrys
> of cached SQL ?  that will consume huge memory ,  anyway to limit the cached 
> plan entry to save memory
> consumption?  Or it looks like an abnormal behavior or bug to see so many 
> cached plan lines.

If you have thousands of connections, that's your problem.  You need effective 
connection pooling.
Then 40MB per backend won't be a problem at all.  Having thousands of 
connections will cause
other, worse, problems for you.

See for example
https://www.cybertec-postgresql.com/en/tuning-max_connections-in-postgresql/

If you want to use functions, but don't want to benefit from plan caching, you 
can set
the configuration parameter "plan_cache_mode" to "force_custom_plan".

The problem with too big of cached metadata can be forced by too long sessions 
too.

In this case it is good to throw a session (connect) after 1hour or maybe less.

Regards

Pavel


Yours,
Laurenz Albe



Re: thousands of CachedPlan entry per backend

2023-06-01 Thread Pavel Stehule
Hi

čt 1. 6. 2023 v 8:53 odesílatel Laurenz Albe 
napsal:

> On Thu, 2023-06-01 at 03:36 +, James Pang (chaolpan) wrote:
> > PG V14.8-1 , client using Postgresql JDBC driver we found 40MB process
> memory per
> > backend, from Operating system and memorycontext dump “Grand total:”,
> both mached.
> > But from details, we found almost of entry belong to
>  “CacheMemoryContext”,
> > from this line  CacheMemoryContext: 8737352 total in 42 blocks; 1021944
> free (215 chunks); 7715408 used,
> > but there are thousands of lines of it’s child, the sum of blocks much
> more than “8737352” total in 42 blocks
> >
> > Our application use Postgresql JDBC driver with default
> parameters(maxprepared statement 256),
> > there are many triggers, functions in this database, and a few functions
> run sql by an extension
> > pg_background.  We have thousands of connections and have big concern
> why have thousands of entrys
> > of cached SQL ?  that will consume huge memory ,  anyway to limit the
> cached plan entry to save memory
> > consumption?  Or it looks like an abnormal behavior or bug to see so
> many cached plan lines.
>
> If you have thousands of connections, that's your problem.  You need
> effective connection pooling.
> Then 40MB per backend won't be a problem at all.  Having thousands of
> connections will cause
> other, worse, problems for you.
>
> See for example
>
> https://www.cybertec-postgresql.com/en/tuning-max_connections-in-postgresql/
>
> If you want to use functions, but don't want to benefit from plan caching,
> you can set
> the configuration parameter "plan_cache_mode" to "force_custom_plan".
>

The problem with too big of cached metadata can be forced by too long
sessions too.

In this case it is good to throw a session (connect) after 1hour or maybe
less.

Regards

Pavel


>
> Yours,
> Laurenz Albe
>
>
>


Re: thousands of CachedPlan entry per backend

2023-06-01 Thread Laurenz Albe
On Thu, 2023-06-01 at 03:36 +, James Pang (chaolpan) wrote:
> PG V14.8-1 , client using Postgresql JDBC driver we found 40MB process memory 
> per
> backend, from Operating system and memorycontext dump “Grand total:”, both 
> mached.
> But from details, we found almost of entry belong to  “CacheMemoryContext”,
> from this line  CacheMemoryContext: 8737352 total in 42 blocks; 1021944 free 
> (215 chunks); 7715408 used,
> but there are thousands of lines of it’s child, the sum of blocks much more 
> than “8737352” total in 42 blocks
> 
> Our application use Postgresql JDBC driver with default 
> parameters(maxprepared statement 256),
> there are many triggers, functions in this database, and a few functions run 
> sql by an extension
> pg_background.  We have thousands of connections and have big concern why 
> have thousands of entrys
> of cached SQL ?  that will consume huge memory ,  anyway to limit the cached 
> plan entry to save memory
> consumption?  Or it looks like an abnormal behavior or bug to see so many 
> cached plan lines.

If you have thousands of connections, that's your problem.  You need effective 
connection pooling.
Then 40MB per backend won't be a problem at all.  Having thousands of 
connections will cause
other, worse, problems for you.

See for example 
https://www.cybertec-postgresql.com/en/tuning-max_connections-in-postgresql/

If you want to use functions, but don't want to benefit from plan caching, you 
can set
the configuration parameter "plan_cache_mode" to "force_custom_plan".

Yours,
Laurenz Albe