Обсуждение: BUG #16991: regclass is not case sensitive causing "relation does not exist" error

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

BUG #16991: regclass is not case sensitive causing "relation does not exist" error

От
PG Bug reporting form
Дата:
The following bug has been logged on the website:

Bug reference:      16991
Logged by:          Federico Caselli
Email address:      cfederico87@gmail.com
PostgreSQL version: 13.2
Operating system:   any
Description:

Hi,

Casting the name of an object to regclass using `name_col::regclass` is very
useful when querying the pg_catalog view to find the relevant information.
This casting does not work if the name of the object to cast is case
sensitive when it comes from a column.
Example using indexes to illustrate:

```sql
begin;
create table example(id serial, value text);
create index "CaseSensitiveIndex" on example (value, id);
create index not_case_sensitive on example (id, value);
select pg_relation_size(indexrelname::regclass) from pg_stat_all_indexes
where indexrelname = 'not_case_sensitive';
select pg_relation_size(indexrelname::regclass) from pg_stat_all_indexes
where indexrelname = 'CaseSensitiveIndex';
rollback; 
```
In this example the case the first select using the insensitive
"not_case_sensitive" is correctly casted to regclass, while the second use
using "CaseSensitiveIndex" fails with the error "SQL Error [42P01]: ERROR:
relation "casesensitiveindex" does not exist" suggesting that the case is
not respected by the regclass casting.

While the example makes little sense, since the column "indexrelid" could be
used directly, in many queries the oid of an object is not immediately
available. 
Using the "select oid from pg_class where ..." as suggested in the
documentation here https://www.postgresql.org/docs/current/datatype-oid.html
works, but as mentioned in the documentation is not 100% correct.

It think it would be nice if when casting from a column regclass would use
the case sensitive form, like it's possible when using the literal name
directly, like `select '"CaseSensitiveIndex"'::regclass`

Best,
Federico


PG Bug reporting form <noreply@postgresql.org> writes:
> Casting the name of an object to regclass using `name_col::regclass` is very
> useful when querying the pg_catalog view to find the relevant information.
> This casting does not work if the name of the object to cast is case
> sensitive when it comes from a column.

This is acting as designed and documented: regclass input conversion acts
the same as the regular SQL parser does, which includes case folding of
unquoted text.  If you have input that should be taken literally, you
can apply quote_ident() to it.

Note that your sample query has a second issue: it takes no account of
schemas, so it'll fail if a view row shows a table that is not in your
search_path.  Actually-robust solutions to this problem require something
like
  (quote_ident(schemaname) || '.' || quote_ident(indexrelname))::regclass
which illustrates why you don't really want regclass to take its input
literally: it needs to be able to interpret schema-qualified names.

            regards, tom lane



Thanks for the reply. Taking into consideration the schema as in your solution does indeed explain the current behavior and it makes sense.

I did not come across that documented behavior while searching for regclass in the pg docs. The most relevant page I was able to find was the Object Identifier Types page that does not mention it.

I’ll look into proposing a change in that docs page to mention it, if that’s the appropriate location for it.

 

Thanks

Federico Caselli

 

 

Federico <cfederico87@gmail.com> writes:
> I did not come across that documented behavior while searching for regclass
> in the pg docs. The most relevant page I was able to find was the Object
> Identifier Types page that does not mention it.
> I’ll look into proposing a change in that docs page to mention it, if
> that’s the appropriate location for it.

Hmm ... I *thought* it was documented, but perhaps not.  If not,
it's likely that the other reg* types are likewise underdocumented.

            regards, tom lane