Thread: About #13489

About #13489

From
Bruno Bonfils
Date:
Hello there, 

A few years ago, someone reported a bug (#13489) about attndims, which
returned a false value on an array on a table created by CREATE TABLE
<cloned_table> (LIKE <original_table> INCLUDING ALL), 

example:

CREATE TABLE test (data integer, data_array integer[];
CREATE TABLE test_clone (LIKE test INCLUDING ALL);

SELECT attndims FROM pg_attribute WHERE attrelid = 'test'::regclass AND
attname = 'data_array';

returns 1

but

SELECT attndims FROM pg_attribute WHERE attrelid = 'test_clone'::regclass AND
attname = 'data_array';

returns 0

However, according to the documentation https://www.postgresql.org/docs/15/catalog-pg-attribute.html,
since data_array is an array I expected the returned value should be
greater than 0

Thanks

(tested on PostgreSQL 15.2 (Debian 15.2-1.pgdg110+1))




Re: About #13489, array dimensions and CREATE TABLE ... LIKE

From
Bruce Momjian
Date:
On Wed, Apr 19, 2023 at 11:35:29AM +0200, Bruno Bonfils wrote:
> Hello there, 
> 
> A few years ago, someone reported a bug (#13489) about attndims, which
> returned a false value on an array on a table created by CREATE TABLE
> <cloned_table> (LIKE <original_table> INCLUDING ALL), 
> 
> example:
> 
> CREATE TABLE test (data integer, data_array integer[];
> CREATE TABLE test_clone (LIKE test INCLUDING ALL);
> 
> SELECT attndims FROM pg_attribute WHERE attrelid = 'test'::regclass AND
> attname = 'data_array';
> 
> returns 1
> 
> but
> 
> SELECT attndims FROM pg_attribute WHERE attrelid = 'test_clone'::regclass AND
> attname = 'data_array';
> 
> returns 0
> 
> However, according to the documentation https://www.postgresql.org/docs/15/catalog-pg-attribute.html,
> since data_array is an array I expected the returned value should be
> greater than 0

I did a lot of research on this and found out a few things.  First,
CREATE TABLE is a complex command that gets its column names, types,
type modifiers, and array dimensions from a a variety of places:

*  Specified literally
*  Gotten from LIKE
*  Gotten from queries

What you found is that we don't pass the array dimensions properly with
LIKE.  As the code is written, it can only get dimensions that are
literally specified in the query.  What I was able to do in the attached
patch is to pass the array dimensions to the ColumnDef structure, which
is picked up by LIKE, and optionally use that if no dimensions are
specified in the query.

I am not sure how I feel about the patch.  We don't seem to record array
dimensionality well --- we don't record the dimension constants and we
don't enforce the dimensionality either, and psql doesn't even show the
dimensionality we do record in pg_attribute, which looks like another
bug. (I think the SQL function format_type() would need to pass in the
array dimensionality to fix this):

    CREATE TABLE test (data integer, data_array integer[5][5]);

    CREATE TABLE test_clone (LIKE test INCLUDING ALL);

    SELECT attndims FROM pg_attribute WHERE attrelid = 'test'::regclass AND
    attname = 'data_array';
     attndims
    ----------
            2
    
    SELECT attndims FROM pg_attribute WHERE attrelid = 'test_clone'::regclass AND
    attname = 'data_array';
     attndims
    ----------
-->            2
    
    INSERT INTO test VALUES (1, '{1}');
    INSERT INTO test VALUES (1, '{{1},{2}}');
    INSERT INTO test VALUES (1, '{{1},{2},{3}}');

    \d test
                       Table "public.test"
       Column   |   Type    | Collation | Nullable | Default
    ------------+-----------+-----------+----------+---------
     data       | integer   |           |          |
-->     data_array | integer[] |           |          |
    
    SELECT * FROM test;
     data |  data_array
    ------+---------------
-->        1 | {1}
        1 | {{1},{2}}
-->        1 | {{1},{2},{3}}

Is it worth applying this patch and improving psql?  Are there other
missing pieces that could be easily improved.

However, we already document that array dimensions are for documentation
purposes only, so the fact we don't update pg_attribute, and don't
display the dimensions properly, could be considered acceptable:

    https://www.postgresql.org/docs/devel/arrays.html#ARRAYS-DECLARATION
    
    The current implementation does not enforce the declared number of
    dimensions either. Arrays of a particular element type are all
    considered to be of the same type, regardless of size or number of
    dimensions. So, declaring the array size or number of dimensions in
    CREATE TABLE is simply documentation; it does not affect run-time
    behavior.

I knew we only considered the array dimension sizes to be documentation
_in_ the query, but I thought we at least properly displayed the number
of dimensions specified at creation when we described the table in psql,
but it seems we don't do that either.

A big question is why we even bother to record the dimensions in
pg_attribute if is not accurate for LIKE and not displayed to the user
in a meaningful way by psql.

I think another big question is whether the structure we are using to
supply the column information to BuildDescForRelation is optimal.  The
typmod that has to be found for CREATE TABLE uses:

        typenameTypeIdAndMod(NULL, entry->typeName, &atttypid, &atttypmod);

which calls typenameTypeIdAndMod() -> typenameType() -> LookupTypeName()
-> LookupTypeNameExtended() -> typenameTypeMod().  This seems very
complicated because the ColumnDef, at least in the LIKE case,  already
has the value.  Is there a need to revisit how we handle type such
cases?

-- 
  Bruce Momjian  <bruce@momjian.us>        https://momjian.us
  EDB                                      https://enterprisedb.com

  Only you can decide what is important to you.

Attachment