Add connection active, idle time to pg_stat_activity

Started by Rafia Sabihabout 4 years ago55 messages
#1Rafia Sabih
rafia.pghackers@gmail.com

Hello there hackers,

We at Zalando have faced some issues around long running idle
transactions and were thinking about increasing the visibility of
pg_stat_* views to capture them easily. What I found is that currently
in pg_stat_activity there is a lot of good information about the
current state of the process, but it is lacking the cumulative
information on how much time the connection spent being idle, idle in
transaction or active, we would like to see cumulative values for each
of these per connection. I believe it would be helpful for us and more
people out there if we could have total connection active and idle
time displayed in pg_stat_activity.

To provide this information I was digging into how the statistics
collector is working and found out there is already information like
total time that a connection is active as well as idle computed in
pgstat_report_activity[1]https://github.com/postgres/postgres/blob/cd3f429d9565b2e5caf0980ea7c707e37bc3b317/src/backend/utils/activity/backend_status.c#L593. Ideally, this would be the values we would
like to see per process in pg_stat_activity.

Curious to know your thoughts on this.

[1]: https://github.com/postgres/postgres/blob/cd3f429d9565b2e5caf0980ea7c707e37bc3b317/src/backend/utils/activity/backend_status.c#L593

--
Regards,
Rafia Sabih

#2Rafia Sabih
rafia.pghackers@gmail.com
In reply to: Rafia Sabih (#1)
1 attachment(s)
Re: Add connection active, idle time to pg_stat_activity

On Fri, 22 Oct 2021 at 10:22, Rafia Sabih <rafia.pghackers@gmail.com> wrote:

Hello there hackers,

We at Zalando have faced some issues around long running idle
transactions and were thinking about increasing the visibility of
pg_stat_* views to capture them easily. What I found is that currently
in pg_stat_activity there is a lot of good information about the
current state of the process, but it is lacking the cumulative
information on how much time the connection spent being idle, idle in
transaction or active, we would like to see cumulative values for each
of these per connection. I believe it would be helpful for us and more
people out there if we could have total connection active and idle
time displayed in pg_stat_activity.

To provide this information I was digging into how the statistics
collector is working and found out there is already information like
total time that a connection is active as well as idle computed in
pgstat_report_activity[1]. Ideally, this would be the values we would
like to see per process in pg_stat_activity.

Curious to know your thoughts on this.

[1]https://github.com/postgres/postgres/blob/cd3f429d9565b2e5caf0980ea7c707e37bc3b317/src/backend/utils/activity/backend_status.c#L593

--
Regards,
Rafia Sabih

Please find the attached patch for the idea of our intentions.
It basically adds three attributes for idle, idle_in_transaction, and
active time respectively.
Please let me know your views on this and I shall add this to the
upcoming commitfest for better tracking.

--
Regards,
Rafia Sabih

Attachments:

v1_add_idle_active_time.patchtext/x-patch; charset=US-ASCII; name=v1_add_idle_active_time.patchDownload
diff --git a/src/backend/catalog/system_views.sql b/src/backend/catalog/system_views.sql
index 55f6e3711d..c721dbc0c5 100644
--- a/src/backend/catalog/system_views.sql
+++ b/src/backend/catalog/system_views.sql
@@ -835,7 +835,10 @@ CREATE VIEW pg_stat_activity AS
             s.backend_xmin,
             S.query_id,
             S.query,
-            S.backend_type
+            S.backend_type,
+            S.active_time,
+            S.idle_in_transaction_time,
+            S.idle_time
     FROM pg_stat_get_activity(NULL) AS S
         LEFT JOIN pg_database AS D ON (S.datid = D.oid)
         LEFT JOIN pg_authid AS U ON (S.usesysid = U.oid);
diff --git a/src/backend/postmaster/pgstat.c b/src/backend/postmaster/pgstat.c
index b7d0fbaefd..3e0eb963b3 100644
--- a/src/backend/postmaster/pgstat.c
+++ b/src/backend/postmaster/pgstat.c
@@ -249,6 +249,7 @@ PgStat_Counter pgStatBlockWriteTime = 0;
 static PgStat_Counter pgLastSessionReportTime = 0;
 PgStat_Counter pgStatActiveTime = 0;
 PgStat_Counter pgStatTransactionIdleTime = 0;
+PgStat_Counter pgStatTransactionIdleInTxnTime = 0;
 SessionEndType pgStatSessionEndCause = DISCONNECT_NORMAL;
 
 /* Record that's written to 2PC state file when pgstat state is persisted */
diff --git a/src/backend/utils/activity/backend_status.c b/src/backend/utils/activity/backend_status.c
index 7229598822..7ced0f738b 100644
--- a/src/backend/utils/activity/backend_status.c
+++ b/src/backend/utils/activity/backend_status.c
@@ -590,9 +590,20 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 
 		if (beentry->st_state == STATE_RUNNING ||
 			beentry->st_state == STATE_FASTPATH)
-			pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 + usecs);
+		{
+				pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 + usecs);
+				beentry->st_active_time = pgStatActiveTime;
+		}
+		else if (beentry->st_state ==  STATE_IDLEINTRANSACTION)
+		{
+			pgstat_count_conn_txn_idle_in_txn_time((PgStat_Counter) secs * 1000000 + usecs);
+			beentry->st_idle_in_transaction_time = pgStatTransactionIdleInTxnTime;
+		}
 		else
+		{
 			pgstat_count_conn_txn_idle_time((PgStat_Counter) secs * 1000000 + usecs);
+			beentry->st_idle_time = pgStatTransactionIdleTime;
+		}
 	}
 
 	/*
diff --git a/src/backend/utils/adt/pgstatfuncs.c b/src/backend/utils/adt/pgstatfuncs.c
index ff5aedc99c..8044318533 100644
--- a/src/backend/utils/adt/pgstatfuncs.c
+++ b/src/backend/utils/adt/pgstatfuncs.c
@@ -567,7 +567,7 @@ pg_stat_get_progress_info(PG_FUNCTION_ARGS)
 Datum
 pg_stat_get_activity(PG_FUNCTION_ARGS)
 {
-#define PG_STAT_GET_ACTIVITY_COLS	30
+#define PG_STAT_GET_ACTIVITY_COLS	33
 	int			num_backends = pgstat_fetch_stat_numbackends();
 	int			curr_backend;
 	int			pid = PG_ARGISNULL(0) ? -1 : PG_GETARG_INT32(0);
@@ -916,6 +916,10 @@ pg_stat_get_activity(PG_FUNCTION_ARGS)
 				nulls[29] = true;
 			else
 				values[29] = UInt64GetDatum(beentry->st_query_id);
+
+			values[30] = Int64GetDatum(beentry->st_active_time);
+			values[31] = Int64GetDatum(beentry->st_idle_in_transaction_time);
+			values[32] = Int64GetDatum(beentry->st_idle_time);
 		}
 		else
 		{
@@ -944,6 +948,9 @@ pg_stat_get_activity(PG_FUNCTION_ARGS)
 			nulls[27] = true;
 			nulls[28] = true;
 			nulls[29] = true;
+			values[30] = true;
+			values[31] = true;
+			values[32] = true;
 		}
 
 		tuplestore_putvalues(tupstore, tupdesc, values, nulls);
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index d068d6532e..6f2b1a8dbd 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -5348,9 +5348,9 @@
   proname => 'pg_stat_get_activity', prorows => '100', proisstrict => 'f',
   proretset => 't', provolatile => 's', proparallel => 'r',
   prorettype => 'record', proargtypes => 'int4',
-  proallargtypes => '{int4,oid,int4,oid,text,text,text,text,text,timestamptz,timestamptz,timestamptz,timestamptz,inet,text,int4,xid,xid,text,bool,text,text,int4,text,numeric,text,bool,text,bool,int4,int8}',
-  proargmodes => '{i,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o}',
-  proargnames => '{pid,datid,pid,usesysid,application_name,state,query,wait_event_type,wait_event,xact_start,query_start,backend_start,state_change,client_addr,client_hostname,client_port,backend_xid,backend_xmin,backend_type,ssl,sslversion,sslcipher,sslbits,ssl_client_dn,ssl_client_serial,ssl_issuer_dn,gss_auth,gss_princ,gss_enc,leader_pid,query_id}',
+  proallargtypes => '{int4,oid,int4,oid,text,text,text,text,text,timestamptz,timestamptz,timestamptz,timestamptz,inet,text,int4,xid,xid,text,bool,text,text,int4,text,numeric,text,bool,text,bool,int4,int8,int4,int4},int4',
+  proargmodes => '{i,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o}',
+  proargnames => '{pid,datid,pid,usesysid,application_name,state,query,wait_event_type,wait_event,xact_start,query_start,backend_start,state_change,client_addr,client_hostname,client_port,backend_xid,backend_xmin,backend_type,ssl,sslversion,sslcipher,sslbits,ssl_client_dn,ssl_client_serial,ssl_issuer_dn,gss_auth,gss_princ,gss_enc,leader_pid,query_id,active_time,idle_in_transaction_time,idle_time}',
   prosrc => 'pg_stat_get_activity' },
 { oid => '3318',
   descr => 'statistics: information about progress of backends running maintenance command',
diff --git a/src/include/pgstat.h b/src/include/pgstat.h
index bcd3588ea2..916764a02a 100644
--- a/src/include/pgstat.h
+++ b/src/include/pgstat.h
@@ -985,6 +985,7 @@ extern PgStat_Counter pgStatBlockWriteTime;
  */
 extern PgStat_Counter pgStatActiveTime;
 extern PgStat_Counter pgStatTransactionIdleTime;
+extern PgStat_Counter pgStatTransactionIdleInTxnTime;
 
 
 /*
@@ -1092,6 +1093,8 @@ extern void pgstat_initstats(Relation rel);
 	(pgStatActiveTime += (n))
 #define pgstat_count_conn_txn_idle_time(n)							\
 	(pgStatTransactionIdleTime += (n))
+#define pgstat_count_conn_txn_idle_in_txn_time(n)					\
+	(pgStatTransactionIdleInTxnTime += (n))
 
 extern void pgstat_count_heap_insert(Relation rel, PgStat_Counter n);
 extern void pgstat_count_heap_update(Relation rel, bool hot);
diff --git a/src/include/utils/backend_status.h b/src/include/utils/backend_status.h
index 8042b817df..063262e6ae 100644
--- a/src/include/utils/backend_status.h
+++ b/src/include/utils/backend_status.h
@@ -168,6 +168,10 @@ typedef struct PgBackendStatus
 
 	/* query identifier, optionally computed using post_parse_analyze_hook */
 	uint64		st_query_id;
+
+	int64		st_active_time;
+	int64 		st_idle_in_transaction_time;
+	int64 		st_idle_time;
 } PgBackendStatus;
 
 
#3Dilip Kumar
dilipbalaut@gmail.com
In reply to: Rafia Sabih (#2)
Re: Add connection active, idle time to pg_stat_activity

On Tue, Oct 26, 2021 at 5:17 PM Rafia Sabih <rafia.pghackers@gmail.com> wrote:

To provide this information I was digging into how the statistics
collector is working and found out there is already information like
total time that a connection is active as well as idle computed in
pgstat_report_activity[1]. Ideally, this would be the values we would
like to see per process in pg_stat_activity.

Curious to know your thoughts on this.

+1 for the idea

Please find the attached patch for the idea of our intentions.
It basically adds three attributes for idle, idle_in_transaction, and
active time respectively.
Please let me know your views on this and I shall add this to the
upcoming commitfest for better tracking.

About the patch, IIUC earlier all the idle time was accumulated in the
"pgStatTransactionIdleTime" counter, now with your patch you have
introduced one more counter which specifically tracks the
STATE_IDLEINTRANSACTION state. But my concern is that the
STATE_IDLEINTRANSACTION_ABORTED is still computed under STATE_IDLE and
that looks odd to me. Either STATE_IDLEINTRANSACTION_ABORTED should
be accumulated in the "pgStatTransactionIdleInTxnTime" counter or
there should be a separate counter for that. But after your patch we
can not accumulate this in the "pgStatTransactionIdleTime" counter.

--
Regards,
Dilip Kumar
EnterpriseDB: http://www.enterprisedb.com

#4Rafia Sabih
rafia.pghackers@gmail.com
In reply to: Dilip Kumar (#3)
1 attachment(s)
Re: Add connection active, idle time to pg_stat_activity

On Tue, 2 Nov 2021 at 09:00, Dilip Kumar <dilipbalaut@gmail.com> wrote:

On Tue, Oct 26, 2021 at 5:17 PM Rafia Sabih <rafia.pghackers@gmail.com> wrote:

To provide this information I was digging into how the statistics
collector is working and found out there is already information like
total time that a connection is active as well as idle computed in
pgstat_report_activity[1]. Ideally, this would be the values we would
like to see per process in pg_stat_activity.

Curious to know your thoughts on this.

+1 for the idea

Thanks!

Please find the attached patch for the idea of our intentions.
It basically adds three attributes for idle, idle_in_transaction, and
active time respectively.
Please let me know your views on this and I shall add this to the
upcoming commitfest for better tracking.

About the patch, IIUC earlier all the idle time was accumulated in the
"pgStatTransactionIdleTime" counter, now with your patch you have
introduced one more counter which specifically tracks the
STATE_IDLEINTRANSACTION state. But my concern is that the
STATE_IDLEINTRANSACTION_ABORTED is still computed under STATE_IDLE and
that looks odd to me. Either STATE_IDLEINTRANSACTION_ABORTED should
be accumulated in the "pgStatTransactionIdleInTxnTime" counter or
there should be a separate counter for that. But after your patch we
can not accumulate this in the "pgStatTransactionIdleTime" counter.

As per your comments I have added it in pgStatTransactionIdleInTxnTime.
Please let me know if there are any further comments.

--
Regards,
Rafia Sabih

Attachments:

v2_add_idle_active_time.patchtext/x-patch; charset=US-ASCII; name=v2_add_idle_active_time.patchDownload
diff --git a/src/backend/catalog/system_views.sql b/src/backend/catalog/system_views.sql
index eb560955cd..4dfa33ffa9 100644
--- a/src/backend/catalog/system_views.sql
+++ b/src/backend/catalog/system_views.sql
@@ -839,7 +839,10 @@ CREATE VIEW pg_stat_activity AS
             s.backend_xmin,
             S.query_id,
             S.query,
-            S.backend_type
+            S.backend_type,
+            S.active_time,
+            S.idle_in_transaction_time,
+            S.idle_time
     FROM pg_stat_get_activity(NULL) AS S
         LEFT JOIN pg_database AS D ON (S.datid = D.oid)
         LEFT JOIN pg_authid AS U ON (S.usesysid = U.oid);
diff --git a/src/backend/postmaster/pgstat.c b/src/backend/postmaster/pgstat.c
index b7d0fbaefd..3e0eb963b3 100644
--- a/src/backend/postmaster/pgstat.c
+++ b/src/backend/postmaster/pgstat.c
@@ -249,6 +249,7 @@ PgStat_Counter pgStatBlockWriteTime = 0;
 static PgStat_Counter pgLastSessionReportTime = 0;
 PgStat_Counter pgStatActiveTime = 0;
 PgStat_Counter pgStatTransactionIdleTime = 0;
+PgStat_Counter pgStatTransactionIdleInTxnTime = 0;
 SessionEndType pgStatSessionEndCause = DISCONNECT_NORMAL;
 
 /* Record that's written to 2PC state file when pgstat state is persisted */
diff --git a/src/backend/utils/activity/backend_status.c b/src/backend/utils/activity/backend_status.c
index 7229598822..805cf7ae1e 100644
--- a/src/backend/utils/activity/backend_status.c
+++ b/src/backend/utils/activity/backend_status.c
@@ -590,9 +590,21 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 
 		if (beentry->st_state == STATE_RUNNING ||
 			beentry->st_state == STATE_FASTPATH)
-			pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 + usecs);
+		{
+				pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 + usecs);
+				beentry->st_active_time = pgStatActiveTime;
+		}
+		else if (beentry->st_state ==  STATE_IDLEINTRANSACTION ||
+				 beentry->st_state == STATE_IDLEINTRANSACTION_ABORTED)
+		{
+			pgstat_count_conn_txn_idle_in_txn_time((PgStat_Counter) secs * 1000000 + usecs);
+			beentry->st_idle_in_transaction_time = pgStatTransactionIdleInTxnTime;
+		}
 		else
+		{
 			pgstat_count_conn_txn_idle_time((PgStat_Counter) secs * 1000000 + usecs);
+			beentry->st_idle_time = pgStatTransactionIdleTime;
+		}
 	}
 
 	/*
diff --git a/src/backend/utils/adt/pgstatfuncs.c b/src/backend/utils/adt/pgstatfuncs.c
index ff5aedc99c..8044318533 100644
--- a/src/backend/utils/adt/pgstatfuncs.c
+++ b/src/backend/utils/adt/pgstatfuncs.c
@@ -567,7 +567,7 @@ pg_stat_get_progress_info(PG_FUNCTION_ARGS)
 Datum
 pg_stat_get_activity(PG_FUNCTION_ARGS)
 {
-#define PG_STAT_GET_ACTIVITY_COLS	30
+#define PG_STAT_GET_ACTIVITY_COLS	33
 	int			num_backends = pgstat_fetch_stat_numbackends();
 	int			curr_backend;
 	int			pid = PG_ARGISNULL(0) ? -1 : PG_GETARG_INT32(0);
@@ -916,6 +916,10 @@ pg_stat_get_activity(PG_FUNCTION_ARGS)
 				nulls[29] = true;
 			else
 				values[29] = UInt64GetDatum(beentry->st_query_id);
+
+			values[30] = Int64GetDatum(beentry->st_active_time);
+			values[31] = Int64GetDatum(beentry->st_idle_in_transaction_time);
+			values[32] = Int64GetDatum(beentry->st_idle_time);
 		}
 		else
 		{
@@ -944,6 +948,9 @@ pg_stat_get_activity(PG_FUNCTION_ARGS)
 			nulls[27] = true;
 			nulls[28] = true;
 			nulls[29] = true;
+			values[30] = true;
+			values[31] = true;
+			values[32] = true;
 		}
 
 		tuplestore_putvalues(tupstore, tupdesc, values, nulls);
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index d068d6532e..6f2b1a8dbd 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -5348,9 +5348,9 @@
   proname => 'pg_stat_get_activity', prorows => '100', proisstrict => 'f',
   proretset => 't', provolatile => 's', proparallel => 'r',
   prorettype => 'record', proargtypes => 'int4',
-  proallargtypes => '{int4,oid,int4,oid,text,text,text,text,text,timestamptz,timestamptz,timestamptz,timestamptz,inet,text,int4,xid,xid,text,bool,text,text,int4,text,numeric,text,bool,text,bool,int4,int8}',
-  proargmodes => '{i,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o}',
-  proargnames => '{pid,datid,pid,usesysid,application_name,state,query,wait_event_type,wait_event,xact_start,query_start,backend_start,state_change,client_addr,client_hostname,client_port,backend_xid,backend_xmin,backend_type,ssl,sslversion,sslcipher,sslbits,ssl_client_dn,ssl_client_serial,ssl_issuer_dn,gss_auth,gss_princ,gss_enc,leader_pid,query_id}',
+  proallargtypes => '{int4,oid,int4,oid,text,text,text,text,text,timestamptz,timestamptz,timestamptz,timestamptz,inet,text,int4,xid,xid,text,bool,text,text,int4,text,numeric,text,bool,text,bool,int4,int8,int4,int4},int4',
+  proargmodes => '{i,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o}',
+  proargnames => '{pid,datid,pid,usesysid,application_name,state,query,wait_event_type,wait_event,xact_start,query_start,backend_start,state_change,client_addr,client_hostname,client_port,backend_xid,backend_xmin,backend_type,ssl,sslversion,sslcipher,sslbits,ssl_client_dn,ssl_client_serial,ssl_issuer_dn,gss_auth,gss_princ,gss_enc,leader_pid,query_id,active_time,idle_in_transaction_time,idle_time}',
   prosrc => 'pg_stat_get_activity' },
 { oid => '3318',
   descr => 'statistics: information about progress of backends running maintenance command',
diff --git a/src/include/pgstat.h b/src/include/pgstat.h
index bcd3588ea2..916764a02a 100644
--- a/src/include/pgstat.h
+++ b/src/include/pgstat.h
@@ -985,6 +985,7 @@ extern PgStat_Counter pgStatBlockWriteTime;
  */
 extern PgStat_Counter pgStatActiveTime;
 extern PgStat_Counter pgStatTransactionIdleTime;
+extern PgStat_Counter pgStatTransactionIdleInTxnTime;
 
 
 /*
@@ -1092,6 +1093,8 @@ extern void pgstat_initstats(Relation rel);
 	(pgStatActiveTime += (n))
 #define pgstat_count_conn_txn_idle_time(n)							\
 	(pgStatTransactionIdleTime += (n))
+#define pgstat_count_conn_txn_idle_in_txn_time(n)					\
+	(pgStatTransactionIdleInTxnTime += (n))
 
 extern void pgstat_count_heap_insert(Relation rel, PgStat_Counter n);
 extern void pgstat_count_heap_update(Relation rel, bool hot);
diff --git a/src/include/utils/backend_status.h b/src/include/utils/backend_status.h
index 8042b817df..063262e6ae 100644
--- a/src/include/utils/backend_status.h
+++ b/src/include/utils/backend_status.h
@@ -168,6 +168,10 @@ typedef struct PgBackendStatus
 
 	/* query identifier, optionally computed using post_parse_analyze_hook */
 	uint64		st_query_id;
+
+	int64		st_active_time;
+	int64 		st_idle_in_transaction_time;
+	int64 		st_idle_time;
 } PgBackendStatus;
 
 
#5Dilip Kumar
dilipbalaut@gmail.com
In reply to: Rafia Sabih (#4)
Re: Add connection active, idle time to pg_stat_activity

On Tue, Nov 9, 2021 at 8:28 PM Rafia Sabih <rafia.pghackers@gmail.com> wrote:

On Tue, 2 Nov 2021 at 09:00, Dilip Kumar <dilipbalaut@gmail.com> wrote:

About the patch, IIUC earlier all the idle time was accumulated in the
"pgStatTransactionIdleTime" counter, now with your patch you have
introduced one more counter which specifically tracks the
STATE_IDLEINTRANSACTION state. But my concern is that the
STATE_IDLEINTRANSACTION_ABORTED is still computed under STATE_IDLE and
that looks odd to me. Either STATE_IDLEINTRANSACTION_ABORTED should
be accumulated in the "pgStatTransactionIdleInTxnTime" counter or
there should be a separate counter for that. But after your patch we
can not accumulate this in the "pgStatTransactionIdleTime" counter.

As per your comments I have added it in pgStatTransactionIdleInTxnTime.
Please let me know if there are any further comments.

I have a few comments,

             nulls[29] = true;
+            values[30] = true;
+            values[31] = true;
+            values[32] = true;

This looks wrong, this should be nulls[] = true not values[]=true.

if ((beentry->st_state == STATE_RUNNING ||
beentry->st_state == STATE_FASTPATH ||
beentry->st_state == STATE_IDLEINTRANSACTION ||
beentry->st_state == STATE_IDLEINTRANSACTION_ABORTED) &&
state != beentry->st_state)
{
if (beentry->st_state == STATE_RUNNING ||
beentry->st_state == STATE_FASTPATH)
{
pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 + usecs);
beentry->st_active_time = pgStatActiveTime;
}
else if (beentry->st_state == STATE_IDLEINTRANSACTION ||
beentry->st_state == STATE_IDLEINTRANSACTION_ABORTED)
{
pgstat_count_conn_txn_idle_in_txn_time((PgStat_Counter) secs *
1000000 + usecs);
beentry->st_idle_in_transaction_time = pgStatTransactionIdleInTxnTime;
}
else
{
pgstat_count_conn_txn_idle_time((PgStat_Counter) secs * 1000000 + usecs);
beentry->st_idle_time = pgStatTransactionIdleTime;
}

It seems that in beentry->st_idle_time, you want to compute the
STATE_IDLE, but that state is not handled in the outer "if", that
means whenever it comes out of the
STATE_IDLE, it will not enter inside this if check. You can run and
test, I am sure that with this patch the "idle_time" will always
remain 0.

--
Regards,
Dilip Kumar
EnterpriseDB: http://www.enterprisedb.com

#6Rafia Sabih
rafia.pghackers@gmail.com
In reply to: Dilip Kumar (#5)
1 attachment(s)
Re: Add connection active, idle time to pg_stat_activity

On Wed, 10 Nov 2021 at 09:05, Dilip Kumar <dilipbalaut@gmail.com> wrote:

On Tue, Nov 9, 2021 at 8:28 PM Rafia Sabih <rafia.pghackers@gmail.com> wrote:

On Tue, 2 Nov 2021 at 09:00, Dilip Kumar <dilipbalaut@gmail.com> wrote:

About the patch, IIUC earlier all the idle time was accumulated in the
"pgStatTransactionIdleTime" counter, now with your patch you have
introduced one more counter which specifically tracks the
STATE_IDLEINTRANSACTION state. But my concern is that the
STATE_IDLEINTRANSACTION_ABORTED is still computed under STATE_IDLE and
that looks odd to me. Either STATE_IDLEINTRANSACTION_ABORTED should
be accumulated in the "pgStatTransactionIdleInTxnTime" counter or
there should be a separate counter for that. But after your patch we
can not accumulate this in the "pgStatTransactionIdleTime" counter.

As per your comments I have added it in pgStatTransactionIdleInTxnTime.
Please let me know if there are any further comments.

I have a few comments,

nulls[29] = true;
+            values[30] = true;
+            values[31] = true;
+            values[32] = true;

This looks wrong, this should be nulls[] = true not values[]=true.

if ((beentry->st_state == STATE_RUNNING ||
beentry->st_state == STATE_FASTPATH ||
beentry->st_state == STATE_IDLEINTRANSACTION ||
beentry->st_state == STATE_IDLEINTRANSACTION_ABORTED) &&
state != beentry->st_state)
{
if (beentry->st_state == STATE_RUNNING ||
beentry->st_state == STATE_FASTPATH)
{
pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 + usecs);
beentry->st_active_time = pgStatActiveTime;
}
else if (beentry->st_state == STATE_IDLEINTRANSACTION ||
beentry->st_state == STATE_IDLEINTRANSACTION_ABORTED)
{
pgstat_count_conn_txn_idle_in_txn_time((PgStat_Counter) secs *
1000000 + usecs);
beentry->st_idle_in_transaction_time = pgStatTransactionIdleInTxnTime;
}
else
{
pgstat_count_conn_txn_idle_time((PgStat_Counter) secs * 1000000 + usecs);
beentry->st_idle_time = pgStatTransactionIdleTime;
}

It seems that in beentry->st_idle_time, you want to compute the
STATE_IDLE, but that state is not handled in the outer "if", that
means whenever it comes out of the
STATE_IDLE, it will not enter inside this if check. You can run and
test, I am sure that with this patch the "idle_time" will always
remain 0.

Thank you Dilip for your time on this.
And yes you are right in both your observations.
Please find the attached patch for the updated version.

--
Regards,
Rafia Sabih

Attachments:

v3_add_idle_active_time.patchtext/x-patch; charset=US-ASCII; name=v3_add_idle_active_time.patchDownload
diff --git a/src/backend/catalog/system_views.sql b/src/backend/catalog/system_views.sql
index eb560955cd..4dfa33ffa9 100644
--- a/src/backend/catalog/system_views.sql
+++ b/src/backend/catalog/system_views.sql
@@ -839,7 +839,10 @@ CREATE VIEW pg_stat_activity AS
             s.backend_xmin,
             S.query_id,
             S.query,
-            S.backend_type
+            S.backend_type,
+            S.active_time,
+            S.idle_in_transaction_time,
+            S.idle_time
     FROM pg_stat_get_activity(NULL) AS S
         LEFT JOIN pg_database AS D ON (S.datid = D.oid)
         LEFT JOIN pg_authid AS U ON (S.usesysid = U.oid);
diff --git a/src/backend/postmaster/pgstat.c b/src/backend/postmaster/pgstat.c
index b7d0fbaefd..3e0eb963b3 100644
--- a/src/backend/postmaster/pgstat.c
+++ b/src/backend/postmaster/pgstat.c
@@ -249,6 +249,7 @@ PgStat_Counter pgStatBlockWriteTime = 0;
 static PgStat_Counter pgLastSessionReportTime = 0;
 PgStat_Counter pgStatActiveTime = 0;
 PgStat_Counter pgStatTransactionIdleTime = 0;
+PgStat_Counter pgStatTransactionIdleInTxnTime = 0;
 SessionEndType pgStatSessionEndCause = DISCONNECT_NORMAL;
 
 /* Record that's written to 2PC state file when pgstat state is persisted */
diff --git a/src/backend/utils/activity/backend_status.c b/src/backend/utils/activity/backend_status.c
index 7229598822..2d7d3b6dce 100644
--- a/src/backend/utils/activity/backend_status.c
+++ b/src/backend/utils/activity/backend_status.c
@@ -577,6 +577,7 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 	 */
 	if ((beentry->st_state == STATE_RUNNING ||
 		 beentry->st_state == STATE_FASTPATH ||
+		 beentry->st_state == STATE_IDLE ||
 		 beentry->st_state == STATE_IDLEINTRANSACTION ||
 		 beentry->st_state == STATE_IDLEINTRANSACTION_ABORTED) &&
 		state != beentry->st_state)
@@ -590,9 +591,21 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 
 		if (beentry->st_state == STATE_RUNNING ||
 			beentry->st_state == STATE_FASTPATH)
-			pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 + usecs);
+		{
+				pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 + usecs);
+				beentry->st_active_time = pgStatActiveTime;
+		}
+		else if (beentry->st_state ==  STATE_IDLEINTRANSACTION ||
+				 beentry->st_state == STATE_IDLEINTRANSACTION_ABORTED)
+		{
+			pgstat_count_conn_txn_idle_in_txn_time((PgStat_Counter) secs * 1000000 + usecs);
+			beentry->st_idle_in_transaction_time = pgStatTransactionIdleInTxnTime;
+		}
 		else
+		{
 			pgstat_count_conn_txn_idle_time((PgStat_Counter) secs * 1000000 + usecs);
+			beentry->st_idle_time = pgStatTransactionIdleTime;
+		}
 	}
 
 	/*
diff --git a/src/backend/utils/adt/pgstatfuncs.c b/src/backend/utils/adt/pgstatfuncs.c
index ff5aedc99c..471af0db6a 100644
--- a/src/backend/utils/adt/pgstatfuncs.c
+++ b/src/backend/utils/adt/pgstatfuncs.c
@@ -567,7 +567,7 @@ pg_stat_get_progress_info(PG_FUNCTION_ARGS)
 Datum
 pg_stat_get_activity(PG_FUNCTION_ARGS)
 {
-#define PG_STAT_GET_ACTIVITY_COLS	30
+#define PG_STAT_GET_ACTIVITY_COLS	33
 	int			num_backends = pgstat_fetch_stat_numbackends();
 	int			curr_backend;
 	int			pid = PG_ARGISNULL(0) ? -1 : PG_GETARG_INT32(0);
@@ -916,6 +916,10 @@ pg_stat_get_activity(PG_FUNCTION_ARGS)
 				nulls[29] = true;
 			else
 				values[29] = UInt64GetDatum(beentry->st_query_id);
+
+			values[30] = Int64GetDatum(beentry->st_active_time);
+			values[31] = Int64GetDatum(beentry->st_idle_in_transaction_time);
+			values[32] = Int64GetDatum(beentry->st_idle_time);
 		}
 		else
 		{
@@ -944,6 +948,9 @@ pg_stat_get_activity(PG_FUNCTION_ARGS)
 			nulls[27] = true;
 			nulls[28] = true;
 			nulls[29] = true;
+			nulls[30] = true;
+			nulls[31] = true;
+			nulls[32] = true;
 		}
 
 		tuplestore_putvalues(tupstore, tupdesc, values, nulls);
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index d068d6532e..6f2b1a8dbd 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -5348,9 +5348,9 @@
   proname => 'pg_stat_get_activity', prorows => '100', proisstrict => 'f',
   proretset => 't', provolatile => 's', proparallel => 'r',
   prorettype => 'record', proargtypes => 'int4',
-  proallargtypes => '{int4,oid,int4,oid,text,text,text,text,text,timestamptz,timestamptz,timestamptz,timestamptz,inet,text,int4,xid,xid,text,bool,text,text,int4,text,numeric,text,bool,text,bool,int4,int8}',
-  proargmodes => '{i,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o}',
-  proargnames => '{pid,datid,pid,usesysid,application_name,state,query,wait_event_type,wait_event,xact_start,query_start,backend_start,state_change,client_addr,client_hostname,client_port,backend_xid,backend_xmin,backend_type,ssl,sslversion,sslcipher,sslbits,ssl_client_dn,ssl_client_serial,ssl_issuer_dn,gss_auth,gss_princ,gss_enc,leader_pid,query_id}',
+  proallargtypes => '{int4,oid,int4,oid,text,text,text,text,text,timestamptz,timestamptz,timestamptz,timestamptz,inet,text,int4,xid,xid,text,bool,text,text,int4,text,numeric,text,bool,text,bool,int4,int8,int4,int4},int4',
+  proargmodes => '{i,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o}',
+  proargnames => '{pid,datid,pid,usesysid,application_name,state,query,wait_event_type,wait_event,xact_start,query_start,backend_start,state_change,client_addr,client_hostname,client_port,backend_xid,backend_xmin,backend_type,ssl,sslversion,sslcipher,sslbits,ssl_client_dn,ssl_client_serial,ssl_issuer_dn,gss_auth,gss_princ,gss_enc,leader_pid,query_id,active_time,idle_in_transaction_time,idle_time}',
   prosrc => 'pg_stat_get_activity' },
 { oid => '3318',
   descr => 'statistics: information about progress of backends running maintenance command',
diff --git a/src/include/pgstat.h b/src/include/pgstat.h
index bcd3588ea2..916764a02a 100644
--- a/src/include/pgstat.h
+++ b/src/include/pgstat.h
@@ -985,6 +985,7 @@ extern PgStat_Counter pgStatBlockWriteTime;
  */
 extern PgStat_Counter pgStatActiveTime;
 extern PgStat_Counter pgStatTransactionIdleTime;
+extern PgStat_Counter pgStatTransactionIdleInTxnTime;
 
 
 /*
@@ -1092,6 +1093,8 @@ extern void pgstat_initstats(Relation rel);
 	(pgStatActiveTime += (n))
 #define pgstat_count_conn_txn_idle_time(n)							\
 	(pgStatTransactionIdleTime += (n))
+#define pgstat_count_conn_txn_idle_in_txn_time(n)					\
+	(pgStatTransactionIdleInTxnTime += (n))
 
 extern void pgstat_count_heap_insert(Relation rel, PgStat_Counter n);
 extern void pgstat_count_heap_update(Relation rel, bool hot);
diff --git a/src/include/utils/backend_status.h b/src/include/utils/backend_status.h
index 8042b817df..063262e6ae 100644
--- a/src/include/utils/backend_status.h
+++ b/src/include/utils/backend_status.h
@@ -168,6 +168,10 @@ typedef struct PgBackendStatus
 
 	/* query identifier, optionally computed using post_parse_analyze_hook */
 	uint64		st_query_id;
+
+	int64		st_active_time;
+	int64 		st_idle_in_transaction_time;
+	int64 		st_idle_time;
 } PgBackendStatus;
 
 
#7Dilip Kumar
dilipbalaut@gmail.com
In reply to: Rafia Sabih (#6)
Re: Add connection active, idle time to pg_stat_activity

On Wed, Nov 10, 2021 at 1:47 PM Rafia Sabih <rafia.pghackers@gmail.com> wrote:

It seems that in beentry->st_idle_time, you want to compute the
STATE_IDLE, but that state is not handled in the outer "if", that
means whenever it comes out of the
STATE_IDLE, it will not enter inside this if check. You can run and
test, I am sure that with this patch the "idle_time" will always
remain 0.

Thank you Dilip for your time on this.
And yes you are right in both your observations.
Please find the attached patch for the updated version.

Looks fine now except these variable names,

PgStat_Counter pgStatTransactionIdleTime = 0;
+PgStat_Counter pgStatTransactionIdleInTxnTime = 0;

Now, pgStatTransactionIdleTime is collecting just the Idle time so
pgStatTransactionIdleTime should be renamed to "pgStatIdleTime" and
pgStatTransactionIdleInTxnTime should be renamed to
"pgStatTransactionIdleTime"

--
Regards,
Dilip Kumar
EnterpriseDB: http://www.enterprisedb.com

#8Rafia Sabih
rafia.pghackers@gmail.com
In reply to: Dilip Kumar (#7)
1 attachment(s)
Re: Add connection active, idle time to pg_stat_activity

On Mon, 15 Nov 2021 at 10:24, Dilip Kumar <dilipbalaut@gmail.com> wrote:

On Wed, Nov 10, 2021 at 1:47 PM Rafia Sabih <rafia.pghackers@gmail.com> wrote:

It seems that in beentry->st_idle_time, you want to compute the
STATE_IDLE, but that state is not handled in the outer "if", that
means whenever it comes out of the
STATE_IDLE, it will not enter inside this if check. You can run and
test, I am sure that with this patch the "idle_time" will always
remain 0.

Thank you Dilip for your time on this.
And yes you are right in both your observations.
Please find the attached patch for the updated version.

Looks fine now except these variable names,

PgStat_Counter pgStatTransactionIdleTime = 0;
+PgStat_Counter pgStatTransactionIdleInTxnTime = 0;

Now, pgStatTransactionIdleTime is collecting just the Idle time so
pgStatTransactionIdleTime should be renamed to "pgStatIdleTime" and
pgStatTransactionIdleInTxnTime should be renamed to
"pgStatTransactionIdleTime"

Good point!
Done.

--
Regards,
Rafia Sabih

Attachments:

v4_add_idle_active_time.patchtext/x-patch; charset=US-ASCII; name=v4_add_idle_active_time.patchDownload
diff --git a/src/backend/catalog/system_views.sql b/src/backend/catalog/system_views.sql
index eb560955cd..4dfa33ffa9 100644
--- a/src/backend/catalog/system_views.sql
+++ b/src/backend/catalog/system_views.sql
@@ -839,7 +839,10 @@ CREATE VIEW pg_stat_activity AS
             s.backend_xmin,
             S.query_id,
             S.query,
-            S.backend_type
+            S.backend_type,
+            S.active_time,
+            S.idle_in_transaction_time,
+            S.idle_time
     FROM pg_stat_get_activity(NULL) AS S
         LEFT JOIN pg_database AS D ON (S.datid = D.oid)
         LEFT JOIN pg_authid AS U ON (S.usesysid = U.oid);
diff --git a/src/backend/postmaster/pgstat.c b/src/backend/postmaster/pgstat.c
index b7d0fbaefd..84c2aba9e2 100644
--- a/src/backend/postmaster/pgstat.c
+++ b/src/backend/postmaster/pgstat.c
@@ -248,6 +248,7 @@ PgStat_Counter pgStatBlockReadTime = 0;
 PgStat_Counter pgStatBlockWriteTime = 0;
 static PgStat_Counter pgLastSessionReportTime = 0;
 PgStat_Counter pgStatActiveTime = 0;
+PgStat_Counter pgStatIdleTime = 0;
 PgStat_Counter pgStatTransactionIdleTime = 0;
 SessionEndType pgStatSessionEndCause = DISCONNECT_NORMAL;
 
@@ -1018,7 +1019,7 @@ pgstat_send_tabstat(PgStat_MsgTabstat *tsmsg, TimestampTz now)
 			pgLastSessionReportTime = now;
 			tsmsg->m_session_time = (PgStat_Counter) secs * 1000000 + usecs;
 			tsmsg->m_active_time = pgStatActiveTime;
-			tsmsg->m_idle_in_xact_time = pgStatTransactionIdleTime;
+			tsmsg->m_idle_in_xact_time = pgStatIdleTime;
 		}
 		else
 		{
@@ -1031,7 +1032,7 @@ pgstat_send_tabstat(PgStat_MsgTabstat *tsmsg, TimestampTz now)
 		pgStatBlockReadTime = 0;
 		pgStatBlockWriteTime = 0;
 		pgStatActiveTime = 0;
-		pgStatTransactionIdleTime = 0;
+		pgStatIdleTime = 0;
 	}
 	else
 	{
diff --git a/src/backend/utils/activity/backend_status.c b/src/backend/utils/activity/backend_status.c
index 7229598822..560fa0fa0c 100644
--- a/src/backend/utils/activity/backend_status.c
+++ b/src/backend/utils/activity/backend_status.c
@@ -577,6 +577,7 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 	 */
 	if ((beentry->st_state == STATE_RUNNING ||
 		 beentry->st_state == STATE_FASTPATH ||
+		 beentry->st_state == STATE_IDLE ||
 		 beentry->st_state == STATE_IDLEINTRANSACTION ||
 		 beentry->st_state == STATE_IDLEINTRANSACTION_ABORTED) &&
 		state != beentry->st_state)
@@ -590,9 +591,21 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 
 		if (beentry->st_state == STATE_RUNNING ||
 			beentry->st_state == STATE_FASTPATH)
-			pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 + usecs);
-		else
+		{
+				pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 + usecs);
+				beentry->st_active_time = pgStatActiveTime;
+		}
+		else if (beentry->st_state ==  STATE_IDLEINTRANSACTION ||
+				 beentry->st_state == STATE_IDLEINTRANSACTION_ABORTED)
+		{
 			pgstat_count_conn_txn_idle_time((PgStat_Counter) secs * 1000000 + usecs);
+			beentry->st_transaction_idle_time = pgStatTransactionIdleTime;
+		}
+		else
+		{
+			pgstat_count_conn_idle_time((PgStat_Counter) secs * 1000000 + usecs);
+			beentry->st_idle_time = pgStatIdleTime;
+		}
 	}
 
 	/*
diff --git a/src/backend/utils/adt/pgstatfuncs.c b/src/backend/utils/adt/pgstatfuncs.c
index ff5aedc99c..4049d0679e 100644
--- a/src/backend/utils/adt/pgstatfuncs.c
+++ b/src/backend/utils/adt/pgstatfuncs.c
@@ -567,7 +567,7 @@ pg_stat_get_progress_info(PG_FUNCTION_ARGS)
 Datum
 pg_stat_get_activity(PG_FUNCTION_ARGS)
 {
-#define PG_STAT_GET_ACTIVITY_COLS	30
+#define PG_STAT_GET_ACTIVITY_COLS	33
 	int			num_backends = pgstat_fetch_stat_numbackends();
 	int			curr_backend;
 	int			pid = PG_ARGISNULL(0) ? -1 : PG_GETARG_INT32(0);
@@ -916,6 +916,10 @@ pg_stat_get_activity(PG_FUNCTION_ARGS)
 				nulls[29] = true;
 			else
 				values[29] = UInt64GetDatum(beentry->st_query_id);
+
+			values[30] = Int64GetDatum(beentry->st_active_time);
+			values[31] = Int64GetDatum(beentry->st_transaction_idle_time);
+			values[32] = Int64GetDatum(beentry->st_idle_time);
 		}
 		else
 		{
@@ -944,6 +948,9 @@ pg_stat_get_activity(PG_FUNCTION_ARGS)
 			nulls[27] = true;
 			nulls[28] = true;
 			nulls[29] = true;
+			nulls[30] = true;
+			nulls[31] = true;
+			nulls[32] = true;
 		}
 
 		tuplestore_putvalues(tupstore, tupdesc, values, nulls);
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index d068d6532e..6f2b1a8dbd 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -5348,9 +5348,9 @@
   proname => 'pg_stat_get_activity', prorows => '100', proisstrict => 'f',
   proretset => 't', provolatile => 's', proparallel => 'r',
   prorettype => 'record', proargtypes => 'int4',
-  proallargtypes => '{int4,oid,int4,oid,text,text,text,text,text,timestamptz,timestamptz,timestamptz,timestamptz,inet,text,int4,xid,xid,text,bool,text,text,int4,text,numeric,text,bool,text,bool,int4,int8}',
-  proargmodes => '{i,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o}',
-  proargnames => '{pid,datid,pid,usesysid,application_name,state,query,wait_event_type,wait_event,xact_start,query_start,backend_start,state_change,client_addr,client_hostname,client_port,backend_xid,backend_xmin,backend_type,ssl,sslversion,sslcipher,sslbits,ssl_client_dn,ssl_client_serial,ssl_issuer_dn,gss_auth,gss_princ,gss_enc,leader_pid,query_id}',
+  proallargtypes => '{int4,oid,int4,oid,text,text,text,text,text,timestamptz,timestamptz,timestamptz,timestamptz,inet,text,int4,xid,xid,text,bool,text,text,int4,text,numeric,text,bool,text,bool,int4,int8,int4,int4},int4',
+  proargmodes => '{i,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o}',
+  proargnames => '{pid,datid,pid,usesysid,application_name,state,query,wait_event_type,wait_event,xact_start,query_start,backend_start,state_change,client_addr,client_hostname,client_port,backend_xid,backend_xmin,backend_type,ssl,sslversion,sslcipher,sslbits,ssl_client_dn,ssl_client_serial,ssl_issuer_dn,gss_auth,gss_princ,gss_enc,leader_pid,query_id,active_time,idle_in_transaction_time,idle_time}',
   prosrc => 'pg_stat_get_activity' },
 { oid => '3318',
   descr => 'statistics: information about progress of backends running maintenance command',
diff --git a/src/include/pgstat.h b/src/include/pgstat.h
index bcd3588ea2..1a7f476829 100644
--- a/src/include/pgstat.h
+++ b/src/include/pgstat.h
@@ -984,6 +984,7 @@ extern PgStat_Counter pgStatBlockWriteTime;
  * pgstat_report_activity().
  */
 extern PgStat_Counter pgStatActiveTime;
+extern PgStat_Counter pgStatIdleTime;
 extern PgStat_Counter pgStatTransactionIdleTime;
 
 
@@ -1090,7 +1091,9 @@ extern void pgstat_initstats(Relation rel);
 	(pgStatBlockWriteTime += (n))
 #define pgstat_count_conn_active_time(n)							\
 	(pgStatActiveTime += (n))
-#define pgstat_count_conn_txn_idle_time(n)							\
+#define pgstat_count_conn_idle_time(n)							\
+	(pgStatIdleTime += (n))
+#define pgstat_count_conn_txn_idle_time(n)					\
 	(pgStatTransactionIdleTime += (n))
 
 extern void pgstat_count_heap_insert(Relation rel, PgStat_Counter n);
diff --git a/src/include/utils/backend_status.h b/src/include/utils/backend_status.h
index 8042b817df..5cb001e1a4 100644
--- a/src/include/utils/backend_status.h
+++ b/src/include/utils/backend_status.h
@@ -168,6 +168,10 @@ typedef struct PgBackendStatus
 
 	/* query identifier, optionally computed using post_parse_analyze_hook */
 	uint64		st_query_id;
+
+	int64		st_active_time;
+	int64 		st_transaction_idle_time;
+	int64 		st_idle_time;
 } PgBackendStatus;
 
 
#9Dilip Kumar
dilipbalaut@gmail.com
In reply to: Rafia Sabih (#8)
Re: Add connection active, idle time to pg_stat_activity

On Mon, Nov 15, 2021 at 4:46 PM Rafia Sabih <rafia.pghackers@gmail.com> wrote:

On Mon, 15 Nov 2021 at 10:24, Dilip Kumar <dilipbalaut@gmail.com> wrote:

On Wed, Nov 10, 2021 at 1:47 PM Rafia Sabih <rafia.pghackers@gmail.com> wrote:

It seems that in beentry->st_idle_time, you want to compute the
STATE_IDLE, but that state is not handled in the outer "if", that
means whenever it comes out of the
STATE_IDLE, it will not enter inside this if check. You can run and
test, I am sure that with this patch the "idle_time" will always
remain 0.

Thank you Dilip for your time on this.
And yes you are right in both your observations.
Please find the attached patch for the updated version.

Looks fine now except these variable names,

PgStat_Counter pgStatTransactionIdleTime = 0;
+PgStat_Counter pgStatTransactionIdleInTxnTime = 0;

Now, pgStatTransactionIdleTime is collecting just the Idle time so
pgStatTransactionIdleTime should be renamed to "pgStatIdleTime" and
pgStatTransactionIdleInTxnTime should be renamed to
"pgStatTransactionIdleTime"

Good point!
Done.

@@ -1018,7 +1019,7 @@ pgstat_send_tabstat(PgStat_MsgTabstat *tsmsg,
TimestampTz now)
  pgLastSessionReportTime = now;
  tsmsg->m_session_time = (PgStat_Counter) secs * 1000000 + usecs;
  tsmsg->m_active_time = pgStatActiveTime;
- tsmsg->m_idle_in_xact_time = pgStatTransactionIdleTime;
+ tsmsg->m_idle_in_xact_time = pgStatIdleTime;

I think this change is wrong, basically, "tsmsg->m_idle_in_xact_time"
is used for counting the database level idle in transaction count, you
can check "pg_stat_get_db_idle_in_transaction_time" function for that.
So "pgStatTransactionIdleTime" is the variable counting the idle in
transaction time, pgStatIdleTime is just counting the idle time
outside the transaction so if we make this change we are changing the
meaning of tsmsg->m_idle_in_xact_time.

--
Regards,
Dilip Kumar
EnterpriseDB: http://www.enterprisedb.com

#10Rafia Sabih
rafia.pghackers@gmail.com
In reply to: Dilip Kumar (#9)
1 attachment(s)
Re: Add connection active, idle time to pg_stat_activity

On Mon, 15 Nov 2021 at 12:40, Dilip Kumar <dilipbalaut@gmail.com> wrote:

On Mon, Nov 15, 2021 at 4:46 PM Rafia Sabih <rafia.pghackers@gmail.com> wrote:

On Mon, 15 Nov 2021 at 10:24, Dilip Kumar <dilipbalaut@gmail.com> wrote:

On Wed, Nov 10, 2021 at 1:47 PM Rafia Sabih <rafia.pghackers@gmail.com> wrote:

It seems that in beentry->st_idle_time, you want to compute the
STATE_IDLE, but that state is not handled in the outer "if", that
means whenever it comes out of the
STATE_IDLE, it will not enter inside this if check. You can run and
test, I am sure that with this patch the "idle_time" will always
remain 0.

Thank you Dilip for your time on this.
And yes you are right in both your observations.
Please find the attached patch for the updated version.

Looks fine now except these variable names,

PgStat_Counter pgStatTransactionIdleTime = 0;
+PgStat_Counter pgStatTransactionIdleInTxnTime = 0;

Now, pgStatTransactionIdleTime is collecting just the Idle time so
pgStatTransactionIdleTime should be renamed to "pgStatIdleTime" and
pgStatTransactionIdleInTxnTime should be renamed to
"pgStatTransactionIdleTime"

Good point!
Done.

@@ -1018,7 +1019,7 @@ pgstat_send_tabstat(PgStat_MsgTabstat *tsmsg,
TimestampTz now)
pgLastSessionReportTime = now;
tsmsg->m_session_time = (PgStat_Counter) secs * 1000000 + usecs;
tsmsg->m_active_time = pgStatActiveTime;
- tsmsg->m_idle_in_xact_time = pgStatTransactionIdleTime;
+ tsmsg->m_idle_in_xact_time = pgStatIdleTime;

I think this change is wrong, basically, "tsmsg->m_idle_in_xact_time"
is used for counting the database level idle in transaction count, you
can check "pg_stat_get_db_idle_in_transaction_time" function for that.
So "pgStatTransactionIdleTime" is the variable counting the idle in
transaction time, pgStatIdleTime is just counting the idle time
outside the transaction so if we make this change we are changing the
meaning of tsmsg->m_idle_in_xact_time.

Got it.
Updated

--
Regards,
Rafia Sabih

Attachments:

v5_add_idle_active_time.patchtext/x-patch; charset=US-ASCII; name=v5_add_idle_active_time.patchDownload
diff --git a/src/backend/catalog/system_views.sql b/src/backend/catalog/system_views.sql
index eb560955cd..4dfa33ffa9 100644
--- a/src/backend/catalog/system_views.sql
+++ b/src/backend/catalog/system_views.sql
@@ -839,7 +839,10 @@ CREATE VIEW pg_stat_activity AS
             s.backend_xmin,
             S.query_id,
             S.query,
-            S.backend_type
+            S.backend_type,
+            S.active_time,
+            S.idle_in_transaction_time,
+            S.idle_time
     FROM pg_stat_get_activity(NULL) AS S
         LEFT JOIN pg_database AS D ON (S.datid = D.oid)
         LEFT JOIN pg_authid AS U ON (S.usesysid = U.oid);
diff --git a/src/backend/postmaster/pgstat.c b/src/backend/postmaster/pgstat.c
index 8c166e5e16..fc5e58e06b 100644
--- a/src/backend/postmaster/pgstat.c
+++ b/src/backend/postmaster/pgstat.c
@@ -248,6 +248,7 @@ PgStat_Counter pgStatBlockReadTime = 0;
 PgStat_Counter pgStatBlockWriteTime = 0;
 static PgStat_Counter pgLastSessionReportTime = 0;
 PgStat_Counter pgStatActiveTime = 0;
+PgStat_Counter pgStatIdleTime = 0;
 PgStat_Counter pgStatTransactionIdleTime = 0;
 SessionEndType pgStatSessionEndCause = DISCONNECT_NORMAL;
 
@@ -1031,7 +1032,7 @@ pgstat_send_tabstat(PgStat_MsgTabstat *tsmsg, TimestampTz now)
 		pgStatBlockReadTime = 0;
 		pgStatBlockWriteTime = 0;
 		pgStatActiveTime = 0;
-		pgStatTransactionIdleTime = 0;
+		pgStatIdleTime = 0;
 	}
 	else
 	{
diff --git a/src/backend/utils/activity/backend_status.c b/src/backend/utils/activity/backend_status.c
index 7229598822..560fa0fa0c 100644
--- a/src/backend/utils/activity/backend_status.c
+++ b/src/backend/utils/activity/backend_status.c
@@ -577,6 +577,7 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 	 */
 	if ((beentry->st_state == STATE_RUNNING ||
 		 beentry->st_state == STATE_FASTPATH ||
+		 beentry->st_state == STATE_IDLE ||
 		 beentry->st_state == STATE_IDLEINTRANSACTION ||
 		 beentry->st_state == STATE_IDLEINTRANSACTION_ABORTED) &&
 		state != beentry->st_state)
@@ -590,9 +591,21 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 
 		if (beentry->st_state == STATE_RUNNING ||
 			beentry->st_state == STATE_FASTPATH)
-			pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 + usecs);
-		else
+		{
+				pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 + usecs);
+				beentry->st_active_time = pgStatActiveTime;
+		}
+		else if (beentry->st_state ==  STATE_IDLEINTRANSACTION ||
+				 beentry->st_state == STATE_IDLEINTRANSACTION_ABORTED)
+		{
 			pgstat_count_conn_txn_idle_time((PgStat_Counter) secs * 1000000 + usecs);
+			beentry->st_transaction_idle_time = pgStatTransactionIdleTime;
+		}
+		else
+		{
+			pgstat_count_conn_idle_time((PgStat_Counter) secs * 1000000 + usecs);
+			beentry->st_idle_time = pgStatIdleTime;
+		}
 	}
 
 	/*
diff --git a/src/backend/utils/adt/pgstatfuncs.c b/src/backend/utils/adt/pgstatfuncs.c
index e64857e540..5ec64cdd90 100644
--- a/src/backend/utils/adt/pgstatfuncs.c
+++ b/src/backend/utils/adt/pgstatfuncs.c
@@ -567,7 +567,7 @@ pg_stat_get_progress_info(PG_FUNCTION_ARGS)
 Datum
 pg_stat_get_activity(PG_FUNCTION_ARGS)
 {
-#define PG_STAT_GET_ACTIVITY_COLS	30
+#define PG_STAT_GET_ACTIVITY_COLS	33
 	int			num_backends = pgstat_fetch_stat_numbackends();
 	int			curr_backend;
 	int			pid = PG_ARGISNULL(0) ? -1 : PG_GETARG_INT32(0);
@@ -916,6 +916,10 @@ pg_stat_get_activity(PG_FUNCTION_ARGS)
 				nulls[29] = true;
 			else
 				values[29] = UInt64GetDatum(beentry->st_query_id);
+
+			values[30] = Int64GetDatum(beentry->st_active_time);
+			values[31] = Int64GetDatum(beentry->st_transaction_idle_time);
+			values[32] = Int64GetDatum(beentry->st_idle_time);
 		}
 		else
 		{
@@ -944,6 +948,9 @@ pg_stat_get_activity(PG_FUNCTION_ARGS)
 			nulls[27] = true;
 			nulls[28] = true;
 			nulls[29] = true;
+			nulls[30] = true;
+			nulls[31] = true;
+			nulls[32] = true;
 		}
 
 		tuplestore_putvalues(tupstore, tupdesc, values, nulls);
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index d068d6532e..6f2b1a8dbd 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -5348,9 +5348,9 @@
   proname => 'pg_stat_get_activity', prorows => '100', proisstrict => 'f',
   proretset => 't', provolatile => 's', proparallel => 'r',
   prorettype => 'record', proargtypes => 'int4',
-  proallargtypes => '{int4,oid,int4,oid,text,text,text,text,text,timestamptz,timestamptz,timestamptz,timestamptz,inet,text,int4,xid,xid,text,bool,text,text,int4,text,numeric,text,bool,text,bool,int4,int8}',
-  proargmodes => '{i,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o}',
-  proargnames => '{pid,datid,pid,usesysid,application_name,state,query,wait_event_type,wait_event,xact_start,query_start,backend_start,state_change,client_addr,client_hostname,client_port,backend_xid,backend_xmin,backend_type,ssl,sslversion,sslcipher,sslbits,ssl_client_dn,ssl_client_serial,ssl_issuer_dn,gss_auth,gss_princ,gss_enc,leader_pid,query_id}',
+  proallargtypes => '{int4,oid,int4,oid,text,text,text,text,text,timestamptz,timestamptz,timestamptz,timestamptz,inet,text,int4,xid,xid,text,bool,text,text,int4,text,numeric,text,bool,text,bool,int4,int8,int4,int4},int4',
+  proargmodes => '{i,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o}',
+  proargnames => '{pid,datid,pid,usesysid,application_name,state,query,wait_event_type,wait_event,xact_start,query_start,backend_start,state_change,client_addr,client_hostname,client_port,backend_xid,backend_xmin,backend_type,ssl,sslversion,sslcipher,sslbits,ssl_client_dn,ssl_client_serial,ssl_issuer_dn,gss_auth,gss_princ,gss_enc,leader_pid,query_id,active_time,idle_in_transaction_time,idle_time}',
   prosrc => 'pg_stat_get_activity' },
 { oid => '3318',
   descr => 'statistics: information about progress of backends running maintenance command',
diff --git a/src/include/pgstat.h b/src/include/pgstat.h
index bcd3588ea2..1a7f476829 100644
--- a/src/include/pgstat.h
+++ b/src/include/pgstat.h
@@ -984,6 +984,7 @@ extern PgStat_Counter pgStatBlockWriteTime;
  * pgstat_report_activity().
  */
 extern PgStat_Counter pgStatActiveTime;
+extern PgStat_Counter pgStatIdleTime;
 extern PgStat_Counter pgStatTransactionIdleTime;
 
 
@@ -1090,7 +1091,9 @@ extern void pgstat_initstats(Relation rel);
 	(pgStatBlockWriteTime += (n))
 #define pgstat_count_conn_active_time(n)							\
 	(pgStatActiveTime += (n))
-#define pgstat_count_conn_txn_idle_time(n)							\
+#define pgstat_count_conn_idle_time(n)							\
+	(pgStatIdleTime += (n))
+#define pgstat_count_conn_txn_idle_time(n)					\
 	(pgStatTransactionIdleTime += (n))
 
 extern void pgstat_count_heap_insert(Relation rel, PgStat_Counter n);
diff --git a/src/include/utils/backend_status.h b/src/include/utils/backend_status.h
index 8042b817df..5cb001e1a4 100644
--- a/src/include/utils/backend_status.h
+++ b/src/include/utils/backend_status.h
@@ -168,6 +168,10 @@ typedef struct PgBackendStatus
 
 	/* query identifier, optionally computed using post_parse_analyze_hook */
 	uint64		st_query_id;
+
+	int64		st_active_time;
+	int64 		st_transaction_idle_time;
+	int64 		st_idle_time;
 } PgBackendStatus;
 
 
#11Dilip Kumar
dilipbalaut@gmail.com
In reply to: Rafia Sabih (#10)
Re: Add connection active, idle time to pg_stat_activity

On Tue, Nov 16, 2021 at 5:06 PM Rafia Sabih <rafia.pghackers@gmail.com> wrote:

I think this change is wrong, basically, "tsmsg->m_idle_in_xact_time"
is used for counting the database level idle in transaction count, you
can check "pg_stat_get_db_idle_in_transaction_time" function for that.
So "pgStatTransactionIdleTime" is the variable counting the idle in
transaction time, pgStatIdleTime is just counting the idle time
outside the transaction so if we make this change we are changing the
meaning of tsmsg->m_idle_in_xact_time.

Got it.
Updated

Okay, thanks, I will look into it one more time early next week and if
I see no issues then I will move it to RFC.

--
Regards,
Dilip Kumar
EnterpriseDB: http://www.enterprisedb.com

#12Bharath Rupireddy
bharath.rupireddyforpostgres@gmail.com
In reply to: Rafia Sabih (#10)
Re: Add connection active, idle time to pg_stat_activity

On Tue, Nov 16, 2021 at 5:06 PM Rafia Sabih <rafia.pghackers@gmail.com> wrote:

Got it.
Updated

Thanks for the patch. +1 for adding the idle/idle_in_txn_time/active
time. I believe these are the total times a backend in its lifetime
accumulates. For instance, if a backend runs 100 txns, then these new
columns show the total time that the backend spent during these 100
txns, right?

Few comments on the patch:

1) Patch is missing a commit message. It is good to have a commit
message describing the high-level of the feature.
2) This patch needs to bump the catalog version, at the end of the
commit message, we usually keep a note "Bump the catalog version".
3) It looks like the documentation is missing [1]https://www.postgresql.org/docs/devel/monitoring-stats.html#MONITORING-PG-STAT-ACTIVITY-VIEW, for the new columns.
4) When will these backend variables be reset? Is it at the backend
startup? Or some other? If these variables are reset only at the
backend startup and do they keep growing during the entire life of the
backend process? If yes, what happens for a long running backend/user
session, don't they get overflowed?

+
+ int64 st_active_time;
+ int64 st_transaction_idle_time;
+ int64 st_idle_time;
 } PgBackendStatus;

5) Is there any way you can get them tested?
6) What will be entries of st_active_time, st_transaction_idle_time,
st_idle_time for non-backend processes, like bg writer, checkpointer,
parallel worker, bg worker, logical replication launcher, stats
collector, sys logger etc?

[1]: https://www.postgresql.org/docs/devel/monitoring-stats.html#MONITORING-PG-STAT-ACTIVITY-VIEW

Regards,
Bharath Rupireddy.

#13Dilip Kumar
dilipbalaut@gmail.com
In reply to: Bharath Rupireddy (#12)
Re: Add connection active, idle time to pg_stat_activity

On Sat, Nov 27, 2021 at 8:00 AM Bharath Rupireddy
<bharath.rupireddyforpostgres@gmail.com> wrote:

On Tue, Nov 16, 2021 at 5:06 PM Rafia Sabih <rafia.pghackers@gmail.com> wrote:

Got it.
Updated

Thanks for the patch. +1 for adding the idle/idle_in_txn_time/active
time. I believe these are the total times a backend in its lifetime
accumulates. For instance, if a backend runs 100 txns, then these new
columns show the total time that the backend spent during these 100
txns, right?

Few comments on the patch:

1) Patch is missing a commit message. It is good to have a commit
message describing the high-level of the feature.
2) This patch needs to bump the catalog version, at the end of the
commit message, we usually keep a note "Bump the catalog version".
3) It looks like the documentation is missing [1], for the new columns.
4) When will these backend variables be reset? Is it at the backend
startup? Or some other? If these variables are reset only at the
backend startup and do they keep growing during the entire life of the
backend process? If yes, what happens for a long running backend/user
session, don't they get overflowed?

This is a 64-bit variable so I am not sure do we really need to worry
about overflow? I mean if we are storing microseconds then also this
will be able to last for ~300,000 years no?

--
Regards,
Dilip Kumar
EnterpriseDB: http://www.enterprisedb.com

#14Kuntal Ghosh
kuntalghosh.2007@gmail.com
In reply to: Rafia Sabih (#1)
Re: Add connection active, idle time to pg_stat_activity

On Fri, Oct 22, 2021 at 1:53 PM Rafia Sabih <rafia.pghackers@gmail.com> wrote:

To provide this information I was digging into how the statistics
collector is working and found out there is already information like
total time that a connection is active as well as idle computed in
pgstat_report_activity[1]. Ideally, this would be the values we would
like to see per process in pg_stat_activity.

It's definitely useful to know how much time a backend has spent for
query executions. Once you've this info, you can easily calculate the
idle time using this information: (now() - backend_start) -
active_time. But, I'm wondering why you need to distinguish between
idle and idle in transactions - what's the usage? Either the backend
is doing some work or it sits idle. Another useful information would
be when the last query execution was ended. From this information, you
can figure out whether a backend is idle for a long time since the
last execution and the execution time of the last query (query_end -
query_start).

You also need to update the documentation.

--
Thanks & Regards,
Kuntal Ghosh

#15Julien Rouhaud
rjuju123@gmail.com
In reply to: Kuntal Ghosh (#14)
Re: Add connection active, idle time to pg_stat_activity

Hi,

On Mon, Nov 29, 2021 at 11:04 PM Kuntal Ghosh
<kuntalghosh.2007@gmail.com> wrote:

You also need to update the documentation.

You also need to update rules.sql: https://cirrus-ci.com/task/6145265819189248

#16Julien Rouhaud
rjuju123@gmail.com
In reply to: Julien Rouhaud (#15)
Re: Add connection active, idle time to pg_stat_activity

Hi,

On Wed, Jan 12, 2022 at 02:16:35PM +0800, Julien Rouhaud wrote:

On Mon, Nov 29, 2021 at 11:04 PM Kuntal Ghosh
<kuntalghosh.2007@gmail.com> wrote:

You also need to update the documentation.

You also need to update rules.sql: https://cirrus-ci.com/task/6145265819189248

There has been multiple comments in the last two months that weren't addressed
since, and also the patch doesn't pass the regression tests anymore.

Rafia, do you plan to send a new version soon? Without update in the next few
days this patch will be closed as Returned with Feedback, per the commitfest
rules.

#17Sergey Dudoladov
sergey.dudoladov@gmail.com
In reply to: Julien Rouhaud (#16)
1 attachment(s)
Re: Add connection active, idle time to pg_stat_activity

Hello,

Without update in the next few
days this patch will be closed as Returned with Feedback,

Thank you for the reminder, Julien.

Per agreement with Rafia I have reworked the patch in the past days.
The new version 6 is now ready for review.

Regards,
Sergey Dudoladov

Attachments:

v6_add_idle_active_time.patchtext/x-patch; charset=US-ASCII; name=v6_add_idle_active_time.patchDownload
diff --git a/doc/src/sgml/monitoring.sgml b/doc/src/sgml/monitoring.sgml
index 62f2a3332b..25290d1260 100644
--- a/doc/src/sgml/monitoring.sgml
+++ b/doc/src/sgml/monitoring.sgml
@@ -967,6 +967,28 @@ postgres   27093  0.0  0.0  30096  2752 ?        Ss   11:34   0:00 postgres: ser
        additional types.
       </para></entry>
      </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>active_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in <literal>active</literal> and
+       <literal>fastpath</literal> states. This value is
+       updated when a backend switches from these states to a new state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>idle_in_transaction_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in <literal>idle in transaction</literal>
+       and <literal>idle in transaction (aborted)</literal> states. This value is
+       updated when a backend switches from these states to a new state.
+      </para></entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
diff --git a/src/backend/catalog/system_views.sql b/src/backend/catalog/system_views.sql
index 3cb69b1f87..e349709c05 100644
--- a/src/backend/catalog/system_views.sql
+++ b/src/backend/catalog/system_views.sql
@@ -841,7 +841,9 @@ CREATE VIEW pg_stat_activity AS
             s.backend_xmin,
             S.query_id,
             S.query,
-            S.backend_type
+            S.backend_type,
+            S.active_time,
+            S.idle_in_transaction_time
     FROM pg_stat_get_activity(NULL) AS S
         LEFT JOIN pg_database AS D ON (S.datid = D.oid)
         LEFT JOIN pg_authid AS U ON (S.usesysid = U.oid);
diff --git a/src/backend/utils/activity/backend_status.c b/src/backend/utils/activity/backend_status.c
index 2fecf26a2c..224422cb67 100644
--- a/src/backend/utils/activity/backend_status.c
+++ b/src/backend/utils/activity/backend_status.c
@@ -468,6 +468,13 @@ pgstat_beshutdown_hook(int code, Datum arg)
 
 	beentry->st_procpid = 0;	/* mark invalid */
 
+	/*
+	 * Reset per-backend counters so that accumulated values for the current
+	 * backend are not used for future backends.
+	 */
+	beentry->st_total_active_time = 0;
+	beentry->st_total_transaction_idle_time = 0;
+
 	PGSTAT_END_WRITE_ACTIVITY(beentry);
 
 	/* so that functions can check if backend_status.c is up via MyBEEntry */
@@ -550,6 +557,9 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 			beentry->st_xact_start_timestamp = 0;
 			beentry->st_query_id = UINT64CONST(0);
 			proc->wait_event_info = 0;
+
+			beentry->st_total_active_time = 0;
+			beentry->st_total_transaction_idle_time = 0;
 			PGSTAT_END_WRITE_ACTIVITY(beentry);
 		}
 		return;
@@ -583,16 +593,31 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 	{
 		long		secs;
 		int			usecs;
+		int64		usecs_diff;
 
 		TimestampDifference(beentry->st_state_start_timestamp,
 							current_timestamp,
 							&secs, &usecs);
+		usecs_diff = secs * 1000000 + usecs;
 
+		/*
+		 * We update per-backend st_total_active_time and st_total_transaction_idle_time
+		 * separately from pgStatActiveTime and pgStatTransactionIdleTime
+		 * used in pg_stat_database to provide per-DB statistics
+		 * because the latter values are reset to 0 once the data has been sent
+		 * to the statistics collector.
+		 */
 		if (beentry->st_state == STATE_RUNNING ||
 			beentry->st_state == STATE_FASTPATH)
-			pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 + usecs);
+		{
+			pgstat_count_conn_active_time((PgStat_Counter) usecs_diff);
+			beentry->st_total_active_time += usecs_diff;
+		}
 		else
-			pgstat_count_conn_txn_idle_time((PgStat_Counter) secs * 1000000 + usecs);
+		{
+			pgstat_count_conn_txn_idle_time((PgStat_Counter) usecs_diff);
+			beentry->st_total_transaction_idle_time += usecs_diff;
+		}
 	}
 
 	/*
diff --git a/src/backend/utils/adt/pgstatfuncs.c b/src/backend/utils/adt/pgstatfuncs.c
index 15cb17ace4..7c2776c14c 100644
--- a/src/backend/utils/adt/pgstatfuncs.c
+++ b/src/backend/utils/adt/pgstatfuncs.c
@@ -567,7 +567,7 @@ pg_stat_get_progress_info(PG_FUNCTION_ARGS)
 Datum
 pg_stat_get_activity(PG_FUNCTION_ARGS)
 {
-#define PG_STAT_GET_ACTIVITY_COLS	30
+#define PG_STAT_GET_ACTIVITY_COLS	32
 	int			num_backends = pgstat_fetch_stat_numbackends();
 	int			curr_backend;
 	int			pid = PG_ARGISNULL(0) ? -1 : PG_GETARG_INT32(0);
@@ -916,6 +916,10 @@ pg_stat_get_activity(PG_FUNCTION_ARGS)
 				nulls[29] = true;
 			else
 				values[29] = UInt64GetDatum(beentry->st_query_id);
+
+			/* convert to msec for display */
+			values[30] = Float8GetDatum(beentry->st_total_active_time / 1000.0) ;
+			values[31] = Float8GetDatum(beentry->st_total_transaction_idle_time / 1000.0);
 		}
 		else
 		{
@@ -944,6 +948,8 @@ pg_stat_get_activity(PG_FUNCTION_ARGS)
 			nulls[27] = true;
 			nulls[28] = true;
 			nulls[29] = true;
+			nulls[30] = true;
+			nulls[31] = true;
 		}
 
 		tuplestore_putvalues(tupstore, tupdesc, values, nulls);
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index b6f689e8d1..59479b8594 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -5334,9 +5334,9 @@
   proname => 'pg_stat_get_activity', prorows => '100', proisstrict => 'f',
   proretset => 't', provolatile => 's', proparallel => 'r',
   prorettype => 'record', proargtypes => 'int4',
-  proallargtypes => '{int4,oid,int4,oid,text,text,text,text,text,timestamptz,timestamptz,timestamptz,timestamptz,inet,text,int4,xid,xid,text,bool,text,text,int4,text,numeric,text,bool,text,bool,int4,int8}',
-  proargmodes => '{i,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o}',
-  proargnames => '{pid,datid,pid,usesysid,application_name,state,query,wait_event_type,wait_event,xact_start,query_start,backend_start,state_change,client_addr,client_hostname,client_port,backend_xid,backend_xmin,backend_type,ssl,sslversion,sslcipher,sslbits,ssl_client_dn,ssl_client_serial,ssl_issuer_dn,gss_auth,gss_princ,gss_enc,leader_pid,query_id}',
+  proallargtypes => '{int4,oid,int4,oid,text,text,text,text,text,timestamptz,timestamptz,timestamptz,timestamptz,inet,text,int4,xid,xid,text,bool,text,text,int4,text,numeric,text,bool,text,bool,int4,int8,float8,float8}',
+  proargmodes => '{i,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o}',
+  proargnames => '{pid,datid,pid,usesysid,application_name,state,query,wait_event_type,wait_event,xact_start,query_start,backend_start,state_change,client_addr,client_hostname,client_port,backend_xid,backend_xmin,backend_type,ssl,sslversion,sslcipher,sslbits,ssl_client_dn,ssl_client_serial,ssl_issuer_dn,gss_auth,gss_princ,gss_enc,leader_pid,query_id,active_time,idle_in_transaction_time}',
   prosrc => 'pg_stat_get_activity' },
 { oid => '3318',
   descr => 'statistics: information about progress of backends running maintenance command',
diff --git a/src/include/utils/backend_status.h b/src/include/utils/backend_status.h
index 8217d0cb6b..96d432ce49 100644
--- a/src/include/utils/backend_status.h
+++ b/src/include/utils/backend_status.h
@@ -168,6 +168,10 @@ typedef struct PgBackendStatus
 
 	/* query identifier, optionally computed using post_parse_analyze_hook */
 	uint64		st_query_id;
+
+	/* time spent in respective states in usec */
+	int64		st_total_active_time;
+	int64		st_total_transaction_idle_time;
 } PgBackendStatus;
 
 
diff --git a/src/test/regress/expected/rules.out b/src/test/regress/expected/rules.out
index d652f7b5fb..5e7ee70edd 100644
--- a/src/test/regress/expected/rules.out
+++ b/src/test/regress/expected/rules.out
@@ -1764,8 +1764,10 @@ pg_stat_activity| SELECT s.datid,
     s.backend_xmin,
     s.query_id,
     s.query,
-    s.backend_type
-   FROM ((pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id)
+    s.backend_type,
+    s.active_time,
+    s.idle_in_transaction_time
+   FROM ((pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id, active_time, idle_in_transaction_time)
      LEFT JOIN pg_database d ON ((s.datid = d.oid)))
      LEFT JOIN pg_authid u ON ((s.usesysid = u.oid)));
 pg_stat_all_indexes| SELECT c.oid AS relid,
@@ -1877,7 +1879,7 @@ pg_stat_gssapi| SELECT s.pid,
     s.gss_auth AS gss_authenticated,
     s.gss_princ AS principal,
     s.gss_enc AS encrypted
-   FROM pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id)
+   FROM pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id, active_time, idle_in_transaction_time)
   WHERE (s.client_port IS NOT NULL);
 pg_stat_progress_analyze| SELECT s.pid,
     s.datid,
@@ -2047,7 +2049,7 @@ pg_stat_replication| SELECT s.pid,
     w.sync_priority,
     w.sync_state,
     w.reply_time
-   FROM ((pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id)
+   FROM ((pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id, active_time, idle_in_transaction_time)
      JOIN pg_stat_get_wal_senders() w(pid, state, sent_lsn, write_lsn, flush_lsn, replay_lsn, write_lag, flush_lag, replay_lag, sync_priority, sync_state, reply_time) ON ((s.pid = w.pid)))
      LEFT JOIN pg_authid u ON ((s.usesysid = u.oid)));
 pg_stat_replication_slots| SELECT s.slot_name,
@@ -2081,7 +2083,7 @@ pg_stat_ssl| SELECT s.pid,
     s.ssl_client_dn AS client_dn,
     s.ssl_client_serial AS client_serial,
     s.ssl_issuer_dn AS issuer_dn
-   FROM pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id)
+   FROM pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id, active_time, idle_in_transaction_time)
   WHERE (s.client_port IS NOT NULL);
 pg_stat_subscription| SELECT su.oid AS subid,
     su.subname,
#18Julien Rouhaud
rjuju123@gmail.com
In reply to: Sergey Dudoladov (#17)
Re: Add connection active, idle time to pg_stat_activity

Hi,

On Thu, Jan 27, 2022 at 11:43:26AM +0100, Sergey Dudoladov wrote:

Per agreement with Rafia I have reworked the patch in the past days.
The new version 6 is now ready for review.

Great, thanks a lot Sergey!

The cfbot is happy with this new version:
https://cirrus-ci.com/github/postgresql-cfbot/postgresql/commitfest/36/3405

#19Kyotaro Horiguchi
horikyota.ntt@gmail.com
In reply to: Julien Rouhaud (#16)
Re: Add connection active, idle time to pg_stat_activity

Hi.

At Thu, 27 Jan 2022 20:36:56 +0800, Julien Rouhaud <rjuju123@gmail.com> wrote in

On Thu, Jan 27, 2022 at 11:43:26AM +0100, Sergey Dudoladov wrote:

Per agreement with Rafia I have reworked the patch in the past days.
The new version 6 is now ready for review.

Great, thanks a lot Sergey!

The cfbot is happy with this new version:
https://cirrus-ci.com/github/postgresql-cfbot/postgresql/commitfest/36/3405

I think we can easily add the duration of the current state to the two
in pg_stat_get_activity and it would offer better information.

 		if (beentry->st_state == STATE_RUNNING ||
 			beentry->st_state == STATE_FASTPATH)
-			pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 + usecs);
+		{
+			pgstat_count_conn_active_time((PgStat_Counter) usecs_diff);
+			beentry->st_total_active_time += usecs_diff;
+		}

The two lines operates exactly the same way on variables with slightly
different behavior. pgStatActiveTime is reported at transaction end
and reset at every tabstat reporting. st_total_active_time is reported
immediately and reset at session end. Since we do the latter, the
first can be omitted by remembering the last values for the local
variables at every reporting. This needs additional two exporting
function in pgstatfuncs like pgstat_get_my_queryid so others might
think differently.

The write operation to beentry needs to be enclosed by
PGSTAT_BEGIN/END_WRITE_ACTIVITY(). In that perspective, it would be
better to move that writes to the PGSTAT_WRITE_ACTIVITY section just
below.

regards.

--
Kyotaro Horiguchi
NTT Open Source Software Center

#20Kyotaro Horiguchi
horikyota.ntt@gmail.com
In reply to: Kuntal Ghosh (#14)
Re: Add connection active, idle time to pg_stat_activity

At Mon, 29 Nov 2021 20:34:14 +0530, Kuntal Ghosh <kuntalghosh.2007@gmail.com> wrote in

active_time. But, I'm wondering why you need to distinguish between
idle and idle in transactions - what's the usage? Either the backend
is doing some work or it sits idle. Another useful information would

I believe many people suffer from mysterious long idle in
transactions, which harm server performance many ways. In many cases
transactions with unexpectedly long idle time is an omen or a cause of
trouble.

regards.

--
Kyotaro Horiguchi
NTT Open Source Software Center

#21Kyotaro Horiguchi
horikyota.ntt@gmail.com
In reply to: Kyotaro Horiguchi (#19)
Re: Add connection active, idle time to pg_stat_activity

At Fri, 28 Jan 2022 14:36:31 +0900 (JST), Kyotaro Horiguchi <horikyota.ntt@gmail.com> wrote in

Hi.

At Thu, 27 Jan 2022 20:36:56 +0800, Julien Rouhaud <rjuju123@gmail.com> wrote in

On Thu, Jan 27, 2022 at 11:43:26AM +0100, Sergey Dudoladov wrote:

Per agreement with Rafia I have reworked the patch in the past days.
The new version 6 is now ready for review.

Great, thanks a lot Sergey!

The cfbot is happy with this new version:
https://cirrus-ci.com/github/postgresql-cfbot/postgresql/commitfest/36/3405

I think we can easily add the duration of the current state to the two
in pg_stat_get_activity and it would offer better information.

if (beentry->st_state == STATE_RUNNING ||
beentry->st_state == STATE_FASTPATH)
-			pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 + usecs);
+		{
+			pgstat_count_conn_active_time((PgStat_Counter) usecs_diff);
+			beentry->st_total_active_time += usecs_diff;
+		}

The two lines operates exactly the same way on variables with slightly
different behavior. pgStatActiveTime is reported at transaction end
and reset at every tabstat reporting. st_total_active_time is reported
immediately and reset at session end. Since we do the latter, the

first can be omitted by remembering the last values for the local
variables at every reporting. This needs additional two exporting

Of course it's typo(?) of "values of the shared variables".
Sorry for the mistake.

function in pgstatfuncs like pgstat_get_my_queryid so others might
think differently.

The write operation to beentry needs to be enclosed by
PGSTAT_BEGIN/END_WRITE_ACTIVITY(). In that perspective, it would be
better to move that writes to the PGSTAT_WRITE_ACTIVITY section just
below.

regards.

--
Kyotaro Horiguchi
NTT Open Source Software Center

#22Sergey Dudoladov
sergey.dudoladov@gmail.com
In reply to: Kyotaro Horiguchi (#21)
1 attachment(s)
Re: Add connection active, idle time to pg_stat_activity

Hi,

Thank you for the reviews.

The write operation to beentry needs to be enclosed by
PGSTAT_BEGIN/END_WRITE_ACTIVITY(). In that perspective, it would be
better to move that writes to the PGSTAT_WRITE_ACTIVITY section just
below.

I have fixed it in the new version.

if (beentry->st_state == STATE_RUNNING ||
beentry->st_state == STATE_FASTPATH)
-                     pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 + usecs);
+             {
+                     pgstat_count_conn_active_time((PgStat_Counter) usecs_diff);
+                     beentry->st_total_active_time += usecs_diff;
+             }

The two lines operates exactly the same way on variables with slightly
different behavior. pgStatActiveTime is reported at transaction end
and reset at every tabstat reporting. st_total_active_time is reported
immediately and reset at session end. Since we do the latter, the
first can be omitted by remembering the last values for the local
variables at every reporting. This needs additional two exporting

Of course it's typo(?) of "values of the shared variables".

Could you please elaborate on this idea ?
So we have pgStatActiveTime and pgStatIdleInTransactionTime ultimately
used to report respective metrics in pg_stat_database.
Now beentry's st_total_active_time / st_total_transaction_idle_time
duplicates this info, so one may get rid of pgStat*Time counters. Is
the idea to report instead of them at every tabstat reporting the
difference between the last memorized value of st_total_*_time and
its current value ?

This needs additional two exporting
function in pgstatfuncs like pgstat_get_my_queryid so others might
think differently.

What would be example functions to look at ?

Regards,
Sergey

Attachments:

v7_add_idle_active_time.patchtext/x-patch; charset=US-ASCII; name=v7_add_idle_active_time.patchDownload
diff --git a/doc/src/sgml/monitoring.sgml b/doc/src/sgml/monitoring.sgml
index 62f2a3332b..25290d1260 100644
--- a/doc/src/sgml/monitoring.sgml
+++ b/doc/src/sgml/monitoring.sgml
@@ -967,6 +967,28 @@ postgres   27093  0.0  0.0  30096  2752 ?        Ss   11:34   0:00 postgres: ser
        additional types.
       </para></entry>
      </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>active_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in <literal>active</literal> and
+       <literal>fastpath</literal> states. This value is
+       updated when a backend switches from these states to a new state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>idle_in_transaction_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in <literal>idle in transaction</literal>
+       and <literal>idle in transaction (aborted)</literal> states. This value is
+       updated when a backend switches from these states to a new state.
+      </para></entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
diff --git a/src/backend/catalog/system_views.sql b/src/backend/catalog/system_views.sql
index 3cb69b1f87..e349709c05 100644
--- a/src/backend/catalog/system_views.sql
+++ b/src/backend/catalog/system_views.sql
@@ -841,7 +841,9 @@ CREATE VIEW pg_stat_activity AS
             s.backend_xmin,
             S.query_id,
             S.query,
-            S.backend_type
+            S.backend_type,
+            S.active_time,
+            S.idle_in_transaction_time
     FROM pg_stat_get_activity(NULL) AS S
         LEFT JOIN pg_database AS D ON (S.datid = D.oid)
         LEFT JOIN pg_authid AS U ON (S.usesysid = U.oid);
diff --git a/src/backend/utils/activity/backend_status.c b/src/backend/utils/activity/backend_status.c
index 2fecf26a2c..31adde5ffe 100644
--- a/src/backend/utils/activity/backend_status.c
+++ b/src/backend/utils/activity/backend_status.c
@@ -468,6 +468,13 @@ pgstat_beshutdown_hook(int code, Datum arg)
 
 	beentry->st_procpid = 0;	/* mark invalid */
 
+	/*
+	 * Reset per-backend counters so that accumulated values for the current
+	 * backend are not used for future backends.
+	 */
+	beentry->st_total_active_time = 0;
+	beentry->st_total_transaction_idle_time = 0;
+
 	PGSTAT_END_WRITE_ACTIVITY(beentry);
 
 	/* so that functions can check if backend_status.c is up via MyBEEntry */
@@ -524,6 +531,8 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 	TimestampTz start_timestamp;
 	TimestampTz current_timestamp;
 	int			len = 0;
+	int64		active_time_diff = 0;
+	int64		transaction_idle_time_diff = 0;
 
 	TRACE_POSTGRESQL_STATEMENT_STATUS(cmd_str);
 
@@ -550,6 +559,9 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 			beentry->st_xact_start_timestamp = 0;
 			beentry->st_query_id = UINT64CONST(0);
 			proc->wait_event_info = 0;
+
+			beentry->st_total_active_time = 0;
+			beentry->st_total_transaction_idle_time = 0;
 			PGSTAT_END_WRITE_ACTIVITY(beentry);
 		}
 		return;
@@ -583,16 +595,33 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 	{
 		long		secs;
 		int			usecs;
+		int64		usecs_diff;
 
 		TimestampDifference(beentry->st_state_start_timestamp,
 							current_timestamp,
 							&secs, &usecs);
+		usecs_diff = secs * 1000000 + usecs;
 
+		/*
+		 * We update per-backend st_total_active_time and st_total_transaction_idle_time
+		 * separately from pgStatActiveTime and pgStatTransactionIdleTime
+		 * used in pg_stat_database to provide per-DB statistics because
+		 * 1. Changing the former values implies modifying beentry and thus
+		 * have to be wrapped into PGSTAT_*_WRITE_ACTIVITY macros (see below).
+		 * 2. The latter values are reset to 0 once the data has been sent
+		 * to the statistics collector.
+		 */
 		if (beentry->st_state == STATE_RUNNING ||
 			beentry->st_state == STATE_FASTPATH)
-			pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 + usecs);
+		{
+			pgstat_count_conn_active_time((PgStat_Counter) usecs_diff);
+			active_time_diff = usecs_diff;
+		}
 		else
-			pgstat_count_conn_txn_idle_time((PgStat_Counter) secs * 1000000 + usecs);
+		{
+			pgstat_count_conn_txn_idle_time((PgStat_Counter) usecs_diff);
+			transaction_idle_time_diff = usecs_diff;
+		}
 	}
 
 	/*
@@ -618,6 +647,9 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 		beentry->st_activity_start_timestamp = start_timestamp;
 	}
 
+	beentry->st_total_active_time += active_time_diff;
+	beentry->st_total_transaction_idle_time += transaction_idle_time_diff;
+
 	PGSTAT_END_WRITE_ACTIVITY(beentry);
 }
 
diff --git a/src/backend/utils/adt/pgstatfuncs.c b/src/backend/utils/adt/pgstatfuncs.c
index 15cb17ace4..7c2776c14c 100644
--- a/src/backend/utils/adt/pgstatfuncs.c
+++ b/src/backend/utils/adt/pgstatfuncs.c
@@ -567,7 +567,7 @@ pg_stat_get_progress_info(PG_FUNCTION_ARGS)
 Datum
 pg_stat_get_activity(PG_FUNCTION_ARGS)
 {
-#define PG_STAT_GET_ACTIVITY_COLS	30
+#define PG_STAT_GET_ACTIVITY_COLS	32
 	int			num_backends = pgstat_fetch_stat_numbackends();
 	int			curr_backend;
 	int			pid = PG_ARGISNULL(0) ? -1 : PG_GETARG_INT32(0);
@@ -916,6 +916,10 @@ pg_stat_get_activity(PG_FUNCTION_ARGS)
 				nulls[29] = true;
 			else
 				values[29] = UInt64GetDatum(beentry->st_query_id);
+
+			/* convert to msec for display */
+			values[30] = Float8GetDatum(beentry->st_total_active_time / 1000.0) ;
+			values[31] = Float8GetDatum(beentry->st_total_transaction_idle_time / 1000.0);
 		}
 		else
 		{
@@ -944,6 +948,8 @@ pg_stat_get_activity(PG_FUNCTION_ARGS)
 			nulls[27] = true;
 			nulls[28] = true;
 			nulls[29] = true;
+			nulls[30] = true;
+			nulls[31] = true;
 		}
 
 		tuplestore_putvalues(tupstore, tupdesc, values, nulls);
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index b6f689e8d1..59479b8594 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -5334,9 +5334,9 @@
   proname => 'pg_stat_get_activity', prorows => '100', proisstrict => 'f',
   proretset => 't', provolatile => 's', proparallel => 'r',
   prorettype => 'record', proargtypes => 'int4',
-  proallargtypes => '{int4,oid,int4,oid,text,text,text,text,text,timestamptz,timestamptz,timestamptz,timestamptz,inet,text,int4,xid,xid,text,bool,text,text,int4,text,numeric,text,bool,text,bool,int4,int8}',
-  proargmodes => '{i,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o}',
-  proargnames => '{pid,datid,pid,usesysid,application_name,state,query,wait_event_type,wait_event,xact_start,query_start,backend_start,state_change,client_addr,client_hostname,client_port,backend_xid,backend_xmin,backend_type,ssl,sslversion,sslcipher,sslbits,ssl_client_dn,ssl_client_serial,ssl_issuer_dn,gss_auth,gss_princ,gss_enc,leader_pid,query_id}',
+  proallargtypes => '{int4,oid,int4,oid,text,text,text,text,text,timestamptz,timestamptz,timestamptz,timestamptz,inet,text,int4,xid,xid,text,bool,text,text,int4,text,numeric,text,bool,text,bool,int4,int8,float8,float8}',
+  proargmodes => '{i,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o}',
+  proargnames => '{pid,datid,pid,usesysid,application_name,state,query,wait_event_type,wait_event,xact_start,query_start,backend_start,state_change,client_addr,client_hostname,client_port,backend_xid,backend_xmin,backend_type,ssl,sslversion,sslcipher,sslbits,ssl_client_dn,ssl_client_serial,ssl_issuer_dn,gss_auth,gss_princ,gss_enc,leader_pid,query_id,active_time,idle_in_transaction_time}',
   prosrc => 'pg_stat_get_activity' },
 { oid => '3318',
   descr => 'statistics: information about progress of backends running maintenance command',
diff --git a/src/include/utils/backend_status.h b/src/include/utils/backend_status.h
index 8217d0cb6b..96d432ce49 100644
--- a/src/include/utils/backend_status.h
+++ b/src/include/utils/backend_status.h
@@ -168,6 +168,10 @@ typedef struct PgBackendStatus
 
 	/* query identifier, optionally computed using post_parse_analyze_hook */
 	uint64		st_query_id;
+
+	/* time spent in respective states in usec */
+	int64		st_total_active_time;
+	int64		st_total_transaction_idle_time;
 } PgBackendStatus;
 
 
diff --git a/src/test/regress/expected/rules.out b/src/test/regress/expected/rules.out
index d652f7b5fb..5e7ee70edd 100644
--- a/src/test/regress/expected/rules.out
+++ b/src/test/regress/expected/rules.out
@@ -1764,8 +1764,10 @@ pg_stat_activity| SELECT s.datid,
     s.backend_xmin,
     s.query_id,
     s.query,
-    s.backend_type
-   FROM ((pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id)
+    s.backend_type,
+    s.active_time,
+    s.idle_in_transaction_time
+   FROM ((pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id, active_time, idle_in_transaction_time)
      LEFT JOIN pg_database d ON ((s.datid = d.oid)))
      LEFT JOIN pg_authid u ON ((s.usesysid = u.oid)));
 pg_stat_all_indexes| SELECT c.oid AS relid,
@@ -1877,7 +1879,7 @@ pg_stat_gssapi| SELECT s.pid,
     s.gss_auth AS gss_authenticated,
     s.gss_princ AS principal,
     s.gss_enc AS encrypted
-   FROM pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id)
+   FROM pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id, active_time, idle_in_transaction_time)
   WHERE (s.client_port IS NOT NULL);
 pg_stat_progress_analyze| SELECT s.pid,
     s.datid,
@@ -2047,7 +2049,7 @@ pg_stat_replication| SELECT s.pid,
     w.sync_priority,
     w.sync_state,
     w.reply_time
-   FROM ((pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id)
+   FROM ((pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id, active_time, idle_in_transaction_time)
      JOIN pg_stat_get_wal_senders() w(pid, state, sent_lsn, write_lsn, flush_lsn, replay_lsn, write_lag, flush_lag, replay_lag, sync_priority, sync_state, reply_time) ON ((s.pid = w.pid)))
      LEFT JOIN pg_authid u ON ((s.usesysid = u.oid)));
 pg_stat_replication_slots| SELECT s.slot_name,
@@ -2081,7 +2083,7 @@ pg_stat_ssl| SELECT s.pid,
     s.ssl_client_dn AS client_dn,
     s.ssl_client_serial AS client_serial,
     s.ssl_issuer_dn AS issuer_dn
-   FROM pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id)
+   FROM pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id, active_time, idle_in_transaction_time)
   WHERE (s.client_port IS NOT NULL);
 pg_stat_subscription| SELECT su.oid AS subid,
     su.subname,
#23Kyotaro Horiguchi
horikyota.ntt@gmail.com
In reply to: Sergey Dudoladov (#22)
2 attachment(s)
Re: Add connection active, idle time to pg_stat_activity

At Mon, 31 Jan 2022 15:11:56 +0100, Sergey Dudoladov <sergey.dudoladov@gmail.com> wrote in

if (beentry->st_state == STATE_RUNNING ||
beentry->st_state == STATE_FASTPATH)
-                     pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 + usecs);
+             {
+                     pgstat_count_conn_active_time((PgStat_Counter) usecs_diff);
+                     beentry->st_total_active_time += usecs_diff;
+             }

The two lines operates exactly the same way on variables with slightly
different behavior. pgStatActiveTime is reported at transaction end
and reset at every tabstat reporting. st_total_active_time is reported
immediately and reset at session end. Since we do the latter, the
first can be omitted by remembering the last values for the local
variables at every reporting. This needs additional two exporting

Of course it's typo(?) of "values of the shared variables".

Could you please elaborate on this idea ?
So we have pgStatActiveTime and pgStatIdleInTransactionTime ultimately
used to report respective metrics in pg_stat_database.
Now beentry's st_total_active_time / st_total_transaction_idle_time
duplicates this info, so one may get rid of pgStat*Time counters. Is
the idea to report instead of them at every tabstat reporting the
difference between the last memorized value of st_total_*_time and
its current value ?

Exactly. The attached first diff is the schetch of that.

This needs additional two exporting
function in pgstatfuncs like pgstat_get_my_queryid so others might
think differently.

What would be example functions to look at ?

pgstat_get_my_queryid..

And, it seems like I forgot to mention this, but as Kuntal suggested
(in a different context and objective, though) upthraed, I think that
we can show realtime values in the two time fields by adding the time
of the current state. See the attached second diff.

regards.

--
Kyotaro Horiguchi
NTT Open Source Software Center

Attachments:

remove-pgStatActiveTime.diff.txttext/plain; charset=us-asciiDownload
diff --git a/src/backend/postmaster/pgstat.c b/src/backend/postmaster/pgstat.c
index 0646f53098..27419c1851 100644
--- a/src/backend/postmaster/pgstat.c
+++ b/src/backend/postmaster/pgstat.c
@@ -249,8 +249,8 @@ static int	pgStatXactRollback = 0;
 PgStat_Counter pgStatBlockReadTime = 0;
 PgStat_Counter pgStatBlockWriteTime = 0;
 static PgStat_Counter pgLastSessionReportTime = 0;
-PgStat_Counter pgStatActiveTime = 0;
-PgStat_Counter pgStatTransactionIdleTime = 0;
+PgStat_Counter pgStatLastActiveTime = 0;
+PgStat_Counter pgStatLastTransactionIdleTime = 0;
 SessionEndType pgStatSessionEndCause = DISCONNECT_NORMAL;
 
 /* Record that's written to 2PC state file when pgstat state is persisted */
@@ -1026,8 +1026,13 @@ pgstat_send_tabstat(PgStat_MsgTabstat *tsmsg, TimestampTz now)
 			TimestampDifference(pgLastSessionReportTime, now, &secs, &usecs);
 			pgLastSessionReportTime = now;
 			tsmsg->m_session_time = (PgStat_Counter) secs * 1000000 + usecs;
-			tsmsg->m_active_time = pgStatActiveTime;
-			tsmsg->m_idle_in_xact_time = pgStatTransactionIdleTime;
+
+			/* send the difference since the last report */
+			tsmsg->m_active_time =
+				pgstat_get_my_active_time() - pgStatLastActiveTime;
+			tsmsg->m_idle_in_xact_time =
+				pgstat_get_my_transaction_idle_time() -
+				pgStatLastTransactionIdleTime;
 		}
 		else
 		{
@@ -1039,8 +1044,8 @@ pgstat_send_tabstat(PgStat_MsgTabstat *tsmsg, TimestampTz now)
 		pgStatXactRollback = 0;
 		pgStatBlockReadTime = 0;
 		pgStatBlockWriteTime = 0;
-		pgStatActiveTime = 0;
-		pgStatTransactionIdleTime = 0;
+		pgStatLastActiveTime = pgstat_get_my_active_time();
+		pgStatLastTransactionIdleTime =  pgstat_get_my_transaction_idle_time();
 	}
 	else
 	{
diff --git a/src/backend/utils/activity/backend_status.c b/src/backend/utils/activity/backend_status.c
index 5f15dcdc05..8b6836a662 100644
--- a/src/backend/utils/activity/backend_status.c
+++ b/src/backend/utils/activity/backend_status.c
@@ -613,15 +613,9 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 		 */
 		if (beentry->st_state == STATE_RUNNING ||
 			beentry->st_state == STATE_FASTPATH)
-		{
-			pgstat_count_conn_active_time((PgStat_Counter) usecs_diff);
 			active_time_diff = usecs_diff;
-		}
 		else
-		{
-			pgstat_count_conn_txn_idle_time((PgStat_Counter) usecs_diff);
 			transaction_idle_time_diff = usecs_diff;
-		}
 	}
 
 	/*
@@ -1078,6 +1072,48 @@ pgstat_get_my_query_id(void)
 }
 
 
+/* ----------
+ * pgstat_get_my_active_time() -
+ *
+ * Return current backend's accumulated active time.
+ */
+uint64
+pgstat_get_my_active_time(void)
+{
+	if (!MyBEEntry)
+		return 0;
+
+	/*
+	 * There's no need for a lock around pgstat_begin_read_activity /
+	 * pgstat_end_read_activity here as it's only called from
+	 * pg_stat_get_activity which is already protected, or from the same
+	 * backend which means that there won't be concurrent writes.
+	 */
+	return MyBEEntry->st_total_active_time;
+}
+
+
+/* ----------
+ * pgstat_get_my_transaction_idle_time() -
+ *
+ * Return current backend's accumulated in-transaction idel time.
+ */
+uint64
+pgstat_get_my_transaction_idle_time(void)
+{
+	if (!MyBEEntry)
+		return 0;
+
+	/*
+	 * There's no need for a lock around pgstat_begin_read_activity /
+	 * pgstat_end_read_activity here as it's only called from
+	 * pg_stat_get_activity which is already protected, or from the same
+	 * backend which means that there won't be concurrent writes.
+	 */
+	return MyBEEntry->st_total_transaction_idle_time;
+}
+
+
 /* ----------
  * pgstat_fetch_stat_beentry() -
  *
diff --git a/src/include/pgstat.h b/src/include/pgstat.h
index e10d20222a..382d7202c1 100644
--- a/src/include/pgstat.h
+++ b/src/include/pgstat.h
@@ -1185,10 +1185,6 @@ extern void pgstat_initstats(Relation rel);
 	(pgStatBlockReadTime += (n))
 #define pgstat_count_buffer_write_time(n)							\
 	(pgStatBlockWriteTime += (n))
-#define pgstat_count_conn_active_time(n)							\
-	(pgStatActiveTime += (n))
-#define pgstat_count_conn_txn_idle_time(n)							\
-	(pgStatTransactionIdleTime += (n))
 
 extern void pgstat_count_heap_insert(Relation rel, PgStat_Counter n);
 extern void pgstat_count_heap_update(Relation rel, bool hot);
diff --git a/src/include/utils/backend_status.h b/src/include/utils/backend_status.h
index 96d432ce49..1791dd6842 100644
--- a/src/include/utils/backend_status.h
+++ b/src/include/utils/backend_status.h
@@ -309,6 +309,8 @@ extern const char *pgstat_get_backend_current_activity(int pid, bool checkUser);
 extern const char *pgstat_get_crashed_backend_activity(int pid, char *buffer,
 													   int buflen);
 extern uint64 pgstat_get_my_query_id(void);
+extern uint64 pgstat_get_my_active_time(void);
+extern uint64 pgstat_get_my_transaction_idle_time(void);
 
 
 /* ----------
show-realtime-value-for-the-counters.diff.txttext/plain; charset=us-asciiDownload
diff --git a/src/backend/utils/activity/backend_status.c b/src/backend/utils/activity/backend_status.c
index 8b6836a662..996f4e88d7 100644
--- a/src/backend/utils/activity/backend_status.c
+++ b/src/backend/utils/activity/backend_status.c
@@ -587,10 +587,7 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 	 * If the state has changed from "active" or "idle in transaction",
 	 * calculate the duration.
 	 */
-	if ((beentry->st_state == STATE_RUNNING ||
-		 beentry->st_state == STATE_FASTPATH ||
-		 beentry->st_state == STATE_IDLEINTRANSACTION ||
-		 beentry->st_state == STATE_IDLEINTRANSACTION_ABORTED) &&
+	if ((PGSTAT_IS_ACTIVE(beentry) || PGSTAT_IS_IDLEINTRANSACTION(beentry)) &&
 		state != beentry->st_state)
 	{
 		long		secs;
@@ -611,8 +608,7 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 		 * 2. The latter values are reset to 0 once the data has been sent
 		 * to the statistics collector.
 		 */
-		if (beentry->st_state == STATE_RUNNING ||
-			beentry->st_state == STATE_FASTPATH)
+		if (PGSTAT_IS_ACTIVE(beentry))
 			active_time_diff = usecs_diff;
 		else
 			transaction_idle_time_diff = usecs_diff;
diff --git a/src/backend/utils/adt/pgstatfuncs.c b/src/backend/utils/adt/pgstatfuncs.c
index 7c2776c14c..48c0ffa33a 100644
--- a/src/backend/utils/adt/pgstatfuncs.c
+++ b/src/backend/utils/adt/pgstatfuncs.c
@@ -675,6 +675,7 @@ pg_stat_get_activity(PG_FUNCTION_ARGS)
 		{
 			SockAddr	zero_clientaddr;
 			char	   *clipped_activity;
+			int64		tmp_time;
 
 			switch (beentry->st_state)
 			{
@@ -917,9 +918,25 @@ pg_stat_get_activity(PG_FUNCTION_ARGS)
 			else
 				values[29] = UInt64GetDatum(beentry->st_query_id);
 
-			/* convert to msec for display */
-			values[30] = Float8GetDatum(beentry->st_total_active_time / 1000.0) ;
-			values[31] = Float8GetDatum(beentry->st_total_transaction_idle_time / 1000.0);
+			tmp_time = beentry->st_total_active_time;
+
+			/* add the realtime value to the counter if needed */
+			if (PGSTAT_IS_ACTIVE(beentry))
+				tmp_time +=
+					GetCurrentTimestamp() - beentry->st_state_start_timestamp;
+
+			/* convert it to msec */
+			values[30] = Float8GetDatum(tmp_time / 1000.0) ;
+
+			tmp_time = beentry->st_total_transaction_idle_time;
+
+			/* add the realtime value to the counter if needed */
+			if (PGSTAT_IS_IDLEINTRANSACTION(beentry))
+				tmp_time +=
+					GetCurrentTimestamp() - beentry->st_state_start_timestamp;
+
+			/* convert it to msec */
+			values[31] = Float8GetDatum(tmp_time);
 		}
 		else
 		{
diff --git a/src/include/utils/backend_status.h b/src/include/utils/backend_status.h
index 1791dd6842..a03225c4f0 100644
--- a/src/include/utils/backend_status.h
+++ b/src/include/utils/backend_status.h
@@ -235,6 +235,12 @@ typedef struct PgBackendStatus
 	((before_changecount) == (after_changecount) && \
 	 ((before_changecount) & 1) == 0)
 
+/* macros to identify the states for time accounting */
+#define PGSTAT_IS_ACTIVE(s)												\
+	((s)->st_state == STATE_RUNNING || (s)->st_state == STATE_FASTPATH)
+#define PGSTAT_IS_IDLEINTRANSACTION(s)			 \
+	((s)->st_state == STATE_IDLEINTRANSACTION ||		\
+	 (s)->st_state == STATE_IDLEINTRANSACTION_ABORTED)
 
 /* ----------
  * LocalPgBackendStatus
#24Sergey Dudoladov
sergey.dudoladov@gmail.com
In reply to: Kyotaro Horiguchi (#23)
1 attachment(s)
Re: Add connection active, idle time to pg_stat_activity

Hi,

Could you please elaborate on this idea ?
So we have pgStatActiveTime and pgStatIdleInTransactionTime ultimately
used to report respective metrics in pg_stat_database.
Now beentry's st_total_active_time / st_total_transaction_idle_time
duplicates this info, so one may get rid of pgStat*Time counters. Is
the idea to report instead of them at every tabstat reporting the
difference between the last memorized value of st_total_*_time and
its current value ?

Exactly. The attached first diff is the schetch of that.

This diff actually adds more code than it removes and somewhat bloats the patch.
I decided to incorporate it anyway because the diff explicitly shows
that time differences since the last report
are send to the statistics collector,which is not immediately evident
from the existing PgStat*Time counters.
That point may be worth further discussion though.

And, it seems like I forgot to mention this, but as Kuntal suggested
(in a different context and objective, though) upthraed, I think that
we can show realtime values in the two time fields by adding the time
of the current state. See the attached second diff.

That is exactly what we need in our infra, also included into the patch.

@Kyotaro Horiguchi
Thank you for the contribution. I included both of your diffs with
minor changes.
Should I add you to the authors of the patch given that now half of it
is basically your code ?

Regards,
Sergey

Attachments:

v8_add_idle_active_time.patchtext/x-patch; charset=US-ASCII; name=v8_add_idle_active_time.patchDownload
diff --git a/doc/src/sgml/monitoring.sgml b/doc/src/sgml/monitoring.sgml
index 62f2a3332b..bc76016834 100644
--- a/doc/src/sgml/monitoring.sgml
+++ b/doc/src/sgml/monitoring.sgml
@@ -967,6 +967,26 @@ postgres   27093  0.0  0.0  30096  2752 ?        Ss   11:34   0:00 postgres: ser
        additional types.
       </para></entry>
      </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>active_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in <literal>active</literal> and
+       <literal>fastpath</literal> states.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>idle_in_transaction_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in <literal>idle in transaction</literal>
+       and <literal>idle in transaction (aborted)</literal> states.
+      </para></entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
diff --git a/src/backend/catalog/system_views.sql b/src/backend/catalog/system_views.sql
index 3cb69b1f87..e349709c05 100644
--- a/src/backend/catalog/system_views.sql
+++ b/src/backend/catalog/system_views.sql
@@ -841,7 +841,9 @@ CREATE VIEW pg_stat_activity AS
             s.backend_xmin,
             S.query_id,
             S.query,
-            S.backend_type
+            S.backend_type,
+            S.active_time,
+            S.idle_in_transaction_time
     FROM pg_stat_get_activity(NULL) AS S
         LEFT JOIN pg_database AS D ON (S.datid = D.oid)
         LEFT JOIN pg_authid AS U ON (S.usesysid = U.oid);
diff --git a/src/backend/postmaster/pgstat.c b/src/backend/postmaster/pgstat.c
index 0646f53098..8b84533953 100644
--- a/src/backend/postmaster/pgstat.c
+++ b/src/backend/postmaster/pgstat.c
@@ -249,8 +249,8 @@ static int	pgStatXactRollback = 0;
 PgStat_Counter pgStatBlockReadTime = 0;
 PgStat_Counter pgStatBlockWriteTime = 0;
 static PgStat_Counter pgLastSessionReportTime = 0;
-PgStat_Counter pgStatActiveTime = 0;
-PgStat_Counter pgStatTransactionIdleTime = 0;
+PgStat_Counter pgStatLastActiveTime = 0;
+PgStat_Counter pgStatLastTransactionIdleTime = 0;
 SessionEndType pgStatSessionEndCause = DISCONNECT_NORMAL;
 
 /* Record that's written to 2PC state file when pgstat state is persisted */
@@ -1026,8 +1026,12 @@ pgstat_send_tabstat(PgStat_MsgTabstat *tsmsg, TimestampTz now)
 			TimestampDifference(pgLastSessionReportTime, now, &secs, &usecs);
 			pgLastSessionReportTime = now;
 			tsmsg->m_session_time = (PgStat_Counter) secs * 1000000 + usecs;
-			tsmsg->m_active_time = pgStatActiveTime;
-			tsmsg->m_idle_in_xact_time = pgStatTransactionIdleTime;
+
+			/* send the difference since the last report */
+			tsmsg->m_active_time =
+				pgstat_get_my_active_time() - pgStatLastActiveTime;
+			tsmsg->m_idle_in_xact_time =
+				pgstat_get_my_transaction_idle_time() - pgStatLastTransactionIdleTime;
 		}
 		else
 		{
@@ -1039,8 +1043,8 @@ pgstat_send_tabstat(PgStat_MsgTabstat *tsmsg, TimestampTz now)
 		pgStatXactRollback = 0;
 		pgStatBlockReadTime = 0;
 		pgStatBlockWriteTime = 0;
-		pgStatActiveTime = 0;
-		pgStatTransactionIdleTime = 0;
+		pgStatLastActiveTime = pgstat_get_my_active_time();
+		pgStatLastTransactionIdleTime = pgstat_get_my_transaction_idle_time();
 	}
 	else
 	{
diff --git a/src/backend/utils/activity/backend_status.c b/src/backend/utils/activity/backend_status.c
index 2fecf26a2c..ccea8e3325 100644
--- a/src/backend/utils/activity/backend_status.c
+++ b/src/backend/utils/activity/backend_status.c
@@ -468,6 +468,13 @@ pgstat_beshutdown_hook(int code, Datum arg)
 
 	beentry->st_procpid = 0;	/* mark invalid */
 
+	/*
+	 * Reset per-backend counters so that accumulated values for the current
+	 * backend are not used for future backends.
+	 */
+	beentry->st_total_active_time = 0;
+	beentry->st_total_transaction_idle_time = 0;
+
 	PGSTAT_END_WRITE_ACTIVITY(beentry);
 
 	/* so that functions can check if backend_status.c is up via MyBEEntry */
@@ -524,6 +531,8 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 	TimestampTz start_timestamp;
 	TimestampTz current_timestamp;
 	int			len = 0;
+	int64		active_time_diff = 0;
+	int64		transaction_idle_time_diff = 0;
 
 	TRACE_POSTGRESQL_STATEMENT_STATUS(cmd_str);
 
@@ -550,6 +559,9 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 			beentry->st_xact_start_timestamp = 0;
 			beentry->st_query_id = UINT64CONST(0);
 			proc->wait_event_info = 0;
+
+			beentry->st_total_active_time = 0;
+			beentry->st_total_transaction_idle_time = 0;
 			PGSTAT_END_WRITE_ACTIVITY(beentry);
 		}
 		return;
@@ -575,24 +587,31 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 	 * If the state has changed from "active" or "idle in transaction",
 	 * calculate the duration.
 	 */
-	if ((beentry->st_state == STATE_RUNNING ||
-		 beentry->st_state == STATE_FASTPATH ||
-		 beentry->st_state == STATE_IDLEINTRANSACTION ||
-		 beentry->st_state == STATE_IDLEINTRANSACTION_ABORTED) &&
+	if ((PGSTAT_IS_ACTIVE(beentry) || PGSTAT_IS_IDLEINTRANSACTION(beentry)) &&
 		state != beentry->st_state)
 	{
 		long		secs;
 		int			usecs;
+		int64		usecs_diff;
 
 		TimestampDifference(beentry->st_state_start_timestamp,
 							current_timestamp,
 							&secs, &usecs);
+		usecs_diff = secs * 1000000 + usecs;
 
-		if (beentry->st_state == STATE_RUNNING ||
-			beentry->st_state == STATE_FASTPATH)
-			pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 + usecs);
+		/*
+		 * We update per-backend st_total_active_time and st_total_transaction_idle_time
+		 * separately from pgStatActiveTime and pgStatTransactionIdleTime
+		 * used in pg_stat_database to provide per-DB statistics because
+		 * 1. Changing the former values implies modifying beentry and thus
+		 * have to be wrapped into PGSTAT_*_WRITE_ACTIVITY macros (see below).
+		 * 2. The latter values are reset to 0 once the data has been sent
+		 * to the statistics collector.
+		 */
+		if (PGSTAT_IS_ACTIVE(beentry))
+			active_time_diff = usecs_diff;
 		else
-			pgstat_count_conn_txn_idle_time((PgStat_Counter) secs * 1000000 + usecs);
+			transaction_idle_time_diff = usecs_diff;
 	}
 
 	/*
@@ -618,6 +637,9 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 		beentry->st_activity_start_timestamp = start_timestamp;
 	}
 
+	beentry->st_total_active_time += active_time_diff;
+	beentry->st_total_transaction_idle_time += transaction_idle_time_diff;
+
 	PGSTAT_END_WRITE_ACTIVITY(beentry);
 }
 
@@ -1046,6 +1068,48 @@ pgstat_get_my_query_id(void)
 }
 
 
+/* ----------
+ * pgstat_get_my_active_time() -
+ *
+ * Return current backend's accumulated active time.
+ */
+uint64
+pgstat_get_my_active_time(void)
+{
+	if (!MyBEEntry)
+		return 0;
+
+	/*
+	 * There's no need for a lock around pgstat_begin_read_activity /
+	 * pgstat_end_read_activity here as it's only called from
+	 * pg_stat_get_activity which is already protected, or from the same
+	 * backend which means that there won't be concurrent writes.
+	 */
+	return MyBEEntry->st_total_active_time;
+}
+
+
+/* ----------
+ * pgstat_get_my_transaction_idle_time() -
+ *
+ * Return current backend's accumulated in-transaction idle time.
+ */
+uint64
+pgstat_get_my_transaction_idle_time(void)
+{
+	if (!MyBEEntry)
+		return 0;
+
+	/*
+	 * There's no need for a lock around pgstat_begin_read_activity /
+	 * pgstat_end_read_activity here as it's only called from
+	 * pg_stat_get_activity which is already protected, or from the same
+	 * backend which means that there won't be concurrent writes.
+	 */
+	return MyBEEntry->st_total_transaction_idle_time;
+}
+
+
 /* ----------
  * pgstat_fetch_stat_beentry() -
  *
diff --git a/src/backend/utils/adt/pgstatfuncs.c b/src/backend/utils/adt/pgstatfuncs.c
index 15cb17ace4..076fa1f049 100644
--- a/src/backend/utils/adt/pgstatfuncs.c
+++ b/src/backend/utils/adt/pgstatfuncs.c
@@ -567,7 +567,7 @@ pg_stat_get_progress_info(PG_FUNCTION_ARGS)
 Datum
 pg_stat_get_activity(PG_FUNCTION_ARGS)
 {
-#define PG_STAT_GET_ACTIVITY_COLS	30
+#define PG_STAT_GET_ACTIVITY_COLS	32
 	int			num_backends = pgstat_fetch_stat_numbackends();
 	int			curr_backend;
 	int			pid = PG_ARGISNULL(0) ? -1 : PG_GETARG_INT32(0);
@@ -675,6 +675,7 @@ pg_stat_get_activity(PG_FUNCTION_ARGS)
 		{
 			SockAddr	zero_clientaddr;
 			char	   *clipped_activity;
+			int64		time_to_report;
 
 			switch (beentry->st_state)
 			{
@@ -916,6 +917,23 @@ pg_stat_get_activity(PG_FUNCTION_ARGS)
 				nulls[29] = true;
 			else
 				values[29] = UInt64GetDatum(beentry->st_query_id);
+
+			time_to_report = beentry->st_total_active_time;
+			/* add the realtime value to the counter if needed */
+			if (PGSTAT_IS_ACTIVE(beentry))
+				time_to_report +=
+					GetCurrentTimestamp() - beentry->st_state_start_timestamp;
+			/* convert it to msec */
+			values[30] = Float8GetDatum(time_to_report / 1000.0) ;
+
+			time_to_report = beentry->st_total_transaction_idle_time;
+			/* add the realtime value to the counter if needed */
+			if (PGSTAT_IS_IDLEINTRANSACTION(beentry))
+				time_to_report +=
+					GetCurrentTimestamp() - beentry->st_state_start_timestamp;
+
+			/* convert it to msec */
+			values[31] = Float8GetDatum(time_to_report / 1000.0);
 		}
 		else
 		{
@@ -944,6 +962,8 @@ pg_stat_get_activity(PG_FUNCTION_ARGS)
 			nulls[27] = true;
 			nulls[28] = true;
 			nulls[29] = true;
+			nulls[30] = true;
+			nulls[31] = true;
 		}
 
 		tuplestore_putvalues(tupstore, tupdesc, values, nulls);
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index b6f689e8d1..59479b8594 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -5334,9 +5334,9 @@
   proname => 'pg_stat_get_activity', prorows => '100', proisstrict => 'f',
   proretset => 't', provolatile => 's', proparallel => 'r',
   prorettype => 'record', proargtypes => 'int4',
-  proallargtypes => '{int4,oid,int4,oid,text,text,text,text,text,timestamptz,timestamptz,timestamptz,timestamptz,inet,text,int4,xid,xid,text,bool,text,text,int4,text,numeric,text,bool,text,bool,int4,int8}',
-  proargmodes => '{i,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o}',
-  proargnames => '{pid,datid,pid,usesysid,application_name,state,query,wait_event_type,wait_event,xact_start,query_start,backend_start,state_change,client_addr,client_hostname,client_port,backend_xid,backend_xmin,backend_type,ssl,sslversion,sslcipher,sslbits,ssl_client_dn,ssl_client_serial,ssl_issuer_dn,gss_auth,gss_princ,gss_enc,leader_pid,query_id}',
+  proallargtypes => '{int4,oid,int4,oid,text,text,text,text,text,timestamptz,timestamptz,timestamptz,timestamptz,inet,text,int4,xid,xid,text,bool,text,text,int4,text,numeric,text,bool,text,bool,int4,int8,float8,float8}',
+  proargmodes => '{i,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o}',
+  proargnames => '{pid,datid,pid,usesysid,application_name,state,query,wait_event_type,wait_event,xact_start,query_start,backend_start,state_change,client_addr,client_hostname,client_port,backend_xid,backend_xmin,backend_type,ssl,sslversion,sslcipher,sslbits,ssl_client_dn,ssl_client_serial,ssl_issuer_dn,gss_auth,gss_princ,gss_enc,leader_pid,query_id,active_time,idle_in_transaction_time}',
   prosrc => 'pg_stat_get_activity' },
 { oid => '3318',
   descr => 'statistics: information about progress of backends running maintenance command',
diff --git a/src/include/pgstat.h b/src/include/pgstat.h
index e10d20222a..2f168cbdab 100644
--- a/src/include/pgstat.h
+++ b/src/include/pgstat.h
@@ -1071,13 +1071,6 @@ extern PgStat_MsgWal WalStats;
 extern PgStat_Counter pgStatBlockReadTime;
 extern PgStat_Counter pgStatBlockWriteTime;
 
-/*
- * Updated by pgstat_count_conn_*_time macros, called by
- * pgstat_report_activity().
- */
-extern PgStat_Counter pgStatActiveTime;
-extern PgStat_Counter pgStatTransactionIdleTime;
-
 
 /*
  * Updated by the traffic cop and in errfinish()
@@ -1185,10 +1178,6 @@ extern void pgstat_initstats(Relation rel);
 	(pgStatBlockReadTime += (n))
 #define pgstat_count_buffer_write_time(n)							\
 	(pgStatBlockWriteTime += (n))
-#define pgstat_count_conn_active_time(n)							\
-	(pgStatActiveTime += (n))
-#define pgstat_count_conn_txn_idle_time(n)							\
-	(pgStatTransactionIdleTime += (n))
 
 extern void pgstat_count_heap_insert(Relation rel, PgStat_Counter n);
 extern void pgstat_count_heap_update(Relation rel, bool hot);
diff --git a/src/include/utils/backend_status.h b/src/include/utils/backend_status.h
index 8217d0cb6b..e06f2c4022 100644
--- a/src/include/utils/backend_status.h
+++ b/src/include/utils/backend_status.h
@@ -168,6 +168,10 @@ typedef struct PgBackendStatus
 
 	/* query identifier, optionally computed using post_parse_analyze_hook */
 	uint64		st_query_id;
+
+	/* time spent in respective states in usec */
+	int64		st_total_active_time;
+	int64		st_total_transaction_idle_time;
 } PgBackendStatus;
 
 
@@ -231,6 +235,12 @@ typedef struct PgBackendStatus
 	((before_changecount) == (after_changecount) && \
 	 ((before_changecount) & 1) == 0)
 
+/* Macros to identify the states for time accounting */
+#define PGSTAT_IS_ACTIVE(s) \
+	((s)->st_state == STATE_RUNNING || (s)->st_state == STATE_FASTPATH)
+#define PGSTAT_IS_IDLEINTRANSACTION(s) \
+	((s)->st_state == STATE_IDLEINTRANSACTION || \
+	 (s)->st_state == STATE_IDLEINTRANSACTION_ABORTED)
 
 /* ----------
  * LocalPgBackendStatus
@@ -305,6 +315,8 @@ extern const char *pgstat_get_backend_current_activity(int pid, bool checkUser);
 extern const char *pgstat_get_crashed_backend_activity(int pid, char *buffer,
 													   int buflen);
 extern uint64 pgstat_get_my_query_id(void);
+extern uint64 pgstat_get_my_active_time(void);
+extern uint64 pgstat_get_my_transaction_idle_time(void);
 
 
 /* ----------
diff --git a/src/test/regress/expected/rules.out b/src/test/regress/expected/rules.out
index d652f7b5fb..5e7ee70edd 100644
--- a/src/test/regress/expected/rules.out
+++ b/src/test/regress/expected/rules.out
@@ -1764,8 +1764,10 @@ pg_stat_activity| SELECT s.datid,
     s.backend_xmin,
     s.query_id,
     s.query,
-    s.backend_type
-   FROM ((pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id)
+    s.backend_type,
+    s.active_time,
+    s.idle_in_transaction_time
+   FROM ((pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id, active_time, idle_in_transaction_time)
      LEFT JOIN pg_database d ON ((s.datid = d.oid)))
      LEFT JOIN pg_authid u ON ((s.usesysid = u.oid)));
 pg_stat_all_indexes| SELECT c.oid AS relid,
@@ -1877,7 +1879,7 @@ pg_stat_gssapi| SELECT s.pid,
     s.gss_auth AS gss_authenticated,
     s.gss_princ AS principal,
     s.gss_enc AS encrypted
-   FROM pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id)
+   FROM pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id, active_time, idle_in_transaction_time)
   WHERE (s.client_port IS NOT NULL);
 pg_stat_progress_analyze| SELECT s.pid,
     s.datid,
@@ -2047,7 +2049,7 @@ pg_stat_replication| SELECT s.pid,
     w.sync_priority,
     w.sync_state,
     w.reply_time
-   FROM ((pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id)
+   FROM ((pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id, active_time, idle_in_transaction_time)
      JOIN pg_stat_get_wal_senders() w(pid, state, sent_lsn, write_lsn, flush_lsn, replay_lsn, write_lag, flush_lag, replay_lag, sync_priority, sync_state, reply_time) ON ((s.pid = w.pid)))
      LEFT JOIN pg_authid u ON ((s.usesysid = u.oid)));
 pg_stat_replication_slots| SELECT s.slot_name,
@@ -2081,7 +2083,7 @@ pg_stat_ssl| SELECT s.pid,
     s.ssl_client_dn AS client_dn,
     s.ssl_client_serial AS client_serial,
     s.ssl_issuer_dn AS issuer_dn
-   FROM pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id)
+   FROM pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id, active_time, idle_in_transaction_time)
   WHERE (s.client_port IS NOT NULL);
 pg_stat_subscription| SELECT su.oid AS subid,
     su.subname,
#25Andres Freund
andres@anarazel.de
In reply to: Sergey Dudoladov (#24)
Re: Add connection active, idle time to pg_stat_activity

Hi,

On 2022-02-04 10:58:24 +0100, Sergey Dudoladov wrote:

Thank you for the contribution. I included both of your diffs with
minor changes.

This currently doesn't apply: http://cfbot.cputube.org/patch_37_3405.log

Could you rebase? Marking as waiting on author for now.

- Andres

#26Sergey Dudoladov
sergey.dudoladov@gmail.com
In reply to: Andres Freund (#25)
1 attachment(s)
Re: Add connection active, idle time to pg_stat_activity

Hello,

I've updated the patch in preparation for the upcoming commitfest.

Regards,
Sergey.

Attachments:

v9_add_idle_active_time.patchtext/x-patch; charset=US-ASCII; name=v9_add_idle_active_time.patchDownload
diff --git a/doc/src/sgml/monitoring.sgml b/doc/src/sgml/monitoring.sgml
index 4549c2560e..cf00685c96 100644
--- a/doc/src/sgml/monitoring.sgml
+++ b/doc/src/sgml/monitoring.sgml
@@ -979,6 +979,26 @@ postgres   27093  0.0  0.0  30096  2752 ?        Ss   11:34   0:00 postgres: ser
        additional types.
       </para></entry>
      </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>active_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in <literal>active</literal> and
+       <literal>fastpath</literal> states.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>idle_in_transaction_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in <literal>idle in transaction</literal>
+       and <literal>idle in transaction (aborted)</literal> states.
+      </para></entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
diff --git a/src/backend/catalog/system_views.sql b/src/backend/catalog/system_views.sql
index fedaed533b..06cea5f01c 100644
--- a/src/backend/catalog/system_views.sql
+++ b/src/backend/catalog/system_views.sql
@@ -864,7 +864,9 @@ CREATE VIEW pg_stat_activity AS
             s.backend_xmin,
             S.query_id,
             S.query,
-            S.backend_type
+            S.backend_type,
+            S.active_time,
+            S.idle_in_transaction_time
     FROM pg_stat_get_activity(NULL) AS S
         LEFT JOIN pg_database AS D ON (S.datid = D.oid)
         LEFT JOIN pg_authid AS U ON (S.usesysid = U.oid);
diff --git a/src/backend/utils/activity/backend_status.c b/src/backend/utils/activity/backend_status.c
index c7ed1e6d7a..dbb7a0aec6 100644
--- a/src/backend/utils/activity/backend_status.c
+++ b/src/backend/utils/activity/backend_status.c
@@ -468,6 +468,13 @@ pgstat_beshutdown_hook(int code, Datum arg)
 
 	beentry->st_procpid = 0;	/* mark invalid */
 
+	/*
+	 * Reset per-backend counters so that accumulated values for the current
+	 * backend are not used for future backends.
+	 */
+	beentry->st_total_active_time = 0;
+	beentry->st_total_transaction_idle_time = 0;
+
 	PGSTAT_END_WRITE_ACTIVITY(beentry);
 
 	/* so that functions can check if backend_status.c is up via MyBEEntry */
@@ -524,6 +531,8 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 	TimestampTz start_timestamp;
 	TimestampTz current_timestamp;
 	int			len = 0;
+	int64		active_time_diff = 0;
+	int64		transaction_idle_time_diff = 0;
 
 	TRACE_POSTGRESQL_STATEMENT_STATUS(cmd_str);
 
@@ -550,6 +559,9 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 			beentry->st_xact_start_timestamp = 0;
 			beentry->st_query_id = UINT64CONST(0);
 			proc->wait_event_info = 0;
+
+			beentry->st_total_active_time = 0;
+			beentry->st_total_transaction_idle_time = 0;
 			PGSTAT_END_WRITE_ACTIVITY(beentry);
 		}
 		return;
@@ -575,24 +587,31 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 	 * If the state has changed from "active" or "idle in transaction",
 	 * calculate the duration.
 	 */
-	if ((beentry->st_state == STATE_RUNNING ||
-		 beentry->st_state == STATE_FASTPATH ||
-		 beentry->st_state == STATE_IDLEINTRANSACTION ||
-		 beentry->st_state == STATE_IDLEINTRANSACTION_ABORTED) &&
+	if ((PGSTAT_IS_ACTIVE(beentry) || PGSTAT_IS_IDLEINTRANSACTION(beentry)) &&
 		state != beentry->st_state)
 	{
 		long		secs;
 		int			usecs;
+		int64		usecs_diff;
 
 		TimestampDifference(beentry->st_state_start_timestamp,
 							current_timestamp,
 							&secs, &usecs);
+		usecs_diff = secs * 1000000 + usecs;
 
-		if (beentry->st_state == STATE_RUNNING ||
-			beentry->st_state == STATE_FASTPATH)
-			pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 + usecs);
+		/*
+		 * We update per-backend st_total_active_time and st_total_transaction_idle_time
+		 * separately from pgStatActiveTime and pgStatTransactionIdleTime
+		 * used in pg_stat_database to provide per-DB statistics because
+		 * 1. Changing the former values implies modifying beentry and thus
+		 * have to be wrapped into PGSTAT_*_WRITE_ACTIVITY macros (see below).
+		 * 2. The latter values are reset to 0 once the data has been sent
+		 * to the statistics collector.
+		 */
+		if (PGSTAT_IS_ACTIVE(beentry))
+			active_time_diff = usecs_diff;
 		else
-			pgstat_count_conn_txn_idle_time((PgStat_Counter) secs * 1000000 + usecs);
+			transaction_idle_time_diff = usecs_diff;
 	}
 
 	/*
@@ -618,6 +637,9 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 		beentry->st_activity_start_timestamp = start_timestamp;
 	}
 
+	beentry->st_total_active_time += active_time_diff;
+	beentry->st_total_transaction_idle_time += transaction_idle_time_diff;
+
 	PGSTAT_END_WRITE_ACTIVITY(beentry);
 }
 
@@ -1046,6 +1068,48 @@ pgstat_get_my_query_id(void)
 }
 
 
+/* ----------
+ * pgstat_get_my_active_time() -
+ *
+ * Return current backend's accumulated active time.
+ */
+uint64
+pgstat_get_my_active_time(void)
+{
+	if (!MyBEEntry)
+		return 0;
+
+	/*
+	 * There's no need for a lock around pgstat_begin_read_activity /
+	 * pgstat_end_read_activity here as it's only called from
+	 * pg_stat_get_activity which is already protected, or from the same
+	 * backend which means that there won't be concurrent writes.
+	 */
+	return MyBEEntry->st_total_active_time;
+}
+
+
+/* ----------
+ * pgstat_get_my_transaction_idle_time() -
+ *
+ * Return current backend's accumulated in-transaction idle time.
+ */
+uint64
+pgstat_get_my_transaction_idle_time(void)
+{
+	if (!MyBEEntry)
+		return 0;
+
+	/*
+	 * There's no need for a lock around pgstat_begin_read_activity /
+	 * pgstat_end_read_activity here as it's only called from
+	 * pg_stat_get_activity which is already protected, or from the same
+	 * backend which means that there won't be concurrent writes.
+	 */
+	return MyBEEntry->st_total_transaction_idle_time;
+}
+
+
 /* ----------
  * pgstat_fetch_stat_beentry() -
  *
diff --git a/src/backend/utils/adt/pgstatfuncs.c b/src/backend/utils/adt/pgstatfuncs.c
index 893690dad5..12c89c34cf 100644
--- a/src/backend/utils/adt/pgstatfuncs.c
+++ b/src/backend/utils/adt/pgstatfuncs.c
@@ -539,7 +539,7 @@ pg_stat_get_progress_info(PG_FUNCTION_ARGS)
 Datum
 pg_stat_get_activity(PG_FUNCTION_ARGS)
 {
-#define PG_STAT_GET_ACTIVITY_COLS	30
+#define PG_STAT_GET_ACTIVITY_COLS	32
 	int			num_backends = pgstat_fetch_stat_numbackends();
 	int			curr_backend;
 	int			pid = PG_ARGISNULL(0) ? -1 : PG_GETARG_INT32(0);
@@ -621,6 +621,7 @@ pg_stat_get_activity(PG_FUNCTION_ARGS)
 		{
 			SockAddr	zero_clientaddr;
 			char	   *clipped_activity;
+			int64		time_to_report;
 
 			switch (beentry->st_state)
 			{
@@ -862,6 +863,22 @@ pg_stat_get_activity(PG_FUNCTION_ARGS)
 				nulls[29] = true;
 			else
 				values[29] = UInt64GetDatum(beentry->st_query_id);
+
+			time_to_report = beentry->st_total_active_time;
+			/* add the realtime value to the counter if needed */
+			if (PGSTAT_IS_ACTIVE(beentry))
+				time_to_report +=
+					GetCurrentTimestamp() - beentry->st_state_start_timestamp;
+			/* convert it to msec */
+			values[30] = Float8GetDatum(time_to_report / 1000.0);
+
+			time_to_report = beentry->st_total_transaction_idle_time;
+			/* add the realtime value to the counter if needed */
+			if (PGSTAT_IS_IDLEINTRANSACTION(beentry))
+				time_to_report +=
+					GetCurrentTimestamp() - beentry->st_state_start_timestamp;
+			/* convert it to msec */
+			values[31] = Float8GetDatum(time_to_report / 1000.0);
 		}
 		else
 		{
@@ -890,6 +907,8 @@ pg_stat_get_activity(PG_FUNCTION_ARGS)
 			nulls[27] = true;
 			nulls[28] = true;
 			nulls[29] = true;
+			nulls[30] = true;
+			nulls[31] = true;
 		}
 
 		tuplestore_putvalues(rsinfo->setResult, rsinfo->setDesc, values, nulls);
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index 87aa571a33..795130c1c2 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -5340,9 +5340,9 @@
   proname => 'pg_stat_get_activity', prorows => '100', proisstrict => 'f',
   proretset => 't', provolatile => 's', proparallel => 'r',
   prorettype => 'record', proargtypes => 'int4',
-  proallargtypes => '{int4,oid,int4,oid,text,text,text,text,text,timestamptz,timestamptz,timestamptz,timestamptz,inet,text,int4,xid,xid,text,bool,text,text,int4,text,numeric,text,bool,text,bool,int4,int8}',
-  proargmodes => '{i,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o}',
-  proargnames => '{pid,datid,pid,usesysid,application_name,state,query,wait_event_type,wait_event,xact_start,query_start,backend_start,state_change,client_addr,client_hostname,client_port,backend_xid,backend_xmin,backend_type,ssl,sslversion,sslcipher,sslbits,ssl_client_dn,ssl_client_serial,ssl_issuer_dn,gss_auth,gss_princ,gss_enc,leader_pid,query_id}',
+  proallargtypes => '{int4,oid,int4,oid,text,text,text,text,text,timestamptz,timestamptz,timestamptz,timestamptz,inet,text,int4,xid,xid,text,bool,text,text,int4,text,numeric,text,bool,text,bool,int4,int8,float8,float8}',
+  proargmodes => '{i,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o}',
+  proargnames => '{pid,datid,pid,usesysid,application_name,state,query,wait_event_type,wait_event,xact_start,query_start,backend_start,state_change,client_addr,client_hostname,client_port,backend_xid,backend_xmin,backend_type,ssl,sslversion,sslcipher,sslbits,ssl_client_dn,ssl_client_serial,ssl_issuer_dn,gss_auth,gss_princ,gss_enc,leader_pid,query_id,active_time,idle_in_transaction_time}',
   prosrc => 'pg_stat_get_activity' },
 { oid => '3318',
   descr => 'statistics: information about progress of backends running maintenance command',
diff --git a/src/include/pgstat.h b/src/include/pgstat.h
index ac28f813b4..8248e63931 100644
--- a/src/include/pgstat.h
+++ b/src/include/pgstat.h
@@ -469,10 +469,6 @@ extern void pgstat_report_connect(Oid dboid);
 	(pgStatBlockReadTime += (n))
 #define pgstat_count_buffer_write_time(n)							\
 	(pgStatBlockWriteTime += (n))
-#define pgstat_count_conn_active_time(n)							\
-	(pgStatActiveTime += (n))
-#define pgstat_count_conn_txn_idle_time(n)							\
-	(pgStatTransactionIdleTime += (n))
 
 extern PgStat_StatDBEntry *pgstat_fetch_stat_dbentry(Oid dbid);
 
@@ -673,12 +669,6 @@ extern PGDLLIMPORT PgStat_CheckpointerStats PendingCheckpointerStats;
 extern PGDLLIMPORT PgStat_Counter pgStatBlockReadTime;
 extern PGDLLIMPORT PgStat_Counter pgStatBlockWriteTime;
 
-/*
- * Updated by pgstat_count_conn_*_time macros, called by
- * pgstat_report_activity().
- */
-extern PGDLLIMPORT PgStat_Counter pgStatActiveTime;
-extern PGDLLIMPORT PgStat_Counter pgStatTransactionIdleTime;
 
 /* updated by the traffic cop and in errfinish() */
 extern PGDLLIMPORT SessionEndType pgStatSessionEndCause;
diff --git a/src/include/utils/backend_status.h b/src/include/utils/backend_status.h
index 7403bca25e..23660753fe 100644
--- a/src/include/utils/backend_status.h
+++ b/src/include/utils/backend_status.h
@@ -168,6 +168,10 @@ typedef struct PgBackendStatus
 
 	/* query identifier, optionally computed using post_parse_analyze_hook */
 	uint64		st_query_id;
+
+	/* time spent in respective states in usec */
+	int64		st_total_active_time;
+	int64		st_total_transaction_idle_time;
 } PgBackendStatus;
 
 
@@ -231,6 +235,12 @@ typedef struct PgBackendStatus
 	((before_changecount) == (after_changecount) && \
 	 ((before_changecount) & 1) == 0)
 
+/* Macros to identify the states for time accounting */
+#define PGSTAT_IS_ACTIVE(s) \
+	((s)->st_state == STATE_RUNNING || (s)->st_state == STATE_FASTPATH)
+#define PGSTAT_IS_IDLEINTRANSACTION(s) \
+	((s)->st_state == STATE_IDLEINTRANSACTION || \
+	 (s)->st_state == STATE_IDLEINTRANSACTION_ABORTED)
 
 /* ----------
  * LocalPgBackendStatus
@@ -305,6 +315,8 @@ extern const char *pgstat_get_backend_current_activity(int pid, bool checkUser);
 extern const char *pgstat_get_crashed_backend_activity(int pid, char *buffer,
 													   int buflen);
 extern uint64 pgstat_get_my_query_id(void);
+extern uint64 pgstat_get_my_active_time(void);
+extern uint64 pgstat_get_my_transaction_idle_time(void);
 
 
 /* ----------
diff --git a/src/test/regress/expected/rules.out b/src/test/regress/expected/rules.out
index fc3cde3226..92174235f3 100644
--- a/src/test/regress/expected/rules.out
+++ b/src/test/regress/expected/rules.out
@@ -1757,8 +1757,10 @@ pg_stat_activity| SELECT s.datid,
     s.backend_xmin,
     s.query_id,
     s.query,
-    s.backend_type
-   FROM ((pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id)
+    s.backend_type,
+    s.active_time,
+    s.idle_in_transaction_time
+   FROM ((pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id, active_time, idle_in_transaction_time)
      LEFT JOIN pg_database d ON ((s.datid = d.oid)))
      LEFT JOIN pg_authid u ON ((s.usesysid = u.oid)));
 pg_stat_all_indexes| SELECT c.oid AS relid,
@@ -1870,7 +1872,7 @@ pg_stat_gssapi| SELECT s.pid,
     s.gss_auth AS gss_authenticated,
     s.gss_princ AS principal,
     s.gss_enc AS encrypted
-   FROM pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id)
+   FROM pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id, active_time, idle_in_transaction_time)
   WHERE (s.client_port IS NOT NULL);
 pg_stat_progress_analyze| SELECT s.pid,
     s.datid,
@@ -2051,7 +2053,7 @@ pg_stat_replication| SELECT s.pid,
     w.sync_priority,
     w.sync_state,
     w.reply_time
-   FROM ((pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id)
+   FROM ((pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id, active_time, idle_in_transaction_time)
      JOIN pg_stat_get_wal_senders() w(pid, state, sent_lsn, write_lsn, flush_lsn, replay_lsn, write_lag, flush_lag, replay_lag, sync_priority, sync_state, reply_time) ON ((s.pid = w.pid)))
      LEFT JOIN pg_authid u ON ((s.usesysid = u.oid)));
 pg_stat_replication_slots| SELECT s.slot_name,
@@ -2085,7 +2087,7 @@ pg_stat_ssl| SELECT s.pid,
     s.ssl_client_dn AS client_dn,
     s.ssl_client_serial AS client_serial,
     s.ssl_issuer_dn AS issuer_dn
-   FROM pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id)
+   FROM pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id, active_time, idle_in_transaction_time)
   WHERE (s.client_port IS NOT NULL);
 pg_stat_subscription| SELECT su.oid AS subid,
     su.subname,
#27Drouvot, Bertrand
bdrouvot@amazon.com
In reply to: Sergey Dudoladov (#26)
Re: Add connection active, idle time to pg_stat_activity

Hi,

On 6/13/22 4:51 PM, Sergey Dudoladov wrote:

Hello,

I've updated the patch in preparation for the upcoming commitfest.

I really like the idea of adding additional information like the ones in
this patch, so +1 for the patch.

As far the patch:

@@ -864,7 +864,9 @@ CREATE VIEW pg_stat_activity AS
              s.backend_xmin,
              S.query_id,
              S.query,
-            S.backend_type
+            S.backend_type,
+            S.active_time,
+            S.idle_in_transaction_time

what about using total_active_time and total_idle_in_transaction_time?

I think that would avoid any confusion and "total_" is also already used
in other pg_stat_* views when appropriate.

@@ -468,6 +468,13 @@ pgstat_beshutdown_hook(int code, Datum arg)

        beentry->st_procpid = 0;        /* mark invalid */

+       /*
+        * Reset per-backend counters so that accumulated values for the 
current
+        * backend are not used for future backends.
+        */
+       beentry->st_total_active_time = 0;
+       beentry->st_total_transaction_idle_time = 0;

shouldn't that be in pgstat_bestart() instead? (and just let
pgstat_beshutdown_hook() set st_procpid to 0)

         /* so that functions can check if backend_status.c is up via 
MyBEEntry */
@@ -524,6 +531,8 @@ pgstat_report_activity(BackendState state, const 
char *cmd_str)
         TimestampTz start_timestamp;
         TimestampTz current_timestamp;
         int                     len = 0;
+       int64           active_time_diff = 0;
+       int64           transaction_idle_time_diff = 0;

I think here we can use only a single variable say "state_time_diff" for
example, as later only one of those two is incremented anyway.

+++ b/src/backend/utils/adt/pgstatfuncs.c
@@ -539,7 +539,7 @@ pg_stat_get_progress_info(PG_FUNCTION_ARGS)
  Datum
  pg_stat_get_activity(PG_FUNCTION_ARGS)
  {
-#define PG_STAT_GET_ACTIVITY_COLS      30
+#define PG_STAT_GET_ACTIVITY_COLS      32
         int                     num_backends = 
pgstat_fetch_stat_numbackends();
         int                     curr_backend;
         int                     pid = PG_ARGISNULL(0) ? -1 : 
PG_GETARG_INT32(0);
@@ -621,6 +621,7 @@ pg_stat_get_activity(PG_FUNCTION_ARGS)
                 {
                         SockAddr        zero_clientaddr;
                         char       *clipped_activity;
+                       int64           time_to_report;

what about total_time_to_report instead?

Also, maybe not for this patch but I think that would be also useful to
get the total time waited (so that we would get more inside of what the
"active" time was made of).

Regards,

--

Bertrand Drouvot
Amazon Web Services:https://aws.amazon.com

#28Sergey Dudoladov
sergey.dudoladov@gmail.com
In reply to: Drouvot, Bertrand (#27)
1 attachment(s)
Re: Add connection active, idle time to pg_stat_activity

Hello,

thanks for the helpful review. I have incorporated most of the
suggestions into the patch. I have also rebased and tested the patch
on top of the current master (2cd2569c72b89200).

+       int64           active_time_diff = 0;
+       int64           transaction_idle_time_diff = 0;

I think here we can use only a single variable say "state_time_diff" for
example, as later only one of those two is incremented anyway.

I have written it this way to avoid cluttering the critical section
between PGSTAT_(BEGIN|END)_WRITE_ACTIVITY.
With two variable one can leave only actual increments in the section
and check conditions / call TimestampDifference outside of it.

Regards,
Sergey

Attachments:

v10_add_idle_active_time.patchtext/x-patch; charset=US-ASCII; name=v10_add_idle_active_time.patchDownload
diff --git a/doc/src/sgml/monitoring.sgml b/doc/src/sgml/monitoring.sgml
index 4549c2560e..a0384fd3a5 100644
--- a/doc/src/sgml/monitoring.sgml
+++ b/doc/src/sgml/monitoring.sgml
@@ -979,6 +979,26 @@ postgres   27093  0.0  0.0  30096  2752 ?        Ss   11:34   0:00 postgres: ser
        additional types.
       </para></entry>
      </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>total_active_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in <literal>active</literal> and
+       <literal>fastpath</literal> states.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>total_idle_in_transaction_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in <literal>idle in transaction</literal>
+       and <literal>idle in transaction (aborted)</literal> states.
+      </para></entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
diff --git a/src/backend/catalog/system_views.sql b/src/backend/catalog/system_views.sql
index fedaed533b..3498ea874a 100644
--- a/src/backend/catalog/system_views.sql
+++ b/src/backend/catalog/system_views.sql
@@ -864,7 +864,9 @@ CREATE VIEW pg_stat_activity AS
             s.backend_xmin,
             S.query_id,
             S.query,
-            S.backend_type
+            S.backend_type,
+            S.total_active_time,
+            S.total_idle_in_transaction_time
     FROM pg_stat_get_activity(NULL) AS S
         LEFT JOIN pg_database AS D ON (S.datid = D.oid)
         LEFT JOIN pg_authid AS U ON (S.usesysid = U.oid);
diff --git a/src/backend/utils/activity/backend_status.c b/src/backend/utils/activity/backend_status.c
index c7ed1e6d7a..27285cb27d 100644
--- a/src/backend/utils/activity/backend_status.c
+++ b/src/backend/utils/activity/backend_status.c
@@ -336,6 +336,8 @@ pgstat_bestart(void)
 	lbeentry.st_activity_start_timestamp = 0;
 	lbeentry.st_state_start_timestamp = 0;
 	lbeentry.st_xact_start_timestamp = 0;
+	lbeentry.st_total_active_time = 0;
+	lbeentry.st_total_transaction_idle_time = 0;
 	lbeentry.st_databaseid = MyDatabaseId;
 
 	/* We have userid for client-backends, wal-sender and bgworker processes */
@@ -524,6 +526,8 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 	TimestampTz start_timestamp;
 	TimestampTz current_timestamp;
 	int			len = 0;
+	int64		active_time_diff = 0;
+	int64		transaction_idle_time_diff = 0;
 
 	TRACE_POSTGRESQL_STATEMENT_STATUS(cmd_str);
 
@@ -550,6 +554,9 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 			beentry->st_xact_start_timestamp = 0;
 			beentry->st_query_id = UINT64CONST(0);
 			proc->wait_event_info = 0;
+
+			beentry->st_total_active_time = 0;
+			beentry->st_total_transaction_idle_time = 0;
 			PGSTAT_END_WRITE_ACTIVITY(beentry);
 		}
 		return;
@@ -575,24 +582,31 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 	 * If the state has changed from "active" or "idle in transaction",
 	 * calculate the duration.
 	 */
-	if ((beentry->st_state == STATE_RUNNING ||
-		 beentry->st_state == STATE_FASTPATH ||
-		 beentry->st_state == STATE_IDLEINTRANSACTION ||
-		 beentry->st_state == STATE_IDLEINTRANSACTION_ABORTED) &&
+	if ((PGSTAT_IS_ACTIVE(beentry) || PGSTAT_IS_IDLEINTRANSACTION(beentry)) &&
 		state != beentry->st_state)
 	{
 		long		secs;
 		int			usecs;
+		int64		usecs_diff;
 
 		TimestampDifference(beentry->st_state_start_timestamp,
 							current_timestamp,
 							&secs, &usecs);
+		usecs_diff = secs * 1000000 + usecs;
 
-		if (beentry->st_state == STATE_RUNNING ||
-			beentry->st_state == STATE_FASTPATH)
-			pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 + usecs);
+		/*
+		 * We update per-backend st_total_active_time and st_total_transaction_idle_time
+		 * separately from pgStatActiveTime and pgStatTransactionIdleTime
+		 * used in pg_stat_database to provide per-DB statistics because
+		 * 1. Changing the former values implies modifying beentry and thus
+		 * have to be wrapped into PGSTAT_*_WRITE_ACTIVITY macros (see below).
+		 * 2. The latter values are reset to 0 once the data has been sent
+		 * to the statistics collector.
+		 */
+		if (PGSTAT_IS_ACTIVE(beentry))
+			active_time_diff = usecs_diff;
 		else
-			pgstat_count_conn_txn_idle_time((PgStat_Counter) secs * 1000000 + usecs);
+			transaction_idle_time_diff = usecs_diff;
 	}
 
 	/*
@@ -618,6 +632,9 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 		beentry->st_activity_start_timestamp = start_timestamp;
 	}
 
+	beentry->st_total_active_time += active_time_diff;
+	beentry->st_total_transaction_idle_time += transaction_idle_time_diff;
+
 	PGSTAT_END_WRITE_ACTIVITY(beentry);
 }
 
@@ -1046,6 +1063,48 @@ pgstat_get_my_query_id(void)
 }
 
 
+/* ----------
+ * pgstat_get_my_active_time() -
+ *
+ * Return current backend's accumulated active time.
+ */
+uint64
+pgstat_get_my_active_time(void)
+{
+	if (!MyBEEntry)
+		return 0;
+
+	/*
+	 * There's no need for a lock around pgstat_begin_read_activity /
+	 * pgstat_end_read_activity here as it's only called from
+	 * pg_stat_get_activity which is already protected, or from the same
+	 * backend which means that there won't be concurrent writes.
+	 */
+	return MyBEEntry->st_total_active_time;
+}
+
+
+/* ----------
+ * pgstat_get_my_transaction_idle_time() -
+ *
+ * Return current backend's accumulated in-transaction idle time.
+ */
+uint64
+pgstat_get_my_transaction_idle_time(void)
+{
+	if (!MyBEEntry)
+		return 0;
+
+	/*
+	 * There's no need for a lock around pgstat_begin_read_activity /
+	 * pgstat_end_read_activity here as it's only called from
+	 * pg_stat_get_activity which is already protected, or from the same
+	 * backend which means that there won't be concurrent writes.
+	 */
+	return MyBEEntry->st_total_transaction_idle_time;
+}
+
+
 /* ----------
  * pgstat_fetch_stat_beentry() -
  *
diff --git a/src/backend/utils/adt/pgstatfuncs.c b/src/backend/utils/adt/pgstatfuncs.c
index 893690dad5..17685c1ab8 100644
--- a/src/backend/utils/adt/pgstatfuncs.c
+++ b/src/backend/utils/adt/pgstatfuncs.c
@@ -539,7 +539,7 @@ pg_stat_get_progress_info(PG_FUNCTION_ARGS)
 Datum
 pg_stat_get_activity(PG_FUNCTION_ARGS)
 {
-#define PG_STAT_GET_ACTIVITY_COLS	30
+#define PG_STAT_GET_ACTIVITY_COLS	32
 	int			num_backends = pgstat_fetch_stat_numbackends();
 	int			curr_backend;
 	int			pid = PG_ARGISNULL(0) ? -1 : PG_GETARG_INT32(0);
@@ -621,6 +621,7 @@ pg_stat_get_activity(PG_FUNCTION_ARGS)
 		{
 			SockAddr	zero_clientaddr;
 			char	   *clipped_activity;
+			int64		total_time_to_report;
 
 			switch (beentry->st_state)
 			{
@@ -862,6 +863,22 @@ pg_stat_get_activity(PG_FUNCTION_ARGS)
 				nulls[29] = true;
 			else
 				values[29] = UInt64GetDatum(beentry->st_query_id);
+
+			total_time_to_report = beentry->st_total_active_time;
+			/* add the realtime value to the counter if needed */
+			if (PGSTAT_IS_ACTIVE(beentry))
+				total_time_to_report +=
+					GetCurrentTimestamp() - beentry->st_state_start_timestamp;
+			/* convert it to msec */
+			values[30] = Float8GetDatum(total_time_to_report / 1000.0) ;
+
+			total_time_to_report = beentry->st_total_transaction_idle_time;
+			/* add the realtime value to the counter if needed */
+			if (PGSTAT_IS_IDLEINTRANSACTION(beentry))
+				total_time_to_report +=
+					GetCurrentTimestamp() - beentry->st_state_start_timestamp;
+			/* convert it to msec */
+			values[31] = Float8GetDatum(total_time_to_report / 1000.0);
 		}
 		else
 		{
@@ -890,6 +907,8 @@ pg_stat_get_activity(PG_FUNCTION_ARGS)
 			nulls[27] = true;
 			nulls[28] = true;
 			nulls[29] = true;
+			nulls[30] = true;
+			nulls[31] = true;
 		}
 
 		tuplestore_putvalues(rsinfo->setResult, rsinfo->setDesc, values, nulls);
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index 2e41f4d9e8..bcd106897e 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -5340,9 +5340,9 @@
   proname => 'pg_stat_get_activity', prorows => '100', proisstrict => 'f',
   proretset => 't', provolatile => 's', proparallel => 'r',
   prorettype => 'record', proargtypes => 'int4',
-  proallargtypes => '{int4,oid,int4,oid,text,text,text,text,text,timestamptz,timestamptz,timestamptz,timestamptz,inet,text,int4,xid,xid,text,bool,text,text,int4,text,numeric,text,bool,text,bool,int4,int8}',
-  proargmodes => '{i,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o}',
-  proargnames => '{pid,datid,pid,usesysid,application_name,state,query,wait_event_type,wait_event,xact_start,query_start,backend_start,state_change,client_addr,client_hostname,client_port,backend_xid,backend_xmin,backend_type,ssl,sslversion,sslcipher,sslbits,ssl_client_dn,ssl_client_serial,ssl_issuer_dn,gss_auth,gss_princ,gss_enc,leader_pid,query_id}',
+  proallargtypes => '{int4,oid,int4,oid,text,text,text,text,text,timestamptz,timestamptz,timestamptz,timestamptz,inet,text,int4,xid,xid,text,bool,text,text,int4,text,numeric,text,bool,text,bool,int4,int8,float8,float8}',
+  proargmodes => '{i,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o}',
+  proargnames => '{pid,datid,pid,usesysid,application_name,state,query,wait_event_type,wait_event,xact_start,query_start,backend_start,state_change,client_addr,client_hostname,client_port,backend_xid,backend_xmin,backend_type,ssl,sslversion,sslcipher,sslbits,ssl_client_dn,ssl_client_serial,ssl_issuer_dn,gss_auth,gss_princ,gss_enc,leader_pid,query_id,total_active_time,total_idle_in_transaction_time}',
   prosrc => 'pg_stat_get_activity' },
 { oid => '3318',
   descr => 'statistics: information about progress of backends running maintenance command',
diff --git a/src/include/pgstat.h b/src/include/pgstat.h
index ac28f813b4..8248e63931 100644
--- a/src/include/pgstat.h
+++ b/src/include/pgstat.h
@@ -469,10 +469,6 @@ extern void pgstat_report_connect(Oid dboid);
 	(pgStatBlockReadTime += (n))
 #define pgstat_count_buffer_write_time(n)							\
 	(pgStatBlockWriteTime += (n))
-#define pgstat_count_conn_active_time(n)							\
-	(pgStatActiveTime += (n))
-#define pgstat_count_conn_txn_idle_time(n)							\
-	(pgStatTransactionIdleTime += (n))
 
 extern PgStat_StatDBEntry *pgstat_fetch_stat_dbentry(Oid dbid);
 
@@ -673,12 +669,6 @@ extern PGDLLIMPORT PgStat_CheckpointerStats PendingCheckpointerStats;
 extern PGDLLIMPORT PgStat_Counter pgStatBlockReadTime;
 extern PGDLLIMPORT PgStat_Counter pgStatBlockWriteTime;
 
-/*
- * Updated by pgstat_count_conn_*_time macros, called by
- * pgstat_report_activity().
- */
-extern PGDLLIMPORT PgStat_Counter pgStatActiveTime;
-extern PGDLLIMPORT PgStat_Counter pgStatTransactionIdleTime;
 
 /* updated by the traffic cop and in errfinish() */
 extern PGDLLIMPORT SessionEndType pgStatSessionEndCause;
diff --git a/src/include/utils/backend_status.h b/src/include/utils/backend_status.h
index 7403bca25e..23660753fe 100644
--- a/src/include/utils/backend_status.h
+++ b/src/include/utils/backend_status.h
@@ -168,6 +168,10 @@ typedef struct PgBackendStatus
 
 	/* query identifier, optionally computed using post_parse_analyze_hook */
 	uint64		st_query_id;
+
+	/* time spent in respective states in usec */
+	int64		st_total_active_time;
+	int64		st_total_transaction_idle_time;
 } PgBackendStatus;
 
 
@@ -231,6 +235,12 @@ typedef struct PgBackendStatus
 	((before_changecount) == (after_changecount) && \
 	 ((before_changecount) & 1) == 0)
 
+/* Macros to identify the states for time accounting */
+#define PGSTAT_IS_ACTIVE(s) \
+	((s)->st_state == STATE_RUNNING || (s)->st_state == STATE_FASTPATH)
+#define PGSTAT_IS_IDLEINTRANSACTION(s) \
+	((s)->st_state == STATE_IDLEINTRANSACTION || \
+	 (s)->st_state == STATE_IDLEINTRANSACTION_ABORTED)
 
 /* ----------
  * LocalPgBackendStatus
@@ -305,6 +315,8 @@ extern const char *pgstat_get_backend_current_activity(int pid, bool checkUser);
 extern const char *pgstat_get_crashed_backend_activity(int pid, char *buffer,
 													   int buflen);
 extern uint64 pgstat_get_my_query_id(void);
+extern uint64 pgstat_get_my_active_time(void);
+extern uint64 pgstat_get_my_transaction_idle_time(void);
 
 
 /* ----------
diff --git a/src/test/regress/expected/rules.out b/src/test/regress/expected/rules.out
index 7ec3d2688f..4c9f5f8369 100644
--- a/src/test/regress/expected/rules.out
+++ b/src/test/regress/expected/rules.out
@@ -1758,8 +1758,10 @@ pg_stat_activity| SELECT s.datid,
     s.backend_xmin,
     s.query_id,
     s.query,
-    s.backend_type
-   FROM ((pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id)
+    s.backend_type,
+    s.total_active_time,
+    s.total_idle_in_transaction_time
+   FROM ((pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id, total_active_time, total_idle_in_transaction_time)
      LEFT JOIN pg_database d ON ((s.datid = d.oid)))
      LEFT JOIN pg_authid u ON ((s.usesysid = u.oid)));
 pg_stat_all_indexes| SELECT c.oid AS relid,
@@ -1871,7 +1873,7 @@ pg_stat_gssapi| SELECT s.pid,
     s.gss_auth AS gss_authenticated,
     s.gss_princ AS principal,
     s.gss_enc AS encrypted
-   FROM pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id)
+   FROM pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id, total_active_time, total_idle_in_transaction_time)
   WHERE (s.client_port IS NOT NULL);
 pg_stat_progress_analyze| SELECT s.pid,
     s.datid,
@@ -2052,7 +2054,7 @@ pg_stat_replication| SELECT s.pid,
     w.sync_priority,
     w.sync_state,
     w.reply_time
-   FROM ((pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id)
+   FROM ((pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id, total_active_time, total_idle_in_transaction_time)
      JOIN pg_stat_get_wal_senders() w(pid, state, sent_lsn, write_lsn, flush_lsn, replay_lsn, write_lag, flush_lag, replay_lag, sync_priority, sync_state, reply_time) ON ((s.pid = w.pid)))
      LEFT JOIN pg_authid u ON ((s.usesysid = u.oid)));
 pg_stat_replication_slots| SELECT s.slot_name,
@@ -2086,7 +2088,7 @@ pg_stat_ssl| SELECT s.pid,
     s.ssl_client_dn AS client_dn,
     s.ssl_client_serial AS client_serial,
     s.ssl_issuer_dn AS issuer_dn
-   FROM pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id)
+   FROM pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id, total_active_time, total_idle_in_transaction_time)
   WHERE (s.client_port IS NOT NULL);
 pg_stat_subscription| SELECT su.oid AS subid,
     su.subname,
#29Aleksander Alekseev
aleksander@timescale.com
In reply to: Sergey Dudoladov (#28)
Re: Add connection active, idle time to pg_stat_activity

Rafia, Sergey,

Many thanks for working on this!

I have incorporated most of the suggestions into the patch. I have also rebased and tested the patch on top of the current master

I noticed that this patch is marked as "Needs Review" and decided to
take a look.

I believe there is a bug in the implementation. Here is what I did:

```
57033 (master) =# select * from pg_stat_activity where pid = 57033;
...
total_active_time | 9.128
total_idle_in_transaction_time | 0

57033 (master) =# select * from pg_stat_activity where pid = 57033;
...
total_active_time | 10.626
total_idle_in_transaction_time | 0

57033 (master) =# BEGIN;
57033 (master) =# select * from pg_stat_activity where pid = 57033;
...
total_active_time | 17.443
total_idle_in_transaction_time | 2314.703

57033 (master) =# select * from pg_stat_activity where pid = 57033;
...
total_active_time | 2514.635
total_idle_in_transaction_time | 2314.703

57033 (master) =# COMMIT;
57033 (master) =# select * from pg_stat_activity where pid = 57033;
...
total_active_time | 22.048
total_idle_in_transaction_time | 7300.911
```

So it looks like total_active_time tracks seconds when a user executes
single expressions and milliseconds when running a transaction. It
should always track milliseconds.

Please use `git format-patch` for the next patch and provide a commit
message, as it was previously pointed out by Bharath. Please specify
the list of the authors and reviewers and add a note about
incrementing the catalog version.

--
Best regards,
Aleksander Alekseev

#30Aleksander Alekseev
aleksander@timescale.com
In reply to: Aleksander Alekseev (#29)
Re: Add connection active, idle time to pg_stat_activity

Hi again,

57033 (master) =# select * from pg_stat_activity where pid = 57033;
...
total_active_time | 2514.635
total_idle_in_transaction_time | 2314.703

57033 (master) =# COMMIT;
57033 (master) =# select * from pg_stat_activity where pid = 57033;
...
total_active_time | 22.048
total_idle_in_transaction_time | 7300.911
```

My previous message was wrong, total_active_time doesn't track
seconds. I got confused by the name of this column. Still I'm pretty
confident it shouldn't decrease.

--
Best regards,
Aleksander Alekseev

#31torikoshia
torikoshia@oss.nttdata.com
In reply to: Sergey Dudoladov (#28)
Re: Add connection active, idle time to pg_stat_activity

Rafia, Sergey,

+1 for adding the total_active_time and total_idle_in_transaction_time
to pg_stat_activity.

I reviewed the patch and here are some comments.

+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>total_active_time</structfield> <type>double 
precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in 
<literal>active</literal> and
+       <literal>fastpath</literal> states.

Is 'fastpath' an abbreviation of 'fastpath function call'?
If so, I feel it's clearer '<literal>fastpath function call</literal>'
than '<literal>fastpath</literal>'.

+extern uint64 pgstat_get_my_active_time(void);
+extern uint64 pgstat_get_my_transaction_idle_time(void);

Are these functions necessary?
It seems they are not called from anywhere, doesn't it?

--
Regards,

--
Atsushi Torikoshi
NTT DATA CORPORATION

#32Sergey Dudoladov
sergey.dudoladov@gmail.com
In reply to: torikoshia (#31)
1 attachment(s)
Re: Add connection active, idle time to pg_stat_activity

Hello,

I have addressed the reviews.

@Aleksander Alekseev thanks for reporting the issue. I have altered
the patch to respect the behavior of pg_stat_activity, specifically
[1]: https://www.postgresql.org/docs/14/monitoring-stats.html#MONITORING-STATS-VIEWS

Another important point is that when a server process is asked to display any of these statistics,
it first fetches the most recent report emitted by the collector process and then continues to use this snapshot
for all statistical views and functions until the end of its current transaction.
So the statistics will show static information as long as you continue the current transaction.

For the patch it means no computing of real-time values of
total_*_time. Here is an example to illustrate the new behavior:

=# begin;

=*# select total_active_time, total_idle_in_transaction_time from
pg_stat_activity where pid = pg_backend_pid();
total_active_time | total_idle_in_transaction_time
-------------------+--------------------------------
0.124 | 10505.098

postgres=*# select pg_sleep(10);

postgres=*# select total_active_time, total_idle_in_transaction_time
from pg_stat_activity where pid = pg_backend_pid();
total_active_time | total_idle_in_transaction_time
-------------------+--------------------------------
0.124 | 10505.098

postgres=*# commit;

postgres=# select total_active_time, total_idle_in_transaction_time
from pg_stat_activity where pid = pg_backend_pid();
total_active_time | total_idle_in_transaction_time
-------------------+--------------------------------
10015.796 | 29322.831

[1]: https://www.postgresql.org/docs/14/monitoring-stats.html#MONITORING-STATS-VIEWS

Regards,
Sergey

Attachments:

0001-pg_stat_activity-add-total_active_time-and-total_idl.patchtext/x-patch; charset=US-ASCII; name=0001-pg_stat_activity-add-total_active_time-and-total_idl.patchDownload
From b5298301a3f5223bd78c519ddcddbd1bec9cf000 Mon Sep 17 00:00:00 2001
From: Sergey Dudoladov <sergey.dudoladov@gmail.com>
Date: Wed, 20 Apr 2022 23:47:37 +0200
Subject: [PATCH] pg_stat_activity: add 'total_active_time' and
 'total_idle_in_transaction_time'

catversion bump because of the change in the contents of pg_stat_activity

Author: Sergey Dudoladov, based on the initial version by Rafia Sabih

Reviewed-by: Aleksander Alekseev, Bertrand Drouvot, and Atsushi Torikoshi

Discussion: https://www.postgresql.org/message-id/flat/CA%2BFpmFcJF0vwi-SWW0wYO-c-FbhyawLq4tCpRDCJJ8Bq%3Dja-gA%40mail.gmail.com
---
 doc/src/sgml/monitoring.sgml                | 20 +++++++++++++
 src/backend/catalog/system_views.sql        |  4 ++-
 src/backend/utils/activity/backend_status.c | 33 ++++++++++++++++-----
 src/backend/utils/adt/pgstatfuncs.c         |  8 ++++-
 src/include/catalog/pg_proc.dat             |  6 ++--
 src/include/pgstat.h                        | 10 -------
 src/include/utils/backend_status.h          | 10 +++++++
 src/test/regress/expected/rules.out         | 12 ++++----
 8 files changed, 75 insertions(+), 28 deletions(-)

diff --git a/doc/src/sgml/monitoring.sgml b/doc/src/sgml/monitoring.sgml
index 7dbbab6f5c..943927fe34 100644
--- a/doc/src/sgml/monitoring.sgml
+++ b/doc/src/sgml/monitoring.sgml
@@ -979,6 +979,26 @@ postgres   27093  0.0  0.0  30096  2752 ?        Ss   11:34   0:00 postgres: ser
        additional types.
       </para></entry>
      </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>total_active_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in <literal>active</literal> and
+       <literal>fastpath function call</literal> states.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>total_idle_in_transaction_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in <literal>idle in transaction</literal>
+       and <literal>idle in transaction (aborted)</literal> states.
+      </para></entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
diff --git a/src/backend/catalog/system_views.sql b/src/backend/catalog/system_views.sql
index f369b1fc14..2ec6ea2304 100644
--- a/src/backend/catalog/system_views.sql
+++ b/src/backend/catalog/system_views.sql
@@ -864,7 +864,9 @@ CREATE VIEW pg_stat_activity AS
             s.backend_xmin,
             S.query_id,
             S.query,
-            S.backend_type
+            S.backend_type,
+            S.total_active_time,
+            S.total_idle_in_transaction_time
     FROM pg_stat_get_activity(NULL) AS S
         LEFT JOIN pg_database AS D ON (S.datid = D.oid)
         LEFT JOIN pg_authid AS U ON (S.usesysid = U.oid);
diff --git a/src/backend/utils/activity/backend_status.c b/src/backend/utils/activity/backend_status.c
index c7ed1e6d7a..8fe2929fba 100644
--- a/src/backend/utils/activity/backend_status.c
+++ b/src/backend/utils/activity/backend_status.c
@@ -336,6 +336,8 @@ pgstat_bestart(void)
 	lbeentry.st_activity_start_timestamp = 0;
 	lbeentry.st_state_start_timestamp = 0;
 	lbeentry.st_xact_start_timestamp = 0;
+	lbeentry.st_total_active_time = 0;
+	lbeentry.st_total_transaction_idle_time = 0;
 	lbeentry.st_databaseid = MyDatabaseId;
 
 	/* We have userid for client-backends, wal-sender and bgworker processes */
@@ -524,6 +526,8 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 	TimestampTz start_timestamp;
 	TimestampTz current_timestamp;
 	int			len = 0;
+	int64		active_time_diff = 0;
+	int64		transaction_idle_time_diff = 0;
 
 	TRACE_POSTGRESQL_STATEMENT_STATUS(cmd_str);
 
@@ -550,6 +554,9 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 			beentry->st_xact_start_timestamp = 0;
 			beentry->st_query_id = UINT64CONST(0);
 			proc->wait_event_info = 0;
+
+			beentry->st_total_active_time = 0;
+			beentry->st_total_transaction_idle_time = 0;
 			PGSTAT_END_WRITE_ACTIVITY(beentry);
 		}
 		return;
@@ -575,24 +582,31 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 	 * If the state has changed from "active" or "idle in transaction",
 	 * calculate the duration.
 	 */
-	if ((beentry->st_state == STATE_RUNNING ||
-		 beentry->st_state == STATE_FASTPATH ||
-		 beentry->st_state == STATE_IDLEINTRANSACTION ||
-		 beentry->st_state == STATE_IDLEINTRANSACTION_ABORTED) &&
+	if ((PGSTAT_IS_ACTIVE(beentry) || PGSTAT_IS_IDLEINTRANSACTION(beentry)) &&
 		state != beentry->st_state)
 	{
 		long		secs;
 		int			usecs;
+		int64		usecs_diff;
 
 		TimestampDifference(beentry->st_state_start_timestamp,
 							current_timestamp,
 							&secs, &usecs);
+		usecs_diff = secs * 1000000 + usecs;
 
-		if (beentry->st_state == STATE_RUNNING ||
-			beentry->st_state == STATE_FASTPATH)
-			pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 + usecs);
+		/*
+		 * We update per-backend st_total_active_time and st_total_transaction_idle_time
+		 * separately from pgStatActiveTime and pgStatTransactionIdleTime
+		 * used in pg_stat_database to provide per-DB statistics because
+		 * 1. Changing the former values implies modifying beentry and thus
+		 * have to be wrapped into PGSTAT_*_WRITE_ACTIVITY macros (see below).
+		 * 2. The latter values are reset to 0 once the data has been sent
+		 * to the statistics collector.
+		 */
+		if (PGSTAT_IS_ACTIVE(beentry))
+			active_time_diff = usecs_diff;
 		else
-			pgstat_count_conn_txn_idle_time((PgStat_Counter) secs * 1000000 + usecs);
+			transaction_idle_time_diff = usecs_diff;
 	}
 
 	/*
@@ -618,6 +632,9 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 		beentry->st_activity_start_timestamp = start_timestamp;
 	}
 
+	beentry->st_total_active_time += active_time_diff;
+	beentry->st_total_transaction_idle_time += transaction_idle_time_diff;
+
 	PGSTAT_END_WRITE_ACTIVITY(beentry);
 }
 
diff --git a/src/backend/utils/adt/pgstatfuncs.c b/src/backend/utils/adt/pgstatfuncs.c
index d9e2a79382..a213211f6a 100644
--- a/src/backend/utils/adt/pgstatfuncs.c
+++ b/src/backend/utils/adt/pgstatfuncs.c
@@ -536,7 +536,7 @@ pg_stat_get_progress_info(PG_FUNCTION_ARGS)
 Datum
 pg_stat_get_activity(PG_FUNCTION_ARGS)
 {
-#define PG_STAT_GET_ACTIVITY_COLS	30
+#define PG_STAT_GET_ACTIVITY_COLS	32
 	int			num_backends = pgstat_fetch_stat_numbackends();
 	int			curr_backend;
 	int			pid = PG_ARGISNULL(0) ? -1 : PG_GETARG_INT32(0);
@@ -856,6 +856,10 @@ pg_stat_get_activity(PG_FUNCTION_ARGS)
 				nulls[29] = true;
 			else
 				values[29] = UInt64GetDatum(beentry->st_query_id);
+
+			/* convert to msec */
+			values[30] = Float8GetDatum(beentry->st_total_active_time / 1000.0);
+			values[31] = Float8GetDatum(beentry->st_total_transaction_idle_time / 1000.0);
 		}
 		else
 		{
@@ -884,6 +888,8 @@ pg_stat_get_activity(PG_FUNCTION_ARGS)
 			nulls[27] = true;
 			nulls[28] = true;
 			nulls[29] = true;
+			nulls[30] = true;
+			nulls[31] = true;
 		}
 
 		tuplestore_putvalues(rsinfo->setResult, rsinfo->setDesc, values, nulls);
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index 2e41f4d9e8..bcd106897e 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -5340,9 +5340,9 @@
   proname => 'pg_stat_get_activity', prorows => '100', proisstrict => 'f',
   proretset => 't', provolatile => 's', proparallel => 'r',
   prorettype => 'record', proargtypes => 'int4',
-  proallargtypes => '{int4,oid,int4,oid,text,text,text,text,text,timestamptz,timestamptz,timestamptz,timestamptz,inet,text,int4,xid,xid,text,bool,text,text,int4,text,numeric,text,bool,text,bool,int4,int8}',
-  proargmodes => '{i,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o}',
-  proargnames => '{pid,datid,pid,usesysid,application_name,state,query,wait_event_type,wait_event,xact_start,query_start,backend_start,state_change,client_addr,client_hostname,client_port,backend_xid,backend_xmin,backend_type,ssl,sslversion,sslcipher,sslbits,ssl_client_dn,ssl_client_serial,ssl_issuer_dn,gss_auth,gss_princ,gss_enc,leader_pid,query_id}',
+  proallargtypes => '{int4,oid,int4,oid,text,text,text,text,text,timestamptz,timestamptz,timestamptz,timestamptz,inet,text,int4,xid,xid,text,bool,text,text,int4,text,numeric,text,bool,text,bool,int4,int8,float8,float8}',
+  proargmodes => '{i,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o}',
+  proargnames => '{pid,datid,pid,usesysid,application_name,state,query,wait_event_type,wait_event,xact_start,query_start,backend_start,state_change,client_addr,client_hostname,client_port,backend_xid,backend_xmin,backend_type,ssl,sslversion,sslcipher,sslbits,ssl_client_dn,ssl_client_serial,ssl_issuer_dn,gss_auth,gss_princ,gss_enc,leader_pid,query_id,total_active_time,total_idle_in_transaction_time}',
   prosrc => 'pg_stat_get_activity' },
 { oid => '3318',
   descr => 'statistics: information about progress of backends running maintenance command',
diff --git a/src/include/pgstat.h b/src/include/pgstat.h
index ac28f813b4..8248e63931 100644
--- a/src/include/pgstat.h
+++ b/src/include/pgstat.h
@@ -469,10 +469,6 @@ extern void pgstat_report_connect(Oid dboid);
 	(pgStatBlockReadTime += (n))
 #define pgstat_count_buffer_write_time(n)							\
 	(pgStatBlockWriteTime += (n))
-#define pgstat_count_conn_active_time(n)							\
-	(pgStatActiveTime += (n))
-#define pgstat_count_conn_txn_idle_time(n)							\
-	(pgStatTransactionIdleTime += (n))
 
 extern PgStat_StatDBEntry *pgstat_fetch_stat_dbentry(Oid dbid);
 
@@ -673,12 +669,6 @@ extern PGDLLIMPORT PgStat_CheckpointerStats PendingCheckpointerStats;
 extern PGDLLIMPORT PgStat_Counter pgStatBlockReadTime;
 extern PGDLLIMPORT PgStat_Counter pgStatBlockWriteTime;
 
-/*
- * Updated by pgstat_count_conn_*_time macros, called by
- * pgstat_report_activity().
- */
-extern PGDLLIMPORT PgStat_Counter pgStatActiveTime;
-extern PGDLLIMPORT PgStat_Counter pgStatTransactionIdleTime;
 
 /* updated by the traffic cop and in errfinish() */
 extern PGDLLIMPORT SessionEndType pgStatSessionEndCause;
diff --git a/src/include/utils/backend_status.h b/src/include/utils/backend_status.h
index 7403bca25e..c904714c17 100644
--- a/src/include/utils/backend_status.h
+++ b/src/include/utils/backend_status.h
@@ -168,6 +168,10 @@ typedef struct PgBackendStatus
 
 	/* query identifier, optionally computed using post_parse_analyze_hook */
 	uint64		st_query_id;
+
+	/* time spent in respective states in usec */
+	int64		st_total_active_time;
+	int64		st_total_transaction_idle_time;
 } PgBackendStatus;
 
 
@@ -231,6 +235,12 @@ typedef struct PgBackendStatus
 	((before_changecount) == (after_changecount) && \
 	 ((before_changecount) & 1) == 0)
 
+/* Macros to identify the states for time accounting */
+#define PGSTAT_IS_ACTIVE(s) \
+	((s)->st_state == STATE_RUNNING || (s)->st_state == STATE_FASTPATH)
+#define PGSTAT_IS_IDLEINTRANSACTION(s) \
+	((s)->st_state == STATE_IDLEINTRANSACTION || \
+	 (s)->st_state == STATE_IDLEINTRANSACTION_ABORTED)
 
 /* ----------
  * LocalPgBackendStatus
diff --git a/src/test/regress/expected/rules.out b/src/test/regress/expected/rules.out
index 7ec3d2688f..4c9f5f8369 100644
--- a/src/test/regress/expected/rules.out
+++ b/src/test/regress/expected/rules.out
@@ -1758,8 +1758,10 @@ pg_stat_activity| SELECT s.datid,
     s.backend_xmin,
     s.query_id,
     s.query,
-    s.backend_type
-   FROM ((pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id)
+    s.backend_type,
+    s.total_active_time,
+    s.total_idle_in_transaction_time
+   FROM ((pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id, total_active_time, total_idle_in_transaction_time)
      LEFT JOIN pg_database d ON ((s.datid = d.oid)))
      LEFT JOIN pg_authid u ON ((s.usesysid = u.oid)));
 pg_stat_all_indexes| SELECT c.oid AS relid,
@@ -1871,7 +1873,7 @@ pg_stat_gssapi| SELECT s.pid,
     s.gss_auth AS gss_authenticated,
     s.gss_princ AS principal,
     s.gss_enc AS encrypted
-   FROM pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id)
+   FROM pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id, total_active_time, total_idle_in_transaction_time)
   WHERE (s.client_port IS NOT NULL);
 pg_stat_progress_analyze| SELECT s.pid,
     s.datid,
@@ -2052,7 +2054,7 @@ pg_stat_replication| SELECT s.pid,
     w.sync_priority,
     w.sync_state,
     w.reply_time
-   FROM ((pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id)
+   FROM ((pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id, total_active_time, total_idle_in_transaction_time)
      JOIN pg_stat_get_wal_senders() w(pid, state, sent_lsn, write_lsn, flush_lsn, replay_lsn, write_lag, flush_lag, replay_lag, sync_priority, sync_state, reply_time) ON ((s.pid = w.pid)))
      LEFT JOIN pg_authid u ON ((s.usesysid = u.oid)));
 pg_stat_replication_slots| SELECT s.slot_name,
@@ -2086,7 +2088,7 @@ pg_stat_ssl| SELECT s.pid,
     s.ssl_client_dn AS client_dn,
     s.ssl_client_serial AS client_serial,
     s.ssl_issuer_dn AS issuer_dn
-   FROM pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id)
+   FROM pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, backend_type, ssl, sslversion, sslcipher, sslbits, ssl_client_dn, ssl_client_serial, ssl_issuer_dn, gss_auth, gss_princ, gss_enc, leader_pid, query_id, total_active_time, total_idle_in_transaction_time)
   WHERE (s.client_port IS NOT NULL);
 pg_stat_subscription| SELECT su.oid AS subid,
     su.subname,
-- 
2.32.0

#33Aleksander Alekseev
aleksander@timescale.com
In reply to: Sergey Dudoladov (#32)
Re: Add connection active, idle time to pg_stat_activity

Hi Sergey,

@Aleksander Alekseev thanks for reporting the issue. I have altered
the patch to respect the behavior of pg_stat_activity, specifically
[1]

Another important point is that when a server process is asked to

display any of these statistics,

it first fetches the most recent report emitted by the collector

process and then continues to use this snapshot

for all statistical views and functions until the end of its current

transaction.

So the statistics will show static information as long as you continue

the current transaction.

For the patch it means no computing of real-time values of
total_*_time. Here is an example to illustrate the new behavior:

=# begin;

=*# select total_active_time, total_idle_in_transaction_time from
pg_stat_activity where pid = pg_backend_pid();
total_active_time | total_idle_in_transaction_time
-------------------+--------------------------------
0.124 | 10505.098

postgres=*# select pg_sleep(10);

postgres=*# select total_active_time, total_idle_in_transaction_time
from pg_stat_activity where pid = pg_backend_pid();
total_active_time | total_idle_in_transaction_time
-------------------+--------------------------------
0.124 | 10505.098

postgres=*# commit;

postgres=# select total_active_time, total_idle_in_transaction_time
from pg_stat_activity where pid = pg_backend_pid();
total_active_time | total_idle_in_transaction_time
-------------------+--------------------------------
10015.796 | 29322.831

[1]

https://www.postgresql.org/docs/14/monitoring-stats.html#MONITORING-STATS-VIEWS

This looks reasonable.

What concerns me though is the fact that total_idle_in_transaction_time for
given session doesn't seem to updated from the perspective of another
session:

```
session1 (78376) =# BEGIN;
session1 (78376) =# select * from pg_stat_activity where pid = 78376;
...
total_active_time | 40.057
total_idle_in_transaction_time | 34322.171

session1 (78376) =# select * from pg_stat_activity where pid = 78376;
...
total_active_time | 40.057
total_idle_in_transaction_time | 34322.171

session2 (78382) =# select * from pg_stat_activity where pid = 78376;
...
total_active_time | 46.908
total_idle_in_transaction_time | 96933.518

session2 (78382) =# select * from pg_stat_activity where pid = 78376;
...
total_active_time | 46.908
total_idle_in_transaction_time | 96933.518 <--- doesn't change!

session1 (78376) =# COMMIT;
session1 (78376) =# select * from pg_stat_activity where pid = 78376;
...
total_active_time | 47.16
total_idle_in_transaction_time | 218422.143

session2 (78382) =# select * from pg_stat_activity where pid = 78376;
total_active_time | 50.631
total_idle_in_transaction_time | 218422.143
```

This is consistent with the current documentation:

Each individual server process transmits new statistical counts to the

collector just before going idle; so a query or transaction still in
progress does not affect the displayed totals.

But it makes me wonder if there will be a lot of use of
total_idle_in_transaction_time and if the patch should actually alter this
behavior.

Thoughts?

--
Best regards,
Aleksander Alekseev

#34Aleksander Alekseev
aleksander@timescale.com
In reply to: Aleksander Alekseev (#33)
Re: Add connection active, idle time to pg_stat_activity

Hi hackers,

All in all the patch seems to be in good shape.

This is consistent with the current documentation:

Each individual server process transmits new statistical counts to the collector just before going idle; so a query or transaction still in progress does not affect the displayed totals.

But it makes me wonder if there will be a lot of use of total_idle_in_transaction_time and if the patch should actually alter this behavior.

Thoughts?

On second thought, this is arguably out of scope of this particular
patch and this particular discussion. In any case, having some stats
is better than none.

I'm going to change the status of the patch to "Ready for Committer"
in a short time unless anyone has a second opinion.

--
Best regards,
Aleksander Alekseev

#35Sergey Dudoladov
sergey.dudoladov@gmail.com
In reply to: Aleksander Alekseev (#34)
Re: Add connection active, idle time to pg_stat_activity

Hello hackers,

Is there anything we can do to facilitate merging of this patch ?
It has been in the "ready-for-commiter" state for 3 commitfests in a row now.

We would appreciate if the patch makes it to version 16: the need to
monitor idle-in-transaction connections is very real for us.

Regards,
Sergey Dudoladov

#36Andres Freund
andres@anarazel.de
In reply to: Sergey Dudoladov (#32)
Re: Add connection active, idle time to pg_stat_activity

Hi,

On 2022-07-21 18:22:51 +0200, Sergey Dudoladov wrote:

From b5298301a3f5223bd78c519ddcddbd1bec9cf000 Mon Sep 17 00:00:00 2001
From: Sergey Dudoladov <sergey.dudoladov@gmail.com>
Date: Wed, 20 Apr 2022 23:47:37 +0200
Subject: [PATCH] pg_stat_activity: add 'total_active_time' and
'total_idle_in_transaction_time'

catversion bump because of the change in the contents of pg_stat_activity

Author: Sergey Dudoladov, based on the initial version by Rafia Sabih

Reviewed-by: Aleksander Alekseev, Bertrand Drouvot, and Atsushi Torikoshi

Discussion: /messages/by-id/CA+FpmFcJF0vwi-SWW0wYO-c-FbhyawLq4tCpRDCJJ8Bq=ja-gA@mail.gmail.com

Isn't this patch breaking pg_stat_database? You removed
pgstat_count_conn_active_time() etc and the declaration for pgStatActiveTime /
pgStatTransactionIdleTime (but left the definition in pgstat_database.c), but
didn't replace it with anything afaics.

Separately from that, I'm a bit worried about starting to add accumulative
counters to pg_stat_activity. It's already gotten hard to use interactively
due to the number of columns - and why stop with the columns you suggest? Why
not show e.g. the total number of reads/writes, tuples inserted / deleted,
etc. as well?

I wonder if we shouldn't add a pg_stat_session or such for per-connection
counters that show not the current state, but accumulated per-session state.

Greetings,

Andres Freund

#37David G. Johnston
david.g.johnston@gmail.com
In reply to: Andres Freund (#36)
Re: Add connection active, idle time to pg_stat_activity

On Tue, Nov 8, 2022 at 6:56 PM Andres Freund <andres@anarazel.de> wrote:

Separately from that, I'm a bit worried about starting to add accumulative
counters to pg_stat_activity. It's already gotten hard to use interactively
due to the number of columns - and why stop with the columns you suggest?
Why
not show e.g. the total number of reads/writes, tuples inserted / deleted,
etc. as well?

I wonder if we shouldn't add a pg_stat_session or such for per-connection
counters that show not the current state, but accumulated per-session
state.

I would much rather go down this route than make the existing table wider.

pg_stat_activity_state_duration (this patch) [the table - for a given
backend - would be empty if track_activities is off]
pg_stat_activity_bandwidth_usage (if someone feels like implementing the
other items you mention)

I'm not really buying into the idea of having multiple states sum their
times together. I would expect one column per state. Actually two,
because I also suggest that not only is the duration recorded, but a
counter be incremented each time a given state becomes the currently active
state. Seems like having access to a divisor of some form may be useful.

So 10 columns of data plus pid to join back to pg_stat_activity proper.

David J.

#38Andres Freund
andres@anarazel.de
In reply to: David G. Johnston (#37)
Re: Add connection active, idle time to pg_stat_activity

On 2022-11-08 19:25:27 -0700, David G. Johnston wrote:

Actually two, because I also suggest that not only is the duration recorded,
but a counter be incremented each time a given state becomes the currently
active state. Seems like having access to a divisor of some form may be
useful.

What for?

#39David G. Johnston
david.g.johnston@gmail.com
In reply to: Andres Freund (#38)
Re: Add connection active, idle time to pg_stat_activity

On Tue, Nov 8, 2022 at 7:37 PM Andres Freund <andres@anarazel.de> wrote:

On 2022-11-08 19:25:27 -0700, David G. Johnston wrote:

Actually two, because I also suggest that not only is the duration

recorded,

but a counter be incremented each time a given state becomes the

currently

active state. Seems like having access to a divisor of some form may be
useful.

What for?

Because 5 hours of idle-in-transaction time in a single block means
something different than the same 5 hours accumulated across 300 mini-idles.

David J.

#40Sergey Dudoladov
sergey.dudoladov@gmail.com
In reply to: David G. Johnston (#39)
1 attachment(s)
Re: Add connection active, idle time to pg_stat_activity

Hello hackers,

I've sketched the first version of a patch to add pg_stat_session.
Please review this early version.

Regards,
Sergey.

Attachments:

0001-Add-pg_stat_session.patchtext/x-patch; charset=US-ASCII; name=0001-Add-pg_stat_session.patchDownload
From 31f781ecd69fc42aaadd9bcdbebaf8f72449946c Mon Sep 17 00:00:00 2001
From: Sergey Dudoladov <sergey.dudoladov@gmail.com>
Date: Tue, 22 Nov 2022 09:23:32 +0100
Subject: [PATCH] Add pg_stat_session

Author: Sergey Dudoladov

Adds pg_stat_session view to track statistics accumulated during
 lifetime of a session.

Reviewed-by: Aleksander Alekseev, Bertrand Drouvot, and Atsushi
Torikoshi

Discussion:
https://www.postgresql.org/message-id/flat/CA%2BFpmFcJF0vwi-SWW0wYO-c-FbhyawLq4tCpRDCJJ8Bq%3Dja-gA%40mail.gmail.com
---
 doc/src/sgml/monitoring.sgml                | 153 ++++++++++++++++++++
 src/backend/catalog/system_views.sql        |  15 ++
 src/backend/utils/activity/backend_status.c |  58 ++++++--
 src/backend/utils/adt/pgstatfuncs.c         |  70 +++++++++
 src/include/catalog/pg_proc.dat             |   9 ++
 src/include/utils/backend_status.h          |  37 +++++
 src/test/regress/expected/rules.out         |  12 ++
 7 files changed, 345 insertions(+), 9 deletions(-)

diff --git a/doc/src/sgml/monitoring.sgml b/doc/src/sgml/monitoring.sgml
index 1756f1a4b6..38cc29810a 100644
--- a/doc/src/sgml/monitoring.sgml
+++ b/doc/src/sgml/monitoring.sgml
@@ -414,6 +414,20 @@ postgres   27093  0.0  0.0  30096  2752 ?        Ss   11:34   0:00 postgres: ser
        See <xref linkend='copy-progress-reporting'/>.
       </entry>
      </row>
+
+     <row>
+      <entry>
+       <structname>pg_stat_session</structname>
+       <indexterm><primary>pg_stat_session</primary></indexterm>
+      </entry>
+      <entry>
+       One row per server process, showing information related to
+       the currently accumulated activity of that process, such as time spent in
+       a certain state.
+       See <link linkend="monitoring-pg-stat-session-view">
+       <structname>pg_stat_session</structname></link> for details.
+      </entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
@@ -5315,6 +5329,129 @@ SELECT pid, wait_event_type, wait_event FROM pg_stat_activity WHERE wait_event i
    </tgroup>
   </table>
 
+  <table id="monitoring-pg-stat-session-view" xreflabel="pg_stat_session">
+   <title><structname>pg_stat_session</structname> View</title>
+   <tgroup cols="1">
+    <thead>
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       Column Type
+      </para>
+      <para>
+       Description
+      </para></entry>
+     </row>
+    </thead>
+
+    <tbody>
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>pid</structfield> <type>integer</type>
+      </para>
+      <para>
+       Process ID of this backend.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>total_running_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in the <literal>running</literal> state.
+      </para></entry>
+     </row>
+
+    <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>total_running_count</structfield> <type>bigint</type>
+      </para>
+      <para>
+       Number of times this backend switched to the <literal>running</literal> state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>total_idle_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in the <literal>idle</literal> state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>total_idle_count</structfield> <type>bigint</type>
+      </para>
+      <para>
+       Number of times this backend switched to the <literal>idle</literal> state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>total_transaction_idle_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in the <literal>idle in transaction</literal>
+       state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>total_transaction_idle_count</structfield> <type>bigint</type>
+      </para>
+      <para>
+       Number of times this backend switched to the <literal>idle in transaction</literal>
+       state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>total_transaction_idle_aborted_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in the <literal>idle in transaction (aborted)</literal> 
+       state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>total_transaction_idle_aborted_count</structfield> <type>bigint</type>
+      </para>
+      <para>
+       Number of times this backend switched to the <literal>idle in transaction (aborted)</literal>
+       state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>total_fastpath_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in the <literal>fastpath</literal> state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>total_fastpath_count</structfield> <type>bigint</type>
+      </para>
+      <para>
+       Number of times this backend switched to the <literal>fastpath</literal>
+       state.
+      </para></entry>
+     </row>
+
+    </tbody>
+   </tgroup>
+  </table>
+
  </sect2>
 
  <sect2 id="monitoring-stats-functions">
@@ -5382,6 +5519,22 @@ SELECT pid, wait_event_type, wait_event FROM pg_stat_activity WHERE wait_event i
        </para></entry>
       </row>
 
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>pg_stat_get_session</primary>
+        </indexterm>
+        <function>pg_stat_get_session</function> ( <type>integer</type> )
+        <returnvalue>setof record</returnvalue>
+       </para>
+       <para>
+        Returns a record of information about the backend with the specified
+        process ID, or one record for each active backend in the system
+        if <literal>NULL</literal> is specified.  The fields returned are a
+        subset of those in the <structname>pg_stat_session</structname> view.
+       </para></entry>
+      </row>
+
       <row>
        <entry role="func_table_entry"><para role="func_signature">
         <indexterm>
diff --git a/src/backend/catalog/system_views.sql b/src/backend/catalog/system_views.sql
index 8608e3fa5b..8f68a6ea00 100644
--- a/src/backend/catalog/system_views.sql
+++ b/src/backend/catalog/system_views.sql
@@ -870,6 +870,21 @@ CREATE VIEW pg_stat_activity AS
         LEFT JOIN pg_database AS D ON (S.datid = D.oid)
         LEFT JOIN pg_authid AS U ON (S.usesysid = U.oid);
 
+CREATE VIEW pg_stat_session AS
+    SELECT
+            s.pid,
+            s.total_running_time,
+            s.total_running_count,
+            s.total_idle_time,
+            s.total_idle_count,
+            s.total_transaction_idle_time,
+            s.total_transaction_idle_count,
+            s.total_transaction_idle_aborted_time,
+            s.total_transaction_idle_aborted_count,
+            s.total_fastpath_time,
+            s.total_fastpath_count
+     FROM pg_stat_get_session(NULL) as s;
+
 CREATE VIEW pg_stat_replication AS
     SELECT
             S.pid,
diff --git a/src/backend/utils/activity/backend_status.c b/src/backend/utils/activity/backend_status.c
index 608d01ea0d..804b91cf9f 100644
--- a/src/backend/utils/activity/backend_status.c
+++ b/src/backend/utils/activity/backend_status.c
@@ -338,6 +338,8 @@ pgstat_bestart(void)
 	lbeentry.st_xact_start_timestamp = 0;
 	lbeentry.st_databaseid = MyDatabaseId;
 
+	MemSet(&lbeentry.st_session, 0, sizeof(lbeentry.st_session));
+
 	/* We have userid for client-backends, wal-sender and bgworker processes */
 	if (lbeentry.st_backendType == B_BACKEND
 		|| lbeentry.st_backendType == B_WAL_SENDER
@@ -525,6 +527,9 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 	TimestampTz current_timestamp;
 	int			len = 0;
 
+	PgBackendSessionStatus st_session_diff;
+	MemSet(&st_session_diff, 0, sizeof(st_session_diff));
+
 	TRACE_POSTGRESQL_STATEMENT_STATUS(cmd_str);
 
 	if (!beentry)
@@ -550,6 +555,7 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 			beentry->st_xact_start_timestamp = 0;
 			beentry->st_query_id = UINT64CONST(0);
 			proc->wait_event_info = 0;
+			MemSet(&beentry->st_session, 0, sizeof(beentry->st_session));
 			PGSTAT_END_WRITE_ACTIVITY(beentry);
 		}
 		return;
@@ -572,27 +578,46 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 	current_timestamp = GetCurrentTimestamp();
 
 	/*
-	 * If the state has changed from "active" or "idle in transaction",
-	 * calculate the duration.
+	 * If the state has changed, update per-database and per-session counters.
 	 */
-	if ((beentry->st_state == STATE_RUNNING ||
-		 beentry->st_state == STATE_FASTPATH ||
-		 beentry->st_state == STATE_IDLEINTRANSACTION ||
-		 beentry->st_state == STATE_IDLEINTRANSACTION_ABORTED) &&
+	if ((PGSTAT_IS_ACTIVE(beentry) ||
+		 PGSTAT_IS_IDLEINTRANSACTION(beentry) ||
+		 PGSTAT_IS_IDLEINTRANSACTION_ABORTED(beentry) || 
+		 PGSTAT_IS_IDLE(beentry)) &&
 		state != beentry->st_state)
 	{
 		long		secs;
 		int			usecs;
+		int64		usecs_diff;
 
 		TimestampDifference(beentry->st_state_start_timestamp,
 							current_timestamp,
 							&secs, &usecs);
+		usecs_diff = secs * 1000000 + usecs;
 
-		if (beentry->st_state == STATE_RUNNING ||
-			beentry->st_state == STATE_FASTPATH)
+		/* Keep statistics for pg_stat_database intact */
+		if (PGSTAT_IS_ACTIVE(beentry))
 			pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 + usecs);
-		else
+		else if (PGSTAT_IS_IDLEINTRANSACTION(beentry) ||
+				 PGSTAT_IS_IDLEINTRANSACTION_ABORTED(beentry))
 			pgstat_count_conn_txn_idle_time((PgStat_Counter) secs * 1000000 + usecs);
+
+		if (PGSTAT_IS_RUNNING(beentry)) {
+			st_session_diff.total_running_time = usecs_diff;
+			st_session_diff.total_running_count += 1;
+		} else if (PGSTAT_IS_IDLE(beentry)){
+			st_session_diff.total_idle_time = usecs_diff;
+			st_session_diff.total_idle_count += 1;
+		} else if (PGSTAT_IS_IDLEINTRANSACTION(beentry)){
+			st_session_diff.total_transaction_idle_time = usecs_diff;
+			st_session_diff.total_transaction_idle_count += 1;
+		} else if (PGSTAT_IS_IDLEINTRANSACTION_ABORTED(beentry)){
+			st_session_diff.total_transaction_idle_aborted_time = usecs_diff;
+			st_session_diff.total_transaction_idle_aborted_count += 1;
+		} else if (PGSTAT_IS_FASTPATH(beentry)){
+			st_session_diff.total_fastpath_time = usecs_diff;
+			st_session_diff.total_fastpath_count += 1;
+		}
 	}
 
 	/*
@@ -618,6 +643,21 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 		beentry->st_activity_start_timestamp = start_timestamp;
 	}
 
+	beentry->st_session.total_running_time += st_session_diff.total_running_time;
+	beentry->st_session.total_running_count += st_session_diff.total_running_count;
+
+	beentry->st_session.total_idle_time += st_session_diff.total_idle_time;
+	beentry->st_session.total_idle_count += st_session_diff.total_idle_count;
+
+	beentry->st_session.total_transaction_idle_time += st_session_diff.total_transaction_idle_time;
+	beentry->st_session.total_transaction_idle_count += st_session_diff.total_transaction_idle_count;
+
+	beentry->st_session.total_transaction_idle_aborted_time += st_session_diff.total_transaction_idle_aborted_time;
+	beentry->st_session.total_transaction_idle_aborted_count += st_session_diff.total_transaction_idle_aborted_count;
+
+	beentry->st_session.total_fastpath_time += st_session_diff.total_fastpath_time;
+	beentry->st_session.total_fastpath_count += st_session_diff.total_fastpath_count;
+
 	PGSTAT_END_WRITE_ACTIVITY(beentry);
 }
 
diff --git a/src/backend/utils/adt/pgstatfuncs.c b/src/backend/utils/adt/pgstatfuncs.c
index 6737493402..3a76a5bf06 100644
--- a/src/backend/utils/adt/pgstatfuncs.c
+++ b/src/backend/utils/adt/pgstatfuncs.c
@@ -297,6 +297,76 @@ pg_stat_get_progress_info(PG_FUNCTION_ARGS)
 	return (Datum) 0;
 }
 
+/*
+ * Returns accumulated statistics of current PG backends.
+ */
+Datum
+pg_stat_get_session(PG_FUNCTION_ARGS)
+{
+#define PG_STAT_GET_SESSION_COLS	11
+	int			num_backends = pgstat_fetch_stat_numbackends();
+	int			curr_backend;
+	int			pid = PG_ARGISNULL(0) ? -1 : PG_GETARG_INT32(0);
+	ReturnSetInfo *rsinfo = (ReturnSetInfo *) fcinfo->resultinfo;
+
+	InitMaterializedSRF(fcinfo, 0);
+
+	/* 1-based index */
+	for (curr_backend = 1; curr_backend <= num_backends; curr_backend++)
+	{
+		/* for each row */
+		Datum		values[PG_STAT_GET_SESSION_COLS] = {0};
+		bool		nulls[PG_STAT_GET_SESSION_COLS] = {0};
+		LocalPgBackendStatus *local_beentry;
+		PgBackendStatus *beentry;
+
+		/* Get the next one in the list */
+		local_beentry = pgstat_fetch_stat_local_beentry(curr_backend);
+		beentry = &local_beentry->backendStatus;
+
+		/* If looking for specific PID, ignore all the others */
+		if (pid != -1 && beentry->st_procpid != pid)
+			continue;
+
+		/* Values available to all callers */
+		values[0] = Int32GetDatum(beentry->st_procpid);
+
+		/* Values only available to role member or pg_read_all_stats */
+		if (HAS_PGSTAT_PERMISSIONS(beentry->st_userid)){
+			/* convert to msec */
+			values[1] = Float8GetDatum(beentry->st_session.total_running_time / 1000.0);
+			values[2] = Int64GetDatum(beentry->st_session.total_running_count);
+			values[3] = Float8GetDatum(beentry->st_session.total_idle_time / 1000.0);
+			values[4] = Int64GetDatum(beentry->st_session.total_idle_count);
+			values[5] = Float8GetDatum(beentry->st_session.total_transaction_idle_time / 1000.0);
+			values[6] = Int64GetDatum(beentry->st_session.total_transaction_idle_count);
+			values[7] = Float8GetDatum(beentry->st_session.total_transaction_idle_aborted_time / 1000.0);
+			values[8] = Int64GetDatum(beentry->st_session.total_transaction_idle_aborted_count);
+			values[9] = Float8GetDatum(beentry->st_session.total_fastpath_time / 1000.0);
+			values[10] = Int64GetDatum(beentry->st_session.total_fastpath_count);
+		} else {
+			nulls[1] = true;
+			nulls[2] = true;
+			nulls[3] = true;
+			nulls[4] = true;
+			nulls[5] = true;
+			nulls[6] = true;
+			nulls[7] = true;
+			nulls[8] = true;
+			nulls[9] = true;
+			nulls[10] = true;
+		}
+
+		tuplestore_putvalues(rsinfo->setResult, rsinfo->setDesc, values, nulls);
+
+		/* If only a single backend was requested, and we found it, break. */
+		if (pid != -1)
+			break;
+	}
+
+	return (Datum) 0;
+}
+
 /*
  * Returns activity of PG backends.
  */
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index c0f2a8a77c..4c063e2422 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -5408,6 +5408,15 @@
   proargmodes => '{i,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o}',
   proargnames => '{pid,datid,pid,usesysid,application_name,state,query,wait_event_type,wait_event,xact_start,query_start,backend_start,state_change,client_addr,client_hostname,client_port,backend_xid,backend_xmin,backend_type,ssl,sslversion,sslcipher,sslbits,ssl_client_dn,ssl_client_serial,ssl_issuer_dn,gss_auth,gss_princ,gss_enc,leader_pid,query_id}',
   prosrc => 'pg_stat_get_activity' },
+{ oid => '2173',
+  descr => 'statistics: cumulative information about currently active backends',
+  proname => 'pg_stat_get_session', prorows => '100', proisstrict => 'f',
+  proretset => 't', provolatile => 's', proparallel => 'r',
+  prorettype => 'record', proargtypes => 'int4',
+  proallargtypes => '{int4,int4,float8,int8,float8,int8,float8,int8,float8,int8,float8,int8}',
+  proargmodes => '{i,o,o,o,o,o,o,o,o,o,o,o}',
+  proargnames => '{pid,pid,total_running_time,total_running_count,total_idle_time,total_idle_count,total_transaction_idle_time,total_transaction_idle_count,total_transaction_idle_aborted_time,total_transaction_idle_aborted_count,total_fastpath_time,total_fastpath_count}',
+  prosrc => 'pg_stat_get_session' },
 { oid => '3318',
   descr => 'statistics: information about progress of backends running maintenance command',
   proname => 'pg_stat_get_progress_info', prorows => '100', proretset => 't',
diff --git a/src/include/utils/backend_status.h b/src/include/utils/backend_status.h
index f7bd83113a..17eeb02a84 100644
--- a/src/include/utils/backend_status.h
+++ b/src/include/utils/backend_status.h
@@ -80,6 +80,26 @@ typedef struct PgBackendGSSStatus
 
 } PgBackendGSSStatus;
 
+/*
+ * PgBackendSessionStatus
+ *
+ * For each session, we keep counters accumulated since the start of the session
+ * in a separate struct. The struct is always filled.
+ *
+ */
+typedef struct PgBackendSessionStatus
+{
+	int64		total_running_time;
+	int64		total_running_count;
+	int64		total_idle_time;
+	int64		total_idle_count;
+	int64		total_transaction_idle_time;
+	int64		total_transaction_idle_count;
+	int64		total_transaction_idle_aborted_time;
+	int64		total_transaction_idle_aborted_count;
+	int64		total_fastpath_time;
+	int64		total_fastpath_count;
+} PgBackendSessionStatus;
 
 /* ----------
  * PgBackendStatus
@@ -169,6 +189,9 @@ typedef struct PgBackendStatus
 
 	/* query identifier, optionally computed using post_parse_analyze_hook */
 	uint64		st_query_id;
+
+	/* Counters accumulated since the start of the session */
+	PgBackendSessionStatus st_session;
 } PgBackendStatus;
 
 
@@ -233,6 +256,20 @@ typedef struct PgBackendStatus
 	 ((before_changecount) & 1) == 0)
 
 
+/* Macros to identify the states for time accounting */
+#define PGSTAT_IS_RUNNING(s) \
+	((s)->st_state == STATE_RUNNING)
+#define PGSTAT_IS_FASTPATH(s) \
+	((s)->st_state == STATE_FASTPATH)
+#define PGSTAT_IS_IDLE(s) \
+	((s)->st_state == STATE_IDLE)
+#define PGSTAT_IS_IDLEINTRANSACTION(s) \
+	((s)->st_state == STATE_IDLEINTRANSACTION)
+#define PGSTAT_IS_IDLEINTRANSACTION_ABORTED(s) \
+	((s)->st_state == STATE_IDLEINTRANSACTION_ABORTED)
+#define PGSTAT_IS_ACTIVE(s) \
+	((s)->st_state == STATE_RUNNING || (s)->st_state == STATE_FASTPATH)
+
 /* ----------
  * LocalPgBackendStatus
  *
diff --git a/src/test/regress/expected/rules.out b/src/test/regress/expected/rules.out
index e7a2f5856a..73f10c8477 100644
--- a/src/test/regress/expected/rules.out
+++ b/src/test/regress/expected/rules.out
@@ -2071,6 +2071,18 @@ pg_stat_replication_slots| SELECT s.slot_name,
    FROM pg_replication_slots r,
     LATERAL pg_stat_get_replication_slot((r.slot_name)::text) s(slot_name, spill_txns, spill_count, spill_bytes, stream_txns, stream_count, stream_bytes, total_txns, total_bytes, stats_reset)
   WHERE (r.datoid IS NOT NULL);
+pg_stat_session| SELECT pid,
+    total_running_time,
+    total_running_count,
+    total_idle_time,
+    total_idle_count,
+    total_transaction_idle_time,
+    total_transaction_idle_count,
+    total_transaction_idle_aborted_time,
+    total_transaction_idle_aborted_count,
+    total_fastpath_time,
+    total_fastpath_count
+   FROM pg_stat_get_session(NULL::integer) s(pid, total_running_time, total_running_count, total_idle_time, total_idle_count, total_transaction_idle_time, total_transaction_idle_count, total_transaction_idle_aborted_time, total_transaction_idle_aborted_count, total_fastpath_time, total_fastpath_count);
 pg_stat_slru| SELECT name,
     blks_zeroed,
     blks_hit,
-- 
2.34.1

#41Andrey Borodin
amborodin86@gmail.com
In reply to: Sergey Dudoladov (#40)
Re: Add connection active, idle time to pg_stat_activity

On Wed, Feb 1, 2023 at 12:46 PM Sergey Dudoladov
<sergey.dudoladov@gmail.com> wrote:

I've sketched the first version of a patch to add pg_stat_session.
Please review this early version.

Hi Sergey!

I've taken a look into the patch and got some notes.
1. It is hard to understand what fastpath backend state is. What do
fastpath metrics mean for a user?
2. Anyway, the path "if (PGSTAT_IS_FASTPATH(beentry))" seems
unreachable to me. I'm a bit surprised that compilers do not produce
warnings about it. Maybe I'm just wrong.
3. Tests do not check any incrementation logic. I think we can have
some test that verifies delta for select some_counter from
pg_stat_session where pid = pg_backend_pid();
4. Macroses like PGSTAT_IS_RUNNING do not look like net win in code
readability and PGSTAT prefix have no semantic load.

That's all I've found so far. Thank you!

Best regards, Andrey Borodin.

PS. We were doing on-air review session [0]https://youtu.be/vTV8XhWf3mo?t=2404, I hope Nik will chime-in
with "usability part of a review".

[0]: https://youtu.be/vTV8XhWf3mo?t=2404

#42Sergey Dudoladov
sergey.dudoladov@gmail.com
In reply to: Andrey Borodin (#41)
1 attachment(s)
Re: Add connection active, idle time to pg_stat_activity

Hello hackers,

Andrey and Nik, thank you for selecting this patch for review in
Postgres Hacking 101: I've modified the patch based both on your email
and the video.

1. Session statistics is now collected only for client backends. PG
internal processes like wal sender seem to stop sending statistics
after they have entered their respective main loops.
2. Fastpath state now counts towards the running state. I think this
special case does not justify tracking two extra numbers for every
client backend.
3. I've added a small test for pg_stat_session similar to other tests
in src/test/regress/sql/sysviews.sql
4. Here are the pb_bench results requested in the video review:

Conditions: no assertions, number of transactions = 1000
The query: SELECT generate_series(1, 10000000) OFFSET 10000000;
With pg_stat_session:
latency average = 324.480 ms
tps = 3.081857 (without initial connection time)

Without pg_stat_session:
latency average = 327.370 ms
tps = 3.054651 (without initial connection time)

Regards,
Sergey

Attachments:

0002-Add-pg_stat_session.patchtext/x-patch; charset=US-ASCII; name=0002-Add-pg_stat_session.patchDownload
From 329db9a594b96499135bcbfdfad674f6af7ae1dc Mon Sep 17 00:00:00 2001
From: Sergey Dudoladov <sergey.dudoladov@gmail.com>
Date: Tue, 22 Nov 2022 09:23:32 +0100
Subject: [PATCH] Add pg_stat_session

Author: Sergey Dudoladov

Adds pg_stat_session view to track statistics accumulated during
 lifetime of a session (client backend).

catversion bump is necessary due to a new view / function

Reviewed-by: Aleksander Alekseev, Bertrand Drouvot, and Atsushi
Torikoshi

Discussion:
https://www.postgresql.org/message-id/flat/CA%2BFpmFcJF0vwi-SWW0wYO-c-FbhyawLq4tCpRDCJJ8Bq%3Dja-gA%40mail.gmail.com
---
 doc/src/sgml/monitoring.sgml                | 134 ++++++++++++++++++++
 src/backend/catalog/system_views.sql        |  13 ++
 src/backend/utils/activity/backend_status.c |  57 +++++++--
 src/backend/utils/adt/pgstatfuncs.c         |  70 ++++++++++
 src/include/catalog/pg_proc.dat             |   9 ++
 src/include/utils/backend_status.h          |  32 +++++
 src/test/regress/expected/rules.out         |  10 ++
 src/test/regress/expected/sysviews.out      |   7 +
 src/test/regress/sql/sysviews.sql           |   3 +
 9 files changed, 325 insertions(+), 10 deletions(-)

diff --git a/doc/src/sgml/monitoring.sgml b/doc/src/sgml/monitoring.sgml
index 5cfdc70c03..aa759e36c5 100644
--- a/doc/src/sgml/monitoring.sgml
+++ b/doc/src/sgml/monitoring.sgml
@@ -414,6 +414,20 @@ postgres   27093  0.0  0.0  30096  2752 ?        Ss   11:34   0:00 postgres: ser
        See <xref linkend="copy-progress-reporting"/>.
       </entry>
      </row>
+
+     <row>
+      <entry>
+       <structname>pg_stat_session</structname>
+       <indexterm><primary>pg_stat_session</primary></indexterm>
+      </entry>
+      <entry>
+       One row per client backend, showing information related to
+       the currently accumulated activity of that process, such as time spent in
+       a certain state.
+       See <link linkend="monitoring-pg-stat-session-view">
+       <structname>pg_stat_session</structname></link> for details.
+      </entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
@@ -5755,6 +5769,110 @@ SELECT pid, wait_event_type, wait_event FROM pg_stat_activity WHERE wait_event i
    </tgroup>
   </table>
 
+  <table id="monitoring-pg-stat-session-view" xreflabel="pg_stat_session">
+   <title><structname>pg_stat_session</structname> View</title>
+   <tgroup cols="1">
+    <thead>
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       Column Type
+      </para>
+      <para>
+       Description
+      </para></entry>
+     </row>
+    </thead>
+
+    <tbody>
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>pid</structfield> <type>integer</type>
+      </para>
+      <para>
+       Process ID of this client backend.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>total_running_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in the <literal>running</literal> or <literal>fastpath</literal> state.
+      </para></entry>
+     </row>
+
+    <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>total_running_count</structfield> <type>bigint</type>
+      </para>
+      <para>
+       Number of times this backend switched to the <literal>running</literal> or <literal>fastpath</literal> state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>total_idle_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in the <literal>idle</literal> state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>total_idle_count</structfield> <type>bigint</type>
+      </para>
+      <para>
+       Number of times this backend switched to the <literal>idle</literal> state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>total_transaction_idle_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in the <literal>idle in transaction</literal>
+       state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>total_transaction_idle_count</structfield> <type>bigint</type>
+      </para>
+      <para>
+       Number of times this backend switched to the <literal>idle in transaction</literal>
+       state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>total_transaction_idle_aborted_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in the <literal>idle in transaction (aborted)</literal> 
+       state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>total_transaction_idle_aborted_count</structfield> <type>bigint</type>
+      </para>
+      <para>
+       Number of times this backend switched to the <literal>idle in transaction (aborted)</literal>
+       state.
+      </para></entry>
+     </row>
+
+    </tbody>
+   </tgroup>
+  </table>
+
  </sect2>
 
  <sect2 id="monitoring-stats-functions">
@@ -5822,6 +5940,22 @@ SELECT pid, wait_event_type, wait_event FROM pg_stat_activity WHERE wait_event i
        </para></entry>
       </row>
 
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>pg_stat_get_session</primary>
+        </indexterm>
+        <function>pg_stat_get_session</function> ( <type>integer</type> )
+        <returnvalue>setof record</returnvalue>
+       </para>
+       <para>
+        Returns a record of information about the client backend with the specified
+        process ID, or one record for each active backend in the system
+        if <literal>NULL</literal> is specified.  The fields returned are a
+        subset of those in the <structname>pg_stat_session</structname> view.
+       </para></entry>
+      </row>
+
       <row>
        <entry role="func_table_entry"><para role="func_signature">
         <indexterm>
diff --git a/src/backend/catalog/system_views.sql b/src/backend/catalog/system_views.sql
index c18fea8362..8f073b442c 100644
--- a/src/backend/catalog/system_views.sql
+++ b/src/backend/catalog/system_views.sql
@@ -872,6 +872,19 @@ CREATE VIEW pg_stat_activity AS
         LEFT JOIN pg_database AS D ON (S.datid = D.oid)
         LEFT JOIN pg_authid AS U ON (S.usesysid = U.oid);
 
+CREATE VIEW pg_stat_session AS
+    SELECT
+            s.pid,
+            s.total_running_time,
+            s.total_running_count,
+            s.total_idle_time,
+            s.total_idle_count,
+            s.total_transaction_idle_time,
+            s.total_transaction_idle_count,
+            s.total_transaction_idle_aborted_time,
+            s.total_transaction_idle_aborted_count
+     FROM pg_stat_get_session(NULL) as s;
+
 CREATE VIEW pg_stat_replication AS
     SELECT
             S.pid,
diff --git a/src/backend/utils/activity/backend_status.c b/src/backend/utils/activity/backend_status.c
index 38f91a495b..b20ef8c51e 100644
--- a/src/backend/utils/activity/backend_status.c
+++ b/src/backend/utils/activity/backend_status.c
@@ -338,6 +338,8 @@ pgstat_bestart(void)
 	lbeentry.st_xact_start_timestamp = 0;
 	lbeentry.st_databaseid = MyDatabaseId;
 
+	MemSet(&lbeentry.st_session, 0, sizeof(lbeentry.st_session));
+
 	/* We have userid for client-backends, wal-sender and bgworker processes */
 	if (lbeentry.st_backendType == B_BACKEND
 		|| lbeentry.st_backendType == B_WAL_SENDER
@@ -526,6 +528,9 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 	TimestampTz current_timestamp;
 	int			len = 0;
 
+	PgBackendSessionStatus st_session_diff;
+	MemSet(&st_session_diff, 0, sizeof(st_session_diff));
+
 	TRACE_POSTGRESQL_STATEMENT_STATUS(cmd_str);
 
 	if (!beentry)
@@ -551,6 +556,7 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 			beentry->st_xact_start_timestamp = 0;
 			beentry->st_query_id = UINT64CONST(0);
 			proc->wait_event_info = 0;
+			MemSet(&beentry->st_session, 0, sizeof(beentry->st_session));
 			PGSTAT_END_WRITE_ACTIVITY(beentry);
 		}
 		return;
@@ -573,27 +579,44 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 	current_timestamp = GetCurrentTimestamp();
 
 	/*
-	 * If the state has changed from "active" or "idle in transaction",
-	 * calculate the duration.
+	 * If a client backend has changed state, update per-database and per-session counters.
 	 */
-	if ((beentry->st_state == STATE_RUNNING ||
-		 beentry->st_state == STATE_FASTPATH ||
-		 beentry->st_state == STATE_IDLEINTRANSACTION ||
-		 beentry->st_state == STATE_IDLEINTRANSACTION_ABORTED) &&
-		state != beentry->st_state)
+	if ((PGSTAT_IS_ACTIVE(beentry) ||
+		 PGSTAT_IS_IDLEINTRANSACTION(beentry) ||
+		 PGSTAT_IS_IDLEINTRANSACTION_ABORTED(beentry) || 
+		 PGSTAT_IS_IDLE(beentry)) &&
+		state != beentry->st_state &&
+		beentry->st_backendType == B_BACKEND)
 	{
 		long		secs;
 		int			usecs;
+		int64		usecs_diff;
 
 		TimestampDifference(beentry->st_state_start_timestamp,
 							current_timestamp,
 							&secs, &usecs);
+		usecs_diff = secs * 1000000 + usecs;
 
-		if (beentry->st_state == STATE_RUNNING ||
-			beentry->st_state == STATE_FASTPATH)
+		/* Keep statistics for pg_stat_database intact */
+		if (PGSTAT_IS_ACTIVE(beentry))
 			pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 + usecs);
-		else
+		else if (PGSTAT_IS_IDLEINTRANSACTION(beentry) ||
+				 PGSTAT_IS_IDLEINTRANSACTION_ABORTED(beentry))
 			pgstat_count_conn_txn_idle_time((PgStat_Counter) secs * 1000000 + usecs);
+
+		if (PGSTAT_IS_ACTIVE(beentry)) {
+			st_session_diff.total_running_time = usecs_diff;
+			st_session_diff.total_running_count += 1;
+		} else if (PGSTAT_IS_IDLE(beentry)){
+			st_session_diff.total_idle_time = usecs_diff;
+			st_session_diff.total_idle_count += 1;
+		} else if (PGSTAT_IS_IDLEINTRANSACTION(beentry)){
+			st_session_diff.total_transaction_idle_time = usecs_diff;
+			st_session_diff.total_transaction_idle_count += 1;
+		} else if (PGSTAT_IS_IDLEINTRANSACTION_ABORTED(beentry)){
+			st_session_diff.total_transaction_idle_aborted_time = usecs_diff;
+			st_session_diff.total_transaction_idle_aborted_count += 1;
+		}
 	}
 
 	/*
@@ -619,6 +642,20 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 		beentry->st_activity_start_timestamp = start_timestamp;
 	}
 
+	if (beentry->st_backendType == B_BACKEND) {
+		beentry->st_session.total_running_time += st_session_diff.total_running_time;
+		beentry->st_session.total_running_count += st_session_diff.total_running_count;
+
+		beentry->st_session.total_idle_time += st_session_diff.total_idle_time;
+		beentry->st_session.total_idle_count += st_session_diff.total_idle_count;
+
+		beentry->st_session.total_transaction_idle_time += st_session_diff.total_transaction_idle_time;
+		beentry->st_session.total_transaction_idle_count += st_session_diff.total_transaction_idle_count;
+
+		beentry->st_session.total_transaction_idle_aborted_time += st_session_diff.total_transaction_idle_aborted_time;
+		beentry->st_session.total_transaction_idle_aborted_count += st_session_diff.total_transaction_idle_aborted_count;
+	}
+
 	PGSTAT_END_WRITE_ACTIVITY(beentry);
 }
 
diff --git a/src/backend/utils/adt/pgstatfuncs.c b/src/backend/utils/adt/pgstatfuncs.c
index 49adc319fc..6eb2384618 100644
--- a/src/backend/utils/adt/pgstatfuncs.c
+++ b/src/backend/utils/adt/pgstatfuncs.c
@@ -297,6 +297,76 @@ pg_stat_get_progress_info(PG_FUNCTION_ARGS)
 	return (Datum) 0;
 }
 
+/*
+ * Returns accumulated statistics of current PG backends.
+ */
+Datum
+pg_stat_get_session(PG_FUNCTION_ARGS)
+{
+#define PG_STAT_GET_SESSION_COLS	9
+	int			num_backends = pgstat_fetch_stat_numbackends();
+	int			curr_backend;
+	int			pid = PG_ARGISNULL(0) ? -1 : PG_GETARG_INT32(0);
+	ReturnSetInfo *rsinfo = (ReturnSetInfo *) fcinfo->resultinfo;
+
+	InitMaterializedSRF(fcinfo, 0);
+
+	/* 1-based index */
+	for (curr_backend = 1; curr_backend <= num_backends; curr_backend++)
+	{
+		/* for each row */
+		Datum		values[PG_STAT_GET_SESSION_COLS] = {0};
+		bool		nulls[PG_STAT_GET_SESSION_COLS] = {0};
+		LocalPgBackendStatus *local_beentry;
+		PgBackendStatus *beentry;
+
+		/* Get the next one in the list */
+		local_beentry = pgstat_fetch_stat_local_beentry(curr_backend);
+		beentry = &local_beentry->backendStatus;
+
+		/* Report statistics only for client backends */
+		if (beentry->st_backendType != B_BACKEND)
+			continue;
+
+		/* If looking for specific PID, ignore all the others */
+		if (pid != -1 && beentry->st_procpid != pid)
+			continue;
+
+		/* Values available to all callers */
+		values[0] = Int32GetDatum(beentry->st_procpid);
+
+		/* Values only available to role member or pg_read_all_stats */
+		if (HAS_PGSTAT_PERMISSIONS(beentry->st_userid)){
+			/* convert to msec */
+			values[1] = Float8GetDatum(beentry->st_session.total_running_time / 1000.0);
+			values[2] = Int64GetDatum(beentry->st_session.total_running_count);
+			values[3] = Float8GetDatum(beentry->st_session.total_idle_time / 1000.0);
+			values[4] = Int64GetDatum(beentry->st_session.total_idle_count);
+			values[5] = Float8GetDatum(beentry->st_session.total_transaction_idle_time / 1000.0);
+			values[6] = Int64GetDatum(beentry->st_session.total_transaction_idle_count);
+			values[7] = Float8GetDatum(beentry->st_session.total_transaction_idle_aborted_time / 1000.0);
+			values[8] = Int64GetDatum(beentry->st_session.total_transaction_idle_aborted_count);
+		} else {
+			nulls[1] = true;
+			nulls[2] = true;
+			nulls[3] = true;
+			nulls[4] = true;
+			nulls[5] = true;
+			nulls[6] = true;
+			nulls[7] = true;
+			nulls[8] = true;
+		}
+
+		tuplestore_putvalues(rsinfo->setResult, rsinfo->setDesc, values, nulls);
+
+		/* If only a single backend was requested, and we found it, break. */
+		if (pid != -1)
+			break;
+	}
+
+	return (Datum) 0;
+}
+
 /*
  * Returns activity of PG backends.
  */
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index 6996073989..60ac6ea3de 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -5417,6 +5417,15 @@
   proargmodes => '{i,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o,o}',
   proargnames => '{pid,datid,pid,usesysid,application_name,state,query,wait_event_type,wait_event,xact_start,query_start,backend_start,state_change,client_addr,client_hostname,client_port,backend_xid,backend_xmin,backend_type,ssl,sslversion,sslcipher,sslbits,ssl_client_dn,ssl_client_serial,ssl_issuer_dn,gss_auth,gss_princ,gss_enc,gss_delegation,leader_pid,query_id}',
   prosrc => 'pg_stat_get_activity' },
+{ oid => '2173',
+  descr => 'statistics: cumulative information about currently active client backends',
+  proname => 'pg_stat_get_session', prorows => '100', proisstrict => 'f',
+  proretset => 't', provolatile => 's', proparallel => 'r',
+  prorettype => 'record', proargtypes => 'int4',
+  proallargtypes => '{int4,int4,float8,int8,float8,int8,float8,int8,float8,int8}',
+  proargmodes => '{i,o,o,o,o,o,o,o,o,o}',
+  proargnames => '{pid,pid,total_running_time,total_running_count,total_idle_time,total_idle_count,total_transaction_idle_time,total_transaction_idle_count,total_transaction_idle_aborted_time,total_transaction_idle_aborted_count}',
+  prosrc => 'pg_stat_get_session' },
 { oid => '3318',
   descr => 'statistics: information about progress of backends running maintenance command',
   proname => 'pg_stat_get_progress_info', prorows => '100', proretset => 't',
diff --git a/src/include/utils/backend_status.h b/src/include/utils/backend_status.h
index 16500d53b2..b0099d307e 100644
--- a/src/include/utils/backend_status.h
+++ b/src/include/utils/backend_status.h
@@ -81,6 +81,24 @@ typedef struct PgBackendGSSStatus
 
 } PgBackendGSSStatus;
 
+/*
+ * PgBackendSessionStatus
+ *
+ * For each session, we keep counters accumulated since the start of the session
+ * in a separate struct. The struct is always filled.
+ *
+ */
+typedef struct PgBackendSessionStatus
+{
+	int64		total_running_time;
+	int64		total_running_count;
+	int64		total_idle_time;
+	int64		total_idle_count;
+	int64		total_transaction_idle_time;
+	int64		total_transaction_idle_count;
+	int64		total_transaction_idle_aborted_time;
+	int64		total_transaction_idle_aborted_count;
+} PgBackendSessionStatus;
 
 /* ----------
  * PgBackendStatus
@@ -170,6 +188,9 @@ typedef struct PgBackendStatus
 
 	/* query identifier, optionally computed using post_parse_analyze_hook */
 	uint64		st_query_id;
+
+	/* Counters accumulated since the start of the session */
+	PgBackendSessionStatus st_session;
 } PgBackendStatus;
 
 
@@ -234,6 +255,17 @@ typedef struct PgBackendStatus
 	 ((before_changecount) & 1) == 0)
 
 
+/* Macros to identify the states for time accounting */
+#define PGSTAT_IS_ACTIVE(s) \
+	((s)->st_state == STATE_RUNNING || (s)->st_state == STATE_FASTPATH)
+#define PGSTAT_IS_IDLE(s) \
+	((s)->st_state == STATE_IDLE)
+#define PGSTAT_IS_IDLEINTRANSACTION(s) \
+	((s)->st_state == STATE_IDLEINTRANSACTION)
+#define PGSTAT_IS_IDLEINTRANSACTION_ABORTED(s) \
+	((s)->st_state == STATE_IDLEINTRANSACTION_ABORTED)
+
+
 /* ----------
  * LocalPgBackendStatus
  *
diff --git a/src/test/regress/expected/rules.out b/src/test/regress/expected/rules.out
index 7fd81e6a7d..9eb67d4763 100644
--- a/src/test/regress/expected/rules.out
+++ b/src/test/regress/expected/rules.out
@@ -2094,6 +2094,16 @@ pg_stat_replication_slots| SELECT s.slot_name,
    FROM pg_replication_slots r,
     LATERAL pg_stat_get_replication_slot((r.slot_name)::text) s(slot_name, spill_txns, spill_count, spill_bytes, stream_txns, stream_count, stream_bytes, total_txns, total_bytes, stats_reset)
   WHERE (r.datoid IS NOT NULL);
+pg_stat_session| SELECT pid,
+    total_running_time,
+    total_running_count,
+    total_idle_time,
+    total_idle_count,
+    total_transaction_idle_time,
+    total_transaction_idle_count,
+    total_transaction_idle_aborted_time,
+    total_transaction_idle_aborted_count
+   FROM pg_stat_get_session(NULL::integer) s(pid, total_running_time, total_running_count, total_idle_time, total_idle_count, total_transaction_idle_time, total_transaction_idle_count, total_transaction_idle_aborted_time, total_transaction_idle_aborted_count);
 pg_stat_slru| SELECT name,
     blks_zeroed,
     blks_hit,
diff --git a/src/test/regress/expected/sysviews.out b/src/test/regress/expected/sysviews.out
index 001c6e7eb9..e66c08cd40 100644
--- a/src/test/regress/expected/sysviews.out
+++ b/src/test/regress/expected/sysviews.out
@@ -167,3 +167,10 @@ select count(distinct utc_offset) >= 24 as ok from pg_timezone_abbrevs;
  t
 (1 row)
 
+select total_idle_count as prev_idle_count from pg_stat_session where pid = pg_backend_pid() \gset
+select (select total_idle_count from pg_stat_session where pid = pg_backend_pid()) - :prev_idle_count = 1 as ok;
+ ok 
+----
+ t
+(1 row)
+
diff --git a/src/test/regress/sql/sysviews.sql b/src/test/regress/sql/sysviews.sql
index 351e469c77..6545e65d21 100644
--- a/src/test/regress/sql/sysviews.sql
+++ b/src/test/regress/sql/sysviews.sql
@@ -68,3 +68,6 @@ set timezone_abbreviations = 'Australia';
 select count(distinct utc_offset) >= 24 as ok from pg_timezone_abbrevs;
 set timezone_abbreviations = 'India';
 select count(distinct utc_offset) >= 24 as ok from pg_timezone_abbrevs;
+
+select total_idle_count as prev_idle_count from pg_stat_session where pid = pg_backend_pid() \gset
+select (select total_idle_count from pg_stat_session where pid = pg_backend_pid()) - :prev_idle_count = 1 as ok;
\ No newline at end of file
-- 
2.34.1

#43Andrei Zubkov
zubkov@moonset.ru
In reply to: Sergey Dudoladov (#42)
Re: Add connection active, idle time to pg_stat_activity

Hi Sergey,

I've done a review of this patch. I found the patch idea very useful,
thank you for the patch. I've noted something observing this patch:
1. Patch can't be applied on the current master. My review is based on
application of this patch over ac68323a878
2. Being applied over ac68323a878 patch works as expected.
3. Field names seems quite long to me (and they should be uniformly
named with the same statistics in other views. For example
"running" term is called "active" in pg_stat_database)
4. Meaningless spaces at the end of line:
- backend_status.c:586
- monitoring.sgml:5857
5. Patch adds

usecs_diff = secs * 1000000 + usecs;

at backend_status.c:pgstat_report_activity() to optimize
calculations. But

pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 +
usecs);
and
pgstat_count_conn_txn_idle_time((PgStat_Counter) secs * 1000000 +
usecs);

are left in place after that.
6. I'm not sure that I can understand the comment
/* Keep statistics for pg_stat_database intact */
at backend_status.c:600 correctly. Can you please explain it a
little?
7. Tests seems incomplete. It looks like we can check increments in
all fields playing with transactions in tests.

Also, I have a thought about other possible improvements fitting to
this patch.

The view pg_stat_session is really needed in Postgres but I think it
should have much more statistics. I mean all resource statistics
related to sessions. Every backend has instrumentation that tracks
resource consumption. Data of this instrumentation goes to the
cumulative statistics system and is used in monitoring extensions
(like pg_stat_statements). I think pg_stat_session view is able to add
one more dimension of monitoring - a dimension of sessions. In my
opinion this view should provide resource consumption statistics of
current sessions in two cumulative sets of statistics - since backend
start and since transaction start. Such view will be really useful in
monitoring of long running sessions and transactions providing
resource consumption information besides timing statistics.

regards, Andrei Zubkov
Postgres Professional

#44Aleksander Alekseev
aleksander@timescale.com
In reply to: Andrei Zubkov (#43)
Re: Add connection active, idle time to pg_stat_activity

Hi,

I've done a review of this patch. I found the patch idea very useful,
thank you for the patch. I've noted something observing this patch:
1. Patch can't be applied on the current master. My review is based on
application of this patch over ac68323a878

On top of that not sure if I see the patch on the November commitfest
[1]: https://commitfest.postgresql.org/45/

[1]: https://commitfest.postgresql.org/45/

--
Best regards,
Aleksander Alekseev

#45Andrei Zubkov
zubkov@moonset.ru
In reply to: Aleksander Alekseev (#44)
Re: Add connection active, idle time to pg_stat_activity

Hi Aleksander,

On Wed, 2023-10-25 at 16:17 +0300, Aleksander Alekseev wrote:

On top of that not sure if I see the patch on the November commitfest
[1]. Please make sure it's there so that cfbot will check the patch.

Yes, this patch is listed on the November commitfest. cfbot says rebase
needed since 2023-08-21.

regards, Andrei Zubkov

#46Aleksander Alekseev
aleksander@timescale.com
In reply to: Andrei Zubkov (#45)
Re: Add connection active, idle time to pg_stat_activity

Hi,

On Wed, 2023-10-25 at 16:17 +0300, Aleksander Alekseev wrote:

On top of that not sure if I see the patch on the November commitfest
[1]. Please make sure it's there so that cfbot will check the patch.

Yes, this patch is listed on the November commitfest. cfbot says rebase
needed since 2023-08-21.

You are right, I missed the corresponding entry [1]https://commitfest.postgresql.org/45/3405/.

[1]: https://commitfest.postgresql.org/45/3405/

--
Best regards,
Aleksander Alekseev

#47vignesh C
vignesh21@gmail.com
In reply to: Andrei Zubkov (#45)
Re: Add connection active, idle time to pg_stat_activity

On Wed, 25 Oct 2023 at 19:06, Andrei Zubkov <zubkov@moonset.ru> wrote:

Hi Aleksander,

On Wed, 2023-10-25 at 16:17 +0300, Aleksander Alekseev wrote:

On top of that not sure if I see the patch on the November commitfest
[1]. Please make sure it's there so that cfbot will check the patch.

Yes, this patch is listed on the November commitfest. cfbot says rebase
needed since 2023-08-21.

I have changed the status of commitfest entry to "Returned with
Feedback" as Andrei Zubkov's comments have not yet been resolved.
Please feel free to post an updated version of the patch and update
the commitfest entry accordingly.

Regards,
Vignesh

#48Sergey Dudoladov
sergey.dudoladov@gmail.com
In reply to: vignesh C (#47)
1 attachment(s)
Re: Add connection active, idle time to pg_stat_activity

Hi all,

@Andrei Zubkov
I've modify the patch to address most of your comments.

I have a thought about other possible improvements fitting to this patch.
I think pg_stat_session view is able to add one more dimension of

monitoring - a dimension of sessions

I would like to remind here about the initial scope of this patch. The main
goal of it was to ease tracking "idle in transactions" connections, a
feature that would really help in my work. The "pg_stat_session" came into
play only because the "pg_stat_activity" was seen as an unsuitable place
for the relevant counters. With that I still would like to maintaint the
focus on committing the "idle in transactions" part of pg_stat_session
first.

Regards,
Sergey

Attachments:

0003-Add-pg_stat_session.patchtext/x-patch; charset=US-ASCII; name=0003-Add-pg_stat_session.patchDownload
From 05f5117be52b613bb9d11114833eec38e152c6f9 Mon Sep 17 00:00:00 2001
From: Sergey Dudoladov <sergey.dudoladov@gmail.com>
Date: Thu, 1 Feb 2024 16:11:36 +0100
Subject: [PATCH] Add pg_stat_session

Author: Sergey Dudoladov

Adds pg_stat_session view to track statistics accumulated during
 lifetime of a session (client backend).

catversion bump is necessary due to a new view / function

Reviewed-by: Aleksander Alekseev, Bertrand Drouvot, Atsushi
Torikoshi, and Andrei Zubkov

Discussion:
https://www.postgresql.org/message-id/flat/CA%2BFpmFcJF0vwi-SWW0wYO-c-FbhyawLq4tCpRDCJJ8Bq%3Dja-gA%40mail.gmail.com
---
 doc/src/sgml/monitoring.sgml                | 134 ++++++++++++++++++++
 src/backend/catalog/system_views.sql        |  13 ++
 src/backend/utils/activity/backend_status.c |  64 ++++++++--
 src/backend/utils/adt/pgstatfuncs.c         |  70 ++++++++++
 src/include/catalog/pg_proc.dat             |   9 ++
 src/include/utils/backend_status.h          |  32 +++++
 src/test/regress/expected/rules.out         |  10 ++
 src/test/regress/expected/sysviews.out      |   7 +
 src/test/regress/sql/sysviews.sql           |   3 +
 9 files changed, 329 insertions(+), 13 deletions(-)

diff --git a/doc/src/sgml/monitoring.sgml b/doc/src/sgml/monitoring.sgml
index d9b8b37585..b10423428a 100644
--- a/doc/src/sgml/monitoring.sgml
+++ b/doc/src/sgml/monitoring.sgml
@@ -414,6 +414,20 @@ postgres   27093  0.0  0.0  30096  2752 ?        Ss   11:34   0:00 postgres: ser
        See <xref linkend="copy-progress-reporting"/>.
       </entry>
      </row>
+
+     <row>
+      <entry>
+       <structname>pg_stat_session</structname>
+       <indexterm><primary>pg_stat_session</primary></indexterm>
+      </entry>
+      <entry>
+       One row per client backend, showing information related to
+       the currently accumulated activity of that process, such as time spent in
+       a certain state.
+       See <link linkend="monitoring-pg-stat-session-view">
+       <structname>pg_stat_session</structname></link> for details.
+      </entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
@@ -4589,6 +4603,110 @@ description | Waiting for a newly initialized WAL file to reach durable storage
    </tgroup>
   </table>

+  <table id="monitoring-pg-stat-session-view" xreflabel="pg_stat_session">
+   <title><structname>pg_stat_session</structname> View</title>
+   <tgroup cols="1">
+    <thead>
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       Column Type
+      </para>
+      <para>
+       Description
+      </para></entry>
+     </row>
+    </thead>
+
+    <tbody>
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>pid</structfield> <type>integer</type>
+      </para>
+      <para>
+       Process ID of this client backend.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>active_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in the <literal>running</literal> or <literal>fastpath</literal> state.
+      </para></entry>
+     </row>
+
+    <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>active_count</structfield> <type>bigint</type>
+      </para>
+      <para>
+       Number of times this backend switched to the <literal>running</literal> or <literal>fastpath</literal> state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>idle_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in the <literal>idle</literal> state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>idle_count</structfield> <type>bigint</type>
+      </para>
+      <para>
+       Number of times this backend switched to the <literal>idle</literal> state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>idle_in_transaction_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in the <literal>idle in transaction</literal>
+       state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>idle_in_transaction_count</structfield> <type>bigint</type>
+      </para>
+      <para>
+       Number of times this backend switched to the <literal>idle in transaction</literal>
+       state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>idle_in_transaction_aborted_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in the <literal>idle in transaction (aborted)</literal>
+       state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>idle_in_transaction_aborted_count</structfield> <type>bigint</type>
+      </para>
+      <para>
+       Number of times this backend switched to the <literal>idle in transaction (aborted)</literal>
+       state.
+      </para></entry>
+     </row>
+
+    </tbody>
+   </tgroup>
+  </table>
+
  </sect2>

  <sect2 id="monitoring-stats-functions">
@@ -5128,6 +5246,22 @@ FROM pg_stat_get_backend_idset() AS backendid;
        </para></entry>
       </row>

+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>pg_stat_get_session</primary>
+        </indexterm>
+        <function>pg_stat_get_session</function> ( <type>integer</type> )
+        <returnvalue>setof record</returnvalue>
+       </para>
+       <para>
+        Returns a record of information about the client backend with the specified
+        process ID, or one record for each active backend in the system
+        if <literal>NULL</literal> is specified.  The fields returned are a
+        subset of those in the <structname>pg_stat_session</structname> view.
+       </para></entry>
+      </row>
+
       <row>
        <entry role="func_table_entry"><para role="func_signature">
         <indexterm>
diff --git a/src/backend/catalog/system_views.sql b/src/backend/catalog/system_views.sql
index 6791bff9dd..79db3af28b 100644
--- a/src/backend/catalog/system_views.sql
+++ b/src/backend/catalog/system_views.sql
@@ -893,6 +893,19 @@ CREATE VIEW pg_stat_activity AS
         LEFT JOIN pg_database AS D ON (S.datid = D.oid)
         LEFT JOIN pg_authid AS U ON (S.usesysid = U.oid);

+CREATE VIEW pg_stat_session AS
+    SELECT
+            s.pid,
+            s.active_time,
+            s.active_count,
+            s.idle_time,
+            s.idle_count,
+            s.idle_in_transaction_time,
+            s.idle_in_transaction_count,
+            s.idle_in_transaction_aborted_time,
+            s.idle_in_transaction_aborted_count
+     FROM pg_stat_get_session(NULL) as s;
+
 CREATE VIEW pg_stat_replication AS
     SELECT
             S.pid,
diff --git a/src/backend/utils/activity/backend_status.c b/src/backend/utils/activity/backend_status.c
index 1a1050c8da..31763a1efd 100644
--- a/src/backend/utils/activity/backend_status.c
+++ b/src/backend/utils/activity/backend_status.c
@@ -338,6 +338,8 @@ pgstat_bestart(void)
 	lbeentry.st_xact_start_timestamp = 0;
 	lbeentry.st_databaseid = MyDatabaseId;

+	MemSet(&lbeentry.st_session, 0, sizeof(lbeentry.st_session));
+
 	/* We have userid for client-backends, wal-sender and bgworker processes */
 	if (lbeentry.st_backendType == B_BACKEND
 		|| lbeentry.st_backendType == B_WAL_SENDER
@@ -526,6 +528,9 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 	TimestampTz current_timestamp;
 	int			len = 0;

+	PgBackendSessionStatus st_session_diff;
+	MemSet(&st_session_diff, 0, sizeof(st_session_diff));
+
 	TRACE_POSTGRESQL_STATEMENT_STATUS(cmd_str);

 	if (!beentry)
@@ -551,6 +556,7 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 			beentry->st_xact_start_timestamp = 0;
 			beentry->st_query_id = UINT64CONST(0);
 			proc->wait_event_info = 0;
+			MemSet(&beentry->st_session, 0, sizeof(beentry->st_session));
 			PGSTAT_END_WRITE_ACTIVITY(beentry);
 		}
 		return;
@@ -573,27 +579,45 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 	current_timestamp = GetCurrentTimestamp();

 	/*
-	 * If the state has changed from "active" or "idle in transaction",
-	 * calculate the duration.
+	 * If a client backend has changed state, update per-database and per-session counters.
 	 */
-	if ((beentry->st_state == STATE_RUNNING ||
-		 beentry->st_state == STATE_FASTPATH ||
-		 beentry->st_state == STATE_IDLEINTRANSACTION ||
-		 beentry->st_state == STATE_IDLEINTRANSACTION_ABORTED) &&
-		state != beentry->st_state)
+	if ((PGSTAT_IS_ACTIVE(beentry) ||
+		 PGSTAT_IS_IDLEINTRANSACTION(beentry) ||
+		 PGSTAT_IS_IDLEINTRANSACTION_ABORTED(beentry) ||
+		 PGSTAT_IS_IDLE(beentry)) &&
+		state != beentry->st_state &&
+		beentry->st_backendType == B_BACKEND)
 	{
 		long		secs;
 		int			usecs;
+		int64		usecs_diff;

 		TimestampDifference(beentry->st_state_start_timestamp,
 							current_timestamp,
 							&secs, &usecs);
-
-		if (beentry->st_state == STATE_RUNNING ||
-			beentry->st_state == STATE_FASTPATH)
-			pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 + usecs);
-		else
-			pgstat_count_conn_txn_idle_time((PgStat_Counter) secs * 1000000 + usecs);
+		usecs_diff = secs * 1000000 + usecs;
+
+		/* compute values for pg_stat_database */
+		if (PGSTAT_IS_ACTIVE(beentry))
+			pgstat_count_conn_active_time((PgStat_Counter) usecs_diff);
+		else if (PGSTAT_IS_IDLEINTRANSACTION(beentry) ||
+				 PGSTAT_IS_IDLEINTRANSACTION_ABORTED(beentry))
+			pgstat_count_conn_txn_idle_time((PgStat_Counter) usecs_diff);
+
+		/* compute values for pg_stat_session */
+		if (PGSTAT_IS_ACTIVE(beentry)) {
+			st_session_diff.active_time = usecs_diff;
+			st_session_diff.active_count += 1;
+		} else if (PGSTAT_IS_IDLE(beentry)){
+			st_session_diff.idle_time = usecs_diff;
+			st_session_diff.idle_count += 1;
+		} else if (PGSTAT_IS_IDLEINTRANSACTION(beentry)){
+			st_session_diff.idle_in_transaction_time = usecs_diff;
+			st_session_diff.idle_in_transaction_count += 1;
+		} else if (PGSTAT_IS_IDLEINTRANSACTION_ABORTED(beentry)){
+			st_session_diff.idle_in_transaction_aborted_time = usecs_diff;
+			st_session_diff.idle_in_transaction_aborted_count += 1;
+		}
 	}

 	/*
@@ -619,6 +643,20 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 		beentry->st_activity_start_timestamp = start_timestamp;
 	}

+	if (beentry->st_backendType == B_BACKEND) {
+		beentry->st_session.active_time += st_session_diff.active_time;
+		beentry->st_session.active_count += st_session_diff.active_count;
+
+		beentry->st_session.idle_time += st_session_diff.idle_time;
+		beentry->st_session.idle_count += st_session_diff.idle_count;
+
+		beentry->st_session.idle_in_transaction_time += st_session_diff.idle_in_transaction_time;
+		beentry->st_session.idle_in_transaction_count += st_session_diff.idle_in_transaction_count;
+
+		beentry->st_session.idle_in_transaction_aborted_time += st_session_diff.idle_in_transaction_aborted_time;
+		beentry->st_session.idle_in_transaction_aborted_count += st_session_diff.idle_in_transaction_aborted_count;
+	}
+
 	PGSTAT_END_WRITE_ACTIVITY(beentry);
 }

diff --git a/src/backend/utils/adt/pgstatfuncs.c b/src/backend/utils/adt/pgstatfuncs.c
index 30a2063505..a4a8c7204c 100644
--- a/src/backend/utils/adt/pgstatfuncs.c
+++ b/src/backend/utils/adt/pgstatfuncs.c
@@ -298,6 +298,76 @@ pg_stat_get_progress_info(PG_FUNCTION_ARGS)
 	return (Datum) 0;
 }

+/*
+ * Returns accumulated statistics of current PG backends.
+ */
+Datum
+pg_stat_get_session(PG_FUNCTION_ARGS)
+{
+#define PG_STAT_GET_SESSION_COLS	9
+	int			num_backends = pgstat_fetch_stat_numbackends();
+	int			curr_backend;
+	int			pid = PG_ARGISNULL(0) ? -1 : PG_GETARG_INT32(0);
+	ReturnSetInfo *rsinfo = (ReturnSetInfo *) fcinfo->resultinfo;
+
+	InitMaterializedSRF(fcinfo, 0);
+
+	/* 1-based index */
+	for (curr_backend = 1; curr_backend <= num_backends; curr_backend++)
+	{
+		/* for each row */
+		Datum		values[PG_STAT_GET_SESSION_COLS] = {0};
+		bool		nulls[PG_STAT_GET_SESSION_COLS] = {0};
+		LocalPgBackendStatus *local_beentry;
+		PgBackendStatus *beentry;
+
+		/* Get the next one in the list */
+		local_beentry = pgstat_get_local_beentry_by_index(curr_backend);
+		beentry = &local_beentry->backendStatus;
+
+		/* Report statistics only for client backends */
+		if (beentry->st_backendType != B_BACKEND)
+			continue;
+
+		/* If looking for specific PID, ignore all the others */
+		if (pid != -1 && beentry->st_procpid != pid)
+			continue;
+
+		/* Values available to all callers */
+		values[0] = Int32GetDatum(beentry->st_procpid);
+
+		/* Values only available to role member or pg_read_all_stats */
+		if (HAS_PGSTAT_PERMISSIONS(beentry->st_userid)){
+			/* convert to msec */
+			values[1] = Float8GetDatum(beentry->st_session.active_time / 1000.0);
+			values[2] = Int64GetDatum(beentry->st_session.active_count);
+			values[3] = Float8GetDatum(beentry->st_session.idle_time / 1000.0);
+			values[4] = Int64GetDatum(beentry->st_session.idle_count);
+			values[5] = Float8GetDatum(beentry->st_session.idle_in_transaction_time / 1000.0);
+			values[6] = Int64GetDatum(beentry->st_session.idle_in_transaction_count);
+			values[7] = Float8GetDatum(beentry->st_session.idle_in_transaction_aborted_time / 1000.0);
+			values[8] = Int64GetDatum(beentry->st_session.idle_in_transaction_aborted_count);
+		} else {
+			nulls[1] = true;
+			nulls[2] = true;
+			nulls[3] = true;
+			nulls[4] = true;
+			nulls[5] = true;
+			nulls[6] = true;
+			nulls[7] = true;
+			nulls[8] = true;
+		}
+
+		tuplestore_putvalues(rsinfo->setResult, rsinfo->setDesc, values, nulls);
+
+		/* If only a single backend was requested, and we found it, break. */
+		if (pid != -1)
+			break;
+	}
+
+	return (Datum) 0;
+}
+
 /*
  * Returns activity of PG backends.
  */
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index 29af4ce65d..1c81f70f9b 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -5450,6 +5450,15 @@
   proargtypes => '', proallargtypes => '{text,text,text}',
   proargmodes => '{o,o,o}', proargnames => '{type,name,description}',
   prosrc => 'pg_get_wait_events' },
+{ oid => '2173',
+  descr => 'statistics: cumulative information about currently active client backends',
+  proname => 'pg_stat_get_session', prorows => '100', proisstrict => 'f',
+  proretset => 't', provolatile => 's', proparallel => 'r',
+  prorettype => 'record', proargtypes => 'int4',
+  proallargtypes => '{int4,int4,float8,int8,float8,int8,float8,int8,float8,int8}',
+  proargmodes => '{i,o,o,o,o,o,o,o,o,o}',
+  proargnames => '{pid,pid,active_time,active_count,idle_time,idle_count,idle_in_transaction_time,idle_in_transaction_count,idle_in_transaction_aborted_time,idle_in_transaction_aborted_count}',
+  prosrc => 'pg_stat_get_session' },
 { oid => '3318',
   descr => 'statistics: information about progress of backends running maintenance command',
   proname => 'pg_stat_get_progress_info', prorows => '100', proretset => 't',
diff --git a/src/include/utils/backend_status.h b/src/include/utils/backend_status.h
index 7b8a34f64f..830df6b9fa 100644
--- a/src/include/utils/backend_status.h
+++ b/src/include/utils/backend_status.h
@@ -81,6 +81,24 @@ typedef struct PgBackendGSSStatus

 } PgBackendGSSStatus;

+/*
+ * PgBackendSessionStatus
+ *
+ * For each session, we keep counters accumulated since the start of the session
+ * in a separate struct. The struct is always filled.
+ *
+ */
+typedef struct PgBackendSessionStatus
+{
+	int64		active_time;
+	int64		active_count;
+	int64		idle_time;
+	int64		idle_count;
+	int64		idle_in_transaction_time;
+	int64		idle_in_transaction_count;
+	int64		idle_in_transaction_aborted_time;
+	int64		idle_in_transaction_aborted_count;
+} PgBackendSessionStatus;

 /* ----------
  * PgBackendStatus
@@ -170,6 +188,9 @@ typedef struct PgBackendStatus

 	/* query identifier, optionally computed using post_parse_analyze_hook */
 	uint64		st_query_id;
+
+	/* Counters accumulated since the start of the session */
+	PgBackendSessionStatus st_session;
 } PgBackendStatus;


@@ -234,6 +255,17 @@ typedef struct PgBackendStatus
 	 ((before_changecount) & 1) == 0)


+/* Macros to identify the states for time accounting */
+#define PGSTAT_IS_ACTIVE(s) \
+	((s)->st_state == STATE_RUNNING || (s)->st_state == STATE_FASTPATH)
+#define PGSTAT_IS_IDLE(s) \
+	((s)->st_state == STATE_IDLE)
+#define PGSTAT_IS_IDLEINTRANSACTION(s) \
+	((s)->st_state == STATE_IDLEINTRANSACTION)
+#define PGSTAT_IS_IDLEINTRANSACTION_ABORTED(s) \
+	((s)->st_state == STATE_IDLEINTRANSACTION_ABORTED)
+
+
 /* ----------
  * LocalPgBackendStatus
  *
diff --git a/src/test/regress/expected/rules.out b/src/test/regress/expected/rules.out
index abc944e8b8..108b5efd15 100644
--- a/src/test/regress/expected/rules.out
+++ b/src/test/regress/expected/rules.out
@@ -2100,6 +2100,16 @@ pg_stat_replication_slots| SELECT s.slot_name,
    FROM pg_replication_slots r,
     LATERAL pg_stat_get_replication_slot((r.slot_name)::text) s(slot_name, spill_txns, spill_count, spill_bytes, stream_txns, stream_count, stream_bytes, total_txns, total_bytes, stats_reset)
   WHERE (r.datoid IS NOT NULL);
+pg_stat_session| SELECT pid,
+    active_time,
+    active_count,
+    idle_time,
+    idle_count,
+    idle_in_transaction_time,
+    idle_in_transaction_count,
+    idle_in_transaction_aborted_time,
+    idle_in_transaction_aborted_count
+   FROM pg_stat_get_session(NULL::integer) s(pid, active_time, active_count, idle_time, idle_count, idle_in_transaction_time, idle_in_transaction_count, idle_in_transaction_aborted_time, idle_in_transaction_aborted_count);
 pg_stat_slru| SELECT name,
     blks_zeroed,
     blks_hit,
diff --git a/src/test/regress/expected/sysviews.out b/src/test/regress/expected/sysviews.out
index 9be7aca2b8..d3fe88b6a5 100644
--- a/src/test/regress/expected/sysviews.out
+++ b/src/test/regress/expected/sysviews.out
@@ -185,3 +185,10 @@ select count(distinct utc_offset) >= 24 as ok from pg_timezone_abbrevs;
  t
 (1 row)

+select idle_count as prev_idle_count from pg_stat_session where pid = pg_backend_pid() \gset
+select (select idle_count from pg_stat_session where pid = pg_backend_pid()) - :prev_idle_count = 1 as ok;
+ ok
+----
+ t
+(1 row)
+
diff --git a/src/test/regress/sql/sysviews.sql b/src/test/regress/sql/sysviews.sql
index 6b4e24601d..910d6a6851 100644
--- a/src/test/regress/sql/sysviews.sql
+++ b/src/test/regress/sql/sysviews.sql
@@ -72,3 +72,6 @@ set timezone_abbreviations = 'Australia';
 select count(distinct utc_offset) >= 24 as ok from pg_timezone_abbrevs;
 set timezone_abbreviations = 'India';
 select count(distinct utc_offset) >= 24 as ok from pg_timezone_abbrevs;
+
+select idle_count as prev_idle_count from pg_stat_session where pid = pg_backend_pid() \gset
+select (select idle_count from pg_stat_session where pid = pg_backend_pid()) - :prev_idle_count = 1 as ok;
\ No newline at end of file
--
2.34.1

#49Sergey Dudoladov
sergey.dudoladov@gmail.com
In reply to: Sergey Dudoladov (#48)
1 attachment(s)
Re: Add connection active, idle time to pg_stat_activity

Hi again,

It looks like we can check increments in all fields playing with

transactions in tests.

I've added such tests.

Regards,
Sergey

Attachments:

0004-Add-pg_stat_session.patchtext/x-patch; charset=US-ASCII; name=0004-Add-pg_stat_session.patchDownload
From 66ac1efe5424aa1385744a60047ffd44d42dd244 Mon Sep 17 00:00:00 2001
From: Sergey Dudoladov <sergey.dudoladov@gmail.com>
Date: Thu, 1 Feb 2024 16:11:36 +0100
Subject: [PATCH] Add pg_stat_session

Author: Sergey Dudoladov

Adds pg_stat_session view to track statistics accumulated during
 lifetime of a session (client backend).

catversion bump is necessary due to a new view / function

Reviewed-by: Aleksander Alekseev, Bertrand Drouvot, Atsushi
Torikoshi, and Andrei Zubkov

Discussion:
https://www.postgresql.org/message-id/flat/CA%2BFpmFcJF0vwi-SWW0wYO-c-FbhyawLq4tCpRDCJJ8Bq%3Dja-gA%40mail.gmail.com
---
 doc/src/sgml/monitoring.sgml                | 134 ++++++++++++++++++++
 src/backend/catalog/system_views.sql        |  13 ++
 src/backend/utils/activity/backend_status.c |  64 ++++++++--
 src/backend/utils/adt/pgstatfuncs.c         |  70 ++++++++++
 src/include/catalog/pg_proc.dat             |   9 ++
 src/include/utils/backend_status.h          |  32 +++++
 src/test/regress/expected/rules.out         |  10 ++
 src/test/regress/expected/sysviews.out      |  37 ++++++
 src/test/regress/sql/sysviews.sql           |  17 +++
 9 files changed, 373 insertions(+), 13 deletions(-)

diff --git a/doc/src/sgml/monitoring.sgml b/doc/src/sgml/monitoring.sgml
index d9b8b37585..b10423428a 100644
--- a/doc/src/sgml/monitoring.sgml
+++ b/doc/src/sgml/monitoring.sgml
@@ -414,6 +414,20 @@ postgres   27093  0.0  0.0  30096  2752 ?        Ss   11:34   0:00 postgres: ser
        See <xref linkend="copy-progress-reporting"/>.
       </entry>
      </row>
+
+     <row>
+      <entry>
+       <structname>pg_stat_session</structname>
+       <indexterm><primary>pg_stat_session</primary></indexterm>
+      </entry>
+      <entry>
+       One row per client backend, showing information related to
+       the currently accumulated activity of that process, such as time spent in
+       a certain state.
+       See <link linkend="monitoring-pg-stat-session-view">
+       <structname>pg_stat_session</structname></link> for details.
+      </entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
@@ -4589,6 +4603,110 @@ description | Waiting for a newly initialized WAL file to reach durable storage
    </tgroup>
   </table>
 
+  <table id="monitoring-pg-stat-session-view" xreflabel="pg_stat_session">
+   <title><structname>pg_stat_session</structname> View</title>
+   <tgroup cols="1">
+    <thead>
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       Column Type
+      </para>
+      <para>
+       Description
+      </para></entry>
+     </row>
+    </thead>
+
+    <tbody>
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>pid</structfield> <type>integer</type>
+      </para>
+      <para>
+       Process ID of this client backend.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>active_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in the <literal>running</literal> or <literal>fastpath</literal> state.
+      </para></entry>
+     </row>
+
+    <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>active_count</structfield> <type>bigint</type>
+      </para>
+      <para>
+       Number of times this backend switched to the <literal>running</literal> or <literal>fastpath</literal> state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>idle_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in the <literal>idle</literal> state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>idle_count</structfield> <type>bigint</type>
+      </para>
+      <para>
+       Number of times this backend switched to the <literal>idle</literal> state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>idle_in_transaction_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in the <literal>idle in transaction</literal>
+       state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>idle_in_transaction_count</structfield> <type>bigint</type>
+      </para>
+      <para>
+       Number of times this backend switched to the <literal>idle in transaction</literal>
+       state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>idle_in_transaction_aborted_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in the <literal>idle in transaction (aborted)</literal>
+       state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>idle_in_transaction_aborted_count</structfield> <type>bigint</type>
+      </para>
+      <para>
+       Number of times this backend switched to the <literal>idle in transaction (aborted)</literal>
+       state.
+      </para></entry>
+     </row>
+
+    </tbody>
+   </tgroup>
+  </table>
+
  </sect2>
 
  <sect2 id="monitoring-stats-functions">
@@ -5128,6 +5246,22 @@ FROM pg_stat_get_backend_idset() AS backendid;
        </para></entry>
       </row>
 
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>pg_stat_get_session</primary>
+        </indexterm>
+        <function>pg_stat_get_session</function> ( <type>integer</type> )
+        <returnvalue>setof record</returnvalue>
+       </para>
+       <para>
+        Returns a record of information about the client backend with the specified
+        process ID, or one record for each active backend in the system
+        if <literal>NULL</literal> is specified.  The fields returned are a
+        subset of those in the <structname>pg_stat_session</structname> view.
+       </para></entry>
+      </row>
+
       <row>
        <entry role="func_table_entry"><para role="func_signature">
         <indexterm>
diff --git a/src/backend/catalog/system_views.sql b/src/backend/catalog/system_views.sql
index 6791bff9dd..79db3af28b 100644
--- a/src/backend/catalog/system_views.sql
+++ b/src/backend/catalog/system_views.sql
@@ -893,6 +893,19 @@ CREATE VIEW pg_stat_activity AS
         LEFT JOIN pg_database AS D ON (S.datid = D.oid)
         LEFT JOIN pg_authid AS U ON (S.usesysid = U.oid);
 
+CREATE VIEW pg_stat_session AS
+    SELECT
+            s.pid,
+            s.active_time,
+            s.active_count,
+            s.idle_time,
+            s.idle_count,
+            s.idle_in_transaction_time,
+            s.idle_in_transaction_count,
+            s.idle_in_transaction_aborted_time,
+            s.idle_in_transaction_aborted_count
+     FROM pg_stat_get_session(NULL) as s;
+
 CREATE VIEW pg_stat_replication AS
     SELECT
             S.pid,
diff --git a/src/backend/utils/activity/backend_status.c b/src/backend/utils/activity/backend_status.c
index 1a1050c8da..31763a1efd 100644
--- a/src/backend/utils/activity/backend_status.c
+++ b/src/backend/utils/activity/backend_status.c
@@ -338,6 +338,8 @@ pgstat_bestart(void)
 	lbeentry.st_xact_start_timestamp = 0;
 	lbeentry.st_databaseid = MyDatabaseId;
 
+	MemSet(&lbeentry.st_session, 0, sizeof(lbeentry.st_session));
+
 	/* We have userid for client-backends, wal-sender and bgworker processes */
 	if (lbeentry.st_backendType == B_BACKEND
 		|| lbeentry.st_backendType == B_WAL_SENDER
@@ -526,6 +528,9 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 	TimestampTz current_timestamp;
 	int			len = 0;
 
+	PgBackendSessionStatus st_session_diff;
+	MemSet(&st_session_diff, 0, sizeof(st_session_diff));
+
 	TRACE_POSTGRESQL_STATEMENT_STATUS(cmd_str);
 
 	if (!beentry)
@@ -551,6 +556,7 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 			beentry->st_xact_start_timestamp = 0;
 			beentry->st_query_id = UINT64CONST(0);
 			proc->wait_event_info = 0;
+			MemSet(&beentry->st_session, 0, sizeof(beentry->st_session));
 			PGSTAT_END_WRITE_ACTIVITY(beentry);
 		}
 		return;
@@ -573,27 +579,45 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 	current_timestamp = GetCurrentTimestamp();
 
 	/*
-	 * If the state has changed from "active" or "idle in transaction",
-	 * calculate the duration.
+	 * If a client backend has changed state, update per-database and per-session counters.
 	 */
-	if ((beentry->st_state == STATE_RUNNING ||
-		 beentry->st_state == STATE_FASTPATH ||
-		 beentry->st_state == STATE_IDLEINTRANSACTION ||
-		 beentry->st_state == STATE_IDLEINTRANSACTION_ABORTED) &&
-		state != beentry->st_state)
+	if ((PGSTAT_IS_ACTIVE(beentry) ||
+		 PGSTAT_IS_IDLEINTRANSACTION(beentry) ||
+		 PGSTAT_IS_IDLEINTRANSACTION_ABORTED(beentry) ||
+		 PGSTAT_IS_IDLE(beentry)) &&
+		state != beentry->st_state &&
+		beentry->st_backendType == B_BACKEND)
 	{
 		long		secs;
 		int			usecs;
+		int64		usecs_diff;
 
 		TimestampDifference(beentry->st_state_start_timestamp,
 							current_timestamp,
 							&secs, &usecs);
-
-		if (beentry->st_state == STATE_RUNNING ||
-			beentry->st_state == STATE_FASTPATH)
-			pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 + usecs);
-		else
-			pgstat_count_conn_txn_idle_time((PgStat_Counter) secs * 1000000 + usecs);
+		usecs_diff = secs * 1000000 + usecs;
+
+		/* compute values for pg_stat_database */
+		if (PGSTAT_IS_ACTIVE(beentry))
+			pgstat_count_conn_active_time((PgStat_Counter) usecs_diff);
+		else if (PGSTAT_IS_IDLEINTRANSACTION(beentry) ||
+				 PGSTAT_IS_IDLEINTRANSACTION_ABORTED(beentry))
+			pgstat_count_conn_txn_idle_time((PgStat_Counter) usecs_diff);
+
+		/* compute values for pg_stat_session */
+		if (PGSTAT_IS_ACTIVE(beentry)) {
+			st_session_diff.active_time = usecs_diff;
+			st_session_diff.active_count += 1;
+		} else if (PGSTAT_IS_IDLE(beentry)){
+			st_session_diff.idle_time = usecs_diff;
+			st_session_diff.idle_count += 1;
+		} else if (PGSTAT_IS_IDLEINTRANSACTION(beentry)){
+			st_session_diff.idle_in_transaction_time = usecs_diff;
+			st_session_diff.idle_in_transaction_count += 1;
+		} else if (PGSTAT_IS_IDLEINTRANSACTION_ABORTED(beentry)){
+			st_session_diff.idle_in_transaction_aborted_time = usecs_diff;
+			st_session_diff.idle_in_transaction_aborted_count += 1;
+		}
 	}
 
 	/*
@@ -619,6 +643,20 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 		beentry->st_activity_start_timestamp = start_timestamp;
 	}
 
+	if (beentry->st_backendType == B_BACKEND) {
+		beentry->st_session.active_time += st_session_diff.active_time;
+		beentry->st_session.active_count += st_session_diff.active_count;
+
+		beentry->st_session.idle_time += st_session_diff.idle_time;
+		beentry->st_session.idle_count += st_session_diff.idle_count;
+
+		beentry->st_session.idle_in_transaction_time += st_session_diff.idle_in_transaction_time;
+		beentry->st_session.idle_in_transaction_count += st_session_diff.idle_in_transaction_count;
+
+		beentry->st_session.idle_in_transaction_aborted_time += st_session_diff.idle_in_transaction_aborted_time;
+		beentry->st_session.idle_in_transaction_aborted_count += st_session_diff.idle_in_transaction_aborted_count;
+	}
+
 	PGSTAT_END_WRITE_ACTIVITY(beentry);
 }
 
diff --git a/src/backend/utils/adt/pgstatfuncs.c b/src/backend/utils/adt/pgstatfuncs.c
index 30a2063505..a4a8c7204c 100644
--- a/src/backend/utils/adt/pgstatfuncs.c
+++ b/src/backend/utils/adt/pgstatfuncs.c
@@ -298,6 +298,76 @@ pg_stat_get_progress_info(PG_FUNCTION_ARGS)
 	return (Datum) 0;
 }
 
+/*
+ * Returns accumulated statistics of current PG backends.
+ */
+Datum
+pg_stat_get_session(PG_FUNCTION_ARGS)
+{
+#define PG_STAT_GET_SESSION_COLS	9
+	int			num_backends = pgstat_fetch_stat_numbackends();
+	int			curr_backend;
+	int			pid = PG_ARGISNULL(0) ? -1 : PG_GETARG_INT32(0);
+	ReturnSetInfo *rsinfo = (ReturnSetInfo *) fcinfo->resultinfo;
+
+	InitMaterializedSRF(fcinfo, 0);
+
+	/* 1-based index */
+	for (curr_backend = 1; curr_backend <= num_backends; curr_backend++)
+	{
+		/* for each row */
+		Datum		values[PG_STAT_GET_SESSION_COLS] = {0};
+		bool		nulls[PG_STAT_GET_SESSION_COLS] = {0};
+		LocalPgBackendStatus *local_beentry;
+		PgBackendStatus *beentry;
+
+		/* Get the next one in the list */
+		local_beentry = pgstat_get_local_beentry_by_index(curr_backend);
+		beentry = &local_beentry->backendStatus;
+
+		/* Report statistics only for client backends */
+		if (beentry->st_backendType != B_BACKEND)
+			continue;
+
+		/* If looking for specific PID, ignore all the others */
+		if (pid != -1 && beentry->st_procpid != pid)
+			continue;
+
+		/* Values available to all callers */
+		values[0] = Int32GetDatum(beentry->st_procpid);
+
+		/* Values only available to role member or pg_read_all_stats */
+		if (HAS_PGSTAT_PERMISSIONS(beentry->st_userid)){
+			/* convert to msec */
+			values[1] = Float8GetDatum(beentry->st_session.active_time / 1000.0);
+			values[2] = Int64GetDatum(beentry->st_session.active_count);
+			values[3] = Float8GetDatum(beentry->st_session.idle_time / 1000.0);
+			values[4] = Int64GetDatum(beentry->st_session.idle_count);
+			values[5] = Float8GetDatum(beentry->st_session.idle_in_transaction_time / 1000.0);
+			values[6] = Int64GetDatum(beentry->st_session.idle_in_transaction_count);
+			values[7] = Float8GetDatum(beentry->st_session.idle_in_transaction_aborted_time / 1000.0);
+			values[8] = Int64GetDatum(beentry->st_session.idle_in_transaction_aborted_count);
+		} else {
+			nulls[1] = true;
+			nulls[2] = true;
+			nulls[3] = true;
+			nulls[4] = true;
+			nulls[5] = true;
+			nulls[6] = true;
+			nulls[7] = true;
+			nulls[8] = true;
+		}
+
+		tuplestore_putvalues(rsinfo->setResult, rsinfo->setDesc, values, nulls);
+
+		/* If only a single backend was requested, and we found it, break. */
+		if (pid != -1)
+			break;
+	}
+
+	return (Datum) 0;
+}
+
 /*
  * Returns activity of PG backends.
  */
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index 29af4ce65d..1c81f70f9b 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -5450,6 +5450,15 @@
   proargtypes => '', proallargtypes => '{text,text,text}',
   proargmodes => '{o,o,o}', proargnames => '{type,name,description}',
   prosrc => 'pg_get_wait_events' },
+{ oid => '2173',
+  descr => 'statistics: cumulative information about currently active client backends',
+  proname => 'pg_stat_get_session', prorows => '100', proisstrict => 'f',
+  proretset => 't', provolatile => 's', proparallel => 'r',
+  prorettype => 'record', proargtypes => 'int4',
+  proallargtypes => '{int4,int4,float8,int8,float8,int8,float8,int8,float8,int8}',
+  proargmodes => '{i,o,o,o,o,o,o,o,o,o}',
+  proargnames => '{pid,pid,active_time,active_count,idle_time,idle_count,idle_in_transaction_time,idle_in_transaction_count,idle_in_transaction_aborted_time,idle_in_transaction_aborted_count}',
+  prosrc => 'pg_stat_get_session' },
 { oid => '3318',
   descr => 'statistics: information about progress of backends running maintenance command',
   proname => 'pg_stat_get_progress_info', prorows => '100', proretset => 't',
diff --git a/src/include/utils/backend_status.h b/src/include/utils/backend_status.h
index 7b8a34f64f..830df6b9fa 100644
--- a/src/include/utils/backend_status.h
+++ b/src/include/utils/backend_status.h
@@ -81,6 +81,24 @@ typedef struct PgBackendGSSStatus
 
 } PgBackendGSSStatus;
 
+/*
+ * PgBackendSessionStatus
+ *
+ * For each session, we keep counters accumulated since the start of the session
+ * in a separate struct. The struct is always filled.
+ *
+ */
+typedef struct PgBackendSessionStatus
+{
+	int64		active_time;
+	int64		active_count;
+	int64		idle_time;
+	int64		idle_count;
+	int64		idle_in_transaction_time;
+	int64		idle_in_transaction_count;
+	int64		idle_in_transaction_aborted_time;
+	int64		idle_in_transaction_aborted_count;
+} PgBackendSessionStatus;
 
 /* ----------
  * PgBackendStatus
@@ -170,6 +188,9 @@ typedef struct PgBackendStatus
 
 	/* query identifier, optionally computed using post_parse_analyze_hook */
 	uint64		st_query_id;
+
+	/* Counters accumulated since the start of the session */
+	PgBackendSessionStatus st_session;
 } PgBackendStatus;
 
 
@@ -234,6 +255,17 @@ typedef struct PgBackendStatus
 	 ((before_changecount) & 1) == 0)
 
 
+/* Macros to identify the states for time accounting */
+#define PGSTAT_IS_ACTIVE(s) \
+	((s)->st_state == STATE_RUNNING || (s)->st_state == STATE_FASTPATH)
+#define PGSTAT_IS_IDLE(s) \
+	((s)->st_state == STATE_IDLE)
+#define PGSTAT_IS_IDLEINTRANSACTION(s) \
+	((s)->st_state == STATE_IDLEINTRANSACTION)
+#define PGSTAT_IS_IDLEINTRANSACTION_ABORTED(s) \
+	((s)->st_state == STATE_IDLEINTRANSACTION_ABORTED)
+
+
 /* ----------
  * LocalPgBackendStatus
  *
diff --git a/src/test/regress/expected/rules.out b/src/test/regress/expected/rules.out
index abc944e8b8..108b5efd15 100644
--- a/src/test/regress/expected/rules.out
+++ b/src/test/regress/expected/rules.out
@@ -2100,6 +2100,16 @@ pg_stat_replication_slots| SELECT s.slot_name,
    FROM pg_replication_slots r,
     LATERAL pg_stat_get_replication_slot((r.slot_name)::text) s(slot_name, spill_txns, spill_count, spill_bytes, stream_txns, stream_count, stream_bytes, total_txns, total_bytes, stats_reset)
   WHERE (r.datoid IS NOT NULL);
+pg_stat_session| SELECT pid,
+    active_time,
+    active_count,
+    idle_time,
+    idle_count,
+    idle_in_transaction_time,
+    idle_in_transaction_count,
+    idle_in_transaction_aborted_time,
+    idle_in_transaction_aborted_count
+   FROM pg_stat_get_session(NULL::integer) s(pid, active_time, active_count, idle_time, idle_count, idle_in_transaction_time, idle_in_transaction_count, idle_in_transaction_aborted_time, idle_in_transaction_aborted_count);
 pg_stat_slru| SELECT name,
     blks_zeroed,
     blks_hit,
diff --git a/src/test/regress/expected/sysviews.out b/src/test/regress/expected/sysviews.out
index 9be7aca2b8..42b04d198b 100644
--- a/src/test/regress/expected/sysviews.out
+++ b/src/test/regress/expected/sysviews.out
@@ -185,3 +185,40 @@ select count(distinct utc_offset) >= 24 as ok from pg_timezone_abbrevs;
  t
 (1 row)
 
+select active_count as prev_active_count from pg_stat_session where pid = pg_backend_pid() \gset
+select (select active_count from pg_stat_session where pid = pg_backend_pid()) - :prev_active_count = 1 as ok;
+ ok 
+----
+ t
+(1 row)
+
+select idle_count as prev_idle_count from pg_stat_session where pid = pg_backend_pid() \gset
+select (select idle_count from pg_stat_session where pid = pg_backend_pid()) - :prev_idle_count = 1 as ok;
+ ok 
+----
+ t
+(1 row)
+
+select idle_in_transaction_count as prev_idle_in_transaction_count from pg_stat_session where pid = pg_backend_pid() \gset
+begin;
+commit;
+select (select idle_in_transaction_count from pg_stat_session where pid = pg_backend_pid()) - :prev_idle_in_transaction_count = 1 as ok;
+ ok 
+----
+ t
+(1 row)
+
+select idle_in_transaction_aborted_count as prev_idle_in_transaction_aborted_count from pg_stat_session where pid = pg_backend_pid() \gset
+begin;
+select non_existent_function();
+ERROR:  function non_existent_function() does not exist
+LINE 1: select non_existent_function();
+               ^
+HINT:  No function matches the given name and argument types. You might need to add explicit type casts.
+rollback;
+select (select idle_in_transaction_aborted_count from pg_stat_session where pid = pg_backend_pid()) - :prev_idle_in_transaction_aborted_count = 1 as ok;
+ ok 
+----
+ t
+(1 row)
+
diff --git a/src/test/regress/sql/sysviews.sql b/src/test/regress/sql/sysviews.sql
index 6b4e24601d..593a3176ca 100644
--- a/src/test/regress/sql/sysviews.sql
+++ b/src/test/regress/sql/sysviews.sql
@@ -72,3 +72,20 @@ set timezone_abbreviations = 'Australia';
 select count(distinct utc_offset) >= 24 as ok from pg_timezone_abbrevs;
 set timezone_abbreviations = 'India';
 select count(distinct utc_offset) >= 24 as ok from pg_timezone_abbrevs;
+
+select active_count as prev_active_count from pg_stat_session where pid = pg_backend_pid() \gset
+select (select active_count from pg_stat_session where pid = pg_backend_pid()) - :prev_active_count = 1 as ok;
+
+select idle_count as prev_idle_count from pg_stat_session where pid = pg_backend_pid() \gset
+select (select idle_count from pg_stat_session where pid = pg_backend_pid()) - :prev_idle_count = 1 as ok;
+
+select idle_in_transaction_count as prev_idle_in_transaction_count from pg_stat_session where pid = pg_backend_pid() \gset
+begin;
+commit;
+select (select idle_in_transaction_count from pg_stat_session where pid = pg_backend_pid()) - :prev_idle_in_transaction_count = 1 as ok;
+
+select idle_in_transaction_aborted_count as prev_idle_in_transaction_aborted_count from pg_stat_session where pid = pg_backend_pid() \gset
+begin;
+select non_existent_function();
+rollback;
+select (select idle_in_transaction_aborted_count from pg_stat_session where pid = pg_backend_pid()) - :prev_idle_in_transaction_aborted_count = 1 as ok;
\ No newline at end of file
-- 
2.34.1

#50Andrei Zubkov
zubkov@moonset.ru
In reply to: Sergey Dudoladov (#49)
Re: Add connection active, idle time to pg_stat_activity

Hi Sergei,

I still would like to maintaint the focus on committing the "idle in

transactions" part of pg_stat_session first.

Agreed.

I've done a review of version 0004. This version is applied successful
over ce571434ae7, installcheck passed. The behavior of pg_stat_session
view and corresponding function looks correct. I've didn't found any
issues in the code.

Notes about the current state of a patch:

Naming
the view and function names 'pg_stat_session' seems correct for this
particular scope of a patch. However possible future resource
consumption statistics are valid for all backends (vacuum for example).
Right now it is not clear for me if we can get resource statistics from
those backends while those are listed in the pg_stat_activity view but
renaming to something like 'pg_stat_backend' seems reasonable to me.

Docs
1. session states referenced in monitoring.sgml is not uniform with
those of the pg_stat_activity view.
monitoring.sgml:4635
monitoring.sgml:4644
+ Time in milliseconds this backend spent in the
<literal>running</literal> or <literal>fastpath</literal> state.
I think those states should be referenced uniformly with
pg_stat_activity.

2. Description of the 'pg_stat_get_session()' function might be as
follows:

Returns a row, showing statistics about the client backend with the
specified process ID, or one row per client backend if
<literal>NULL</literal> is specified. The fields returned are the
same as those of <structname>pg_stat_session</structname> view.

The main thought here is to get rid of 'each active backend' because
'active backend' looks like backend in the 'active' state.

Tests
Call to a non-existing function is depend on non-existence of a
function, which can't be guaranteed absolutely. How about to do some
kind of obvious error here? Couple examples follows:

SELECT 0/0;

- or -

DO $$
BEGIN
RAISE 'test error';
END;
$$ LANGUAGE plpgsql;

My personal choice would be the last one.

--
regards, Andrei Zubkov
Postgres Professional

#51Sergey Dudoladov
sergey.dudoladov@gmail.com
In reply to: Andrei Zubkov (#50)
1 attachment(s)
Re: Add connection active, idle time to pg_stat_activity

Hello, hackers.

I've attached the fifth version of the patch that incorporates suggestions
from Andrei.
The version runs successfully on top of 8fcd80258bcf43dab93d877

Right now it is not clear for me if we can get resource statistics from
those backends while those are listed in the pg_stat_activity view but
renaming to something like 'pg_stat_backend' seems reasonable to me.

For now I kept the "pg_stat_session" naming because I don't know how
desirable it is to collect the
resource statistics in this view given that a plenty of other pg_stat_*
views exists for other backends.

Regards,
Sergey.

Attachments:

0005-Add-pg_stat_session.patchtext/x-patch; charset=US-ASCII; name=0005-Add-pg_stat_session.patchDownload
From 54e4d85a6382fbb4baf4575c99310a6a61a738ac Mon Sep 17 00:00:00 2001
From: Sergey Dudoladov <sergey.dudoladov@gmail.com>
Date: Thu, 1 Feb 2024 16:11:36 +0100
Subject: [PATCH] Add pg_stat_session

Author: Sergey Dudoladov

Adds pg_stat_session view to track statistics accumulated during
 lifetime of a session (client backend).

catversion bump is necessary due to a new view / function

Reviewed-by: Aleksander Alekseev, Bertrand Drouvot, Atsushi
Torikoshi, and Andrei Zubkov

Discussion:
https://www.postgresql.org/message-id/flat/CA%2BFpmFcJF0vwi-SWW0wYO-c-FbhyawLq4tCpRDCJJ8Bq%3Dja-gA%40mail.gmail.com
---
 doc/src/sgml/monitoring.sgml                | 134 ++++++++++++++++++++
 src/backend/catalog/system_views.sql        |  13 ++
 src/backend/utils/activity/backend_status.c |  64 ++++++++--
 src/backend/utils/adt/pgstatfuncs.c         |  70 ++++++++++
 src/include/catalog/pg_proc.dat             |   9 ++
 src/include/utils/backend_status.h          |  32 +++++
 src/test/regress/expected/rules.out         |  10 ++
 src/test/regress/expected/sysviews.out      |  39 ++++++
 src/test/regress/sql/sysviews.sql           |  21 +++
 9 files changed, 379 insertions(+), 13 deletions(-)

diff --git a/doc/src/sgml/monitoring.sgml b/doc/src/sgml/monitoring.sgml
index 840d7f8161..33c98425b4 100644
--- a/doc/src/sgml/monitoring.sgml
+++ b/doc/src/sgml/monitoring.sgml
@@ -414,6 +414,20 @@ postgres   27093  0.0  0.0  30096  2752 ?        Ss   11:34   0:00 postgres: ser
        See <xref linkend="copy-progress-reporting"/>.
       </entry>
      </row>
+
+     <row>
+      <entry>
+       <structname>pg_stat_session</structname>
+       <indexterm><primary>pg_stat_session</primary></indexterm>
+      </entry>
+      <entry>
+       One row per client backend, showing information related to
+       the currently accumulated activity of that process, such as time spent in
+       a certain state.
+       See <link linkend="monitoring-pg-stat-session-view">
+       <structname>pg_stat_session</structname></link> for details.
+      </entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
@@ -4739,6 +4753,110 @@ description | Waiting for a newly initialized WAL file to reach durable storage
    </tgroup>
   </table>
 
+  <table id="monitoring-pg-stat-session-view" xreflabel="pg_stat_session">
+   <title><structname>pg_stat_session</structname> View</title>
+   <tgroup cols="1">
+    <thead>
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       Column Type
+      </para>
+      <para>
+       Description
+      </para></entry>
+     </row>
+    </thead>
+
+    <tbody>
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>pid</structfield> <type>integer</type>
+      </para>
+      <para>
+       Process ID of this client backend.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>active_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in the <literal>running</literal> or <literal>fastpath</literal> state.
+      </para></entry>
+     </row>
+
+    <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>active_count</structfield> <type>bigint</type>
+      </para>
+      <para>
+       Number of times this backend switched to the <literal>running</literal> or <literal>fastpath</literal> state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>idle_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in the <literal>idle</literal> state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>idle_count</structfield> <type>bigint</type>
+      </para>
+      <para>
+       Number of times this backend switched to the <literal>idle</literal> state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>idle_in_transaction_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in the <literal>idle in transaction</literal>
+       state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>idle_in_transaction_count</structfield> <type>bigint</type>
+      </para>
+      <para>
+       Number of times this backend switched to the <literal>idle in transaction</literal>
+       state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>idle_in_transaction_aborted_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in the <literal>idle in transaction (aborted)</literal>
+       state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>idle_in_transaction_aborted_count</structfield> <type>bigint</type>
+      </para>
+      <para>
+       Number of times this backend switched to the <literal>idle in transaction (aborted)</literal>
+       state.
+      </para></entry>
+     </row>
+
+    </tbody>
+   </tgroup>
+  </table>
+
  </sect2>
 
  <sect2 id="monitoring-stats-functions">
@@ -5278,6 +5396,22 @@ FROM pg_stat_get_backend_idset() AS backendid;
        </para></entry>
       </row>
 
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>pg_stat_get_session</primary>
+        </indexterm>
+        <function>pg_stat_get_session</function> ( <type>integer</type> )
+        <returnvalue>setof record</returnvalue>
+       </para>
+       <para>
+        Returns a row, showing statistics about the client backend with the
+        specified process ID, or one row per client backend
+        if <literal>NULL</literal> is specified. The fields returned are the
+        same as those of <structname>pg_stat_session</structname> view.
+       </para></entry>
+      </row>
+
       <row>
        <entry role="func_table_entry"><para role="func_signature">
         <indexterm>
diff --git a/src/backend/catalog/system_views.sql b/src/backend/catalog/system_views.sql
index da9a8fe99f..93a78f7384 100644
--- a/src/backend/catalog/system_views.sql
+++ b/src/backend/catalog/system_views.sql
@@ -886,6 +886,19 @@ CREATE VIEW pg_stat_activity AS
         LEFT JOIN pg_database AS D ON (S.datid = D.oid)
         LEFT JOIN pg_authid AS U ON (S.usesysid = U.oid);
 
+CREATE VIEW pg_stat_session AS
+    SELECT
+            s.pid,
+            s.active_time,
+            s.active_count,
+            s.idle_time,
+            s.idle_count,
+            s.idle_in_transaction_time,
+            s.idle_in_transaction_count,
+            s.idle_in_transaction_aborted_time,
+            s.idle_in_transaction_aborted_count
+     FROM pg_stat_get_session(NULL) as s;
+
 CREATE VIEW pg_stat_replication AS
     SELECT
             S.pid,
diff --git a/src/backend/utils/activity/backend_status.c b/src/backend/utils/activity/backend_status.c
index bdb3a296ca..1e3fc5ffec 100644
--- a/src/backend/utils/activity/backend_status.c
+++ b/src/backend/utils/activity/backend_status.c
@@ -317,6 +317,8 @@ pgstat_bestart(void)
 	lbeentry.st_xact_start_timestamp = 0;
 	lbeentry.st_databaseid = MyDatabaseId;
 
+	MemSet(&lbeentry.st_session, 0, sizeof(lbeentry.st_session));
+
 	/* We have userid for client-backends, wal-sender and bgworker processes */
 	if (lbeentry.st_backendType == B_BACKEND
 		|| lbeentry.st_backendType == B_WAL_SENDER
@@ -505,6 +507,9 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 	TimestampTz current_timestamp;
 	int			len = 0;
 
+	PgBackendSessionStatus st_session_diff;
+	MemSet(&st_session_diff, 0, sizeof(st_session_diff));
+
 	TRACE_POSTGRESQL_STATEMENT_STATUS(cmd_str);
 
 	if (!beentry)
@@ -530,6 +535,7 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 			beentry->st_xact_start_timestamp = 0;
 			beentry->st_query_id = UINT64CONST(0);
 			proc->wait_event_info = 0;
+			MemSet(&beentry->st_session, 0, sizeof(beentry->st_session));
 			PGSTAT_END_WRITE_ACTIVITY(beentry);
 		}
 		return;
@@ -552,27 +558,45 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 	current_timestamp = GetCurrentTimestamp();
 
 	/*
-	 * If the state has changed from "active" or "idle in transaction",
-	 * calculate the duration.
+	 * If a client backend has changed state, update per-database and per-session counters.
 	 */
-	if ((beentry->st_state == STATE_RUNNING ||
-		 beentry->st_state == STATE_FASTPATH ||
-		 beentry->st_state == STATE_IDLEINTRANSACTION ||
-		 beentry->st_state == STATE_IDLEINTRANSACTION_ABORTED) &&
-		state != beentry->st_state)
+	if ((PGSTAT_IS_ACTIVE(beentry) ||
+		 PGSTAT_IS_IDLEINTRANSACTION(beentry) ||
+		 PGSTAT_IS_IDLEINTRANSACTION_ABORTED(beentry) ||
+		 PGSTAT_IS_IDLE(beentry)) &&
+		state != beentry->st_state &&
+		beentry->st_backendType == B_BACKEND)
 	{
 		long		secs;
 		int			usecs;
+		int64		usecs_diff;
 
 		TimestampDifference(beentry->st_state_start_timestamp,
 							current_timestamp,
 							&secs, &usecs);
-
-		if (beentry->st_state == STATE_RUNNING ||
-			beentry->st_state == STATE_FASTPATH)
-			pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 + usecs);
-		else
-			pgstat_count_conn_txn_idle_time((PgStat_Counter) secs * 1000000 + usecs);
+		usecs_diff = secs * 1000000 + usecs;
+
+		/* compute values for pg_stat_database */
+		if (PGSTAT_IS_ACTIVE(beentry))
+			pgstat_count_conn_active_time((PgStat_Counter) usecs_diff);
+		else if (PGSTAT_IS_IDLEINTRANSACTION(beentry) ||
+				 PGSTAT_IS_IDLEINTRANSACTION_ABORTED(beentry))
+			pgstat_count_conn_txn_idle_time((PgStat_Counter) usecs_diff);
+
+		/* compute values for pg_stat_session */
+		if (PGSTAT_IS_ACTIVE(beentry)) {
+			st_session_diff.active_time = usecs_diff;
+			st_session_diff.active_count += 1;
+		} else if (PGSTAT_IS_IDLE(beentry)){
+			st_session_diff.idle_time = usecs_diff;
+			st_session_diff.idle_count += 1;
+		} else if (PGSTAT_IS_IDLEINTRANSACTION(beentry)){
+			st_session_diff.idle_in_transaction_time = usecs_diff;
+			st_session_diff.idle_in_transaction_count += 1;
+		} else if (PGSTAT_IS_IDLEINTRANSACTION_ABORTED(beentry)){
+			st_session_diff.idle_in_transaction_aborted_time = usecs_diff;
+			st_session_diff.idle_in_transaction_aborted_count += 1;
+		}
 	}
 
 	/*
@@ -598,6 +622,20 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 		beentry->st_activity_start_timestamp = start_timestamp;
 	}
 
+	if (beentry->st_backendType == B_BACKEND) {
+		beentry->st_session.active_time += st_session_diff.active_time;
+		beentry->st_session.active_count += st_session_diff.active_count;
+
+		beentry->st_session.idle_time += st_session_diff.idle_time;
+		beentry->st_session.idle_count += st_session_diff.idle_count;
+
+		beentry->st_session.idle_in_transaction_time += st_session_diff.idle_in_transaction_time;
+		beentry->st_session.idle_in_transaction_count += st_session_diff.idle_in_transaction_count;
+
+		beentry->st_session.idle_in_transaction_aborted_time += st_session_diff.idle_in_transaction_aborted_time;
+		beentry->st_session.idle_in_transaction_aborted_count += st_session_diff.idle_in_transaction_aborted_count;
+	}
+
 	PGSTAT_END_WRITE_ACTIVITY(beentry);
 }
 
diff --git a/src/backend/utils/adt/pgstatfuncs.c b/src/backend/utils/adt/pgstatfuncs.c
index 60a397dc56..ba9ff1a2d6 100644
--- a/src/backend/utils/adt/pgstatfuncs.c
+++ b/src/backend/utils/adt/pgstatfuncs.c
@@ -296,6 +296,76 @@ pg_stat_get_progress_info(PG_FUNCTION_ARGS)
 	return (Datum) 0;
 }
 
+/*
+ * Returns accumulated statistics of current PG backends.
+ */
+Datum
+pg_stat_get_session(PG_FUNCTION_ARGS)
+{
+#define PG_STAT_GET_SESSION_COLS	9
+	int			num_backends = pgstat_fetch_stat_numbackends();
+	int			curr_backend;
+	int			pid = PG_ARGISNULL(0) ? -1 : PG_GETARG_INT32(0);
+	ReturnSetInfo *rsinfo = (ReturnSetInfo *) fcinfo->resultinfo;
+
+	InitMaterializedSRF(fcinfo, 0);
+
+	/* 1-based index */
+	for (curr_backend = 1; curr_backend <= num_backends; curr_backend++)
+	{
+		/* for each row */
+		Datum		values[PG_STAT_GET_SESSION_COLS] = {0};
+		bool		nulls[PG_STAT_GET_SESSION_COLS] = {0};
+		LocalPgBackendStatus *local_beentry;
+		PgBackendStatus *beentry;
+
+		/* Get the next one in the list */
+		local_beentry = pgstat_get_local_beentry_by_index(curr_backend);
+		beentry = &local_beentry->backendStatus;
+
+		/* Report statistics only for client backends */
+		if (beentry->st_backendType != B_BACKEND)
+			continue;
+
+		/* If looking for specific PID, ignore all the others */
+		if (pid != -1 && beentry->st_procpid != pid)
+			continue;
+
+		/* Values available to all callers */
+		values[0] = Int32GetDatum(beentry->st_procpid);
+
+		/* Values only available to role member or pg_read_all_stats */
+		if (HAS_PGSTAT_PERMISSIONS(beentry->st_userid)){
+			/* convert to msec */
+			values[1] = Float8GetDatum(beentry->st_session.active_time / 1000.0);
+			values[2] = Int64GetDatum(beentry->st_session.active_count);
+			values[3] = Float8GetDatum(beentry->st_session.idle_time / 1000.0);
+			values[4] = Int64GetDatum(beentry->st_session.idle_count);
+			values[5] = Float8GetDatum(beentry->st_session.idle_in_transaction_time / 1000.0);
+			values[6] = Int64GetDatum(beentry->st_session.idle_in_transaction_count);
+			values[7] = Float8GetDatum(beentry->st_session.idle_in_transaction_aborted_time / 1000.0);
+			values[8] = Int64GetDatum(beentry->st_session.idle_in_transaction_aborted_count);
+		} else {
+			nulls[1] = true;
+			nulls[2] = true;
+			nulls[3] = true;
+			nulls[4] = true;
+			nulls[5] = true;
+			nulls[6] = true;
+			nulls[7] = true;
+			nulls[8] = true;
+		}
+
+		tuplestore_putvalues(rsinfo->setResult, rsinfo->setDesc, values, nulls);
+
+		/* If only a single backend was requested, and we found it, break. */
+		if (pid != -1)
+			break;
+	}
+
+	return (Datum) 0;
+}
+
 /*
  * Returns activity of PG backends.
  */
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index cbbe8acd38..f017de6779 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -5559,6 +5559,15 @@
   proargtypes => '', proallargtypes => '{text,text,text}',
   proargmodes => '{o,o,o}', proargnames => '{type,name,description}',
   prosrc => 'pg_get_wait_events' },
+{ oid => '2173',
+  descr => 'statistics: cumulative information about currently active client backends',
+  proname => 'pg_stat_get_session', prorows => '100', proisstrict => 'f',
+  proretset => 't', provolatile => 's', proparallel => 'r',
+  prorettype => 'record', proargtypes => 'int4',
+  proallargtypes => '{int4,int4,float8,int8,float8,int8,float8,int8,float8,int8}',
+  proargmodes => '{i,o,o,o,o,o,o,o,o,o}',
+  proargnames => '{pid,pid,active_time,active_count,idle_time,idle_count,idle_in_transaction_time,idle_in_transaction_count,idle_in_transaction_aborted_time,idle_in_transaction_aborted_count}',
+  prosrc => 'pg_stat_get_session' },
 { oid => '3318',
   descr => 'statistics: information about progress of backends running maintenance command',
   proname => 'pg_stat_get_progress_info', prorows => '100', proretset => 't',
diff --git a/src/include/utils/backend_status.h b/src/include/utils/backend_status.h
index 97874300c3..b2583b2824 100644
--- a/src/include/utils/backend_status.h
+++ b/src/include/utils/backend_status.h
@@ -81,6 +81,24 @@ typedef struct PgBackendGSSStatus
 
 } PgBackendGSSStatus;
 
+/*
+ * PgBackendSessionStatus
+ *
+ * For each session, we keep counters accumulated since the start of the session
+ * in a separate struct. The struct is always filled.
+ *
+ */
+typedef struct PgBackendSessionStatus
+{
+	int64		active_time;
+	int64		active_count;
+	int64		idle_time;
+	int64		idle_count;
+	int64		idle_in_transaction_time;
+	int64		idle_in_transaction_count;
+	int64		idle_in_transaction_aborted_time;
+	int64		idle_in_transaction_aborted_count;
+} PgBackendSessionStatus;
 
 /* ----------
  * PgBackendStatus
@@ -170,6 +188,9 @@ typedef struct PgBackendStatus
 
 	/* query identifier, optionally computed using post_parse_analyze_hook */
 	uint64		st_query_id;
+
+	/* Counters accumulated since the start of the session */
+	PgBackendSessionStatus st_session;
 } PgBackendStatus;
 
 
@@ -234,6 +255,17 @@ typedef struct PgBackendStatus
 	 ((before_changecount) & 1) == 0)
 
 
+/* Macros to identify the states for time accounting */
+#define PGSTAT_IS_ACTIVE(s) \
+	((s)->st_state == STATE_RUNNING || (s)->st_state == STATE_FASTPATH)
+#define PGSTAT_IS_IDLE(s) \
+	((s)->st_state == STATE_IDLE)
+#define PGSTAT_IS_IDLEINTRANSACTION(s) \
+	((s)->st_state == STATE_IDLEINTRANSACTION)
+#define PGSTAT_IS_IDLEINTRANSACTION_ABORTED(s) \
+	((s)->st_state == STATE_IDLEINTRANSACTION_ABORTED)
+
+
 /* ----------
  * LocalPgBackendStatus
  *
diff --git a/src/test/regress/expected/rules.out b/src/test/regress/expected/rules.out
index 3014d047fe..f37c57e220 100644
--- a/src/test/regress/expected/rules.out
+++ b/src/test/regress/expected/rules.out
@@ -2106,6 +2106,16 @@ pg_stat_replication_slots| SELECT s.slot_name,
    FROM pg_replication_slots r,
     LATERAL pg_stat_get_replication_slot((r.slot_name)::text) s(slot_name, spill_txns, spill_count, spill_bytes, stream_txns, stream_count, stream_bytes, total_txns, total_bytes, stats_reset)
   WHERE (r.datoid IS NOT NULL);
+pg_stat_session| SELECT pid,
+    active_time,
+    active_count,
+    idle_time,
+    idle_count,
+    idle_in_transaction_time,
+    idle_in_transaction_count,
+    idle_in_transaction_aborted_time,
+    idle_in_transaction_aborted_count
+   FROM pg_stat_get_session(NULL::integer) s(pid, active_time, active_count, idle_time, idle_count, idle_in_transaction_time, idle_in_transaction_count, idle_in_transaction_aborted_time, idle_in_transaction_aborted_count);
 pg_stat_slru| SELECT name,
     blks_zeroed,
     blks_hit,
diff --git a/src/test/regress/expected/sysviews.out b/src/test/regress/expected/sysviews.out
index 91089ac215..308780f119 100644
--- a/src/test/regress/expected/sysviews.out
+++ b/src/test/regress/expected/sysviews.out
@@ -223,3 +223,42 @@ select count(distinct utc_offset) >= 24 as ok from pg_timezone_abbrevs;
  t
 (1 row)
 
+select active_count as prev_active_count from pg_stat_session where pid = pg_backend_pid() \gset
+select (select active_count from pg_stat_session where pid = pg_backend_pid()) - :prev_active_count = 1 as ok;
+ ok 
+----
+ t
+(1 row)
+
+select idle_count as prev_idle_count from pg_stat_session where pid = pg_backend_pid() \gset
+select (select idle_count from pg_stat_session where pid = pg_backend_pid()) - :prev_idle_count = 1 as ok;
+ ok 
+----
+ t
+(1 row)
+
+select idle_in_transaction_count as prev_idle_in_transaction_count from pg_stat_session where pid = pg_backend_pid() \gset
+begin;
+commit;
+select (select idle_in_transaction_count from pg_stat_session where pid = pg_backend_pid()) - :prev_idle_in_transaction_count = 1 as ok;
+ ok 
+----
+ t
+(1 row)
+
+select idle_in_transaction_aborted_count as prev_idle_in_transaction_aborted_count from pg_stat_session where pid = pg_backend_pid() \gset
+begin;
+do $$
+begin
+raise 'test error';
+end;
+$$ language plpgsql;
+ERROR:  test error
+CONTEXT:  PL/pgSQL function inline_code_block line 3 at RAISE
+rollback;
+select (select idle_in_transaction_aborted_count from pg_stat_session where pid = pg_backend_pid()) - :prev_idle_in_transaction_aborted_count = 1 as ok;
+ ok 
+----
+ t
+(1 row)
+
diff --git a/src/test/regress/sql/sysviews.sql b/src/test/regress/sql/sysviews.sql
index b2a7923754..cfa69a8975 100644
--- a/src/test/regress/sql/sysviews.sql
+++ b/src/test/regress/sql/sysviews.sql
@@ -98,3 +98,24 @@ set timezone_abbreviations = 'Australia';
 select count(distinct utc_offset) >= 24 as ok from pg_timezone_abbrevs;
 set timezone_abbreviations = 'India';
 select count(distinct utc_offset) >= 24 as ok from pg_timezone_abbrevs;
+
+select active_count as prev_active_count from pg_stat_session where pid = pg_backend_pid() \gset
+select (select active_count from pg_stat_session where pid = pg_backend_pid()) - :prev_active_count = 1 as ok;
+
+select idle_count as prev_idle_count from pg_stat_session where pid = pg_backend_pid() \gset
+select (select idle_count from pg_stat_session where pid = pg_backend_pid()) - :prev_idle_count = 1 as ok;
+
+select idle_in_transaction_count as prev_idle_in_transaction_count from pg_stat_session where pid = pg_backend_pid() \gset
+begin;
+commit;
+select (select idle_in_transaction_count from pg_stat_session where pid = pg_backend_pid()) - :prev_idle_in_transaction_count = 1 as ok;
+
+select idle_in_transaction_aborted_count as prev_idle_in_transaction_aborted_count from pg_stat_session where pid = pg_backend_pid() \gset
+begin;
+do $$
+begin
+raise 'test error';
+end;
+$$ language plpgsql;
+rollback;
+select (select idle_in_transaction_aborted_count from pg_stat_session where pid = pg_backend_pid()) - :prev_idle_in_transaction_aborted_count = 1 as ok;
\ No newline at end of file
-- 
2.34.1

#52Sergey Dudoladov
sergey.dudoladov@gmail.com
In reply to: Sergey Dudoladov (#51)
1 attachment(s)
Re: Add connection active, idle time to pg_stat_activity

Hello,

I've rebased the patch according to the CI bot's requirements. Please have
a look.
Regards,
Sergey

Attachments:

0006_add_pg_stat_session_view.patchtext/x-patch; charset=US-ASCII; name=0006_add_pg_stat_session_view.patchDownload
From 4974c8c9440bbd6d7f9e37e882990602d69b495f Mon Sep 17 00:00:00 2001
From: Sergey Dudoladov <sergey.dudoladov@gmail.com>
Date: Mon, 3 Mar 2025 13:19:56 +0100
Subject: [PATCH] Adds pg_stat_session view to track statistics accumulated
 during  lifetime of a session (client backend).

catversion bump is necessary due to a new view / function

Reviewed-by: Aleksander Alekseev, Bertrand Drouvot, Atsushi
Torikoshi, and Andrei Zubkov

Discussion:
https://www.postgresql.org/message-id/flat/CA%2BFpmFcJF0vwi-SWW0wYO-c-FbhyawLq4tCpRDCJJ8Bq%3Dja-gA%40mail.gmail.com
---
 doc/src/sgml/monitoring.sgml                | 134 ++++++++++++++++++++
 src/backend/catalog/system_views.sql        |  13 ++
 src/backend/utils/activity/backend_status.c |  64 ++++++++--
 src/backend/utils/adt/pgstatfuncs.c         |  70 ++++++++++
 src/include/catalog/pg_proc.dat             |   9 ++
 src/include/utils/backend_status.h          |  32 +++++
 src/test/regress/expected/rules.out         |  10 ++
 src/test/regress/expected/sysviews.out      |  39 ++++++
 src/test/regress/sql/sysviews.sql           |  21 +++
 9 files changed, 379 insertions(+), 13 deletions(-)

diff --git a/doc/src/sgml/monitoring.sgml b/doc/src/sgml/monitoring.sgml
index 9178f1d34e..2f4b77ca52 100644
--- a/doc/src/sgml/monitoring.sgml
+++ b/doc/src/sgml/monitoring.sgml
@@ -414,6 +414,20 @@ postgres   27093  0.0  0.0  30096  2752 ?        Ss   11:34   0:00 postgres: ser
        See <xref linkend="copy-progress-reporting"/>.
       </entry>
      </row>
+
+     <row>
+      <entry>
+       <structname>pg_stat_session</structname>
+       <indexterm><primary>pg_stat_session</primary></indexterm>
+      </entry>
+      <entry>
+       One row per client backend, showing information related to
+       the currently accumulated activity of that process, such as time spent in
+       a certain state.
+       See <link linkend="monitoring-pg-stat-session-view">
+       <structname>pg_stat_session</structname></link> for details.
+      </entry>
+     </row>
     </tbody>
    </tgroup>
   </table>
@@ -4772,6 +4786,110 @@ description | Waiting for a newly initialized WAL file to reach durable storage
    </tgroup>
   </table>
 
+  <table id="monitoring-pg-stat-session-view" xreflabel="pg_stat_session">
+   <title><structname>pg_stat_session</structname> View</title>
+   <tgroup cols="1">
+    <thead>
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       Column Type
+      </para>
+      <para>
+       Description
+      </para></entry>
+     </row>
+    </thead>
+
+    <tbody>
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>pid</structfield> <type>integer</type>
+      </para>
+      <para>
+       Process ID of this client backend.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>active_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in the <literal>running</literal> or <literal>fastpath</literal> state.
+      </para></entry>
+     </row>
+
+    <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>active_count</structfield> <type>bigint</type>
+      </para>
+      <para>
+       Number of times this backend switched to the <literal>running</literal> or <literal>fastpath</literal> state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>idle_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in the <literal>idle</literal> state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>idle_count</structfield> <type>bigint</type>
+      </para>
+      <para>
+       Number of times this backend switched to the <literal>idle</literal> state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>idle_in_transaction_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in the <literal>idle in transaction</literal>
+       state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>idle_in_transaction_count</structfield> <type>bigint</type>
+      </para>
+      <para>
+       Number of times this backend switched to the <literal>idle in transaction</literal>
+       state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>idle_in_transaction_aborted_time</structfield> <type>double precision</type>
+      </para>
+      <para>
+       Time in milliseconds this backend spent in the <literal>idle in transaction (aborted)</literal>
+       state.
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>idle_in_transaction_aborted_count</structfield> <type>bigint</type>
+      </para>
+      <para>
+       Number of times this backend switched to the <literal>idle in transaction (aborted)</literal>
+       state.
+      </para></entry>
+     </row>
+
+    </tbody>
+   </tgroup>
+  </table>
+
  </sect2>
 
  <sect2 id="monitoring-stats-functions">
@@ -5277,6 +5395,22 @@ FROM pg_stat_get_backend_idset() AS backendid;
        </para></entry>
       </row>
 
+      <row>
+       <entry role="func_table_entry"><para role="func_signature">
+        <indexterm>
+         <primary>pg_stat_get_session</primary>
+        </indexterm>
+        <function>pg_stat_get_session</function> ( <type>integer</type> )
+        <returnvalue>setof record</returnvalue>
+       </para>
+       <para>
+        Returns a row, showing statistics about the client backend with the
+        specified process ID, or one row per client backend
+        if <literal>NULL</literal> is specified. The fields returned are the
+        same as those of <structname>pg_stat_session</structname> view.
+       </para></entry>
+      </row>
+
       <row>
        <entry role="func_table_entry"><para role="func_signature">
         <indexterm>
diff --git a/src/backend/catalog/system_views.sql b/src/backend/catalog/system_views.sql
index a4d2cfdcaf..0f191c9b8e 100644
--- a/src/backend/catalog/system_views.sql
+++ b/src/backend/catalog/system_views.sql
@@ -895,6 +895,19 @@ CREATE VIEW pg_stat_activity AS
         LEFT JOIN pg_database AS D ON (S.datid = D.oid)
         LEFT JOIN pg_authid AS U ON (S.usesysid = U.oid);
 
+CREATE VIEW pg_stat_session AS
+    SELECT
+            s.pid,
+            s.active_time,
+            s.active_count,
+            s.idle_time,
+            s.idle_count,
+            s.idle_in_transaction_time,
+            s.idle_in_transaction_count,
+            s.idle_in_transaction_aborted_time,
+            s.idle_in_transaction_aborted_count
+     FROM pg_stat_get_session(NULL) as s;
+
 CREATE VIEW pg_stat_replication AS
     SELECT
             S.pid,
diff --git a/src/backend/utils/activity/backend_status.c b/src/backend/utils/activity/backend_status.c
index 5f68ef26ad..d0c66f6d93 100644
--- a/src/backend/utils/activity/backend_status.c
+++ b/src/backend/utils/activity/backend_status.c
@@ -317,6 +317,8 @@ pgstat_bestart(void)
 	lbeentry.st_xact_start_timestamp = 0;
 	lbeentry.st_databaseid = MyDatabaseId;
 
+	MemSet(&lbeentry.st_session, 0, sizeof(lbeentry.st_session));
+
 	/* We have userid for client-backends, wal-sender and bgworker processes */
 	if (lbeentry.st_backendType == B_BACKEND
 		|| lbeentry.st_backendType == B_WAL_SENDER
@@ -509,6 +511,9 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 	TimestampTz current_timestamp;
 	int			len = 0;
 
+	PgBackendSessionStatus st_session_diff;
+	MemSet(&st_session_diff, 0, sizeof(st_session_diff));
+
 	TRACE_POSTGRESQL_STATEMENT_STATUS(cmd_str);
 
 	if (!beentry)
@@ -534,6 +539,7 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 			beentry->st_xact_start_timestamp = 0;
 			beentry->st_query_id = UINT64CONST(0);
 			proc->wait_event_info = 0;
+			MemSet(&beentry->st_session, 0, sizeof(beentry->st_session));
 			PGSTAT_END_WRITE_ACTIVITY(beentry);
 		}
 		return;
@@ -556,27 +562,45 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 	current_timestamp = GetCurrentTimestamp();
 
 	/*
-	 * If the state has changed from "active" or "idle in transaction",
-	 * calculate the duration.
+	 * If a client backend has changed state, update per-database and per-session counters.
 	 */
-	if ((beentry->st_state == STATE_RUNNING ||
-		 beentry->st_state == STATE_FASTPATH ||
-		 beentry->st_state == STATE_IDLEINTRANSACTION ||
-		 beentry->st_state == STATE_IDLEINTRANSACTION_ABORTED) &&
-		state != beentry->st_state)
+	if ((PGSTAT_IS_ACTIVE(beentry) ||
+		 PGSTAT_IS_IDLEINTRANSACTION(beentry) ||
+		 PGSTAT_IS_IDLEINTRANSACTION_ABORTED(beentry) ||
+		 PGSTAT_IS_IDLE(beentry)) &&
+		state != beentry->st_state &&
+		beentry->st_backendType == B_BACKEND)
 	{
 		long		secs;
 		int			usecs;
+		int64		usecs_diff;
 
 		TimestampDifference(beentry->st_state_start_timestamp,
 							current_timestamp,
 							&secs, &usecs);
-
-		if (beentry->st_state == STATE_RUNNING ||
-			beentry->st_state == STATE_FASTPATH)
-			pgstat_count_conn_active_time((PgStat_Counter) secs * 1000000 + usecs);
-		else
-			pgstat_count_conn_txn_idle_time((PgStat_Counter) secs * 1000000 + usecs);
+		usecs_diff = secs * 1000000 + usecs;
+
+		/* compute values for pg_stat_database */
+		if (PGSTAT_IS_ACTIVE(beentry))
+			pgstat_count_conn_active_time((PgStat_Counter) usecs_diff);
+		else if (PGSTAT_IS_IDLEINTRANSACTION(beentry) ||
+				 PGSTAT_IS_IDLEINTRANSACTION_ABORTED(beentry))
+			pgstat_count_conn_txn_idle_time((PgStat_Counter) usecs_diff);
+
+		/* compute values for pg_stat_session */
+		if (PGSTAT_IS_ACTIVE(beentry)) {
+			st_session_diff.active_time = usecs_diff;
+			st_session_diff.active_count += 1;
+		} else if (PGSTAT_IS_IDLE(beentry)){
+			st_session_diff.idle_time = usecs_diff;
+			st_session_diff.idle_count += 1;
+		} else if (PGSTAT_IS_IDLEINTRANSACTION(beentry)){
+			st_session_diff.idle_in_transaction_time = usecs_diff;
+			st_session_diff.idle_in_transaction_count += 1;
+		} else if (PGSTAT_IS_IDLEINTRANSACTION_ABORTED(beentry)){
+			st_session_diff.idle_in_transaction_aborted_time = usecs_diff;
+			st_session_diff.idle_in_transaction_aborted_count += 1;
+		}
 	}
 
 	/*
@@ -602,6 +626,20 @@ pgstat_report_activity(BackendState state, const char *cmd_str)
 		beentry->st_activity_start_timestamp = start_timestamp;
 	}
 
+	if (beentry->st_backendType == B_BACKEND) {
+		beentry->st_session.active_time += st_session_diff.active_time;
+		beentry->st_session.active_count += st_session_diff.active_count;
+
+		beentry->st_session.idle_time += st_session_diff.idle_time;
+		beentry->st_session.idle_count += st_session_diff.idle_count;
+
+		beentry->st_session.idle_in_transaction_time += st_session_diff.idle_in_transaction_time;
+		beentry->st_session.idle_in_transaction_count += st_session_diff.idle_in_transaction_count;
+
+		beentry->st_session.idle_in_transaction_aborted_time += st_session_diff.idle_in_transaction_aborted_time;
+		beentry->st_session.idle_in_transaction_aborted_count += st_session_diff.idle_in_transaction_aborted_count;
+	}
+
 	PGSTAT_END_WRITE_ACTIVITY(beentry);
 }
 
diff --git a/src/backend/utils/adt/pgstatfuncs.c b/src/backend/utils/adt/pgstatfuncs.c
index 0212d8d590..8a8d185793 100644
--- a/src/backend/utils/adt/pgstatfuncs.c
+++ b/src/backend/utils/adt/pgstatfuncs.c
@@ -324,6 +324,76 @@ pg_stat_get_progress_info(PG_FUNCTION_ARGS)
 	return (Datum) 0;
 }
 
+/*
+ * Returns accumulated statistics of current PG backends.
+ */
+Datum
+pg_stat_get_session(PG_FUNCTION_ARGS)
+{
+#define PG_STAT_GET_SESSION_COLS	9
+	int			num_backends = pgstat_fetch_stat_numbackends();
+	int			curr_backend;
+	int			pid = PG_ARGISNULL(0) ? -1 : PG_GETARG_INT32(0);
+	ReturnSetInfo *rsinfo = (ReturnSetInfo *) fcinfo->resultinfo;
+
+	InitMaterializedSRF(fcinfo, 0);
+
+	/* 1-based index */
+	for (curr_backend = 1; curr_backend <= num_backends; curr_backend++)
+	{
+		/* for each row */
+		Datum		values[PG_STAT_GET_SESSION_COLS] = {0};
+		bool		nulls[PG_STAT_GET_SESSION_COLS] = {0};
+		LocalPgBackendStatus *local_beentry;
+		PgBackendStatus *beentry;
+
+		/* Get the next one in the list */
+		local_beentry = pgstat_get_local_beentry_by_index(curr_backend);
+		beentry = &local_beentry->backendStatus;
+
+		/* Report statistics only for client backends */
+		if (beentry->st_backendType != B_BACKEND)
+			continue;
+
+		/* If looking for specific PID, ignore all the others */
+		if (pid != -1 && beentry->st_procpid != pid)
+			continue;
+
+		/* Values available to all callers */
+		values[0] = Int32GetDatum(beentry->st_procpid);
+
+		/* Values only available to role member or pg_read_all_stats */
+		if (HAS_PGSTAT_PERMISSIONS(beentry->st_userid)){
+			/* convert to msec */
+			values[1] = Float8GetDatum(beentry->st_session.active_time / 1000.0);
+			values[2] = Int64GetDatum(beentry->st_session.active_count);
+			values[3] = Float8GetDatum(beentry->st_session.idle_time / 1000.0);
+			values[4] = Int64GetDatum(beentry->st_session.idle_count);
+			values[5] = Float8GetDatum(beentry->st_session.idle_in_transaction_time / 1000.0);
+			values[6] = Int64GetDatum(beentry->st_session.idle_in_transaction_count);
+			values[7] = Float8GetDatum(beentry->st_session.idle_in_transaction_aborted_time / 1000.0);
+			values[8] = Int64GetDatum(beentry->st_session.idle_in_transaction_aborted_count);
+		} else {
+			nulls[1] = true;
+			nulls[2] = true;
+			nulls[3] = true;
+			nulls[4] = true;
+			nulls[5] = true;
+			nulls[6] = true;
+			nulls[7] = true;
+			nulls[8] = true;
+		}
+
+		tuplestore_putvalues(rsinfo->setResult, rsinfo->setDesc, values, nulls);
+
+		/* If only a single backend was requested, and we found it, break. */
+		if (pid != -1)
+			break;
+	}
+
+	return (Datum) 0;
+}
+
 /*
  * Returns activity of PG backends.
  */
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index cd9422d0ba..f78d9a8c45 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -5584,6 +5584,15 @@
   proargtypes => '', proallargtypes => '{text,text,text}',
   proargmodes => '{o,o,o}', proargnames => '{type,name,description}',
   prosrc => 'pg_get_wait_events' },
+{ oid => '2173',
+  descr => 'statistics: cumulative information about currently active client backends',
+  proname => 'pg_stat_get_session', prorows => '100', proisstrict => 'f',
+  proretset => 't', provolatile => 's', proparallel => 'r',
+  prorettype => 'record', proargtypes => 'int4',
+  proallargtypes => '{int4,int4,float8,int8,float8,int8,float8,int8,float8,int8}',
+  proargmodes => '{i,o,o,o,o,o,o,o,o,o}',
+  proargnames => '{pid,pid,active_time,active_count,idle_time,idle_count,idle_in_transaction_time,idle_in_transaction_count,idle_in_transaction_aborted_time,idle_in_transaction_aborted_count}',
+  prosrc => 'pg_stat_get_session' },
 { oid => '3318',
   descr => 'statistics: information about progress of backends running maintenance command',
   proname => 'pg_stat_get_progress_info', prorows => '100', proretset => 't',
diff --git a/src/include/utils/backend_status.h b/src/include/utils/backend_status.h
index d3d4ff6c5c..a04c3581d6 100644
--- a/src/include/utils/backend_status.h
+++ b/src/include/utils/backend_status.h
@@ -81,6 +81,24 @@ typedef struct PgBackendGSSStatus
 
 } PgBackendGSSStatus;
 
+/*
+ * PgBackendSessionStatus
+ *
+ * For each session, we keep counters accumulated since the start of the session
+ * in a separate struct. The struct is always filled.
+ *
+ */
+typedef struct PgBackendSessionStatus
+{
+	int64		active_time;
+	int64		active_count;
+	int64		idle_time;
+	int64		idle_count;
+	int64		idle_in_transaction_time;
+	int64		idle_in_transaction_count;
+	int64		idle_in_transaction_aborted_time;
+	int64		idle_in_transaction_aborted_count;
+} PgBackendSessionStatus;
 
 /* ----------
  * PgBackendStatus
@@ -170,6 +188,9 @@ typedef struct PgBackendStatus
 
 	/* query identifier, optionally computed using post_parse_analyze_hook */
 	uint64		st_query_id;
+
+	/* Counters accumulated since the start of the session */
+	PgBackendSessionStatus st_session;
 } PgBackendStatus;
 
 
@@ -234,6 +255,17 @@ typedef struct PgBackendStatus
 	 ((before_changecount) & 1) == 0)
 
 
+/* Macros to identify the states for time accounting */
+#define PGSTAT_IS_ACTIVE(s) \
+	((s)->st_state == STATE_RUNNING || (s)->st_state == STATE_FASTPATH)
+#define PGSTAT_IS_IDLE(s) \
+	((s)->st_state == STATE_IDLE)
+#define PGSTAT_IS_IDLEINTRANSACTION(s) \
+	((s)->st_state == STATE_IDLEINTRANSACTION)
+#define PGSTAT_IS_IDLEINTRANSACTION_ABORTED(s) \
+	((s)->st_state == STATE_IDLEINTRANSACTION_ABORTED)
+
+
 /* ----------
  * LocalPgBackendStatus
  *
diff --git a/src/test/regress/expected/rules.out b/src/test/regress/expected/rules.out
index 62f69ac20b..81b6de5935 100644
--- a/src/test/regress/expected/rules.out
+++ b/src/test/regress/expected/rules.out
@@ -2114,6 +2114,16 @@ pg_stat_replication_slots| SELECT s.slot_name,
    FROM pg_replication_slots r,
     LATERAL pg_stat_get_replication_slot((r.slot_name)::text) s(slot_name, spill_txns, spill_count, spill_bytes, stream_txns, stream_count, stream_bytes, total_txns, total_bytes, stats_reset)
   WHERE (r.datoid IS NOT NULL);
+pg_stat_session| SELECT pid,
+    active_time,
+    active_count,
+    idle_time,
+    idle_count,
+    idle_in_transaction_time,
+    idle_in_transaction_count,
+    idle_in_transaction_aborted_time,
+    idle_in_transaction_aborted_count
+   FROM pg_stat_get_session(NULL::integer) s(pid, active_time, active_count, idle_time, idle_count, idle_in_transaction_time, idle_in_transaction_count, idle_in_transaction_aborted_time, idle_in_transaction_aborted_count);
 pg_stat_slru| SELECT name,
     blks_zeroed,
     blks_hit,
diff --git a/src/test/regress/expected/sysviews.out b/src/test/regress/expected/sysviews.out
index 83228cfca2..51fd9bee6d 100644
--- a/src/test/regress/expected/sysviews.out
+++ b/src/test/regress/expected/sysviews.out
@@ -232,3 +232,42 @@ select * from pg_timezone_abbrevs where abbrev = 'LMT';
  LMT    | @ 7 hours 52 mins 58 secs ago | f
 (1 row)
 
+select active_count as prev_active_count from pg_stat_session where pid = pg_backend_pid() \gset
+select (select active_count from pg_stat_session where pid = pg_backend_pid()) - :prev_active_count = 1 as ok;
+ ok 
+----
+ t
+(1 row)
+
+select idle_count as prev_idle_count from pg_stat_session where pid = pg_backend_pid() \gset
+select (select idle_count from pg_stat_session where pid = pg_backend_pid()) - :prev_idle_count = 1 as ok;
+ ok 
+----
+ t
+(1 row)
+
+select idle_in_transaction_count as prev_idle_in_transaction_count from pg_stat_session where pid = pg_backend_pid() \gset
+begin;
+commit;
+select (select idle_in_transaction_count from pg_stat_session where pid = pg_backend_pid()) - :prev_idle_in_transaction_count = 1 as ok;
+ ok 
+----
+ t
+(1 row)
+
+select idle_in_transaction_aborted_count as prev_idle_in_transaction_aborted_count from pg_stat_session where pid = pg_backend_pid() \gset
+begin;
+do $$
+begin
+raise 'test error';
+end;
+$$ language plpgsql;
+ERROR:  test error
+CONTEXT:  PL/pgSQL function inline_code_block line 3 at RAISE
+rollback;
+select (select idle_in_transaction_aborted_count from pg_stat_session where pid = pg_backend_pid()) - :prev_idle_in_transaction_aborted_count = 1 as ok;
+ ok 
+----
+ t
+(1 row)
+
diff --git a/src/test/regress/sql/sysviews.sql b/src/test/regress/sql/sysviews.sql
index 66179f026b..b90a911d81 100644
--- a/src/test/regress/sql/sysviews.sql
+++ b/src/test/regress/sql/sysviews.sql
@@ -101,3 +101,24 @@ select count(distinct utc_offset) >= 24 as ok from pg_timezone_abbrevs;
 -- One specific case we can check without much fear of breakage
 -- is the historical local-mean-time value used for America/Los_Angeles.
 select * from pg_timezone_abbrevs where abbrev = 'LMT';
+
+select active_count as prev_active_count from pg_stat_session where pid = pg_backend_pid() \gset
+select (select active_count from pg_stat_session where pid = pg_backend_pid()) - :prev_active_count = 1 as ok;
+
+select idle_count as prev_idle_count from pg_stat_session where pid = pg_backend_pid() \gset
+select (select idle_count from pg_stat_session where pid = pg_backend_pid()) - :prev_idle_count = 1 as ok;
+
+select idle_in_transaction_count as prev_idle_in_transaction_count from pg_stat_session where pid = pg_backend_pid() \gset
+begin;
+commit;
+select (select idle_in_transaction_count from pg_stat_session where pid = pg_backend_pid()) - :prev_idle_in_transaction_count = 1 as ok;
+
+select idle_in_transaction_aborted_count as prev_idle_in_transaction_aborted_count from pg_stat_session where pid = pg_backend_pid() \gset
+begin;
+do $$
+begin
+raise 'test error';
+end;
+$$ language plpgsql;
+rollback;
+select (select idle_in_transaction_aborted_count from pg_stat_session where pid = pg_backend_pid()) - :prev_idle_in_transaction_aborted_count = 1 as ok;
-- 
2.34.1

#53Sadeq Dousti
msdousti@gmail.com
In reply to: Sergey Dudoladov (#52)
Re: Add connection active, idle time to pg_stat_activity

I've rebased the patch according to the CI bot's requirements. Please have
a look.

Dear Sergey & Hackers,

+1 to the idea, and hope it becomes available in v18.

Here are some observations from my review:

1. backend_status.c, Line 572 - the following new condition can break the
logic of existing code, please move it inside the IF body, where you
compute values for pg_stat_session.
beentry->st_backendType == B_BACKEND

2. Macros PGSTAT_IS_* do not seem to help a lot in code readability, I
prefer the original code

3. backend_status.h, Line 193 - Can st_session be defined as a pointer to
PgBackendSessionStatus? (Similar to st_sslstatus and st_gssstatus)?
This helps in "shallow" copying PgBackendStatus.

4. backend_status.h, Lines 93-101 - Can these fields be defined as uint64
rather than int64, since they are unsigned in reality?

5. Changes to pg_proc.dat - Andrey Borodin in this video at 46:05 (
https://youtu.be/vTV8XhWf3mo?t=2765) points out that it should be changed
by committers only; otherwise frequent conflicts happen.

6. pgstatfuncs.c, line 333: The following line is defined inside the
function pg_stat_get_session, but I think it's better suited for
pgstatfuncs.h (though existing function - pg_stat_get_progress_info - does
the same)
#define PG_STAT_GET_SESSION_COLS 9

7. Some information is currently scattered between pg_stat_session and
pg_stat_activity, making joins necessary. However, pg_stat_activity
contains two types of columns: Those being immutable during a session
(e.g., client_addr, application_name, usename) and those being volatile
during the session (e.g., query, query_start, state). The following is thus
a "careless" join, combining immutable, volatile, and cumulative info
together:

select * from pg_stat_activity join pg_stat_session using (pid);

I suggest adding all or some of the immutable columns of pg_stat_activity
to pg_stat_session, thus excluding the need to join the two views (for all
practical purposes).

Best Regards,
Sadeq Dousti

#54Robert Haas
robertmhaas@gmail.com
In reply to: Sergey Dudoladov (#52)
Re: Add connection active, idle time to pg_stat_activity

Hi,

For the most part this patch looks like it's in pretty good shape to
me, although I am less sold on the desirability of it than it sounds
like most people are. I do think it can be useful, and it seems to
mostly piggyback on existing time measurements, so it should be pretty
cheap. But I'm just not quite sure about the design.

While the number of times that we enter each state does seem to have
some utility, it's also a little weird. If I'm not mistaken, the total
number of times you've become idle (any flavor) has got to add up to
the number of times that you've become active, or it can be 1 less if
you're still active. So that seems a bit redundant: why count four
things where three of them basically sum up to the fourth? Basically,
I think you end up with the times-active counter counting how many
statements you executed, the times-idle counter counting how many of
those statements were not in explicit transactions, and the other two
idle flavors counting how many statements you ran within explicit
transactions, divided between statements that errored out and
statements that didn't. I certainly don't think that's useless, but
there are other choices that seem equally valid; e.g. most obviously,
we could count how many statements committed and and how many
statements aborted, which seems like it might be more generally useful
than this, even though this also has some use. The thing that concerns
me is that I don't think we ever want both. If we add this, we're more
or less saying we're never going to do that, or at least I think so.

I'm also not sure that I like the idea of breaking this out into a
separate pg_stat_session view, as Andres proposed. It might be the
right idea, but if you want to see everything, you'll now need to join
the two views -- and there's no guarantee that you'll get a consistent
read across both of them, so the join might do weird things unless
you're very careful.

If we do decide to keep it separate, I think we should consider
omitting rows entirely when the HAS_PGSTAT_PERMISSIONS check fails. In
the case of pg_stat_activity, we still display some useful information
even to unprivileged users, but here all you get without privileges is
the pid. Maybe there is some point to that if we think we might add
unprivileged columns later or if we think it's important to be
consistent with pg_stat_activity, but I'm sort of inclined to think
it's just clutter.

Cuddled braces are not project style. You will find that code like "}
else if (PGSTAT_IS_IDLE(beentry)){" gats reindented by pgindent; but
it's best to run pgindent before submitting.

I'd probably write the increments as ++ rather than += 1 but I'm not
sure if everyone would agree.

--
Robert Haas
EDB: http://www.enterprisedb.com

#55Richard Guo
guofenglinux@gmail.com
In reply to: Robert Haas (#54)
Re: Add connection active, idle time to pg_stat_activity

On Fri, Apr 11, 2025 at 3:47 AM Robert Haas <robertmhaas@gmail.com> wrote:

I'd probably write the increments as ++ rather than += 1 but I'm not
sure if everyone would agree.

I'm a fan of ++ as well, so I agree.

Thanks
Richard