Обсуждение: Assistance needed for the query execution in non-public schema

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

Assistance needed for the query execution in non-public schema

От
Sasmit Utkarsh
Дата:
Hi Postgresql Team,

I'm trying to execute the below query using the below

psql 'host=cucmpsgsu0.postgres.database.azure.com port=5432 dbname=msshctd user=shc_uadmin password=xxxxx sslmode=require options=--search_path=shc_tty'

msshctd=> show search_path;
 search_path
-------------
 shc_tty
(1 row)
msshctd=> SELECT setval(pg_get_serial_sequence('mqa_flfo_cstr', 'id'), coalesce(MAX(id), 1)) from mqa_flfo_cstr;
ERROR:  permission denied for sequence mqa_flfo_cstr_id_seq
msshctd=> SELECT setval(pg_get_serial_sequence('mqa_ffp_nval', 'id'), coalesce(MAX(id), 1)) from mqa_ffp_nval;
ERROR:  permission denied for sequence mqa_ffp_nval_id_seq

msshctd=> \z mqa_flfo_cstr_id_seq
                                           Access privileges
 Schema  |         Name         |   Type   |      Access privileges      | Column privileges | Policies
---------+----------------------+----------+-----------------------------+-------------------+----------
 shc_tty | mqa_flfo_cstr_id_seq | sequence | pgddb_admin=rwU/pgddb_admin+|                   |
         |                      |          | shc_uadmin=rU/pgddb_admin   |                   |
(1 row)

msshctd=> \z mqa_ffp_nval_id_seq
                                           Access privileges
 Schema  |        Name         |   Type   |      Access privileges      | Column privileges | Policies
---------+---------------------+----------+-----------------------------+-------------------+----------
 shc_tty | mqa_ffp_nval_id_seq | sequence | pgddb_admin=rwU/pgddb_admin+|                   |
         |                     |          | shc_uadmin=rU/pgddb_admin   |                   |
(1 row)
 
Above query executes fine when I try to execute as user "pgddb_admin"(Super User). but when I switch to shc_uadmin, I see a permission error. Above I've included the permissions listed for both the users. I also tried to set the alter permissions for one of  the sequence for the shc_uadmin user with the below 

GRANT USAGE, ALTER ON SEQUENCE mqa_flfo_cstr_id_seq TO shc_uadmin;
ERROR: unrecognized privilege type "alter" SQL state: 42601


Is there any other way i can execute the queries, with user "shc_uadmin" for the setval() to work properly without giving complete privileges same as the owner "pgddb_admin" ? Any workaround/ alternate option which would work here? Please assist



Regards,
Sasmit Utkarsh
+91-7674022625

Re: Assistance needed for the query execution in non-public schema

От
David Rowley
Дата:
On Tue, 16 Apr 2024 at 23:00, Sasmit Utkarsh <utkarshsasmit@gmail.com> wrote:
> msshctd=> SELECT setval(pg_get_serial_sequence('mqa_flfo_cstr', 'id'), coalesce(MAX(id), 1)) from mqa_flfo_cstr;
> ERROR:  permission denied for sequence mqa_flfo_cstr_id_seq
> msshctd=> SELECT setval(pg_get_serial_sequence('mqa_ffp_nval', 'id'), coalesce(MAX(id), 1)) from mqa_ffp_nval;
> ERROR:  permission denied for sequence mqa_ffp_nval_id_seq

> GRANT USAGE, ALTER ON SEQUENCE mqa_flfo_cstr_id_seq TO shc_uadmin;
> ERROR: unrecognized privilege type "alter" SQL state: 42601

According to our documentation for setval():

"This function requires UPDATE privilege on the sequence."

https://www.postgresql.org/docs/current/functions-sequence.html

David



Re: Assistance needed for the query execution in non-public schema

От
Laurenz Albe
Дата:
On Tue, 2024-04-16 at 16:30 +0530, Sasmit Utkarsh wrote:
> msshctd=> SELECT setval(pg_get_serial_sequence('mqa_flfo_cstr', 'id'), coalesce(MAX(id), 1)) from mqa_flfo_cstr;
> ERROR:  permission denied for sequence mqa_flfo_cstr_id_seq
> msshctd=> SELECT setval(pg_get_serial_sequence('mqa_ffp_nval', 'id'), coalesce(MAX(id), 1)) from mqa_ffp_nval;
> ERROR:  permission denied for sequence mqa_ffp_nval_id_seq
>
> msshctd=> \z mqa_flfo_cstr_id_seq
>                                            Access privileges
>  Schema  |         Name         |   Type   |      Access privileges      | Column privileges | Policies
> ---------+----------------------+----------+-----------------------------+-------------------+----------
>  shc_tty | mqa_flfo_cstr_id_seq | sequence | pgddb_admin=rwU/pgddb_admin+|                   |
>          |                      |          | shc_uadmin=rU/pgddb_admin   |                   |
> (1 row)
>
> msshctd=> \z mqa_ffp_nval_id_seq
>                                            Access privileges
>  Schema  |        Name         |   Type   |      Access privileges      | Column privileges | Policies
> ---------+---------------------+----------+-----------------------------+-------------------+----------
>  shc_tty | mqa_ffp_nval_id_seq | sequence | pgddb_admin=rwU/pgddb_admin+|                   |
>          |                     |          | shc_uadmin=rU/pgddb_admin   |                   |
> (1 row)
>  
> Above query executes fine when I try to execute as user "pgddb_admin"(Super User).
> but when I switch to shc_uadmin, I see a permission error.

That's because the user is lacking the UPDATE privilege ("U" is USAGE).

> GRANT USAGE, ALTER ON SEQUENCE mqa_flfo_cstr_id_seq TO shc_uadmin;
> ERROR: unrecognized privilege type "alter" SQL state: 42601

There is no ALTER privilege.  Try

  GRANT UPDATE ON SEQUENCE mqa_flfo_cstr_id_seq, mqa_ffp_nval_id_seq TO shc_uadmin;

Yours,
Laurenz Albe



Re: Assistance needed for the query execution in non-public schema

От
Sasmit Utkarsh
Дата:
Thanks Laurenz and David

Regards,
Sasmit Utkarsh
+91-7674022625

On Tue, 16 Apr, 2024, 16:58 Laurenz Albe, <laurenz.albe@cybertec.at> wrote:
On Tue, 2024-04-16 at 16:30 +0530, Sasmit Utkarsh wrote:
> msshctd=> SELECT setval(pg_get_serial_sequence('mqa_flfo_cstr', 'id'), coalesce(MAX(id), 1)) from mqa_flfo_cstr;
> ERROR:  permission denied for sequence mqa_flfo_cstr_id_seq
> msshctd=> SELECT setval(pg_get_serial_sequence('mqa_ffp_nval', 'id'), coalesce(MAX(id), 1)) from mqa_ffp_nval;
> ERROR:  permission denied for sequence mqa_ffp_nval_id_seq
>
> msshctd=> \z mqa_flfo_cstr_id_seq
>                                            Access privileges
>  Schema  |         Name         |   Type   |      Access privileges      | Column privileges | Policies
> ---------+----------------------+----------+-----------------------------+-------------------+----------
>  shc_tty | mqa_flfo_cstr_id_seq | sequence | pgddb_admin=rwU/pgddb_admin+|                   |
>          |                      |          | shc_uadmin=rU/pgddb_admin   |                   |
> (1 row)
>
> msshctd=> \z mqa_ffp_nval_id_seq
>                                            Access privileges
>  Schema  |        Name         |   Type   |      Access privileges      | Column privileges | Policies
> ---------+---------------------+----------+-----------------------------+-------------------+----------
>  shc_tty | mqa_ffp_nval_id_seq | sequence | pgddb_admin=rwU/pgddb_admin+|                   |
>          |                     |          | shc_uadmin=rU/pgddb_admin   |                   |
> (1 row)
>  
> Above query executes fine when I try to execute as user "pgddb_admin"(Super User).
> but when I switch to shc_uadmin, I see a permission error.

That's because the user is lacking the UPDATE privilege ("U" is USAGE).

> GRANT USAGE, ALTER ON SEQUENCE mqa_flfo_cstr_id_seq TO shc_uadmin;
> ERROR: unrecognized privilege type "alter" SQL state: 42601

There is no ALTER privilege.  Try

  GRANT UPDATE ON SEQUENCE mqa_flfo_cstr_id_seq, mqa_ffp_nval_id_seq TO shc_uadmin;

Yours,
Laurenz Albe