On Sun, Jan 19, 2025 at 06:47:14PM -0500, Tom Lane wrote:
> Bruce Momjian <br...@momjian.us> writes:
> > Using the queries in that URL, I see:
> 
> >     CREATE TABLE test (data integer, data_array integer[5][5]);
> >     CREATE TABLE test2 (LIKE test);
> >     CREATE TABLE test3 AS SELECT * FROM test;
> >     SELECT relname, attndims
> >     FROM pg_class JOIN pg_attribute ON (pg_attribute.attrelid = 
> > pg_class.oid)
> >     WHERE attname = 'data_array';
> >      relname | attndims
> >     ---------+----------
> >      test    |        2
> > -->  test2   |        0
> > -->  test3   |        0
> 
> Yeah, that's not great.  We don't have the ability to extract a
> number-of-dimensions from a result column of a SELECT, but we could

I did write a patch in Novemer 2023 to pass the dimension to the layers
that needed it, but it was considered too much code compared to its
value:

        https://www.postgresql.org/message-id/zvwi_ozt8z9mc...@momjian.us

> at least take care to make attndims be 1 not 0 for an array type.
> And CREATE TABLE LIKE can easily do better.  See attached draft.
> (We could simplify it a little bit if we decide to store only 1 or 0
> in all cases.)
> 
> > Interestingly, if I dump and restore with:
> >     $ createdb test2; pg_dump test | sql test2
> > and run the query again I get:
> >      relname | attndims
> >     ---------+----------
> >      test    |        1
> >      test2   |        1
> >      test3   |        1
> 
> I looked at getting a better result here and decided that it didn't
> look very promising.  pg_dump uses format_type() to build the type
> name to put in CREATE TABLE, and that doesn't have access to attndims.

I ran your patch with my tests and it was now consistent in a zero/non-zero
test:

        CREATE TABLE test (data integer, data_array integer[5][5]);
        
        CREATE TABLE test2 (LIKE test);
        
        CREATE TABLE test3 AS SELECT * FROM test;
        
        SELECT relname, attndims
        FROM pg_class JOIN pg_attribute ON (pg_attribute.attrelid = 
pg_class.oid)
        WHERE attname = 'data_array';
         relname | attndims
        ---------+----------
         test    |        2
         test2   |        2
         test3   |        1

        $ createdb test2; pg_dump test | sql test2

        test2=>
        SELECT relname, attndims
        FROM pg_class JOIN pg_attribute ON (pg_attribute.attrelid = 
pg_class.oid)
        WHERE attname = 'data_array';
         relname | attndims
        ---------+----------
         test    |        1
         test2   |        1
         test3   |        1

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

  Do not let urgent matters crowd out time for investment in the future.




Reply via email to