From 6ad7b789312eef71d066e52062e06cf980052956 Mon Sep 17 00:00:00 2001
From: Man Zeng <zengman@halodbtech.com>
Date: Mon, 29 Dec 2025 15:40:17 +0800
Subject: [PATCH v1] This patch extends psql's tab-completion logic to
 recognize the "ALTER ROLE <role> IN DATABASE <dbname>" command structure, and
 provides appropriate completions for the SET and RESET subcommands.
MIME-Version: 1.0
Content-Type: text/plain; charset=UTF-8
Content-Transfer-Encoding: 8bit

Specifically:

  • After "ALTER ROLE <role> IN DATABASE <dbname> SET", psql now
    completes with the list of configuration variables that may be set
    (Query_for_list_of_set_vars), matching the behavior of the plain
    ALTER ROLE ... SET form.

  • After "ALTER ROLE <role> IN DATABASE <dbname> RESET", psql now
    suggests configuration variables that are *actually set* for that
    specific (role,database) pair, as recorded in pg_db_role_setting,
    plus the keyword ALL.  This mirrors the behavior of ALTER DATABASE
    ... RESET, where we complete only the variables currently set for
    the object being modified.

The role name and database name are extracted from the already-parsed
input tokens, and SQL literal quoting is performed via PQescapeLiteral()
using the implicit PGconn (pset.db) available to the tab-completion code.
This avoids any need to alter tab-completion APIs and keeps the patch
self-contained.

Due to the structure of tab-completion, this patch intentionally does
not attempt to complete arbitrary GUC names for RESET, but rather only
those that exist in pg_db_role_setting for the given role and
database.  When none are present, psql falls back to suggesting ALL,
matching existing RESET behavior elsewhere.

Vasuki M
---
 src/bin/psql/tab-complete.in.c | 65 ++++++++++++++++++++++++++++++++--
 1 file changed, 63 insertions(+), 2 deletions(-)

diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c
index 75a101c6ab5..a33818b3654 100644
--- a/src/bin/psql/tab-complete.in.c
+++ b/src/bin/psql/tab-complete.in.c
@@ -2536,12 +2536,73 @@ match_previous_words(int pattern_id,
 	else if (Matches("ALTER", "USER|ROLE", MatchAny) &&
 			 !TailMatches("USER", "MAPPING"))
 		COMPLETE_WITH("BYPASSRLS", "CONNECTION LIMIT", "CREATEDB", "CREATEROLE",
-					  "ENCRYPTED PASSWORD", "INHERIT", "LOGIN", "NOBYPASSRLS",
-					  "NOCREATEDB", "NOCREATEROLE", "NOINHERIT",
+					  "ENCRYPTED PASSWORD", "IN DATABASE", "INHERIT", "LOGIN",
+					  "NOBYPASSRLS", "NOCREATEDB", "NOCREATEROLE", "NOINHERIT",
 					  "NOLOGIN", "NOREPLICATION", "NOSUPERUSER", "PASSWORD",
 					  "RENAME TO", "REPLICATION", "RESET", "SET", "SUPERUSER",
 					  "VALID UNTIL", "WITH");
 
+	/* ALTER USER,ROLE <name> IN */
+	else if (Matches("ALTER", "USER|ROLE", MatchAny, "IN"))
+		COMPLETE_WITH("DATABASE");
+	/* ALTER USER/ROLE <name> IN DATABASE */
+	else if (Matches("ALTER", "USER|ROLE", MatchAny, "IN", "DATABASE"))
+	{
+		/* ALTER ROLE bob IN DATABASE <TAB> → list databases */
+		COMPLETE_WITH_QUERY(Query_for_list_of_databases);
+	}
+	/* ALTER USER/ROLE <name> IN DATABASE <dbname> */
+	else if (Matches("ALTER", "USER|ROLE", MatchAny, "IN", "DATABASE", MatchAny))
+	{
+		/* ALTER ROLE bob IN DATABASE mydb <TAB> → SET, RESET */
+		COMPLETE_WITH("SET", "RESET");
+	}
+	/* ALTER USER/ROLE <name> IN DATABASE <dbname> SET */
+	else if (Matches("ALTER", "USER|ROLE", MatchAny, "IN", "DATABASE", MatchAny, "SET"))
+	{
+		/* ALTER ROLE bob IN DATABASE mydb SET <TAB> */
+		COMPLETE_WITH_QUERY(Query_for_list_of_set_vars);
+	}
+	/* ALTER USER/ROLE <name> IN DATABASE <dbname> RESET */
+	else if (Matches("ALTER", "USER|ROLE", MatchAny, "IN", "DATABASE", MatchAny, "RESET"))
+	{
+		/*
+		 * Extract tokens: prev5 = role name prev2 = database name
+		 */
+		char	   *role = prev5_wd;
+		char	   *dbname = prev2_wd;
+		char	   *q_role;
+		char	   *q_dbname;
+		char	   *query;
+
+		/* Safe SQL literal quoting using libpq */
+		q_role = PQescapeLiteral(pset.db, role, strlen(role));
+		q_dbname = PQescapeLiteral(pset.db, dbname, strlen(dbname));
+		if (!q_role || !q_dbname)
+		{
+			/* If quoting fails, just fall back to ALL */
+			if (q_role)
+				PQfreemem(q_role);
+			if (q_dbname)
+				PQfreemem(q_dbname);
+			COMPLETE_WITH("ALL");
+		}
+		else
+		{
+			query = psprintf(
+							 "SELECT split_part(unnest(setconfig), \'=\', 1) "
+							 "  FROM pg_db_role_setting "
+							 " WHERE setdatabase = "
+							 "       (SELECT oid FROM pg_database WHERE datname = %s) "
+							 "   AND setrole = %s::regrole",
+							 q_dbname, q_role);
+			COMPLETE_WITH_QUERY_PLUS(query, "ALL");
+			PQfreemem(q_role);
+			PQfreemem(q_dbname);
+			pfree(query);
+		}
+	}
+
 	/* ALTER USER,ROLE <name> RESET */
 	else if (Matches("ALTER", "USER|ROLE", MatchAny, "RESET"))
 	{
-- 
2.43.0

