Thread: BUG #6421: Revoke column level privilage

BUG #6421: Revoke column level privilage

From
bdmytrak@eranet.pl
Date:
The following bug has been logged on the website:

Bug reference:      6421
Logged by:          Bartosz Dmytrak
Email address:      bdmytrak@eranet.pl
PostgreSQL version: 9.1.2
Operating system:   Mandriva 2011 64 bit
Description:=20=20=20=20=20=20=20=20

Cannot revoke column level privilages.

Scenario:
1. as =E2=80=9Epostgres=E2=80=9D user create a test table:
CREATE TABLE public."tblTest"
(
    "RowId" serial NOT NULL,
    "Column1" text,
    "Column2" integer,
    "Column3" integer,
    CONSTRAINT "tblTest_pkey" PRIMARY KEY ("RowId")
)
    WITH (
    OIDS=3DFALSE
);

ALTER TABLE public."tblTest"
    OWNER TO postgres;

GRANT ALL ON TABLE public."tblTest" TO postgres;

2. Grant privilages to different user, still using postgres acount:

GRANT UPDATE, INSERT, DELETE, REFERENCES, TRIGGER ON TABLE public."tblTest"
TO "otherUser";
GRANT SELECT ON TABLE public."tblTest" TO "otherUser" WITH GRANT OPTION;

3. Check privilages (assumption: there is the only one table named =E2=80=
=9CtblTest=E2=80=9D
in the database):

SELECT oid, relname, relacl FROM pg_class WHERE relname =3D 'tblTest';

  oid  | relname |                         relacl=20=20=20=20=20=20=20=20=
=20=20=20=20=20=20=20=20=20=20=20=20=20=20=20=20=20
-------+---------+--------------------------------------------------------
 36385 | tblTest | {postgres=3DarwdDxt/postgres,otherUser=3Dar*wdxt/postgre=
s}
(1 row)

and also for columns:

    SELECT attrelid, attname, attacl FROM pg_attribute a
INNER JOIN pg_class c ON (a.attrelid =3D c.oid)
WHERE c.relname =3D 'tblTest';

 attrelid | attname  | attacl=20
----------+----------+--------
    36385 | tableoid |=20
    36385 | cmax     |=20
    36385 | xmax     |=20
    36385 | cmin     |=20
    36385 | xmin     |=20
    36385 | ctid     |=20
    36385 | RowId    |=20
    36385 | Column1  |=20
    36385 | Column2  |=20
    36385 | Column3  |=20
(10 rows)

Everything looks good.

4. login as =E2=80=9CotherUser=E2=80=9D and add column level privilages
myDatabase=3D> GRANT ALL("Column1") ON public."tblTest" TO public;
GRANT

5. Check privilages again (as postgres)
myDatabase=3D# SELECT oid, relname, relacl FROM pg_class
WHERE relname =3D 'tblTest';
  oid  | relname |                         relacl=20=20=20=20=20=20=20=20=
=20=20=20=20=20=20=20=20=20=20=20=20=20=20=20=20=20
-------+---------+--------------------------------------------------------
 36385 | tblTest | {postgres=3DarwdDxt/postgres,otherUser=3Dar*wdxt/postgre=
s}
(1 row)

myDatabase=3D# SELECT attrelid, attname, attacl FROM pg_attribute a
INNER JOIN pg_class c ON (a.attrelid =3D c.oid)
WHERE c.relname =3D 'tblTest';
 attrelid | attname  |     attacl=20=20=20=20=20
----------+----------+----------------
    36385 | tableoid |=20
    36385 | cmax     |=20
    36385 | xmax     |=20
    36385 | cmin     |=20
    36385 | xmin     |=20
    36385 | ctid     |=20
    36385 | RowId    |=20
    36385 | Column1  | {=3Dr/otherUser}
    36385 | Column2  |=20
    36385 | Column3  |=20
(10 rows)

Still looks good.

6. REVOKE Column level privilages from public on table using =E2=80=9Cpostg=
res=E2=80=9D
account:

myDatabase=3D# REVOKE ALL("Column1") ON public."tblTest" FROM public;
REVOKE

7. Check column privilages (as postgres):
myDatabase=3D# SELECT attrelid, attname, attacl FROM pg_attribute a
INNER JOIN pg_class c ON (a.attrelid =3D c.oid)
WHERE c.relname =3D 'tblTest';
 attrelid | attname  |     attacl=20=20=20=20=20
----------+----------+----------------
    36385 | tableoid |=20
    36385 | cmax     |=20
    36385 | xmax     |=20
    36385 | cmin     |=20
    36385 | xmin     |=20
    36385 | ctid     |=20
    36385 | RowId    |=20
    36385 | Column1  | {=3Dr/otherUser}
    36385 | Column2  |=20
    36385 | Column3  |=20
(10 rows)

or using \dp command:
myDatabase=3D# \dp public."tblTest"
                                Access privileges
 Schema |  Name   | Type  |     Access privileges      | Column access
privileges=20
--------+---------+-------+----------------------------+-------------------=
-------
 public | tblTest | table | postgres=3DarwdDxt/postgres +| Column1:=20=20=
=20=20=20=20=20=20=20=20=20
    +
        |         |       | otherUser=3Dar*wdxt/postgres |   =3Dr/otherUser
(1 row)

Looks like privilages has not been revoked.

regards,
Bartek

Re: BUG #6421: Revoke column level privilage

From
Tom Lane
Date:
bdmytrak@eranet.pl writes:
> Cannot revoke column level privilages.

AFAICS this is not a bug, and it's certainly not specific to
column-level privileges.  You had "postgres" grant some privileges to
"otherUser" with grant option, and then had "otherUser" re-grant those
privileges to public.  "postgres" cannot revoke the re-grant directly.
You can have it revoke "otherUser"'s grant option.  (I think this will
require the CASCADE keyword if there are dependent privileges that
have to be revoked in consequence.)  Or you can log in as "otherUser"
and revoke the privilege grants made by that role.  This is per design
and AFAIK it's per the SQL standard's requirements.

There's a lot of fine print in the Notes sections of the GRANT and
REVOKE reference pages, which you might find helpful.

            regards, tom lane

Re: BUG #6421: Revoke column level privilage

From
"bdmytrak@eranet.pl"
Date:
Thanks for Your answer.
Works as designed - I have to get used.
Please notice the return message from REVOKE ALL command:
myDatabase=# REVOKE ALL("Column1") ON public."tblTest" FROM public;
REVOKE
myDatabase=# \dp public."tblTest"
Access privileges
Schema | Name | Type | Access privileges | Column access
privileges
--------+---------+-------+----------------------------+--------------------------
public | tblTest | table | postgres=arwdDxt/postgres +| Column1:
+
| | | otherUser=ar*wdxt/postgres | =r/otherUser
(1 row)
return message is REVOKE, but privileges are not really revoked ? there should be at least warning message generated.
REVOKE...CASCADEworks fine. 
AFAIK SQL Standard defines GRANTED BY. I haven't found it in PosgtreSQL documentation, so assume it is not implemented.
Ithink it is good idea to imlement it, this could help in that case. 
Regards,
Bartek
--- Oryginalna wiadomo?? ---
Od: Tom Lane [mailto: tgl@sss.pgh.pa.us]
Wys?ane: Tuesday, January 31, 2012 03:03 AM
Do: bdmytrak@eranet.pl
Kopia: pgsql-bugs@postgresql.org
Temat: Re: [BUGS] BUG #6421: Revoke column level privilage
bdmytrak@eranet.pl writes:
> Cannot revoke column level privilages.
AFAICS this is not a bug, and it's certainly not specific to
column-level privileges. You had "postgres" grant some privileges to
"otherUser" with grant option, and then had "otherUser" re-grant those
privileges to public. "postgres" cannot revoke the re-grant directly.
You can have it revoke "otherUser"'s grant option. (I think this will
require the CASCADE keyword if there are dependent privileges that
have to be revoked in consequence.) Or you can log in as "otherUser"
and revoke the privilege grants made by that role. This is per design
and AFAIK it's per the SQL standard's requirements.
There's a lot of fine print in the Notes sections of the GRANT and
REVOKE reference pages, which you might find helpful.
regards, tom lane

Pozdrawiam,
Bartek