Oracle FAQ Your Portal to the Oracle Knowledge Grid
HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US
 

Home -> Community -> Mailing Lists -> Oracle-L -> Re: Display all privilleges belong to user

Re: Display all privilleges belong to user

From: Tim Gorman <Tim_at_SageLogix.com>
Date: Thu, 01 Aug 2002 14:23:27 -0800
Message-ID: <F001.004A95FB.20020801142327@fatcity.com>


This is a script I've posted online to www.evdbt.com/tools.htm...

Never mind the "dbo" stuff in the WHERE clause -- it should work just fine regardless. You can get rid of that DECODE if you like...

By the way, you can also pass the name of a ROLE (instead of the name of a USER) to find out permissions associated with that role...

<snip>
set echo off feedback off timing off pagesize 66 verify off trimspool on linesize 100
set recsep off

col sort0 noprint
col priv format a65 word_wrap heading "Granted" col admin_option heading "Adm|Opt"
col dflt heading "Dflt"

undef user

spool privs_&&user

select 1 sort0,

    granted_role priv,
    admin_option,
    default_role dflt
from dba_role_privs
where grantee = decode('&&user','dbo','dbo',upper('&&user')) union
select 2 sort0,

    privilege priv,
    admin_option,
'' dflt

from dba_sys_privs
where grantee = decode('&&user','dbo','dbo',upper('&&user')) union
select 3 sort0,

    privilege || ' on ' || owner || '.' || table_name || ' (by ' || grantor || ')' priv,

    grantable admin_option,
'' dflt

from dba_tab_privs
where grantee = decode('&&user','dbo','dbo',upper('&&user')) union
select 4 sort0,

    'QUOTA: ' ||
    decode(q.max_bytes,

              -1, 'UNLIMITED',
              ltrim(to_char(q.max_bytes/1048576,'999,999,990.00')) || 'M')
||
            ' on ' || q.tablespace_name priv,

'' admin_option,

    decode(u.default_tablespace, q.tablespace_name, 'YES', 'NO') dflt from dba_ts_quotas q, dba_users u
where u.username = decode('&&user','dbo','dbo',upper('&&user')) and q.username = u.username
order by 1, 2, 3, 4;
spool off
</snip>
> How do I display all privilleges belong to an user?
>
> Thanks,
> David
> --
> Please see the official ORACLE-L FAQ: http://www.orafaq.com
> --
> Author: Nguyen, David M
>   INET: david.m.nguyen_at_xo.com
>
> Fat City Network Services    -- (858) 538-5051  FAX: (858) 538-5051
> San Diego, California        -- Public Internet access / Mailing Lists
> --------------------------------------------------------------------
> To REMOVE yourself from this mailing list, send an E-Mail message
> to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in
> the message BODY, include a line containing: UNSUB ORACLE-L
> (or the name of mailing list you want to be removed from).  You may
> also send the HELP command for other information (like subscribing).

-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.com
-- 
Author: Tim Gorman
  INET: Tim_at_SageLogix.com

Fat City Network Services    -- (858) 538-5051  FAX: (858) 538-5051
San Diego, California        -- Public Internet access / Mailing Lists
--------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from).  You may
also send the HELP command for other information (like subscribing).
Received on Thu Aug 01 2002 - 17:23:27 CDT

Original text of this message

HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US