Re: How to get the permissions assigned to user?

Поиск
Список
Период
Сортировка
От Alex Hunsaker
Тема Re: How to get the permissions assigned to user?
Дата
Msg-id 34d269d41002241546v130c1878k45752fe62a30fb21@mail.gmail.com
обсуждение исходный текст
Ответ на How to get the permissions assigned to user?  (Jignesh Shah <jignesh.shah1980@gmail.com>)
Список pgsql-general
On Tue, Feb 23, 2010 at 23:22, Jignesh Shah <jignesh.shah1980@gmail.com> wrote:
> Hi,
>
> Is there any way to get the set of permissions list assigned to user? I want
> to know whether user has create table permissions on particular schema or
> not?

See http://www.postgresql.org/docs/8.4/static/functions-info.html#FUNCTIONS-INFO-ACCESS-TABLE.

You can of course troll through the system tables... You might find
psql -E useful if as it will show you the queries psql runs for the
backslash commands'\d').

For example:

$ psql -E
=>\dpn
 Schema | Name | Type  |            Access privileges             |
Column access privileges
--------+------+-------+------------------------------------------+--------------------------
 public | a    | table |               | logged_session=arwdDxt/guy  |
                       : read_only=r/guy

gives me the sql:
 SELECT n.nspname as "Schema",
  c.relname as "Name",
  CASE c.relkind WHEN 'r' THEN 'table' WHEN 'v' THEN 'view' WHEN 'S'
THEN 'sequence' END as "Type",
  pg_catalog.array_to_string(c.relacl, E'\n') AS "Access privileges",
  pg_catalog.array_to_string(ARRAY(
    SELECT attname || E':\n  ' || pg_catalog.array_to_string(attacl, E'\n  ')
    FROM pg_catalog.pg_attribute a
    WHERE attrelid = c.oid AND NOT attisdropped AND attacl IS NOT NULL
  ), E'\n') AS "Column access privileges"
FROM pg_catalog.pg_class c
     LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
WHERE c.relkind IN ('r', 'v', 'S') ORDER BY 1, 2;

В списке pgsql-general по дате отправления:

Предыдущее
От: Ben Chobot
Дата:
Сообщение: Re: how to clear server log
Следующее
От: Greg Smith
Дата:
Сообщение: Re: Performance comparison