Thread: support create index on virtual generated column.

support create index on virtual generated column.

From
jian he
Date:
hi.
attached patch for implementing $subject feature.

* internally such index will be transformed into expression index.
  for example, an index on (b int GENERATED ALWAYS AS (a * 2) VIRTUAL) will be
  converted into an expression index on ((a * 2)).
* in pageinspect module, add some test to check the index content of
virtual generated column.
* primary key, unique index over virtual generated column are not supported.
  not sure they make sense or not.
* expression index and predicate index over virtual generated columns are
  currently not supported.
* virtual generated column can not be in "include column"
* all types of indexes are supported, and a hash index, gist test has
been added.
* To support ALTER TABLE SET EXPRESSION, in pg_index, we need to track
the original
  virtual generated column attribute number, so ALTER TABLE SET EXPRESSION can
  identify which index needs to be rebuilt.
* ALTER COLUMN SET DATA TYPE will also cause table rewrite, so we really
  need to track the virtual generated column attribute number that
index was built on.

Attachment

Re: support create index on virtual generated column.

From
Kirill Reshke
Date:
On Wed, 26 Mar 2025 at 12:15, jian he <jian.universality@gmail.com> wrote:
>
> hi.
> attached patch for implementing $subject feature.
>
> * internally such index will be transformed into expression index.
>   for example, an index on (b int GENERATED ALWAYS AS (a * 2) VIRTUAL) will be
>   converted into an expression index on ((a * 2)).
> * in pageinspect module, add some test to check the index content of
> virtual generated column.
> * primary key, unique index over virtual generated column are not supported.
>   not sure they make sense or not.
> * expression index and predicate index over virtual generated columns are
>   currently not supported.
> * virtual generated column can not be in "include column"
> * all types of indexes are supported, and a hash index, gist test has
> been added.
> * To support ALTER TABLE SET EXPRESSION, in pg_index, we need to track
> the original
>   virtual generated column attribute number, so ALTER TABLE SET EXPRESSION can
>   identify which index needs to be rebuilt.
> * ALTER COLUMN SET DATA TYPE will also cause table rewrite, so we really
>   need to track the virtual generated column attribute number that
> index was built on.


Hi!
patch applies with warns
```
Applying: support create index on virtual generated column.
.git/rebase-apply/patch:250: trailing whitespace.
     * updated correctly, and they don't seem useful anyway.
.git/rebase-apply/patch:271: trailing whitespace.
     * Also check for system used in expressions or predicates.
warning: 2 lines add whitespace errors.
```



consider this case:


```

reshke=# CREATE TABLE xx (a int, b int GENERATED ALWAYS AS (a * 2) VIRTUAL) ;
CREATE TABLE
reshke=# create index on xx (b);
CREATE INDEX
reshke=#
reshke=# \d+ xx
                                                     Table "public.xx"
 Column |  Type   | Collation | Nullable |           Default
| Storage | Compression | Stats target | Description

--------+---------+-----------+----------+-----------------------------+---------+-------------+--------------+-------------
 a      | integer |           |          |
| plain   |             |              |
 b      | integer |           |          | generated always as (a * 2)
| plain   |             |              |
Indexes:
    "xx_b_idx" btree (b)
Access method: heap

reshke=# alter table xx drop column b;
ALTER TABLE
reshke=# \d+ xx
                                           Table "public.xx"
 Column |  Type   | Collation | Nullable | Default | Storage |
Compression | Stats target | Description
--------+---------+-----------+----------+---------+---------+-------------+--------------+-------------
 a      | integer |           |          |         | plain   |
    |              |
Indexes:
    "xx_b_idx" btree ("........pg.dropped.2........" int4_ops)
Access method: heap

reshke=#
```

with regular columns we have different behaviour - with drop column we
drop the index


-- 
Best regards,
Kirill Reshke



Re: support create index on virtual generated column.

From
jian he
Date:
On Wed, Mar 26, 2025 at 5:36 PM Kirill Reshke <reshkekirill@gmail.com> wrote:
> reshke=# CREATE TABLE xx (a int, b int GENERATED ALWAYS AS (a * 2) VIRTUAL) ;
> CREATE TABLE
> reshke=# create index on xx (b);
> CREATE INDEX
> reshke=#
> reshke=# \d+ xx
>                                                      Table "public.xx"
>  Column |  Type   | Collation | Nullable |           Default
> | Storage | Compression | Stats target | Description
>
--------+---------+-----------+----------+-----------------------------+---------+-------------+--------------+-------------
>  a      | integer |           |          |
> | plain   |             |              |
>  b      | integer |           |          | generated always as (a * 2)
> | plain   |             |              |
> Indexes:
>     "xx_b_idx" btree (b)
> Access method: heap
>
> reshke=# alter table xx drop column b;
> ALTER TABLE
> reshke=# \d+ xx
>                                            Table "public.xx"
>  Column |  Type   | Collation | Nullable | Default | Storage |
> Compression | Stats target | Description
> --------+---------+-----------+----------+---------+---------+-------------+--------------+-------------
>  a      | integer |           |          |         | plain   |
>     |              |
> Indexes:
>     "xx_b_idx" btree ("........pg.dropped.2........" int4_ops)
> Access method: heap
>
> reshke=#
> ```
>
> with regular columns we have different behaviour - with drop column we
> drop the index
>

I was wrong about dependency.
when creating an index on a virtual generated column, it will have
dependency with
virtual generated column attribute and the generation expression
associated attribute.

new patch attached. Now,
ALTER TABLE DROP COLUMN works fine.
ALTER INDEX ATTACH PARTITION works fine.
creating such an index on a partitioned table works just fine.
for table inheritance: create index on parent table will not cascade
to child table,
so we don't need to worry about this.

Attachment

Re: support create index on virtual generated column.

From
Kirill Reshke
Date:
On Mon, 14 Apr 2025 at 16:10, jian he <jian.universality@gmail.com> wrote:
>
> new patch attached. Now,
> ALTER TABLE DROP COLUMN works fine.
> ALTER INDEX ATTACH PARTITION works fine.
> creating such an index on a partitioned table works just fine.
> for table inheritance: create index on parent table will not cascade
> to child table,
> so we don't need to worry about this.

Hi! I reviewed v2, and it seems to be working now.

But there are tests that are comment-out, what is their purpose? I
note that commit 83ea6c5 also included some commented tests, so
perhaps there's a reason I'm not aware of.

```
ALTER TABLE gtest22c DROP COLUMN e;
\d gtest22c

-- EXPLAIN (COSTS OFF) SELECT * FROM gtest22c WHERE b * 3 = 6;
-- SELECT * FROM gtest22c WHERE b * 3 = 6;
-- EXPLAIN (COSTS OFF) SELECT * FROM gtest22c WHERE a = 1 AND b > 0;
-- SELECT * FROM gtest22c WHERE a = 1 AND b > 0;
```


-- 
Best regards,
Kirill Reshke



Re: support create index on virtual generated column.

From
jian he
Date:
On Mon, Apr 14, 2025 at 8:05 PM Kirill Reshke <reshkekirill@gmail.com> wrote:
>
> On Mon, 14 Apr 2025 at 16:10, jian he <jian.universality@gmail.com> wrote:
> >
> > new patch attached. Now,
> > ALTER TABLE DROP COLUMN works fine.
> > ALTER INDEX ATTACH PARTITION works fine.
> > creating such an index on a partitioned table works just fine.
> > for table inheritance: create index on parent table will not cascade
> > to child table,
> > so we don't need to worry about this.
>
> Hi! I reviewed v2, and it seems to be working now.
>
> But there are tests that are comment-out, what is their purpose? I
> note that commit 83ea6c5 also included some commented tests, so
> perhaps there's a reason I'm not aware of.
>

> ```
> ALTER TABLE gtest22c DROP COLUMN e;
> \d gtest22c
>
> -- EXPLAIN (COSTS OFF) SELECT * FROM gtest22c WHERE b * 3 = 6;
> -- SELECT * FROM gtest22c WHERE b * 3 = 6;
> -- EXPLAIN (COSTS OFF) SELECT * FROM gtest22c WHERE a = 1 AND b > 0;
> -- SELECT * FROM gtest22c WHERE a = 1 AND b > 0;
> ```

comment out tests are for to be implemented feature.
There are some test changes that are indeed not necessary, I restored it back,
please check attached.

Attachment