Thread: Filtering tables based on user privileges

Filtering tables based on user privileges

From
Brijesh Shrivastav
Date:
Hi! 

I have a need to filter out tables that have specfic privileges for a user.
For example, select
all tables where user 'joe' has 'select' and 'insert' privileges. Can I
somehow filter
that at SQL level or will I have to get all non-system rows from pg_class
and filter it
one by one? How can I use whre clause against aclitem[] array?

Regards,
Brijesh Shrivastav


Re: Filtering tables based on user privileges

From
Brijesh Shrivastav
Date:
After researching again I have come with following syntax to select all 
table with specific privilege (SELECT/INSERT/UPDATE..)to current user.

SELECT relname FROM pg_class WHERE pg_table_is_visible(oid)       AND relname !~ '^pg_'       AND has_table_privilege
(oid,'INSERT');

Is this the best way to do it? Is there any way to execute such
a statement  for any user? In this case such queries will most
likely be executed by a super user.

regards,
Brijesh

-----Original Message-----
From: Brijesh Shrivastav [mailto:Bshrivastav@esri.com]
Sent: Tuesday, June 15, 2004 9:58 AM
To: Pglibpq (E-mail)
Subject: [INTERFACES] Filtering tables based on user privileges


Hi! 

I have a need to filter out tables that have specfic privileges for a user.
For example, select
all tables where user 'joe' has 'select' and 'insert' privileges. Can I
somehow filter
that at SQL level or will I have to get all non-system rows from pg_class
and filter it
one by one? How can I use whre clause against aclitem[] array?

Regards,
Brijesh Shrivastav

---------------------------(end of broadcast)---------------------------
TIP 2: you can get off all lists at once with the unregister command   (send "unregister YourEmailAddressHere" to
majordomo@postgresql.org)


Re: Filtering tables based on user privileges

From
Tom Lane
Date:
Brijesh Shrivastav <Bshrivastav@esri.com> writes:
> After researching again I have come with following syntax to select all 
> table with specific privilege (SELECT/INSERT/UPDATE..)to current user.

> SELECT relname 
>  FROM pg_class 
>  WHERE pg_table_is_visible(oid) 
>        AND relname !~ '^pg_' 
>        AND has_table_privilege (oid,'INSERT');

> Is this the best way to do it?

You likely also want to filter on relkind, but something about like this
is probably a reasonable starting point.

> Is there any way to execute such
> a statement  for any user?

Sure, see the three-parameter variants of has_table_privilege.

> In this case such queries will most
> likely be executed by a super user.

A superuser will always be considered to have all privileges,
so the has_table_privilege filter will be a no-op for such a one.
        regards, tom lane