get ddl tablespaces
This commit is contained in:
7
compare_grant.sh
Normal file
7
compare_grant.sh
Normal file
@@ -0,0 +1,7 @@
|
|||||||
|
# genérer 2 fichiers avec les ordres grant
|
||||||
|
# ensuite comparer les deux pour garder uniquement les ordres présents dans la source et pas dans la destination
|
||||||
|
|
||||||
|
# dans cet exemple :
|
||||||
|
# La commande pour extraire les GRANT qui sont dans la version 12 mais pas dans la 19 :
|
||||||
|
diff -w <(cat /tmp/grant_12 | grep -v '^$' | sort -u) <(cat /tmp/grant_19 | grep -v '^$' | sort -u) | grep '^<' | sed 's/< //g' | sort
|
||||||
|
|
||||||
25
get_grant_and_priv.sql
Normal file
25
get_grant_and_priv.sql
Normal file
@@ -0,0 +1,25 @@
|
|||||||
|
--
|
||||||
|
-- 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 '||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
|
||||||
|
|
||||||
51
get_tablespaces_ddl.sql
Normal file
51
get_tablespaces_ddl.sql
Normal file
@@ -0,0 +1,51 @@
|
|||||||
|
-- le script génère les ordres de création sql des tablespaces et datafiles
|
||||||
|
-- si un tablespace contient plusieurs fichier, ceci est pris en compte
|
||||||
|
-- les tablespaces SYSTEM, SYSAUX et UNDO ne sont pas affichés
|
||||||
|
--
|
||||||
|
-- version avec la taille exacte des datafile occupée sur disque
|
||||||
|
--
|
||||||
|
|
||||||
|
set head off pages 0 feedback off lines 200
|
||||||
|
|
||||||
|
select '-- -------------------------------------------' from dual;
|
||||||
|
select '-- HOSTNAME:'||host_name||';DB_NAME:'||name||';VERSION='||version from v$database,v$instance;
|
||||||
|
select '-- -------------------------------------------' from dual;
|
||||||
|
|
||||||
|
SELECT 'CREATE '
|
||||||
|
|| DECODE (ts.bigfile, 'YES', 'BIGFILE ') --assuming smallfile is the default table space
|
||||||
|
|| 'TABLESPACE "' || ts.tablespace_name || '" DATAFILE ' || CHR(13) || CHR(10)
|
||||||
|
|| LISTAGG(decode(p.value, NULL, '''' || df.file_name || '''') || ' SIZE '
|
||||||
|
|| ' SIZE '
|
||||||
|
-- || df.bytes -- on ne prends pas la taille du datafile, mais la taille ocupée used_bytes
|
||||||
|
|| nvl(e.used_bytes,10*1024*1024) -- si taille nulle, on retourne 10M
|
||||||
|
|| DECODE (
|
||||||
|
df.autoextensible,
|
||||||
|
'YES', ' AUTOEXTEND ON NEXT ' || df.increment_by * ts.block_size || ' MAXSIZE '
|
||||||
|
|| CASE
|
||||||
|
WHEN maxbytes < POWER (1024, 3) * 2
|
||||||
|
THEN
|
||||||
|
TO_CHAR (maxbytes)
|
||||||
|
ELSE
|
||||||
|
TO_CHAR (FLOOR (maxbytes / POWER (1024, 2))) || 'M'
|
||||||
|
END),
|
||||||
|
',' || CHR (13) || CHR (10))
|
||||||
|
WITHIN GROUP (ORDER BY df.file_id, df.file_name)
|
||||||
|
|| ';'
|
||||||
|
ddl
|
||||||
|
FROM dba_tablespaces ts,
|
||||||
|
dba_data_files df,
|
||||||
|
(SELECT file_id, sum(decode(bytes,NULL,0,bytes)) used_bytes FROM dba_extents GROUP by file_id) e,
|
||||||
|
(select VALUE from v$parameter where name='db_create_file_dest') p
|
||||||
|
WHERE ts.tablespace_name not in ('SYSTEM','SYSAUX')
|
||||||
|
and ts.tablespace_name not like '%UNDO%'
|
||||||
|
and e.file_id (+) = df.file_id
|
||||||
|
and ts.tablespace_name = df.tablespace_name
|
||||||
|
GROUP BY ts.tablespace_name,
|
||||||
|
ts.bigfile,
|
||||||
|
ts.logging,
|
||||||
|
ts.status,
|
||||||
|
ts.block_size
|
||||||
|
ORDER BY ts.tablespace_name;
|
||||||
|
|
||||||
|
exit
|
||||||
|
|
||||||
23
get_tablespaces_ddl_ver_courte.sql
Normal file
23
get_tablespaces_ddl_ver_courte.sql
Normal file
@@ -0,0 +1,23 @@
|
|||||||
|
SET PAGES 999 LINES 150
|
||||||
|
SELECT
|
||||||
|
'CREATE TABLESPACE "' || ts.tablespace_name || '" ' || CHR(13) || CHR(10)
|
||||||
|
|| LISTAGG(' DATAFILE '
|
||||||
|
|| decode(p.value, NULL, '''' || df.file_name || '''') -- si OMF pas de nom de fichier
|
||||||
|
|| ' SIZE '
|
||||||
|
|| nvl(e.used_bytes, 10 * 1024 * 1024) -- si taille nulle, on retourne 10M
|
||||||
|
|| decode(df.autoextensible, 'YES', ' AUTOEXTEND ON'),
|
||||||
|
',' || CHR(13) || CHR(10))
|
||||||
|
WITHIN GROUP(ORDER BY df.file_id, df.file_name)
|
||||||
|
|| ';' ddl
|
||||||
|
FROM dba_tablespaces ts, dba_data_files df,
|
||||||
|
(SELECT file_id, SUM(decode(bytes, NULL, 0, bytes)) used_bytes FROM dba_extents GROUP BY file_id ) e,
|
||||||
|
(select VALUE from v$parameter where name='db_create_file_dest') p
|
||||||
|
WHERE ts.tablespace_name NOT IN ( 'SYSTEM', 'SYSAUX' )
|
||||||
|
AND ts.tablespace_name NOT LIKE '%UNDO%'
|
||||||
|
AND e.file_id (+) = df.file_id
|
||||||
|
AND ts.tablespace_name = df.tablespace_name
|
||||||
|
GROUP BY ts.tablespace_name, ts.bigfile, ts.logging, ts.status, ts.block_size
|
||||||
|
ORDER BY ts.tablespace_name;
|
||||||
|
|
||||||
|
EXIT
|
||||||
|
|
||||||
Reference in New Issue
Block a user