From c28a32aa619b4f07fd80b0017ff5930ef711831e Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Mon, 1 Jul 2024 16:16:39 +0900
Subject: [PATCH v3 1/2] psql: Add leakproof field to \dAo+ meta-command
 results

This adds a field that shows whether the underlying function of an
operator associated with operator families is leak-proof.
It is useful for checking an index can be used with security_barrier
views or row-level security policies when the query's WHERE
clause contains an operator which is associated with the index.
---
 doc/src/sgml/planstats.sgml        |  2 +
 doc/src/sgml/ref/psql-ref.sgml     | 16 ++++---
 doc/src/sgml/rules.sgml            | 10 ++++
 src/bin/psql/describe.c            | 47 +++++++++++++++----
 src/test/regress/expected/psql.out | 75 ++++++++++++++++--------------
 src/test/regress/sql/psql.sql      |  2 +-
 6 files changed, 99 insertions(+), 53 deletions(-)

diff --git a/doc/src/sgml/planstats.sgml b/doc/src/sgml/planstats.sgml
index c7ec749d0a..c2a7142453 100644
--- a/doc/src/sgml/planstats.sgml
+++ b/doc/src/sgml/planstats.sgml
@@ -729,6 +729,8 @@ EXPLAIN (ANALYZE, TIMING OFF) SELECT * FROM t WHERE a &lt;= 49 AND b &gt; 49;
    accurately, the function that the operator is based on).  If not, then the
    selectivity estimator will behave as if no statistics are available, and
    the planner will proceed with default or fall-back assumptions.
+   Use <xref linkend="app-psql"/>'s <command>\do+</command> command to list
+   operators and tell which are marked as leakproof.
   </para>
 
   <para>
diff --git a/doc/src/sgml/ref/psql-ref.sgml b/doc/src/sgml/ref/psql-ref.sgml
index e42073ed74..ef5e366b1d 100644
--- a/doc/src/sgml/ref/psql-ref.sgml
+++ b/doc/src/sgml/ref/psql-ref.sgml
@@ -1420,7 +1420,8 @@ SELECT $1 \parse stmt1
         is specified, only members of operator families whose names match that
         pattern are listed.
         If <literal>+</literal> is appended to the command name, each operator
-        is listed with its sort operator family (if it is an ordering operator).
+        is listed with its sort operator family (if it is an ordering operator),
+        and whether it is leakproof.
         </para>
         </listitem>
       </varlistentry>
@@ -1510,7 +1511,8 @@ SELECT $1 \parse stmt1
         is specified, only casts whose source or target types match the
         pattern are listed.
         If <literal>+</literal> is appended to the command name, each object
-        is listed with its associated description.
+        is listed with whether the underlying function is leakproof and
+        its associated description.
         </para>
         </listitem>
       </varlistentry>
@@ -1711,9 +1713,9 @@ SELECT $1 \parse stmt1
         modifier to include system objects.
         If the form <literal>\df+</literal> is used, additional information
         about each function is shown, including volatility,
-        parallel safety, owner, security classification, access privileges,
-        language, internal name (for C and internal functions only),
-        and description.
+        parallel safety, owner, security classification, whether it is
+        leakproof, access privileges, language, internal name (for C and
+        internal functions only), and description.
         Source code for a specific function can be seen
         using <literal>\sf</literal>.
         </para>
@@ -1862,8 +1864,8 @@ SELECT $1 \parse stmt1
         pattern or the <literal>S</literal> modifier to include system
         objects.
         If <literal>+</literal> is appended to the command name,
-        additional information about each operator is shown, currently just
-        the name of the underlying function.
+        additional information about each operator is shown, currently
+        the name of the underlying function and whether it is leakproof.
         </para>
         </listitem>
       </varlistentry>
diff --git a/doc/src/sgml/rules.sgml b/doc/src/sgml/rules.sgml
index 7a928bd7b9..74cd1d29fd 100644
--- a/doc/src/sgml/rules.sgml
+++ b/doc/src/sgml/rules.sgml
@@ -2167,6 +2167,16 @@ CREATE VIEW phone_number WITH (security_barrier) AS
     view's row filters.
 </para>
 
+<para>
+    For example, an index scan cannot be selected for queries with
+    <literal>security_barrier</literal> views or row-level security policies if an
+    operator used in the <literal>WHERE</literal> clause is associated with the
+    operator family of the index, but its underlying function is not marked
+    <literal>LEAKPROOF</literal>. Use <xref linkend="app-psql"/>'s
+    <command>\dAo+</command> command to list operator families and tell which of
+    their operators are marked as leakproof.
+</para>
+
 <para>
     It is important to understand that even a view created with the
     <literal>security_barrier</literal> option is intended to be secure only
diff --git a/src/bin/psql/describe.c b/src/bin/psql/describe.c
index 2657abdc72..a91c2855e6 100644
--- a/src/bin/psql/describe.c
+++ b/src/bin/psql/describe.c
@@ -304,7 +304,7 @@ describeFunctions(const char *functypes, const char *func_pattern,
 	PQExpBufferData buf;
 	PGresult   *res;
 	printQueryOpt myopt = pset.popt;
-	static const bool translate_columns[] = {false, false, false, false, true, true, true, false, true, false, false, false, false};
+	static const bool translate_columns[] = {false, false, false, false, true, true, true, false, true, false, false, false, false, false};
 
 	/* No "Parallel" column before 9.6 */
 	static const bool translate_columns_pre_96[] = {false, false, false, false, true, true, false, true, false, false, false, false};
@@ -409,11 +409,15 @@ describeFunctions(const char *functypes, const char *func_pattern,
 							  gettext_noop("Parallel"));
 		appendPQExpBuffer(&buf,
 						  ",\n pg_catalog.pg_get_userbyid(p.proowner) as \"%s\""
-						  ",\n CASE WHEN prosecdef THEN '%s' ELSE '%s' END AS \"%s\"",
+						  ",\n CASE WHEN prosecdef THEN '%s' ELSE '%s' END AS \"%s\""
+						  ",\n CASE WHEN p.proleakproof THEN '%s' ELSE '%s' END as \"%s\"",
 						  gettext_noop("Owner"),
 						  gettext_noop("definer"),
 						  gettext_noop("invoker"),
-						  gettext_noop("Security"));
+						  gettext_noop("Security"),
+						  gettext_noop("yes"),
+						  gettext_noop("no"),
+						  gettext_noop("Leakproof"));
 		appendPQExpBufferStr(&buf, ",\n ");
 		printACLColumn(&buf, "p.proacl");
 		appendPQExpBuffer(&buf,
@@ -825,8 +829,12 @@ describeOperators(const char *oper_pattern,
 
 	if (verbose)
 		appendPQExpBuffer(&buf,
-						  "  o.oprcode AS \"%s\",\n",
-						  gettext_noop("Function"));
+						  "  o.oprcode AS \"%s\",\n"
+						  "  CASE WHEN p.proleakproof THEN '%s' ELSE '%s' END AS \"%s\",\n",
+						  gettext_noop("Function"),
+						  gettext_noop("yes"),
+						  gettext_noop("no"),
+						  gettext_noop("Leakproof"));
 
 	appendPQExpBuffer(&buf,
 					  "  coalesce(pg_catalog.obj_description(o.oid, 'pg_operator'),\n"
@@ -851,6 +859,10 @@ describeOperators(const char *oper_pattern,
 							 "     LEFT JOIN pg_catalog.pg_namespace nt0 ON nt0.oid = t0.typnamespace\n");
 	}
 
+	if (verbose)
+		appendPQExpBufferStr(&buf,
+							 "     LEFT JOIN pg_catalog.pg_proc p ON p.oid = o.oprcode\n");
+
 	if (!showSystem && !oper_pattern)
 		appendPQExpBufferStr(&buf, "WHERE n.nspname <> 'pg_catalog'\n"
 							 "      AND n.nspname <> 'information_schema'\n");
@@ -4924,7 +4936,13 @@ listCasts(const char *pattern, bool verbose)
 
 	if (verbose)
 		appendPQExpBuffer(&buf,
-						  ",\n       d.description AS \"%s\"",
+						  ",\n       CASE WHEN p.proleakproof THEN '%s'\n"
+						  "            ELSE '%s'\n"
+						  "       END AS \"%s\",\n"
+						  "       d.description AS \"%s\"",
+						  gettext_noop("yes"),
+						  gettext_noop("no"),
+						  gettext_noop("Leakproof"),
 						  gettext_noop("Description"));
 
 	/*
@@ -6987,7 +7005,7 @@ listOpFamilyOperators(const char *access_method_pattern,
 	printQueryOpt myopt = pset.popt;
 	bool		have_where = false;
 
-	static const bool translate_columns[] = {false, false, false, false, false, false};
+	static const bool translate_columns[] = {false, false, false, false, false, false, false};
 
 	initPQExpBuffer(&buf);
 
@@ -7015,8 +7033,15 @@ listOpFamilyOperators(const char *access_method_pattern,
 
 	if (verbose)
 		appendPQExpBuffer(&buf,
-						  ", ofs.opfname AS \"%s\"\n",
-						  gettext_noop("Sort opfamily"));
+						  ", ofs.opfname AS \"%s\",\n"
+						  "  CASE\n"
+						  "    WHEN p.proleakproof THEN '%s'\n"
+						  "    ELSE '%s'\n"
+						  "  END AS \"%s\"\n",
+						  gettext_noop("Sort opfamily"),
+						  gettext_noop("yes"),
+						  gettext_noop("no"),
+						  gettext_noop("Leakproof"));
 	appendPQExpBufferStr(&buf,
 						 "FROM pg_catalog.pg_amop o\n"
 						 "  LEFT JOIN pg_catalog.pg_opfamily of ON of.oid = o.amopfamily\n"
@@ -7024,7 +7049,9 @@ listOpFamilyOperators(const char *access_method_pattern,
 						 "  LEFT JOIN pg_catalog.pg_namespace nsf ON of.opfnamespace = nsf.oid\n");
 	if (verbose)
 		appendPQExpBufferStr(&buf,
-							 "  LEFT JOIN pg_catalog.pg_opfamily ofs ON ofs.oid = o.amopsortfamily\n");
+							 "  LEFT JOIN pg_catalog.pg_opfamily ofs ON ofs.oid = o.amopsortfamily\n"
+							 "  LEFT JOIN pg_catalog.pg_operator op ON op.oid = o.amopopr\n"
+							 "  LEFT JOIN pg_catalog.pg_proc p ON p.oid = op.oprcode\n");
 
 	if (access_method_pattern)
 	{
diff --git a/src/test/regress/expected/psql.out b/src/test/regress/expected/psql.out
index 36dc31c16c..06d6750abd 100644
--- a/src/test/regress/expected/psql.out
+++ b/src/test/regress/expected/psql.out
@@ -5184,31 +5184,36 @@ List of access methods
  btree | integer_ops     | smallint, integer, bigint
 (1 row)
 
-\dAo+ btree float_ops
-                                List of operators of operator families
-  AM   | Operator family |               Operator                | Strategy | Purpose | Sort opfamily 
--------+-----------------+---------------------------------------+----------+---------+---------------
- btree | float_ops       | <(double precision,double precision)  |        1 | search  | 
- btree | float_ops       | <=(double precision,double precision) |        2 | search  | 
- btree | float_ops       | =(double precision,double precision)  |        3 | search  | 
- btree | float_ops       | >=(double precision,double precision) |        4 | search  | 
- btree | float_ops       | >(double precision,double precision)  |        5 | search  | 
- btree | float_ops       | <(real,real)                          |        1 | search  | 
- btree | float_ops       | <=(real,real)                         |        2 | search  | 
- btree | float_ops       | =(real,real)                          |        3 | search  | 
- btree | float_ops       | >=(real,real)                         |        4 | search  | 
- btree | float_ops       | >(real,real)                          |        5 | search  | 
- btree | float_ops       | <(double precision,real)              |        1 | search  | 
- btree | float_ops       | <=(double precision,real)             |        2 | search  | 
- btree | float_ops       | =(double precision,real)              |        3 | search  | 
- btree | float_ops       | >=(double precision,real)             |        4 | search  | 
- btree | float_ops       | >(double precision,real)              |        5 | search  | 
- btree | float_ops       | <(real,double precision)              |        1 | search  | 
- btree | float_ops       | <=(real,double precision)             |        2 | search  | 
- btree | float_ops       | =(real,double precision)              |        3 | search  | 
- btree | float_ops       | >=(real,double precision)             |        4 | search  | 
- btree | float_ops       | >(real,double precision)              |        5 | search  | 
-(20 rows)
+\dAo+ btree array_ops|float_ops
+                                      List of operators of operator families
+  AM   | Operator family |               Operator                | Strategy | Purpose | Sort opfamily | Leakproof 
+-------+-----------------+---------------------------------------+----------+---------+---------------+-----------
+ btree | array_ops       | <(anyarray,anyarray)                  |        1 | search  |               | no
+ btree | array_ops       | <=(anyarray,anyarray)                 |        2 | search  |               | no
+ btree | array_ops       | =(anyarray,anyarray)                  |        3 | search  |               | no
+ btree | array_ops       | >=(anyarray,anyarray)                 |        4 | search  |               | no
+ btree | array_ops       | >(anyarray,anyarray)                  |        5 | search  |               | no
+ btree | float_ops       | <(double precision,double precision)  |        1 | search  |               | yes
+ btree | float_ops       | <=(double precision,double precision) |        2 | search  |               | yes
+ btree | float_ops       | =(double precision,double precision)  |        3 | search  |               | yes
+ btree | float_ops       | >=(double precision,double precision) |        4 | search  |               | yes
+ btree | float_ops       | >(double precision,double precision)  |        5 | search  |               | yes
+ btree | float_ops       | <(real,real)                          |        1 | search  |               | yes
+ btree | float_ops       | <=(real,real)                         |        2 | search  |               | yes
+ btree | float_ops       | =(real,real)                          |        3 | search  |               | yes
+ btree | float_ops       | >=(real,real)                         |        4 | search  |               | yes
+ btree | float_ops       | >(real,real)                          |        5 | search  |               | yes
+ btree | float_ops       | <(double precision,real)              |        1 | search  |               | yes
+ btree | float_ops       | <=(double precision,real)             |        2 | search  |               | yes
+ btree | float_ops       | =(double precision,real)              |        3 | search  |               | yes
+ btree | float_ops       | >=(double precision,real)             |        4 | search  |               | yes
+ btree | float_ops       | >(double precision,real)              |        5 | search  |               | yes
+ btree | float_ops       | <(real,double precision)              |        1 | search  |               | yes
+ btree | float_ops       | <=(real,double precision)             |        2 | search  |               | yes
+ btree | float_ops       | =(real,double precision)              |        3 | search  |               | yes
+ btree | float_ops       | >=(real,double precision)             |        4 | search  |               | yes
+ btree | float_ops       | >(real,double precision)              |        5 | search  |               | yes
+(25 rows)
 
 \dAo * pg_catalog.jsonb_path_ops
              List of operators of operator families
@@ -5388,12 +5393,12 @@ create function psql_df_plpgsql ()
   as $$ begin return; end; $$;
 comment on function psql_df_plpgsql () is 'some comment';
 \df+ psql_df_*
-                                                                                       List of functions
- Schema |       Name       | Result data type | Argument data types | Type | Volatility | Parallel |       Owner       | Security | Access privileges | Language | Internal name | Description  
---------+------------------+------------------+---------------------+------+------------+----------+-------------------+----------+-------------------+----------+---------------+--------------
- public | psql_df_internal | double precision | double precision    | func | immutable  | safe     | regress_psql_user | invoker  |                   | internal | dsin          | 
- public | psql_df_plpgsql  | void             |                     | func | volatile   | unsafe   | regress_psql_user | invoker  |                   | plpgsql  |               | some comment
- public | psql_df_sql      | integer          | x integer           | func | volatile   | unsafe   | regress_psql_user | definer  |                   | sql      |               | 
+                                                                                             List of functions
+ Schema |       Name       | Result data type | Argument data types | Type | Volatility | Parallel |       Owner       | Security | Leakproof | Access privileges | Language | Internal name | Description  
+--------+------------------+------------------+---------------------+------+------------+----------+-------------------+----------+-----------+-------------------+----------+---------------+--------------
+ public | psql_df_internal | double precision | double precision    | func | immutable  | safe     | regress_psql_user | invoker  | no        |                   | internal | dsin          | 
+ public | psql_df_plpgsql  | void             |                     | func | volatile   | unsafe   | regress_psql_user | invoker  | no        |                   | plpgsql  |               | some comment
+ public | psql_df_sql      | integer          | x integer           | func | volatile   | unsafe   | regress_psql_user | definer  | no        |                   | sql      |               | 
 (3 rows)
 
 rollback;
@@ -6791,10 +6796,10 @@ REVOKE ALL ON DOMAIN regress_zeropriv_domain FROM CURRENT_USER, PUBLIC;
 CREATE PROCEDURE regress_zeropriv_proc() LANGUAGE sql AS '';
 REVOKE ALL ON PROCEDURE regress_zeropriv_proc() FROM CURRENT_USER, PUBLIC;
 \df+ regress_zeropriv_proc
-                                                                                            List of functions
- Schema |         Name          | Result data type | Argument data types | Type | Volatility | Parallel |         Owner          | Security | Access privileges | Language | Internal name | Description 
---------+-----------------------+------------------+---------------------+------+------------+----------+------------------------+----------+-------------------+----------+---------------+-------------
- public | regress_zeropriv_proc |                  |                     | proc | volatile   | unsafe   | regress_zeropriv_owner | invoker  | (none)            | sql      |               | 
+                                                                                                  List of functions
+ Schema |         Name          | Result data type | Argument data types | Type | Volatility | Parallel |         Owner          | Security | Leakproof | Access privileges | Language | Internal name | Description 
+--------+-----------------------+------------------+---------------------+------+------------+----------+------------------------+----------+-----------+-------------------+----------+---------------+-------------
+ public | regress_zeropriv_proc |                  |                     | proc | volatile   | unsafe   | regress_zeropriv_owner | invoker  | no        | (none)            | sql      |               | 
 (1 row)
 
 CREATE TABLE regress_zeropriv_tbl (a int);
diff --git a/src/test/regress/sql/psql.sql b/src/test/regress/sql/psql.sql
index c5021fc0b1..f6c5aa1f8b 100644
--- a/src/test/regress/sql/psql.sql
+++ b/src/test/regress/sql/psql.sql
@@ -1306,7 +1306,7 @@ drop role regress_partitioning_role;
 \dAc brin pg*.oid*
 \dAf spgist
 \dAf btree int4
-\dAo+ btree float_ops
+\dAo+ btree array_ops|float_ops
 \dAo * pg_catalog.jsonb_path_ops
 \dAp+ btree float_ops
 \dAp * pg_catalog.uuid_ops
-- 
2.34.1

