update ddl user
This commit is contained in:
@@ -1,49 +0,0 @@
|
|||||||
--
|
|
||||||
-- Le script prend en parametre un compte utilisateur
|
|
||||||
-- ensuite il retourne les requetes pour creer les grants associe a ce compte
|
|
||||||
-- un fichier grant_USER.lst est généré dans le répertoire courant
|
|
||||||
--
|
|
||||||
SET PAGES 999 HEAD OFF FEEDBACK OFF
|
|
||||||
ACCEPT v_user CHAR PROMPT 'compte utilisateur pour lequel on va extraire les GRANTS : '
|
|
||||||
set verify off
|
|
||||||
|
|
||||||
SPOOL grant_&v_user
|
|
||||||
SELECT '-- Les roles pour le compte &v_user :' FROM DUAL;
|
|
||||||
SELECT DISTINCT 'CREATE ROLE '||GRANTED_ROLE||';' FROM DBA_ROLE_PRIVS WHERE GRANTEE=upper('&v_user');
|
|
||||||
|
|
||||||
SELECT '-- Les GRANTs depuis DBA_ROLE_PRIVS pour le compte &v_user :' FROM DUAL;
|
|
||||||
SELECT DISTINCT 'GRANT '||GRANTED_ROLE||' TO '||GRANTEE|| CASE WHEN ADMIN_OPTION='YES' THEN ' WITH ADMIN OPTION;' ELSE ';' END "Granted Roles" FROM DBA_ROLE_PRIVS WHERE GRANTEE=upper('&v_user') ORDER BY 1;
|
|
||||||
|
|
||||||
SELECT '-- Les GRANTs depuis DBA_SYS_PRIVS pour le compte &v_user :' FROM DUAL;
|
|
||||||
SELECT 'GRANT '||PRIVILEGE||' TO '||GRANTEE|| case when ADMIN_OPTION='YES' THEN ' WITH ADMIN OPTION;' ELSE ';' END "Granted System Privileges" FROM DBA_SYS_PRIVS WHERE GRANTEE=upper('&v_user');
|
|
||||||
|
|
||||||
SELECT '-- Les GRANTs depuis DBA_TAB_PRIVS pour le compte &v_user :' FROM DUAL;
|
|
||||||
SELECT DISTINCT
|
|
||||||
'GRANT '
|
|
||||||
|| privilege
|
|
||||||
|| ' ON '
|
|
||||||
||
|
|
||||||
CASE
|
|
||||||
WHEN type = 'DIRECTORY' THEN
|
|
||||||
'DIRECTORY '
|
|
||||||
END
|
|
||||||
|| owner
|
|
||||||
|| '.'
|
|
||||||
|| table_name
|
|
||||||
|| ' TO '
|
|
||||||
|| grantee
|
|
||||||
||
|
|
||||||
CASE
|
|
||||||
WHEN grantable = 'YES' THEN
|
|
||||||
' WITH GRANT OPTION;'
|
|
||||||
ELSE
|
|
||||||
';'
|
|
||||||
END
|
|
||||||
"Granted Object Privileges"
|
|
||||||
FROM
|
|
||||||
dba_tab_privs
|
|
||||||
WHERE
|
|
||||||
grantee = upper('&v_user');
|
|
||||||
SPOOL OFF
|
|
||||||
EXIT
|
|
||||||
|
|
||||||
@@ -11,56 +11,56 @@ set long 2000000000
|
|||||||
select (case
|
select (case
|
||||||
when ((select count(*)
|
when ((select count(*)
|
||||||
from dba_users
|
from dba_users
|
||||||
where username = '&&User_in_Uppercase' and profile <> 'DEFAULT') > 0)
|
where username = UPPER('&&User_in_Uppercase') and profile <> 'DEFAULT') > 0)
|
||||||
then chr(10)||' -- Note: Profile'||(select dbms_metadata.get_ddl('PROFILE', u.profile) AS ddl from dba_users u where u.username = '&User_in_Uppercase')
|
then chr(10)||' -- Note: Profile'||(select dbms_metadata.get_ddl('PROFILE', u.profile) AS ddl from dba_users u where u.username = UPPER('&User_in_Uppercase'))
|
||||||
else to_clob (chr(10)||' -- Note: Default profile, no need to create!')
|
else to_clob (chr(10)||' -- Note: Default profile, no need to create!')
|
||||||
end ) from dual
|
end ) from dual
|
||||||
UNION ALL
|
UNION ALL
|
||||||
select (case
|
select (case
|
||||||
when ((select count(*)
|
when ((select count(*)
|
||||||
from dba_users
|
from dba_users
|
||||||
where username = '&User_in_Uppercase') > 0)
|
where username = UPPER('&User_in_Uppercase')) > 0)
|
||||||
then ' -- Note: Create user statement'||dbms_metadata.get_ddl ('USER', '&User_in_Uppercase')
|
then ' -- Note: Create user statement'||dbms_metadata.get_ddl ('USER', UPPER('&User_in_Uppercase'))
|
||||||
else to_clob (chr(10)||' -- Note: User not found!')
|
else to_clob (chr(10)||' -- Note: User not found!')
|
||||||
end ) Extracted_DDL from dual
|
end ) Extracted_DDL from dual
|
||||||
UNION ALL
|
UNION ALL
|
||||||
select (case
|
select (case
|
||||||
when ((select count(*)
|
when ((select count(*)
|
||||||
from dba_ts_quotas
|
from dba_ts_quotas
|
||||||
where username = '&User_in_Uppercase') > 0)
|
where username = UPPER('&User_in_Uppercase')) > 0)
|
||||||
then ' -- Note: TBS quota'||dbms_metadata.get_granted_ddl( 'TABLESPACE_QUOTA', '&User_in_Uppercase')
|
then ' -- Note: TBS quota'||dbms_metadata.get_granted_ddl( 'TABLESPACE_QUOTA', UPPER('&User_in_Uppercase'))
|
||||||
else to_clob (chr(10)||' -- Note: No TS Quotas found!')
|
else to_clob (chr(10)||' -- Note: No TS Quotas found!')
|
||||||
end ) from dual
|
end ) from dual
|
||||||
UNION ALL
|
UNION ALL
|
||||||
select (case
|
select (case
|
||||||
when ((select count(*)
|
when ((select count(*)
|
||||||
from dba_role_privs
|
from dba_role_privs
|
||||||
where grantee = '&User_in_Uppercase') > 0)
|
where grantee = UPPER('&User_in_Uppercase')) > 0)
|
||||||
then ' -- Note: Roles'||dbms_metadata.get_granted_ddl ('ROLE_GRANT', '&User_in_Uppercase')
|
then ' -- Note: Roles'||dbms_metadata.get_granted_ddl ('ROLE_GRANT', UPPER('&User_in_Uppercase'))
|
||||||
else to_clob (chr(10)||' -- Note: No granted Roles found!')
|
else to_clob (chr(10)||' -- Note: No granted Roles found!')
|
||||||
end ) from dual
|
end ) from dual
|
||||||
UNION ALL
|
UNION ALL
|
||||||
select (case
|
select (case
|
||||||
when ((select count(*)
|
when ((select count(*)
|
||||||
from V$PWFILE_USERS
|
from V$PWFILE_USERS
|
||||||
where username = '&User_in_Uppercase' and SYSDBA='TRUE') > 0)
|
where username = UPPER('&User_in_Uppercase') and SYSDBA='TRUE') > 0)
|
||||||
then ' -- Note: sysdba'||chr(10)||to_clob (' GRANT SYSDBA TO '||'"'||'&User_in_Uppercase'||'"'||';')
|
then ' -- Note: sysdba'||chr(10)||to_clob (' GRANT SYSDBA TO '||'"'||UPPER('&User_in_Uppercase')||'"'||';')
|
||||||
else to_clob (chr(10)||' -- Note: No sysdba administrative Privilege found!')
|
else to_clob (chr(10)||' -- Note: No sysdba administrative Privilege found!')
|
||||||
end ) from dual
|
end ) from dual
|
||||||
UNION ALL
|
UNION ALL
|
||||||
select (case
|
select (case
|
||||||
when ((select count(*)
|
when ((select count(*)
|
||||||
from dba_sys_privs
|
from dba_sys_privs
|
||||||
where grantee = '&User_in_Uppercase') > 0)
|
where grantee = UPPER('&User_in_Uppercase')) > 0)
|
||||||
then ' -- Note: System Privileges'||dbms_metadata.get_granted_ddl ('SYSTEM_GRANT', '&User_in_Uppercase')
|
then ' -- Note: System Privileges'||dbms_metadata.get_granted_ddl ('SYSTEM_GRANT', UPPER('&User_in_Uppercase'))
|
||||||
else to_clob (chr(10)||' -- Note: No System Privileges found!')
|
else to_clob (chr(10)||' -- Note: No System Privileges found!')
|
||||||
end ) from dual
|
end ) from dual
|
||||||
UNION ALL
|
UNION ALL
|
||||||
select (case
|
select (case
|
||||||
when ((select count(*)
|
when ((select count(*)
|
||||||
from dba_tab_privs
|
from dba_tab_privs
|
||||||
where grantee = '&User_in_Uppercase') > 0)
|
where grantee = UPPER('&User_in_Uppercase')) > 0)
|
||||||
then ' -- Note: Object Privileges'||dbms_metadata.get_granted_ddl ('OBJECT_GRANT', '&User_in_Uppercase')
|
then ' -- Note: Object Privileges'||dbms_metadata.get_granted_ddl ('OBJECT_GRANT', UPPER('&User_in_Uppercase'))
|
||||||
else to_clob (chr(10)||' -- Note: No Object Privileges found!')
|
else to_clob (chr(10)||' -- Note: No Object Privileges found!')
|
||||||
end ) from dual
|
end ) from dual
|
||||||
/
|
/
|
||||||
Reference in New Issue
Block a user