Обсуждение: Adding comments to help understand psql hidden queries

Поиск
Список
Период
Сортировка

Adding comments to help understand psql hidden queries

От
Greg Sabino Mullane
Дата:
The use of the --echo-hidden flag in psql is used to show people the way psql performs its magic for its backslash commands. None of them has more magic than "\d relation", but it suffers from needing a lot of separate queries to gather all of the information it needs. Unfortunately, those queries can get overwhelming and hard to figure out which one does what, especially for those not already very familiar with the system catalogs. Attached is a patch to add a small SQL comment to the top of each SELECT query inside describeOneTableDetail. All other functions use a single query, and thus need no additional context. But "\d mytable" has the potential to run over a dozen SQL queries! The new format looks like this:

/******** QUERY *********/
/* Get information about row-level policies */
SELECT pol.polname, pol.polpermissive,
  CASE WHEN pol.polroles = '{0}' THEN NULL ELSE pg_catalog.array_to_string(array(select rolname from pg_catalog.pg_roles where oid = any (pol.polroles) order by 1),',') END,
  pg_catalog.pg_get_expr(pol.polqual, pol.polrelid),
  pg_catalog.pg_get_expr(pol.polwithcheck, pol.polrelid),
  CASE pol.polcmd
    WHEN 'r' THEN 'SELECT'
    WHEN 'a' THEN 'INSERT'
    WHEN 'w' THEN 'UPDATE'
    WHEN 'd' THEN 'DELETE'
    END AS cmd
FROM pg_catalog.pg_policy pol
WHERE pol.polrelid = '134384' ORDER BY 1;
/************************/

Cheers,
Greg

Вложения

Re: Adding comments to help understand psql hidden queries

От
David Christensen
Дата:
On Thu, Feb 1, 2024 at 4:34 PM Greg Sabino Mullane <htamfids@gmail.com> wrote:
>
> The use of the --echo-hidden flag in psql is used to show people the way psql performs its magic for its backslash
commands.None of them has more magic than "\d relation", but it suffers from needing a lot of separate queries to
gatherall of the information it needs. Unfortunately, those queries can get overwhelming and hard to figure out which
onedoes what, especially for those not already very familiar with the system catalogs. Attached is a patch to add a
smallSQL comment to the top of each SELECT query inside describeOneTableDetail. All other functions use a single query,
andthus need no additional context. But "\d mytable" has the potential to run over a dozen SQL queries! The new format
lookslike this: 
>
> /******** QUERY *********/
> /* Get information about row-level policies */
> SELECT pol.polname, pol.polpermissive,
>   CASE WHEN pol.polroles = '{0}' THEN NULL ELSE pg_catalog.array_to_string(array(select rolname from
pg_catalog.pg_roleswhere oid = any (pol.polroles) order by 1),',') END, 
>   pg_catalog.pg_get_expr(pol.polqual, pol.polrelid),
>   pg_catalog.pg_get_expr(pol.polwithcheck, pol.polrelid),
>   CASE pol.polcmd
>     WHEN 'r' THEN 'SELECT'
>     WHEN 'a' THEN 'INSERT'
>     WHEN 'w' THEN 'UPDATE'
>     WHEN 'd' THEN 'DELETE'
>     END AS cmd
> FROM pg_catalog.pg_policy pol
> WHERE pol.polrelid = '134384' ORDER BY 1;
> /************************/
>
> Cheers,
> Greg

Thanks, this looks like some helpful information. In the same vein,
I'm including a patch which adds information about the command that
generates the given query as well (atop your commit).  This will
modify the query line to include the command itself:

/******** QUERY (\dRs) *********/

Best,

David

Вложения

Re: Adding comments to help understand psql hidden queries

От
Jim Jones
Дата:
Hi Greg, hi David

On 01.02.24 23:39, David Christensen wrote:
> On Thu, Feb 1, 2024 at 4:34 PM Greg Sabino Mullane <htamfids@gmail.com> wrote:
>> The use of the --echo-hidden flag in psql is used to show people the way psql performs its magic for its backslash
commands.None of them has more magic than "\d relation", but it suffers from needing a lot of separate queries to
gatherall of the information it needs. Unfortunately, those queries can get overwhelming and hard to figure out which
onedoes what, especially for those not already very familiar with the system catalogs. Attached is a patch to add a
smallSQL comment to the top of each SELECT query inside describeOneTableDetail. All other functions use a single query,
andthus need no additional context. But "\d mytable" has the potential to run over a dozen SQL queries! The new format
lookslike this:
 
>>
>> /******** QUERY *********/
>> /* Get information about row-level policies */
>> SELECT pol.polname, pol.polpermissive,
>>   CASE WHEN pol.polroles = '{0}' THEN NULL ELSE pg_catalog.array_to_string(array(select rolname from
pg_catalog.pg_roleswhere oid = any (pol.polroles) order by 1),',') END,
 
>>   pg_catalog.pg_get_expr(pol.polqual, pol.polrelid),
>>   pg_catalog.pg_get_expr(pol.polwithcheck, pol.polrelid),
>>   CASE pol.polcmd
>>     WHEN 'r' THEN 'SELECT'
>>     WHEN 'a' THEN 'INSERT'
>>     WHEN 'w' THEN 'UPDATE'
>>     WHEN 'd' THEN 'DELETE'
>>     END AS cmd
>> FROM pg_catalog.pg_policy pol
>> WHERE pol.polrelid = '134384' ORDER BY 1;
>> /************************/
>>
>> Cheers,
>> Greg
> Thanks, this looks like some helpful information. In the same vein,
> I'm including a patch which adds information about the command that
> generates the given query as well (atop your commit).  This will
> modify the query line to include the command itself:
>
> /******** QUERY (\dRs) *********/
>
> Best,
>
> David

Having this kind of information in each query would have saved me a lot
of time in the past :) +1

There is a tiny little issue in the last patch (qualifiers):

command.c:312:16: warning: assignment discards ‘const’ qualifier from
pointer target type [-Wdiscarded-qualifiers]
  312 |         curcmd = cmd;

Thanks

-- 
Jim




Re: Adding comments to help understand psql hidden queries

От
David Christensen
Дата:
Hi Jim,

Thanks for the feedback.  Enclosed is a v2 of this series(?) rebased
and with that warning fixed; @Greg Sabino Mullane I just created a
commit on your behalf with the message to hackers.  I'm also creating
a commit-fest entry for this thread.

Best,

David

Вложения

Re: Adding comments to help understand psql hidden queries

От
David Christensen
Дата:
Created the CF entry in commitfest 48 but didn't see it was already in 47; closing the CFEntry in 48. (Doesn't appear
tobe a different status than "Withdrawn"...) 

Re: Adding comments to help understand psql hidden queries

От
Peter Eisentraut
Дата:
On 21.03.24 18:31, David Christensen wrote:
> Thanks for the feedback.  Enclosed is a v2 of this series(?) rebased
> and with that warning fixed; @Greg Sabino Mullane I just created a
> commit on your behalf with the message to hackers.  I'm also creating
> a commit-fest entry for this thread.

I don't think your patch takes into account that the

/**... QUERY ...**/
...
/**...       ...**/

lines are supposed to align vertically.  With your patch, the first line 
would have variable length depending on the command.



Re: Adding comments to help understand psql hidden queries

От
Greg Sabino Mullane
Дата:
On Thu, Mar 21, 2024 at 6:20 PM Peter Eisentraut <peter@eisentraut.org> wrote:
lines are supposed to align vertically.  With your patch, the first line
would have variable length depending on the command.

Yes, that is a good point. Aligning those would be quite tricky, what if we just kept a standard width for the closing query? Probably the 24 stars we currently have to match "QUERY", which it appears nobody has changed for translation purposes yet anyway. (If I am reading the code correctly, it would be up to the translators to maintain the vertical alignment).

Cheers,
Greg
 

Re: Adding comments to help understand psql hidden queries

От
David Christensen
Дата:
On Fri, Mar 22, 2024 at 9:47 AM Greg Sabino Mullane <htamfids@gmail.com> wrote:
>
> On Thu, Mar 21, 2024 at 6:20 PM Peter Eisentraut <peter@eisentraut.org> wrote:
>>
>> lines are supposed to align vertically.  With your patch, the first line
>> would have variable length depending on the command.
>
>
> Yes, that is a good point. Aligning those would be quite tricky, what if we just kept a standard width for the
closingquery? Probably the 24 stars we currently have to match "QUERY", which it appears nobody has changed for
translationpurposes yet anyway. (If I am reading the code correctly, it would be up to the translators to maintain the
verticalalignment). 

I think it's easier to keep the widths balanced than constant (patch
version included here), but if we needed to squeeze the opening string
to a standard width that would be possible without too much trouble.
The internal comment strings seem to be a bit more of a pain if we
wanted all of the comments to be the same width, as we'd need a table
or something so we can compute the longest string width, etc; doesn't
seem worth the convolutions IMHO.

No changes to Greg's patch, just keeping 'em both so cfbot stays happy.

David

Вложения

Re: Adding comments to help understand psql hidden queries

От
Greg Sabino Mullane
Дата:
On Fri, Mar 22, 2024 at 11:39 AM David Christensen <david+pg@pgguru.net> wrote:
I think it's easier to keep the widths balanced than constant (patch
version included here)

Yeah, I'm fine with that, especially because nobody is translating it, nor are they likely to, to be honest.

Cheers,
Greg

Re: Adding comments to help understand psql hidden queries

От
David Christensen
Дата:
I got Greg's blessing on squashing the commits down, and now including
a v4 with additional improvements on the output formatting front.
Main changes:

- all generated comments are the same width
- width has been bumped to 80
- removed _() functions for consumers of the new output functions

This patch adds two new helper functions, OutputComment() and
OutputCommentStars() to output and wrap the comments to the
appropriate widths.  Everything should continue to work just fine if
we want to adjust the width by just adjusting the MAX_COMMENT_WIDTH
symbol.

I removed _() in the output of the query/stars since there'd be no
sensible existing translations for the constructed string, which
included the query string itself.  If we need it for the "QUERY"
string, this could be added fairly easily, but the existing piece
would have been nonsensical and never used in practice.

Thanks,

David

Вложения

Re: Adding comments to help understand psql hidden queries

От
Peter Eisentraut
Дата:
On 03.04.24 19:16, David Christensen wrote:
> I removed _() in the output of the query/stars since there'd be no
> sensible existing translations for the constructed string, which
> included the query string itself.  If we need it for the "QUERY"
> string, this could be added fairly easily, but the existing piece
> would have been nonsensical and never used in practice.

"QUERY" is currently translated.  Your patch loses that.




Re: Adding comments to help understand psql hidden queries

От
David Christensen
Дата:
On Thu, Apr 4, 2024 at 9:32 AM Peter Eisentraut <peter@eisentraut.org> wrote:
>
> On 03.04.24 19:16, David Christensen wrote:
> > I removed _() in the output of the query/stars since there'd be no
> > sensible existing translations for the constructed string, which
> > included the query string itself.  If we need it for the "QUERY"
> > string, this could be added fairly easily, but the existing piece
> > would have been nonsensical and never used in practice.
>
> "QUERY" is currently translated.  Your patch loses that.

I see; enclosed is v5 which fixes this.

The effective diff from the last one is:

-    char *label = "QUERY";
+    char *label = _("QUERY");

and

-        label = psprintf("QUERY (\\%s)", curcmd);
+        label = psprintf(_("QUERY (\\%s)"), curcmd);

Best,

David

Вложения

Re: Adding comments to help understand psql hidden queries

От
David Christensen
Дата:
On Thu, Apr 4, 2024 at 11:12 AM David Christensen <david+pg@pgguru.net> wrote:
>
> On Thu, Apr 4, 2024 at 9:32 AM Peter Eisentraut <peter@eisentraut.org> wrote:
> >
> > On 03.04.24 19:16, David Christensen wrote:
> > > I removed _() in the output of the query/stars since there'd be no
> > > sensible existing translations for the constructed string, which
> > > included the query string itself.  If we need it for the "QUERY"
> > > string, this could be added fairly easily, but the existing piece
> > > would have been nonsensical and never used in practice.
> >
> > "QUERY" is currently translated.  Your patch loses that.
>
> I see; enclosed is v5 which fixes this.
>
> The effective diff from the last one is:
>
> -    char *label = "QUERY";
> +    char *label = _("QUERY");
>
> and
>
> -        label = psprintf("QUERY (\\%s)", curcmd);
> +        label = psprintf(_("QUERY (\\%s)"), curcmd);

Any further concerns/issues with this patch that I can address to help
move it forward?

David



Re: Adding comments to help understand psql hidden queries

От
Tom Lane
Дата:
David Christensen <david+pg@pgguru.net> writes:
> Any further concerns/issues with this patch that I can address to help
> move it forward?

I got around to looking at this finally --- sorry that it's been on
the back burner for so long.  I think this is basically a good idea
but it still requires a lot of sanding-down of rough edges.

The patch doesn't apply cleanly anymore, which is unsurprising since
it's been sitting for months; what might be more surprising is that
there was only one hunk that had to be fixed by hand.

I noticed also that "git diff --check" complains about a bunch of
whitespace style violations, and that brace layout and comment layout
largely fail to comply with PG project standards.  I ran the patched
code through pgindent to get rid of those warnings, but did not really
look at whether any of what it changed could be done better.

(I attach a v6 with the results of those changes to pacify the cfbot.
I have not made any changes responding to my comments below.)

Playing around with what it does, my first observation is that the
results look absolutely horrid in an 80-column xterm window:

$ psql -E regression
psql (18devel)
Type "help" for help.

regression=# \d tenk1
/********************************* QUERY (\d) **********************************
/
SELECT c.oid,
...
ORDER BY 2, 3;
/*******************************************************************************
/
/********************************* QUERY (\d) **********************************
/
/* Get general table information                                               *
/
SELECT c.relchecks, c.relkind, c.relhasindex, c.relhasrules, c.relhastriggers,
...

So evidently the effective line length is 81 characters not the 80
that the code claims to be using.  I did not look to see where the
off-by-one error is.

On the particular xterm setup I use, backing off the number of stars
by one would be enough to make that look better; but I have very often
used setups where printing 80 characters and a newline would result in
a blank line.  I think the comment width must be reduced to no more
than 79 characters.  Even that seems a little questionable; are there
people who use less-than-80-column terminal windows?  I think aiming
for 60 or so columns might be smarter.

There's another issue here too, arising from the fact that you want to
give translated strings to OutputComment().  That's laudable, but it
means that strlen() isn't even approximately the right computation for
how many columns the string will occupy on-screen.  (There are very
likely some multibyte characters in the translated string, and then
again some of those characters could be double-width ideograms.)
Now psql does contain code that can compute the actual displayed width
of a translated string, but frankly I'm beginning to question the
value of the whole business.  How about just printing a fixed number
of stars, like ten, and dropping the whole concept of a target line
length?

/********** QUERY (\d) **********/
/* Get general table information */
... blah blah blah ...
/*********************/

Secondly, looking at the whole output, it seems quite repetitive:

regression=# \d tenk1
/********************************* QUERY (\d) **********************************/
SELECT ...
/*******************************************************************************/
/********************************* QUERY (\d) **********************************/
/* Get general table information                                               */
SELECT ...
/*******************************************************************************/
/********************************* QUERY (\d) **********************************/
/* Get information about each column
                                          */
SELECT ...
/*******************************************************************************/
/********************************* QUERY (\d) **********************************/
/* Get information about each index                                            */
SELECT ...
/*******************************************************************************/
/********************************* QUERY (\d) **********************************/
/* Get information about row-level policies                                    */
SELECT ...
/*******************************************************************************/
/********************************* QUERY (\d) **********************************/
/* Get information about extended statistics                                   */
SELECT ...
/*******************************************************************************/
/********************************* QUERY (\d) **********************************/
/* Get information about each publication using this table                     */
SELECT ...
/*******************************************************************************/
/********************************* QUERY (\d) **********************************/
SELECT c.oid::pg_catalog.regclass
FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i
WHERE c.oid = i.inhparent AND i.inhrelid = '16418'
  AND c.relkind != 'p' AND c.relkind != 'I'
ORDER BY inhseqno;
/*******************************************************************************/
/********************************* QUERY (\d) **********************************/
/* Get information about child tables                                          */
SELECT ...
/*******************************************************************************/

Surely we do not need to repeat the "QUERY (\d)" line; in fact,
I think it's confusing to do so.  That should appear but once
per user command.

I also find all the stars to be fairly visually distracting.
What do you think of losing those altogether in favor of blank
lines?  Something like

/********** QUERY (\d) **********/
SELECT ...

/* Get general table information */
SELECT ...

/* Get information about each column */
SELECT ...

/* Get information about each index */
SELECT ...

/* Get information about row-level policies */
SELECT ...

/* Get information about extended statistics */
SELECT ...

/* Get information about each publication using this table */
SELECT ...

/* Get information about child tables */
SELECT ...

Maybe that's too far in the other direction, but it seems
worth thinking about.

(BTW, there is one query in the output for \d that lacks an
OutputComment gloss.  Maybe that's one that got added since
this patch was written?)

Moving on to actual code review:

* The "curcmd" global variable is quite horrid IMO.  It would
be only slightly less horrid if it were properly documented
and declared in a header file as globals should be.  I suppose you
did that to avoid having to pass the command string down through
a ton of subroutines.  However, with my proposal that the query
should be printed only once at the start, maybe we could relocate
the responsibility for printing it to somewhere closer to
exec_command(), and thus reduce the notational overhead?

* It took me awhile to realize that OutputComment resets the
target buffer while OutputCommentStars doesn't.  Neither their
names nor their header comments give any clue about that
rather critical-to-callers property.  I don't like the name
"OutputCommentStars" anyway as it puts emphasis on what it should
be *hiding* from callers, namely the form of the output.  Not
sure about a better name.

* Enabling log_statement = 'all' proves that the comments added
by OutputComment are sent to the server, *even when -E is not on*:

2025-01-18 15:09:23.575 EST [2587557] LOG:  statement: /* Get general table information
             */ 
    SELECT c.relchecks, c.relkind, c.relhasindex, c.relhasrules, c.relhastriggers, c.relrowsecurity,
c.relforcerowsecurity,false AS relhasoids, c.relispartition, '', c.reltablespace, CASE WHEN c.reloftype = 0 THEN ''
ELSEc.reloftype::pg_catalog.regtype::pg_catalog.text END, c.relpersistence, c.relreplident, am.amname 
    FROM pg_catalog.pg_class c
     LEFT JOIN pg_catalog.pg_class tc ON (c.reltoastrelid = tc.oid)
    LEFT JOIN pg_catalog.pg_am am ON (c.relam = am.oid)
    WHERE c.oid = '16418';

I don't find that acceptable at all.  For one thing, it makes the
stakes extremely high (as in possibly security-critical) that there
are no "*/" sequences in the label strings.  On the whole I'd rather
arrange things so that the comments are only emitted to the psql
terminal and never sent to the server.  It appears that that's
true already for some of them --- I didn't trouble to try to
understand why these behave differently.

* In connection with that, I'm none too comfortable with the
assumption "there are no inner comments that need to be escaped",
mainly for the comments that include fragments of user queries.
If we can ensure that none of this output gets to the server then
maybe it's not too critical, but I'm not really convinced.  Is it
worth doing something to sanitize the comment contents?

* I think the \n here was unintended:
+    OutputComment(&buf, _("Get information about each column\n"));
That leads to some oddly-formatted output.

Anyway, I encourage you to work on these issues and see if we
can get to a committable patch.

            regards, tom lane

diff --git a/src/bin/psql/command.c b/src/bin/psql/command.c
index 613583145e..f5b8c1d369 100644
--- a/src/bin/psql/command.c
+++ b/src/bin/psql/command.c
@@ -53,6 +53,8 @@ typedef enum EditableObjectType
     EditableView,
 } EditableObjectType;

+char       *curcmd = NULL;
+
 /* local function declarations */
 static backslashResult exec_command(const char *cmd,
                                     PsqlScanState scan_state,
@@ -311,6 +313,7 @@ exec_command(const char *cmd,
                        cmd);
     }

+    curcmd = (char *) cmd;
     if (strcmp(cmd, "a") == 0)
         status = exec_command_a(scan_state, active_branch);
     else if (strcmp(cmd, "bind") == 0)
@@ -438,6 +441,8 @@ exec_command(const char *cmd,
     else
         status = PSQL_CMD_UNKNOWN;

+    curcmd = NULL;
+
     /*
      * All the commands that return PSQL_CMD_SEND want to execute previous_buf
      * if query_buf is empty.  For convenience we implement that here, not in
diff --git a/src/bin/psql/common.c b/src/bin/psql/common.c
index f1a5291c13..d5f7fa9e64 100644
--- a/src/bin/psql/common.c
+++ b/src/bin/psql/common.c
@@ -40,6 +40,7 @@ static int    ExecQueryAndProcessResults(const char *query,
                                        FILE *printQueryFout);
 static bool command_no_begin(const char *query);

+extern char *curcmd;

 /*
  * openQueryOutputFile --- attempt to open a query output file
@@ -620,6 +621,8 @@ PGresult *
 PSQLexec(const char *query)
 {
     PGresult   *res;
+    char       *label = _("QUERY");
+

     if (!pset.db)
     {
@@ -627,21 +630,33 @@ PSQLexec(const char *query)
         return NULL;
     }

+    if (curcmd)
+        label = psprintf(_("QUERY (\\%s)"), curcmd);
+
     if (pset.echo_hidden != PSQL_ECHO_HIDDEN_OFF)
     {
-        printf(_("/******** QUERY *********/\n"
-                 "%s\n"
-                 "/************************/\n\n"), query);
+        PQExpBufferData buf;
+
+        initPQExpBuffer(&buf);
+
+        OutputCommentStars(&buf, label);
+        appendPQExpBufferStr(&buf, query);
+        appendPQExpBufferChar(&buf, '\n');
+        OutputCommentStars(&buf, NULL);
+
+        printf("%s", buf.data);
         fflush(stdout);
         if (pset.logfile)
         {
-            fprintf(pset.logfile,
-                    _("/******** QUERY *********/\n"
-                      "%s\n"
-                      "/************************/\n\n"), query);
+            fprintf(pset.logfile, "%s", buf.data);
             fflush(pset.logfile);
         }

+        pfree(buf.data);
+
+        if (curcmd)
+            pfree(label);
+
         if (pset.echo_hidden == PSQL_ECHO_HIDDEN_NOEXEC)
             return NULL;
     }
@@ -2318,3 +2333,123 @@ recognized_connection_string(const char *connstr)
 {
     return uri_prefix_length(connstr) != 0 || strchr(connstr, '=') != NULL;
 }
+
+/*
+ * OutputComment() outputs the given string to a buffer as a
+ * fixed width comment, wrapping the text given to the proper size and
+ * breaking at a space.  We assume there are no inner comments that need to be
+ * escaped.
+ */
+void
+OutputComment(PQExpBufferData *buf, const char *string)
+{
+    int            len = strlen(string);
+    int            lineStart = 0;
+
+    /* -6 accounts for " * " at the start and " *" at the end of each line */
+    int            lineEnd = MAX_COMMENT_WIDTH - 6;
+    static char spaces[MAX_COMMENT_WIDTH] = {0};
+
+    if (spaces[0] != ' ')
+        memset(spaces, ' ', MAX_COMMENT_WIDTH);
+
+    while (lineStart < len)
+    {
+        /* Adjust lineEnd if it's beyond the length of the string */
+        if (lineEnd >= len)
+        {
+            lineEnd = len - 1;
+        }
+        else
+        {
+            /*
+             * Ensure we break the line at a space (if possible) to avoid
+             * breaking words
+             */
+            while (lineEnd > lineStart && string[lineEnd] != ' ')
+            {
+                lineEnd--;
+            }
+            if (lineEnd == lineStart)
+            {
+                /*
+                 * If we couldn't find a space, force a break at the maximum
+                 * line width
+                 */
+                lineEnd = lineStart + MAX_COMMENT_WIDTH - 6;
+            }
+        }
+
+        /*
+         * output our data for the width we have, including the piece of the
+         * comment
+         */
+        printfPQExpBuffer(buf,
+                          "/* %.*s%.*s */\n",
+                          lineEnd - lineStart + 1,    /* number of chars to
+                                                     * output */
+                          string + lineStart,    /* offset of chars to copy */
+        /* length of padding */
+                          MAX_COMMENT_WIDTH - 6 - (lineEnd - lineStart),
+                          spaces
+            );
+
+        /* Move to the next line */
+        lineStart = lineEnd + 1;
+        lineEnd = lineStart + MAX_COMMENT_WIDTH - 6;
+    }
+}
+
+
+/*
+ * OutputCommentStars() outputs the given single-line string wrapped in stars
+ * to the given width.
+ */
+void
+OutputCommentStars(PQExpBufferData *buf, const char *string)
+{
+    int            len = string ? strlen(string) : 0;
+    char        stars[MAX_COMMENT_WIDTH + 3];
+    int            startOutputOffset;
+
+    /*
+     * This shouldn't happen based on current callers, but we'll truncate to a
+     * safe size if need be.
+     */
+
+    if (len > MAX_COMMENT_WIDTH)    /* space for opening comment, closing
+                                     * comment, and spaces */
+        len = MAX_COMMENT_WIDTH;
+
+    /*
+     * If we have a zero-width string then this is a special-case where we
+     * just want a line of stars. To minimize code disruption in this case,
+     * we'll just set startOutputOffset to a value larger than
+     * MAX_COMMENT_WIDTH.
+     */
+
+    if (len > 0)
+        startOutputOffset = (((MAX_COMMENT_WIDTH - len - 2) / 2));    /* extra for space */
+    else
+        startOutputOffset = MAX_COMMENT_WIDTH * 2;
+
+    stars[0] = '/';
+    stars[MAX_COMMENT_WIDTH] = '/';
+    stars[MAX_COMMENT_WIDTH + 1] = '\n';
+    stars[MAX_COMMENT_WIDTH + 2] = '\0';
+
+    for (int i = 1; i < MAX_COMMENT_WIDTH; i++)
+    {
+        if (i >= startOutputOffset && i <= startOutputOffset + len + 1)
+        {
+            if (i == startOutputOffset || i == startOutputOffset + len + 1)
+                stars[i] = ' ';
+            else
+                stars[i] = string[i - startOutputOffset - 1];
+        }
+        else
+            stars[i] = '*';
+    }
+
+    appendPQExpBufferStr(buf, stars);
+}
diff --git a/src/bin/psql/common.h b/src/bin/psql/common.h
index 7f1a23de1e..5d1c3d63ab 100644
--- a/src/bin/psql/common.h
+++ b/src/bin/psql/common.h
@@ -15,6 +15,8 @@
 #include "fe_utils/psqlscan.h"
 #include "libpq-fe.h"

+#define MAX_COMMENT_WIDTH 80
+
 extern bool openQueryOutputFile(const char *fname, FILE **fout, bool *is_pipe);
 extern bool setQFout(const char *fname);

@@ -45,4 +47,7 @@ extern void clean_extended_state(void);

 extern bool recognized_connection_string(const char *connstr);

+extern void OutputComment(PQExpBufferData *buf, const char *string);
+extern void OutputCommentStars(PQExpBufferData *buf, const char *string);
+
 #endif                            /* COMMON_H */
diff --git a/src/bin/psql/describe.c b/src/bin/psql/describe.c
index 2ef99971ac..af3cd40543 100644
--- a/src/bin/psql/describe.c
+++ b/src/bin/psql/describe.c
@@ -1623,9 +1623,10 @@ describeOneTableDetails(const char *schemaname,
     initPQExpBuffer(&tmpbuf);

     /* Get general table info */
+    OutputComment(&buf, _("Get general table information"));
     if (pset.sversion >= 120000)
     {
-        printfPQExpBuffer(&buf,
+        appendPQExpBuffer(&buf,
                           "SELECT c.relchecks, c.relkind, c.relhasindex, c.relhasrules, "
                           "c.relhastriggers, c.relrowsecurity, c.relforcerowsecurity, "
                           "false AS relhasoids, c.relispartition, %s, c.reltablespace, "
@@ -1643,7 +1644,7 @@ describeOneTableDetails(const char *schemaname,
     }
     else if (pset.sversion >= 100000)
     {
-        printfPQExpBuffer(&buf,
+        appendPQExpBuffer(&buf,
                           "SELECT c.relchecks, c.relkind, c.relhasindex, c.relhasrules, "
                           "c.relhastriggers, c.relrowsecurity, c.relforcerowsecurity, "
                           "c.relhasoids, c.relispartition, %s, c.reltablespace, "
@@ -1660,7 +1661,7 @@ describeOneTableDetails(const char *schemaname,
     }
     else if (pset.sversion >= 90500)
     {
-        printfPQExpBuffer(&buf,
+        appendPQExpBuffer(&buf,
                           "SELECT c.relchecks, c.relkind, c.relhasindex, c.relhasrules, "
                           "c.relhastriggers, c.relrowsecurity, c.relforcerowsecurity, "
                           "c.relhasoids, false as relispartition, %s, c.reltablespace, "
@@ -1677,7 +1678,7 @@ describeOneTableDetails(const char *schemaname,
     }
     else if (pset.sversion >= 90400)
     {
-        printfPQExpBuffer(&buf,
+        appendPQExpBuffer(&buf,
                           "SELECT c.relchecks, c.relkind, c.relhasindex, c.relhasrules, "
                           "c.relhastriggers, false, false, c.relhasoids, "
                           "false as relispartition, %s, c.reltablespace, "
@@ -1694,7 +1695,7 @@ describeOneTableDetails(const char *schemaname,
     }
     else
     {
-        printfPQExpBuffer(&buf,
+        appendPQExpBuffer(&buf,
                           "SELECT c.relchecks, c.relkind, c.relhasindex, c.relhasrules, "
                           "c.relhastriggers, false, false, c.relhasoids, "
                           "false as relispartition, %s, c.reltablespace, "
@@ -1755,9 +1756,10 @@ describeOneTableDetails(const char *schemaname,
         printQueryOpt myopt = pset.popt;
         char       *footers[2] = {NULL, NULL};

+        OutputComment(&buf, _("Get general sequence information *"));
         if (pset.sversion >= 100000)
         {
-            printfPQExpBuffer(&buf,
+            appendPQExpBuffer(&buf,
                               "SELECT pg_catalog.format_type(seqtypid, NULL) AS \"%s\",\n"
                               "       seqstart AS \"%s\",\n"
                               "       seqmin AS \"%s\",\n"
@@ -1781,7 +1783,7 @@ describeOneTableDetails(const char *schemaname,
         }
         else
         {
-            printfPQExpBuffer(&buf,
+            appendPQExpBuffer(&buf,
                               "SELECT 'bigint' AS \"%s\",\n"
                               "       start_value AS \"%s\",\n"
                               "       min_value AS \"%s\",\n"
@@ -1808,7 +1810,8 @@ describeOneTableDetails(const char *schemaname,
             goto error_return;

         /* Get the column that owns this sequence */
-        printfPQExpBuffer(&buf, "SELECT pg_catalog.quote_ident(nspname) || '.' ||"
+        OutputComment(&buf, _("Get the column that owns this sequence"));
+        appendPQExpBuffer(&buf, "SELECT pg_catalog.quote_ident(nspname) || '.' ||"
                           "\n   pg_catalog.quote_ident(relname) || '.' ||"
                           "\n   pg_catalog.quote_ident(attname),"
                           "\n   d.deptype"
@@ -1887,7 +1890,8 @@ describeOneTableDetails(const char *schemaname,
      * duplicative test logic below.
      */
     cols = 0;
-    printfPQExpBuffer(&buf, "SELECT a.attname");
+    OutputComment(&buf, _("Get information about each column\n"));
+    appendPQExpBuffer(&buf, "SELECT a.attname");
     attname_col = cols++;
     appendPQExpBufferStr(&buf, ",\n  pg_catalog.format_type(a.atttypid, a.atttypmod)");
     atttype_col = cols++;
@@ -2183,7 +2187,8 @@ describeOneTableDetails(const char *schemaname,
         /* Footer information for a partition child table */
         PGresult   *result;

-        printfPQExpBuffer(&buf,
+        OutputComment(&buf, _("Get partition information for this table"));
+        appendPQExpBuffer(&buf,
                           "SELECT inhparent::pg_catalog.regclass,\n"
                           "  pg_catalog.pg_get_expr(c.relpartbound, c.oid),\n  ");

@@ -2238,7 +2243,8 @@ describeOneTableDetails(const char *schemaname,
         /* Footer information for a partitioned table (partitioning parent) */
         PGresult   *result;

-        printfPQExpBuffer(&buf,
+        OutputComment(&buf, _("Get the partition key for this table"));
+        appendPQExpBuffer(&buf,
                           "SELECT pg_catalog.pg_get_partkeydef('%s'::pg_catalog.oid);",
                           oid);
         result = PSQLexec(buf.data);
@@ -2260,7 +2266,8 @@ describeOneTableDetails(const char *schemaname,
         /* For a TOAST table, print name of owning table */
         PGresult   *result;

-        printfPQExpBuffer(&buf,
+        OutputComment(&buf, _("Find which table owns this TOAST table"));
+        appendPQExpBuffer(&buf,
                           "SELECT n.nspname, c.relname\n"
                           "FROM pg_catalog.pg_class c"
                           " JOIN pg_catalog.pg_namespace n"
@@ -2288,7 +2295,8 @@ describeOneTableDetails(const char *schemaname,
         /* Footer information about an index */
         PGresult   *result;

-        printfPQExpBuffer(&buf,
+        OutputComment(&buf, _("Get information about this index"));
+        appendPQExpBuffer(&buf,
                           "SELECT i.indisunique, i.indisprimary, i.indisclustered, "
                           "i.indisvalid,\n"
                           "  (NOT i.indimmediate) AND "
@@ -2409,7 +2417,8 @@ describeOneTableDetails(const char *schemaname,
         /* print indexes */
         if (tableinfo.hasindex)
         {
-            printfPQExpBuffer(&buf,
+            OutputComment(&buf, _("Get information about each index"));
+            appendPQExpBuffer(&buf,
                               "SELECT c2.relname, i.indisprimary, i.indisunique, "
                               "i.indisclustered, i.indisvalid, "
                               "pg_catalog.pg_get_indexdef(i.indexrelid, 0, true),\n  "
@@ -2551,6 +2560,8 @@ describeOneTableDetails(const char *schemaname,
         if (tableinfo.hastriggers ||
             tableinfo.relkind == RELKIND_PARTITIONED_TABLE)
         {
+            OutputComment(&buf, _("Get information about foreign key constraints"));
+
             if (pset.sversion >= 120000 &&
                 (tableinfo.ispartition || tableinfo.relkind == RELKIND_PARTITIONED_TABLE))
             {
@@ -2558,7 +2569,7 @@ describeOneTableDetails(const char *schemaname,
                  * Put the constraints defined in this table first, followed
                  * by the constraints defined in ancestor partitioned tables.
                  */
-                printfPQExpBuffer(&buf,
+                appendPQExpBuffer(&buf,
                                   "SELECT conrelid = '%s'::pg_catalog.regclass AS sametable,\n"
                                   "       conname,\n"
                                   "       pg_catalog.pg_get_constraintdef(oid, true) AS condef,\n"
@@ -2571,7 +2582,7 @@ describeOneTableDetails(const char *schemaname,
             }
             else
             {
-                printfPQExpBuffer(&buf,
+                appendPQExpBuffer(&buf,
                                   "SELECT true as sametable, conname,\n"
                                   "  pg_catalog.pg_get_constraintdef(r.oid, true) as condef,\n"
                                   "  conrelid::pg_catalog.regclass AS ontable\n"
@@ -2625,9 +2636,10 @@ describeOneTableDetails(const char *schemaname,
         if (tableinfo.hastriggers ||
             tableinfo.relkind == RELKIND_PARTITIONED_TABLE)
         {
+            OutputComment(&buf, _("Get information about incoming foreign key references"));
             if (pset.sversion >= 120000)
             {
-                printfPQExpBuffer(&buf,
+                appendPQExpBuffer(&buf,
                                   "SELECT conname, conrelid::pg_catalog.regclass AS ontable,\n"
                                   "       pg_catalog.pg_get_constraintdef(oid, true) AS condef\n"
                                   "  FROM pg_catalog.pg_constraint c\n"
@@ -2639,7 +2651,7 @@ describeOneTableDetails(const char *schemaname,
             }
             else
             {
-                printfPQExpBuffer(&buf,
+                appendPQExpBuffer(&buf,
                                   "SELECT conname, conrelid::pg_catalog.regclass AS ontable,\n"
                                   "       pg_catalog.pg_get_constraintdef(oid, true) AS condef\n"
                                   "  FROM pg_catalog.pg_constraint\n"
@@ -2677,7 +2689,8 @@ describeOneTableDetails(const char *schemaname,
         /* print any row-level policies */
         if (pset.sversion >= 90500)
         {
-            printfPQExpBuffer(&buf, "SELECT pol.polname,");
+            OutputComment(&buf, _("Get information about row-level policies"));
+            appendPQExpBuffer(&buf, "SELECT pol.polname,");
             if (pset.sversion >= 100000)
                 appendPQExpBufferStr(&buf,
                                      " pol.polpermissive,\n");
@@ -2757,9 +2770,10 @@ describeOneTableDetails(const char *schemaname,
         }

         /* print any extended statistics */
+        OutputComment(&buf, _("Get information about extended statistics"));
         if (pset.sversion >= 140000)
         {
-            printfPQExpBuffer(&buf,
+            appendPQExpBuffer(&buf,
                               "SELECT oid, "
                               "stxrelid::pg_catalog.regclass, "
                               "stxnamespace::pg_catalog.regnamespace::pg_catalog.text AS nsp, "
@@ -2857,7 +2871,7 @@ describeOneTableDetails(const char *schemaname,
         }
         else if (pset.sversion >= 100000)
         {
-            printfPQExpBuffer(&buf,
+            appendPQExpBuffer(&buf,
                               "SELECT oid, "
                               "stxrelid::pg_catalog.regclass, "
                               "stxnamespace::pg_catalog.regnamespace AS nsp, "
@@ -2936,7 +2950,8 @@ describeOneTableDetails(const char *schemaname,
         /* print rules */
         if (tableinfo.hasrules && tableinfo.relkind != RELKIND_MATVIEW)
         {
-            printfPQExpBuffer(&buf,
+            OutputComment(&buf, _("Get information about each rule for this table"));
+            appendPQExpBuffer(&buf,
                               "SELECT r.rulename, trim(trailing ';' from pg_catalog.pg_get_ruledef(r.oid, true)), "
                               "ev_enabled\n"
                               "FROM pg_catalog.pg_rewrite r\n"
@@ -3019,9 +3034,10 @@ describeOneTableDetails(const char *schemaname,
         /* print any publications */
         if (pset.sversion >= 100000)
         {
+            OutputComment(&buf, _("Get information about each publication using this table"));
             if (pset.sversion >= 150000)
             {
-                printfPQExpBuffer(&buf,
+                appendPQExpBuffer(&buf,
                                   "SELECT pubname\n"
                                   "     , NULL\n"
                                   "     , NULL\n"
@@ -3053,7 +3069,7 @@ describeOneTableDetails(const char *schemaname,
             }
             else
             {
-                printfPQExpBuffer(&buf,
+                appendPQExpBuffer(&buf,
                                   "SELECT pubname\n"
                                   "     , NULL\n"
                                   "     , NULL\n"
@@ -3105,7 +3121,8 @@ describeOneTableDetails(const char *schemaname,
          */
         if (verbose)
         {
-            printfPQExpBuffer(&buf,
+            OutputComment(&buf, _("Get information about NOT NULL constraints"));
+            appendPQExpBuffer(&buf,
                               "SELECT c.conname, a.attname, c.connoinherit,\n"
                               "  c.conislocal, c.coninhcount <> 0\n"
                               "FROM pg_catalog.pg_constraint c JOIN\n"
@@ -3175,7 +3192,8 @@ describeOneTableDetails(const char *schemaname,
         /* print rules */
         if (tableinfo.hasrules)
         {
-            printfPQExpBuffer(&buf,
+            OutputComment(&buf, _("Get information about each rule for this view"));
+            appendPQExpBuffer(&buf,
                               "SELECT r.rulename, trim(trailing ';' from pg_catalog.pg_get_ruledef(r.oid, true))\n"
                               "FROM pg_catalog.pg_rewrite r\n"
                               "WHERE r.ev_class = '%s' AND r.rulename != '_RETURN' ORDER BY 1;",
@@ -3212,7 +3230,8 @@ describeOneTableDetails(const char *schemaname,
         PGresult   *result;
         int            tuples;

-        printfPQExpBuffer(&buf,
+        OutputComment(&buf, _("Get information about each trigger on this table"));
+        appendPQExpBuffer(&buf,
                           "SELECT t.tgname, "
                           "pg_catalog.pg_get_triggerdef(t.oid, true), "
                           "t.tgenabled, t.tgisinternal,\n");
@@ -3430,6 +3449,7 @@ describeOneTableDetails(const char *schemaname,
         }

         /* print tables inherited from (exclude partitioned parents) */
+        OutputComment(&buf, _("Find tables inherited from"));
         printfPQExpBuffer(&buf,
                           "SELECT c.oid::pg_catalog.regclass\n"
                           "FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i\n"
@@ -3467,8 +3487,9 @@ describeOneTableDetails(const char *schemaname,
         }

         /* print child tables (with additional info if partitions) */
+        OutputComment(&buf, _("Get information about child tables"));
         if (pset.sversion >= 140000)
-            printfPQExpBuffer(&buf,
+            appendPQExpBuffer(&buf,
                               "SELECT c.oid::pg_catalog.regclass, c.relkind,"
                               " inhdetachpending,"
                               " pg_catalog.pg_get_expr(c.relpartbound, c.oid)\n"
@@ -3478,7 +3499,7 @@ describeOneTableDetails(const char *schemaname,
                               " c.oid::pg_catalog.regclass::pg_catalog.text;",
                               oid);
         else if (pset.sversion >= 100000)
-            printfPQExpBuffer(&buf,
+            appendPQExpBuffer(&buf,
                               "SELECT c.oid::pg_catalog.regclass, c.relkind,"
                               " false AS inhdetachpending,"
                               " pg_catalog.pg_get_expr(c.relpartbound, c.oid)\n"
@@ -3488,7 +3509,7 @@ describeOneTableDetails(const char *schemaname,
                               " c.oid::pg_catalog.regclass::pg_catalog.text;",
                               oid);
         else
-            printfPQExpBuffer(&buf,
+            appendPQExpBuffer(&buf,
                               "SELECT c.oid::pg_catalog.regclass, c.relkind,"
                               " false AS inhdetachpending, NULL\n"
                               "FROM pg_catalog.pg_class c, pg_catalog.pg_inherits i\n"

Re: Adding comments to help understand psql hidden queries

От
David Christensen
Дата:
On Sat, Jan 18, 2025 at 2:37 PM Tom Lane <tgl@sss.pgh.pa.us> wrote:
>
> David Christensen <david+pg@pgguru.net> writes:
> > Any further concerns/issues with this patch that I can address to help
> > move it forward?
>
> I got around to looking at this finally --- sorry that it's been on
> the back burner for so long.  I think this is basically a good idea
> but it still requires a lot of sanding-down of rough edges.

Hi Tom, thanks for the detailed feedback.  I'll take your v6 and see
about adding the additional changes; I agree with what you've pointed
out at the high level, and will respond with additional questions of
my own if things seem ambiguous in terms of approach.

Thanks,

David



Re: Adding comments to help understand psql hidden queries

От
Maiquel Grassi
Дата:
Hi!

I have read the discussion and would like
to share my humble opinion. I believe that
a visually appealing way to display the
output on the screen is to ensure symmetry
in the length of asterisks and description lines.
I imagine someone looking at the screen and
focusing on symmetrical details. Therefore,
the string length should serve as the basis for
the calculation. If the description length is an
even number, then the formula would be:
((description length − 7) / 2)​
Placing this result of asterisks on both sides of
the string ' QUERY ' ensures balance.
If the description length is an odd number,
then place:
((description length − 7) / 2)​

asterisks on the right side and:

(((description length − 7) / 2) ​+ 1)
asterisks on the left side.
This method does not always result in a perfectly
symmetric number of asterisks, but it provides a
more visually aligned appearance. At the end of
the SQL code, we should also include a line
terminator of the same length of the
description. The format looks like this:

/****************** QUERY *******************/
/* Get information about row-level policies */
SELECT pol.polname, pol.polpermissive,
  CASE WHEN pol.polroles = '{0}' THEN NULL ELSE
pg_catalog.array_to_string(array(select rolname from pg_catalog.pg_roles
where oid = any (pol.polroles) order by 1),',') END,
  pg_catalog.pg_get_expr(pol.polqual, pol.polrelid),
  pg_catalog.pg_get_expr(pol.polwithcheck, pol.polrelid),
  CASE pol.polcmd
    WHEN 'r' THEN 'SELECT'
    WHEN 'a' THEN 'INSERT'
    WHEN 'w' THEN 'UPDATE'
    WHEN 'd' THEN 'DELETE'
    END AS cmd
FROM pg_catalog.pg_policy pol
WHERE pol.polrelid = '134384' ORDER BY 1;
/********************************************/
Regards,
Maiquel.

Re: Adding comments to help understand psql hidden queries

От
Maiquel Grassi
Дата:
Hi!
I have read the discussion and would like
to share my humble opinion. I believe that
a visually appealing way to display the
output on the screen is to ensure symmetry
in the length of asterisks and description lines.
I imagine someone looking at the screen and
focusing on symmetrical details. Therefore,
the string length should serve as the basis for
the calculation. If the description length is an
even number, then the formula would be:

((description length − 7) / 2)​

Placing this result of asterisks on both sides of
the string ' QUERY ' ensures balance.
If the description length is an odd number,
then place:

((description length − 7) / 2)​
asterisks on the right side and:
(((description length − 7) / 2) ​+ 1)

asterisks on the left side.

This method does not always result in a perfectly
symmetric number of asterisks, but it provides a
more visually aligned appearance. At the end of
the SQL code, we should also include a line
terminator of the same length of the
description. The format looks like this:

/****************** QUERY *******************/
/* Get information about row-level policies */
SELECT pol.polname, pol.polpermissive,
CASE WHEN pol.polroles = '{0}' THEN NULL ELSE
pg_catalog.array_to_string(array(select rolname from pg_catalog.pg_roles
where oid = any (pol.polroles) order by 1),',') END,
pg_catalog.pg_get_expr(pol.polqual, pol.polrelid),
pg_catalog.pg_get_expr(pol.polwithcheck, pol.polrelid),
CASE pol.polcmd
WHEN 'r' THEN 'SELECT'
WHEN 'a' THEN 'INSERT'
WHEN 'w' THEN 'UPDATE'
WHEN 'd' THEN 'DELETE'
END AS cmd
FROM pg_catalog.pg_policy pol
WHERE pol.polrelid = '134384' ORDER BY 1;
/********************************************/

Regards,
Maiquel.