SELECT * FROM ROLE_SYS_PRIVS
SELECT * FROM DBA_ROLE_PRIVS;
SELECT * FROM DBA_ROLE_PRIVS WHERE GRANTEE IN ('','','','','','');
SELECT * FROM DBA_ROLE_PRIVS WHERE GRANTED_ROLE IN ('','','','','','');
-- REVOKE ALL
select 'REVOKE ' || GRANTED_ROLE || ' FROM ' || GRANTEE || ';' from dba_role_privs where grantee='SCHEMA';
select 'REVOKE ' || PRIVILEGE || ' FROM ' || GRANTEE || ';' from dba_sys_privs where grantee='SCHEMA';
--Cruzar DBA_ROLE_PRIVS com DBA_TAB_PRIVS
--Se você deseja verificar quais permissões de tabelas os usuários têm, considerando os papéis (roles) atribuídos a eles
SELECT rp.GRANTEE, rp.GRANTED_ROLE, tp.TABLE_NAME, tp.PRIVILEGE
FROM DBA_ROLE_PRIVS rp
JOIN DBA_TAB_PRIVS tp
ON rp.GRANTEE = tp.GRANTEE
WHERE rp.GRANTED_ROLE = 'DBA';
--Cruzar DBA_ROLE_PRIVS com DBA_SYS_PRIVS
--verificar quais privilégios de sistema os usuários têm com base nos papéis que receberam
SELECT rp.GRANTEE, rp.GRANTED_ROLE, sp.PRIVILEGE
FROM DBA_ROLE_PRIVS rp
JOIN DBA_SYS_PRIVS sp
ON rp.GRANTEE = sp.GRANTEE
WHERE rp.GRANTED_ROLE = 'DBA';
--Todos os privilégios combinados: DBA_ROLE_PRIVS, DBA_TAB_PRIVS, DBA_SYS_PRIVS e DBA_COL_PRIVS:
--visão geral de todos os privilégios, incluindo papéis e permissões específicas em objetos de banco de dados
SELECT rp.GRANTEE,
rp.GRANTED_ROLE,
tp.TABLE_NAME, tp.PRIVILEGE AS TABLE_PRIVILEGE,
cp.COLUMN_NAME, cp.PRIVILEGE AS COLUMN_PRIVILEGE,
sp.PRIVILEGE AS SYS_PRIVILEGE
FROM DBA_ROLE_PRIVS rp
LEFT JOIN DBA_TAB_PRIVS tp ON rp.GRANTEE = tp.GRANTEE
LEFT JOIN DBA_COL_PRIVS cp ON rp.GRANTEE = cp.GRANTEE
LEFT JOIN DBA_SYS_PRIVS sp ON rp.GRANTEE = sp.GRANTEE
WHERE rp.GRANTED_ROLE = 'DBA';
select decode( grouping(nm), 1, 'total', nm ) nm, round(sum(val/1024/1024)) mb
from
(
select 'sga' nm, sum(value) val from v$sga
union all
select 'pga', sum(a.value) from v$sesstat a, v$statname b where b.name = 'session pga memory' and a.statistic# = b.statistic#
)
group by rollup(nm);
NM MB
----- ----------
pga 606
sga 5008
total 5614
##########################################
## DATA PUMP EXPORT (EXPDP)
##########################################
expdp C##DBA@PDB PARFILE=parfile.par
COMPRESSION=[ NONE| DATA_ONLY | METADATA_ONLY | ALL ]
COMPRESSION_ALGORITHM= [ BASIC | LOW | MEDIUM | HIGH ]
CONTENT=[ ALL | DATA_ONLY | METADATA_ONLY ]
DUMPFILE=DumpFileName_%U__%D-%M-%Y.dmp
ENCRYPTION=[ ALL | DATA_ONLY | ENCRYPTED_COLUMNS_ONLY | METADATA_ONLY | NONE ]
ENCRYPTION_ALGORITHM=[ AES128 | AES192 | AES256 ]
ENCRYPTION_MODE=[ DUAL | PASSWORD | TRANSPARENT ]
ENCRYPTION_PASSWORD=password
ENCRYPTION_PWD_PROMPT=[ YES | NO ]
ESTIMATE=[ BLOCKS | STATISTICS ]
ESTIMATE_ONLY=[ YES | NO ]
EXCLUDE=object_type [ TABLE,VIEW,FUNCTION,PROCEDURE,SEQUENCE,SYNONYM,PACKAGE,PACKAGE BODY,TRIGGER,INDEX,MATERIALIZED VIEW ]
INCLUDE=object_type [ TABLE,VIEW,FUNCTION,PROCEDURE,SEQUENCE,SYNONYM,PACKAGE,PACKAGE BODY,TRIGGER,INDEX,MATERIALIZED VIEW ]
FILESIZE=integer[ B | KB | MB | GB | TB ]
FULL=[ NO | YES ]
HELP=[ NO | YES ]
JOB_NAME=JOBNAME_STRING
KEEP_MASTER=[ NO | YES ]
LOGFILE=[ directory_object: ]file_name
NOLOGFILE=[ NO | YES ]
LOGTIME=[ NONE | STATUS | LOGFILE | ALL ]
METRICS=[ NO | YES ]
PARALLEL=integer ##COMMAND LINUX: nproc (or) grep -c ^processor /proc/cpuinfo
QUERY=[ schema. ][ table_name: ] query_clause
REUSE_DUMPFILES=[ NO | YES ]
SAMPLE=70 # "HR"."EMPLOYEES":50
SCHEMAS=schema_name [ , ...hr,sh,oe ]
STATUS=0
TABLES=[ schema_name. ]table_name[ :partition_name ] [ , ...employees,jobs,departments ]
TABLESPACES=tablespace_name [ , ...tbs_4, tbs_5, tbs_6 ]
TRANSPORT_FULL_CHECK=[ NO | YES ]
TRANSPORT_TABLESPACES=tablespace_name [ , ... ]
TRANSPORTABLE=[ NEVER |ALWAYS ]
VERSION=[ COMPATIBLE | LATEST | version_string ]
##########################################
## DATA PUMP IMPORT (IMPDP)
##########################################
impdp C##DBA@PDB PARFILE=parfile.par
CONTENT=[ ALL | DATA_ONLY | METADATA_ONLY ]
DIRECTORY=directory_object
DUMPFILE=[ directory_object: ]file_name [ , ... ] %U %l, %L
ENCRYPTION_PASSWORD=password
ENCRYPTION_PWD_PROMPT=[ NO | YES ]
ESTIMATE=[ BLOCKS | STATISTICS ]
EXCLUDE=object_type [ TABLE,VIEW,FUNCTION,PROCEDURE,SEQUENCE,SYNONYM,PACKAGE,PACKAGE BODY,TRIGGER,INDEX,MATERIALIZED VIEW ]
INCLUDE=object_type [ TABLE,VIEW,FUNCTION,PROCEDURE,SEQUENCE,SYNONYM,PACKAGE,PACKAGE BODY,TRIGGER,INDEX,MATERIALIZED VIEW ]
FULL=YES
HELP=[ NO | YES ]
JOB_NAME=JOBNAME_STRING
KEEP_MASTER=[ NO | YES ]
LOGFILE=[ directory_object: ]file_name
NOLOGFILE=[ NO | YES ]
LOGTIME=[ NONE | STATUS | LOGFILE | ALL ]
MASTER_ONLY=[ NO | YES ]
METRICS=[ NO | YES ]
PARALLEL=integer ##COMMAND LINUX: nproc (or) grep -c ^processor /proc/cpuinfo
PARALLEL_THRESHOLD=size-in-bytes
QUERY=[ [ schema_name. ]table_name: ]query_clause
REMAP_DATA=[ schema. ]tablename.column_name:[ schema. ]pkg.function
REMAP_DATAFILE=source_datafile:target_datafile
REMAP_DIRECTORY=source_directory_string:target_directory_string
REMAP_SCHEMA=source_schema:target_schema
REMAP_TABLE=[ schema. ]old_tablename[ :partition ]:new_tablename
REMAP_TABLESPACE=source_tablespace:target_tablespace
SCHEMAS=schema_name [ , ...hr,sh,oe ]
SERVICE_NAME=name
SKIP_UNUSABLE_INDEXES=[ YES | NO ]
SOURCE_EDITION=edition_name
SQLFILE=[ directory_object: ]file_name
STATUS[ =integer ]
STREAMS_CONFIGURATION=[ YES | NO ]
TABLE_EXISTS_ACTION=[ SKIP | APPEND | TRUNCATE | REPLACE ]
REUSE_DATAFILES=[ YES | NO ]
TABLES=[ schema_name. ]table_name[ :partition_name ]
TABLESPACES=tablespace_name [ , ... ]
TARGET_EDITION=name
TRANSFORM=transform_name:value[ :object_type ]
TRANSPORT_FULL_CHECK=[ NO | YES ]
TRANSPORT_TABLESPACES=tablespace_name [ , ... ]
TRANSPORTABLE=[ ALWAYS|NEVER|KEEP_READ_ONLY|NO_BITMAP_REBUILD ]
VERSION=[ COMPATIBLE | LATEST | version_string ]
VIEWS_AS_TABLES=[ schema_name. ]view_name[ :table_name ], ...
##########################################
# Command Used # Activity
##########################################
CONTINUE_CLIENT # Exit interactive-command mode.
EXIT_CLIENT # Stop the import client session, but leave the current job running.
HELP # Display a summary of available commands.
KILL_JOB # Detach all currently attached client sessions and terminate the current job.
PARALLEL # Increase or decrease the number of active worker processes for the current job.
START_JOB # Restart a stopped job to which you are attached.
STATUS # Display detailed status for the current job.
STOP_JOB # Stop the current job.
##########################################
## Directory Configuration
##########################################
CREATE OR REPLACE DIRECTORY DIR_DUMP AS '/caminho/para/dump';
GRANT READ, WRITE ON DIRECTORY DIR_DUMP TO user;
-- Check OMF se está habilitado
SHOW PARAMETER db_create_file_dest;
-- ALTERAR O REDO LOG ATIVO
ALTER SYSTEM SWITCH LOGFILE;
--ADICIONAR REDO:
ALTER DATABASE ADD LOGFILE GROUP X SIZE 500M;
ALTER DATABASE ADD LOGFILE MEMBER '/ora01/oradata/LAB/redo0102.log' TO GROUP 1;
ALTER DATABASE ADD LOGFILE MEMBER '/ora01/oradata/LAB/redo0202.log' TO GROUP 2;
-- REMOVER GRUPO
ALTER DATABASE DROP LOGFILE GROUP X;
-- REMOVER MEMBRO
ALTER DATABASE DROP LOGFILE MEMBER '/ora01/oradata/LAB/redo01.log';
ALTER DATABASE DROP LOGFILE MEMBER '/ora01/oradata/LAB/redo02.log';
-- ARQUIVAR O ATUAL
ALTER SYSTEM ARCHIVE LOG CURRENT;
-- LIMPAR
ALTER DATABASE CLEAR LOGFILE GROUP 1;
ALTER DATABASE CLEAR UNARCHIVED LOGFILE GROUP 1;
-- TAMANHO DO REDO LOG
SELECT GROUP#,THREAD#,SEQUENCE#,BYTES/1024/1024,MEMBERS,STATUS FROM V$LOG;
SELECT
A.GROUP#, A.THREAD#, A.SEQUENCE#, A.ARCHIVED, A.STATUS,
B.MEMBER AS REDOLOG_FILE_NAME, (A.BYTES/1024/1024) AS SIZE_MB
FROM V$LOG A
JOIN V$LOGFILE B ON A.GROUP#=B.GROUP#
ORDER BY A.GROUP#;
SELECT l.GROUP#,
l.BYTES / 1024 / 1024 AS SIZE_MB,
f.MEMBER
FROM V$LOG l, V$LOGFILE f WHERE l.GROUP# = f.GROUP# ORDER BY l.GROUP#;
-- VIEWs:
SELECT * FROM V$LOG -- Exibe as informações do arquivo redo log do arquivo de controle
SELECT * FROM V$LOGFILE --Identifica grupos de redo log e membros e status do membro
SELECT * FROM V$LOG_HISTORY --Contém informações do histórico de log
clear columns
column tablespace format a30
column total_mb format 999,999,999.99
column used_mb format 999,999,999,999.99
column free_mb format 999,999,999.99
column pct_used format 999.99
column graph format a22 heading "GRAPH (X=5%)"
column status format a7
compute sum of total_mb on report
compute sum of used_mb on report
compute sum of free_mb on report
break on report
set lines 200 pages 100
SELECT
total.ts TABLESPACE,
DECODE(total.mb, NULL, 'OFFLINE', dbat.status) status,
total.mb total_mb,
NVL(total.mb - free.mb, total.mb) used_mb,
NVL(free.mb, 0) free_mb,
DECODE(total.mb, NULL, 0, NVL(ROUND((total.mb - free.mb)/(total.mb)*100, 2), 100)) pct_used,
CASE
WHEN (total.mb IS NULL) THEN '['||RPAD(LPAD('OFFLINE', 13, '-'), 20, '-')||']'
ELSE '['|| DECODE(free.mb, NULL, 'XXXXXXXXXXXXXXXXXXXX', NVL(RPAD(LPAD('X', TRUNC((100-ROUND((free.mb)/(total.mb) * 100, 2))/5), 'X'), 20, '-'), '--------------------'))||']'
END AS GRAPH
FROM
(SELECT tablespace_name ts, SUM(bytes)/1024/1024 mb FROM dba_data_files GROUP BY tablespace_name) total,
(SELECT tablespace_name ts, SUM(bytes)/1024/1024 mb FROM dba_free_space GROUP BY tablespace_name) FREE,
dba_tablespaces dbat
WHERE total.ts=free.ts(+)
AND total.ts=dbat.tablespace_name
UNION ALL
SELECT
sh.tablespace_name,
'TEMP',
SUM(sh.bytes_used+sh.bytes_free)/1024/1024 total_mb,
SUM(sh.bytes_used)/1024/1024 used_mb,
SUM(sh.bytes_free)/1024/1024 free_mb,
ROUND(SUM(sh.bytes_used)/SUM(sh.bytes_used+sh.bytes_free)*100, 2) pct_used,
'['||DECODE(SUM(sh.bytes_free), 0, 'XXXXXXXXXXXXXXXXXXXX', NVL(RPAD(LPAD('X',(TRUNC(ROUND((SUM(sh.bytes_used)/SUM(sh.bytes_used+sh.bytes_free))*100, 2)/5)),'X'), 20, '-'), '--------------------'))||']'
FROM v$temp_space_header sh
GROUP BY tablespace_name
ORDER BY 6 DESC
Output:
TABLESPACE STATUS TOTAL_MB USED_MB FREE_MB PCT_USED GRAPH
---------------------- --------- ---------- ---------- ---------- ---------- ----------------------
ONE_4M_T ONLINE 132 132 0 100 [XXXXXXXXXXXXXXXXXXXX]
TWO_128K_I ONLINE 5 1 4 20 [XXXX----------------]
THREE_256M_T ONLINE 10 1,5 8,5 15 [XXX-----------------]
FOUR_256M_T ONLINE 10 1 9 10 [XX------------------]
TEMP_02 TEMP 102400 2 102398 0 [--------------------]
SELECT OWNER, SEGMENT_NAME, SEGMENT_TYPE, EXTENTS, MAX_EXTENTS
FROM DBA_SEGMENTS
WHERE EXTENTS >= (MAX_EXTENTS*50/100);
sysman@emrep.marte> SELECT
LPAD( '-', 150, '-' ) LINHA
,J.JOB_NAME
,J.TARGET
,J.SCHEDULED_TIME
,J.START_TIME
,J.FREQUENCY_CODE
,J.INTERVAL
,J.DEFINITION
FROM USER_JOB.GRID_JOBS_SCHEDULED J
WHERE JOB_NAME LIKE '%DWH1N%'
ORDER BY JOB_NAME
/
------------------------------------------------------------------------------------------------------------------------------------------------------
SET PAGESIZE 1000 HEADING OFF FEEDBACK ON TIMING ON SERVEROUTPUT ON
WHENEVER SQLERROR EXIT SQL.SQLCODE
ALTER SESSION SET query_rewrite_enabled=FALSE;
select instance_name from v$instance;
commit;
SELECT 'INICIO EM : ' || to_char(sysdate,'DD/MM/YYYY HH:MI') FROM DUAL;
execute usr_job.CRG_DWH1N_DWORCAMENTO_DIARIO;
SELECT 'TERMINO EM : ' || to_char(sysdate,'DD/MM/YYYY HH:MI') FROM DUAL;
commit;
exit;
------------------------------------------------------------------------------------------------------------------------------------------------------
SET PAGESIZE 1000 HEADING OFF FEEDBACK ON TIMING ON SERVEROUTPUT ON
WHENEVER SQLERROR EXIT SQL.SQLCODE
SELECT 'INICIO EM : ' || to_char(sysdate,'DD/MM/YYYY HH:MI') FROM DUAL;
--backup ft_favorecido,ft_favorecido_est e ft_execucao_contas
host /prg/oracle/admin/dwh1n/rotinas/expdp_tabs_orcamento.ksh
SELECT 'INICIO EM : ' || to_char(sysdate,'DD/MM/YYYY HH:MI') FROM DUAL;
--Trunca as tabelas dist_uf e dist_municipio
execute usr_job.crg_dwh1n_dworcamento_truncate;
SELECT 'INICIO EM : ' || to_char(sysdate,'DD/MM/YYYY HH:MI') FROM DUAL;
--Carrega as tabelas dist_uf e dist_municipio via sqlloader
host /prg/oracle/admin/dwh1n/rotinas/ex_func_distmun.ksh
host /prg/oracle/admin/dwh1n/rotinas/ex_func_distuf.ksh
SELECT 'INICIO EM : ' || to_char(sysdate,'DD/MM/YYYY HH:MI') FROM DUAL;
--Executa a carga_inc_fato_favorecido
execute usr_job.crg_dwh1n_dworcament_ft_diario;
SELECT '---Procedure OK---' FROM DUAL;
SELECT 'TERMINO EM : ' || to_char(sysdate,'DD/MM/YYYY HH:MI') FROM DUAL;
commit;
exit;
REM This script examines various V$ parameters. The script makes suggestions
REM on mods that can be made to your system if specific conditions exist. The
REM report should be run after the system has been up for at least 5 hours
REM and should be run over a period of time to get a real feel for what the
REM real condition of the database is. A one-time sample run on an inactive
REM system will not give an accurate picture of what is really occuring within
REM the database.
REM
REM If the database is shut down on a nightly basis for backups, the script can
REM be run just prior to shutdown each night to enable trending analysis.
REM
REM This script can be run on any platform but is tailored to evaluate an
REM Oracle7.0.x database. The script should be run from an account that
REM has DBA privileges and on which CATDBSYN.SQL has been run.
REM
REM **NOTE: Be sure to change the "spool" path to reflect your directory
REM structure.
REM
REM Alterada e atualizada por CRF em 19/11/97
Accept arquivo prompt 'Entre o Nome do Arquivo: '
spool C:\Daniel\&arquivo;
set pages 60
set verify off
set head off
col name format a45
col phyrds format 9,999,999
col phywrts format 9,999,999
set echo off termout off feedback off
set newpage 1
set linesize 80
define cr=chr(10)
ttitle 'SYSTEM STATISTICS FOR ORACLE7'
select 'LIBRARY CACHE STATISTICS:' from dual;
ttitle off
select 'PINS - # of times an item in the library cache was executed - '||
sum(pins),
'RELOADS - # of library cache misses on execution steps - '||sum(reloads)||
&cr||&cr,
'RELOADS / PINS * 100 = '||round((sum(reloads) / sum(pins) * 100),2)||'%'
from v$librarycache
/
prompt If more than 1%, tune the library cache...
prompt To increase library cache, increase SHARED_POOL_SIZE
prompt
prompt ** NOTE: Increasing SHARED_POOL_SIZE will increase the SGA size.
prompt
prompt Library Cache Misses indicate that the Shared Pool is not big
prompt enough to hold the shared SQL area for all concurrently open cursors.
prompt If there are never any misses (PINS = 0), you may get a small increase
prompt in performance by setting CURSOR_SPACE_FOR_TIME = TRUE which prevents
prompt ORACLE from deallocating a shared SQL area while an application cursor
prompt associated with it is open.
prompt
prompt ------------------------------------------------------------------------
column xn1 format a50
column xn2 format a50
column xn3 format a50
column xv1 new_value xxv1 noprint
column xv2 new_value xxv2 noprint
column xv3 new_value xxv3 noprint
column d1 format a50
column d2 format a50
prompt HIT RATIO:
prompt
prompt Values Hit Ratio is calculated against:
prompt
select lpad(a.name,20,' ')||' = '||b.value xn1, b.value xv1
from
v$statname a, v$sysstat b
where
a.statistic# = b.statistic#
and b. statistic# = 37
/
select lpad(a.name,20,' ')||' = '||b.value xn2, b.value xv2
from
v$statname a, v$sysstat b
where
a.statistic# = b.statistic#
and b. statistic# = 38
/
select lpad(a.name,20,' ')||' = '||b.value xn3, b.value xv3
from
v$statname a, v$sysstat b
where
a.statistic# = b.statistic#
and b. statistic# = 39
/
set pages 60
select 'Logical reads = db block gets + consistent gets ',
lpad('Logical Reads = ',24,' ')||to_char(&xxv1+&xxv2) d1
from dual
/
select 'Hit Ratio = (logical reads - physical reads) / logical reads',
lpad('Hit Ratio = ',24,' ')||
round( (((&xxv2+&xxv1) - &xxv3) / (&xxv2+&xxv1))*100,2 )||'%' d2
from dual
/
prompt If the hit ratio is less than 60%-70%, increase the initialization
prompt parameter DB_BLOCK_BUFFERS. ** NOTE: Increasing this parameter will
prompt increase the SGA size.
prompt
prompt ------------------------------------------------------------------------
col name format a30
col gets format 9,999,999
col waits format 9,999,999
prompt ROLLBACK CONTENTION STATISTICS:
prompt
prompt GETS - # of gets on the rollback segment header
prompt WAITS - # of waits for the rollback segment header
set head on;
select name, waits, gets
from v$rollstat, v$rollname
where v$rollstat.usn = v$rollname.usn
/
set head off
select 'The average of waits/gets is '||
round((sum(waits) / sum(gets)) * 100,2)||'%'
from v$rollstat
/
prompt
prompt If the ratio of waits to gets is more than 1% or 2%, consider
prompt creating more rollback segments
prompt
prompt Another way to gauge rollback contention is:
prompt
column xn1 format 999999999
column xm1 format 999999999
column xv1 new_value xxv1 noprint
set head on
select class, count
from v$waitstat
where class in ('system undo header','system undo block','undo header',
'undo block')
/
set head off
-- acredito ser esse o SQL correto
SELECT 'Total requests = '||SUM(value) xn1, SUM(value) xv1
FROM v$sysstat WHERE name IN ('db block gets', 'consistent gets')
/
--Esse SQL original do script estava com erro. Foi substituido pelo SQL acima.
--Alterado em 25/09/98
--select 'Total requests = '||sum(count) xn1, sum(count) xv1
--from v$waitstat
select 'Total waits = '||sum(count) xm1 from v$waitstat
/
select 'Contention for system undo header = '||
decode(&xxv1,0,0,(round(count/&xxv1,4)) * 100)||'%'
from v$waitstat
where class = 'system undo header'
/
select 'Contention for system undo block = '||
decode(&xxv1,0,0,(round(count/&xxv1,4)) * 100)||'%'
from v$waitstat
where class = 'system undo block'
/
select 'Contention for undo header = '||
decode(&xxv1,0,0,(round(count/&xxv1,4)) * 100)||'%'
from v$waitstat
where class = 'undo header'
/
select 'Contention for undo block = '||
decode(&xxv1,0,0,(round(count/&xxv1,4)) * 100)||'%'
from v$waitstat
where class = 'undo block'
/
select 'Contention for freelist = '||
decode(&xxv1,0,0,(round(count/&xxv1,4)) * 100)||'%'
from v$waitstat
where class = 'free list'
/
prompt
prompt If the percentage for an area is more than 1% or 2%, consider
prompt creating more rollback segments. Note: This value is usually very small
prompt and has been rounded to 4 places.
prompt
prompt ------------------------------------------------------------------------
prompt REDO CONTENTION STATISTICS:
prompt
prompt The following shows how often user processes had to wait for space in
prompt the redo log buffer:
select name||' = '||value||&cr
from v$sysstat
where name = 'redo log space requests'
/
prompt
prompt This value should be near 0. If this value increments consistently,
prompt processes have had to wait for space in the redo buffer. If this
prompt condition exists over time, increase the size of LOG_BUFFER in the
prompt init.ora file in increments of 5% until the value nears 0.
prompt ** NOTE: increasing the LOG_BUFFER value will increase total SGA size.
prompt
prompt ------------------------------------------------------------------------
col name format a15
col gets format 99999999
col misses format 99999999
col immediate_gets heading 'IMMED GETS' format 99999999
col immediate_misses heading 'IMMED MISS' format 99999999
col sleeps format 9999999
prompt LATCH CONTENTION:
prompt
prompt GETS - # of successful willing-to-wait requests for a latch
prompt MISSES - # of times an initial willing-to-wait request was unsuccessful
prompt IMMEDIATE_GETS - # of successful immediate requests for each latch
prompt IMMEDIATE_MISSES = # of unsuccessful immediate requests for each latch
prompt SLEEPS - # of times a process waited and requests a latch after an initial
prompt willing-to-wait request
prompt
prompt If the latch requested with a willing-to-wait request is not
prompt available, the requesting process waits a short time and requests again.
prompt If the latch requested with an immediate request is not available,
prompt the requesting process does not wait, but continues processing
prompt
set head on;
select name, gets, misses, immediate_gets, immediate_misses, sleeps
from v$latch
where name in ('redo allocation','redo copy')
/
set head off
select 'Ratio of MISSES to GETS: '||round((sum(misses)/sum(gets) * 100),2)||'%'
from v$latch
where name in ('redo allocation','redo copy')
/
select 'Ratio of IMMEDIATE_MISSES to IMMEDIATE_GETS: '||
decode(sum(immediate_misses+immediate_gets),0,0,
round((sum(immediate_misses)/sum(immediate_misses+immediate_gets) * 100),2))
||'%'
from v$latch
where name in ('redo allocation','redo copy')
/
prompt
prompt If either ratio exceeds 1%, performance will be affected.
prompt
prompt Decreasing the size of LOG_SMALL_ENTRY_MAX_SIZE reduces the number of
prompt processes copying information on the redo allocation latch.
prompt
prompt Increasing the size of LOG_SIMULTANEOUS_COPIES will reduce contention for
prompt redo copy latches.
rem
rem This shows the library cache reloads
rem
prompt
prompt ------------------------------------------------------------------------
rem
rem Presented at ECO'94 by Michelle Becci
rem
prompt
prompt Look at gethitratio and pinhit ratio
prompt
prompt GETHITRATIO is number of GETHTS/GETS
prompt PINHIT RATIO is number of PINHITS/PINS - number close to 1 indicates
prompt that most objects requested for pinning have been cached
prompt
set head on
column namespace format a20 heading 'NAME'
column gets format 999999999 heading 'GETS'
column gethits format 999999999 heading 'GETHITS'
column gethitratio format 999.99 heading 'GET HIT|RATIO'
column pins format 999999999 heading 'PINHITS'
column pinhitratio format 999.99 heading 'PIN HIT|RATIO'
select namespace, gets, gethits, gethitratio, pins, pinhitratio
from v$librarycache
/
prompt
prompt ------------------------------------------------------------------------
rem
rem
rem This looks at the sga area breakdown
rem
set head on
prompt THE SGA AREA ALLOCATION:
prompt
prompt
prompt This shows the allocation of SGA storage. Examine this before and
prompt after making changes in the INIT.ORA file which will impact the SGA.
prompt
rem
col name format a40
select name, bytes
from v$sgastat
/
prompt
prompt ------------------------------------------------------------------------
prompt This looks at overall i/o activity against individual files within a
prompt tablespace. Add up the numbers by disk and look for a mismatch across
prompt disks in terms of I/O.
prompt
prompt If activity on the files is unbalanced, move files around to balance
prompt the load. Should see an approximately even set of numbers across files.
prompt
set pagesize 100;
set space 1
column pbr format 999999999 heading 'Physical|Blk Read'
column pbw format 9999999 heading 'Physical|Blks Wrtn'
column pyr format 9999999 heading 'Physical|Reads'
column readtim format 9999999 heading 'Read|Time'
column name format a40 heading 'DataFile Name'
column writetim format 9999999 heading 'Write|Time'
ttitle center 'Tablespace Report' skip 2
compute sum of f.phyblkrd, f.phyblkwrt on report
rem
select fs.name name,f.phyblkrd pbr,f.phyblkwrt pbw,f.readtim,
f.writetim
from v$filestat f, v$dbfile fs
where f.file# = fs.file#
order by fs.name
/
prompt
prompt ------------------------------------------------------------------------
rem
rem Presented at ECO'94 by Michelle Becci - with modifications by M. Theriault
rem
prompt GENERATING WAIT STATISTICS:
prompt
prompt This will show wait stats for certain kernel instances. This may show
prompt the need for additional rbs, wait lists, db_buffers
prompt
ttitle center 'Wait Statistics for the Instance' skip 2
column class heading 'Class Type'
column count format 999,999,999 heading 'Times Waited'
column time heading 'Total Times' format 999,999,999
select class, count, time
from v$waitstat
where count > 0
order by class
/
prompt
prompt Look at the wait statistics generated above (if any). They will
prompt tell you where there is contention in the system. There will
prompt usually be some contention in any system - but if the ratio of
prompt waits for a particular operation starts to rise, you may need to
prompt add additional resource, such as more database buffers, log buffers,
prompt or rollback segments
prompt
prompt ------------------------------------------------------------------------
prompt ROLLBACK STATISTICS:
prompt
ttitle off;
column extents format 9999 heading 'Extents'
column rssize format 999,999,999 heading 'Size in|Bytes'
column optsize format 999,999,999 heading 'Optimal|Size'
column hwmsize format 9,999,999,999 heading 'High Water|Mark'
column shrinks format 9,999,999 heading 'Number of|Shrinks'
column extends format 9,999,999 heading 'Number of|Extends'
column aveactive format 9,999,999,999 heading 'Average size|Active Extents'
column rownum noprint
select rssize, optsize, hwmsize, shrinks, extends, aveactive
from v$rollstat
order by rownum
/
rem
prompt
prompt ------------------------------------------------------------------------
break on report
compute sum of gets waits writes on report
ttitle center 'Rollback Statistics' skip 2
select rownum, extents, rssize, xacts, gets, waits, writes
from v$rollstat
order by rownum
/
ttitle off
set heading off
ttitle off
prompt
prompt ------------------------------------------------------------------------
rem
rem Presented at ECO'94 by Michelle Becci - with modifications by M. Theriault
rem
prompt
prompt SORT AREA SIZE VALUES:
prompt
prompt To make best use of sort memory, the initial extent of your Users
prompt sort-work Tablespace should be sufficient to hold at least one sort
prompt run from memory to reduce dynamic space allocation. If you are getting
prompt a high ratio of disk sorts as opposed to memory sorts, setting
prompt sort_area_retained_size = 0 in init.ora will force the sort area to be
prompt released immediately after a sort finishes.
prompt
column value format 99,999,999,999
select 'INIT.ORA sort_area_size: '||value
from v$parameter where name like 'sort_area_size';
select a.name, value
from v$statname a, v$sysstat b
where a.statistic# = b.statistic#
and a.name in ('sorts (disk)','sorts (memory)','sorts (rows)')
/
prompt
prompt ------------------------------------------------------------------------
set heading on
set space 2
prompt
prompt This looks at Tablespace Sizing - Total bytes and free bytes
prompt
Create or replace view vw_dba_datafiles (tablespace_name, Total_Bytes) as
select tablespace_name, sum(bytes)
from dba_data_files
group by tablespace_name
/
ttitle center 'Tablespace Sizing Information' Skip 2
set heading on
set space 2
column sbytes format 99,999,999,999,999 heading 'Total Bytes'
column fbytes format 9,999,999,999,999 heading 'Free Bytes'
column kount format 9,999 heading 'Free|Chunks'
compute sum of sbytes on report
compute sum of fbytes on report
break on report
select a.tablespace_name, a.Total_bytes sbytes, sum(b.bytes) fbytes,
count(*) kount
from vw_dba_datafiles a, dba_free_space b
where a.tablespace_name = b.tablespace_name
group by a.tablespace_name, a.total_bytes
order by a.tablespace_name
/
Drop view vw_dba_datafiles
/
prompt
prompt A large number of Free Chunks indicates that the tablespace may need
prompt to be defragmented and compressed.
prompt
prompt ------------------------------------------------------------------------
set heading off
ttitle off
column value format 999,999,999,999
select 'Total Physical Reads', value
from v$sysstat
where statistic# = 39
/
prompt
prompt If you can significantly reduce physical reads by adding incremental
prompt data buffers...do it. To determine whether adding data buffers will
prompt help, set db_block_lru_statistics = TRUE and
prompt db_block_lru_extended_statistics = TRUE in the init.ora parameters.
prompt You can determine how many extra hits you would get from memory as
prompt opposed to physical I/O from disk. **NOTE: Turning these on will
prompt impact performance. One shift of statistics gathering should be enough
prompt to get the required information.
prompt
set heading on
clear computes
ttitle off
prompt
prompt ------------------------------------------------------------------------
prompt CHECKING FOR FRAGMENTED DATABASE OBJECTS:
prompt
prompt Fragmentation report - If number of extents is approaching Max extents,
prompt it is time to defragment the table.
prompt
column owner noprint new_value owner_var
column segment_name format a30 heading 'Object Name'
column segment_type format a9 heading 'Table/Indx'
column sum(bytes) format 9,999,999,999 heading 'Bytes Used'
column count(*) format 999 heading 'No.'
break on owner skip page 2
ttitle center 'Table Fragmentation Report' skip 2 -
left 'creator: ' owner_var skip 2
select a.owner, segment_name, segment_type, sum(bytes), max_extents, count(*)
from dba_extents a, dba_tables b
where a.owner = b.owner and
a.owner not in ('SYS','SYSTEM') and
segment_name = b.table_name
having count(*) > 7
group by a.owner, segment_name, segment_type, max_extents
order by a.owner, segment_name, segment_type, max_extents
/
ttitle center 'Index Fragmentation Report' skip 2 -
left 'creator: ' owner_var skip 2
select a.owner, segment_name, segment_type, sum(bytes), max_extents, count(*)
from dba_extents a, dba_indexes b
where a.owner = b.owner and
a.owner not in ('SYS','SYSTEM') and
segment_name = index_name
having count(*) > 7
group by a.owner, segment_name, segment_type, max_extents
order by a.owner, segment_name, segment_type, max_extents
/
prompt
prompt ------------------------------------------------------------------------
spool off
-------------------------------------------------------------------------------------------------
-- Script : nologging_inserts_03.sql
-------------------------------------------------------------------------------------------------
-- This script demonstrates effect of nologging on heap table for bulk insert.
-- Behavior is different from the multi row insert.
--
-- Author : Riyaj Shamsudeen
-- No implied or explicit warranty !
-------------------------------------------------------------------------------------------------
set serveroutput on size 1000000
prompt Test case : Nologging on HEAP table : Bulk inserts : No index
set timing off
set feedback off
drop table ilp_activity_heap;
create table ilp_activity_heap
(
item number not null,
period number not null,
location number not null,
item_type number not null,
sales_units number(*,8),
sales_price number(*,8),
ap_units number (*,8),
ap_price number(*,8),
fc_units number (*,8),
fc_price number(*,8)
)
nologging
storage (initial 10M next 10M pctincrease 0)
;
drop type ilp_activity_table
/
create or replace type ilp_activity_type as object
(
item number ,
period number ,
location number ,
item_type number,
sales_units number,
sales_price number,
ap_units number,
ap_price number,
fc_units number ,
fc_price number
)
/
create or replace type ilp_activity_table is table of ilp_activity_type
/
set feedback on
declare
i number;
l_begin_redo_size number;
l_end_redo_size number;
l_generated_redo number;
l_begin_time number;
l_end_time number;
l_elapsed_time number;
type item_tab is table of ilp_activity_heap.item%TYPE;
type period_tab is table of ilp_activity_heap.period%TYPE;
type location_tab is table of ilp_activity_heap.location%TYPE;
type item_type_tab is table of ilp_activity_heap.item_type%TYPE;
type sales_units_tab is table of ilp_activity_heap.sales_units%TYPE;
type sales_price_tab is table of ilp_activity_heap.sales_price%TYPE;
type ap_units_tab is table of ilp_activity_heap.ap_units%TYPE;
type ap_price_tab is table of ilp_activity_heap.ap_price%TYPE;
type fc_units_tab is table of ilp_activity_heap.fc_units%TYPE;
type fc_price_tab is table of ilp_activity_heap.fc_price%TYPE;
l_item_tab item_tab := item_tab ();
l_period_tab period_tab:= period_tab();
l_location_tab location_tab:=location_tab();
l_item_type_tab item_type_tab:=item_type_tab();
l_sales_units_tab sales_units_tab:=sales_units_tab();
l_sales_price_tab sales_price_tab:=sales_price_tab();
l_ap_units_tab ap_units_tab:=ap_units_tab();
l_ap_price_tab ap_price_tab:=ap_price_tab();
l_fc_units_tab fc_units_tab:=fc_units_tab();
l_fc_price_tab fc_price_tab:=fc_price_tab();
l_index number := 1;
begin
l_item_tab.extend (79950);
l_period_tab.extend (79950);
l_location_tab.extend (79950);
l_item_type_tab.extend (79950);
l_sales_units_tab.extend (79950);
l_sales_price_tab.extend (79950);
l_ap_units_tab.extend (79950);
l_ap_price_tab.extend (79950);
l_fc_units_tab.extend (79950);
l_fc_price_tab.extend (79950);
for i in 1 .. 6 loop
for j in 1 .. 5 loop
for k in 1 .. 533 loop
for l in 1 .. 5 loop
l_item_tab (l_index) := i;
l_period_tab (l_index) := j;
l_location_tab (l_index) := k;
l_item_type_tab (l_index) := l;
l_sales_units_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_sales_price_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_ap_units_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_ap_price_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_fc_units_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_fc_price_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_index := l_index +1;
end loop;
end loop;
end loop;
end loop;
select get_my_statistics('redo size') into l_begin_redo_size from dual;
l_begin_time := dbms_utility.get_time;
FORALL j in l_item_tab.first .. l_item_tab.last
insert into ilp_activity_heap
values
(
l_item_tab (j),
l_period_tab (j),
l_location_tab (j) ,
l_item_type_tab (j),
l_sales_units_tab (j),
l_sales_price_tab (j),
l_ap_units_tab (j),
l_ap_price_tab (j) ,
l_fc_units_tab (j) ,
l_fc_price_tab (j)
);
commit;
select get_my_statistics('redo size') into l_end_redo_size from dual;
l_end_time := dbms_utility.get_time;
dbms_output.put_line ('Total redo generated for heap table with no index ==>'||to_char( l_end_redo_size - l_begin_redo_size));
dbms_output.put_line ('Elapsed time in seconds ==>'||to_char(trunc(( l_end_time-l_begin_time)/100, 2 )));
end;
/
prompt Test case : Nologging on HEAP :Bulk inserts with append hint- no index
set timing off
set feedback off
drop table ilp_activity_heap;
create table ilp_activity_heap
(
item number not null,
period number not null,
location number not null,
item_type number not null,
sales_units number(*,8),
sales_price number(*,8),
ap_units number (*,8),
ap_price number(*,8),
fc_units number (*,8),
fc_price number(*,8)
)
nologging
storage (initial 10M next 10M pctincrease 0)
;
drop type ilp_activity_table
/
create or replace type ilp_activity_type as object
(
item number ,
period number ,
location number ,
item_type number,
sales_units number,
sales_price number,
ap_units number,
ap_price number,
fc_units number ,
fc_price number
)
/
create or replace type ilp_activity_table is table of ilp_activity_type
/
set feedback on
declare
i number;
l_begin_redo_size number;
l_end_redo_size number;
l_generated_redo number;
l_begin_time number;
l_end_time number;
l_elapsed_time number;
type item_tab is table of ilp_activity_heap.item%TYPE;
type period_tab is table of ilp_activity_heap.period%TYPE;
type location_tab is table of ilp_activity_heap.location%TYPE;
type item_type_tab is table of ilp_activity_heap.item_type%TYPE;
type sales_units_tab is table of ilp_activity_heap.sales_units%TYPE;
type sales_price_tab is table of ilp_activity_heap.sales_price%TYPE;
type ap_units_tab is table of ilp_activity_heap.ap_units%TYPE;
type ap_price_tab is table of ilp_activity_heap.ap_price%TYPE;
type fc_units_tab is table of ilp_activity_heap.fc_units%TYPE;
type fc_price_tab is table of ilp_activity_heap.fc_price%TYPE;
l_item_tab item_tab := item_tab ();
l_period_tab period_tab:= period_tab();
l_location_tab location_tab:=location_tab();
l_item_type_tab item_type_tab:=item_type_tab();
l_sales_units_tab sales_units_tab:=sales_units_tab();
l_sales_price_tab sales_price_tab:=sales_price_tab();
l_ap_units_tab ap_units_tab:=ap_units_tab();
l_ap_price_tab ap_price_tab:=ap_price_tab();
l_fc_units_tab fc_units_tab:=fc_units_tab();
l_fc_price_tab fc_price_tab:=fc_price_tab();
l_index number := 1;
begin
l_item_tab.extend (79950);
l_period_tab.extend (79950);
l_location_tab.extend (79950);
l_item_type_tab.extend (79950);
l_sales_units_tab.extend (79950);
l_sales_price_tab.extend (79950);
l_ap_units_tab.extend (79950);
l_ap_price_tab.extend (79950);
l_fc_units_tab.extend (79950);
l_fc_price_tab.extend (79950);
for i in 1 .. 6 loop
for j in 1 .. 5 loop
for k in 1 .. 533 loop
for l in 1 .. 5 loop
l_item_tab (l_index) := i;
l_period_tab (l_index) := j;
l_location_tab (l_index) := k;
l_item_type_tab (l_index) := l;
l_sales_units_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_sales_price_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_ap_units_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_ap_price_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_fc_units_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_fc_price_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_index := l_index +1;
end loop;
end loop;
end loop;
end loop;
select get_my_statistics('redo size') into l_begin_redo_size from dual;
l_begin_time := dbms_utility.get_time;
FORALL j in l_item_tab.first .. l_item_tab.last
insert /*+ append */ into ilp_activity_heap
values
(
l_item_tab (j),
l_period_tab (j),
l_location_tab (j) ,
l_item_type_tab (j),
l_sales_units_tab (j),
l_sales_price_tab (j),
l_ap_units_tab (j),
l_ap_price_tab (j) ,
l_fc_units_tab (j) ,
l_fc_price_tab (j)
);
commit;
select get_my_statistics('redo size') into l_end_redo_size from dual;
l_end_time := dbms_utility.get_time;
dbms_output.put_line ('Total redo generated with no compression ==>'||to_char( l_end_redo_size - l_begin_redo_size));
dbms_output.put_line ('Elapsed time in seconds ==>'||to_char(trunc(( l_end_time-l_begin_time)/100, 2 )));
end;
/
prompt Test case : Nologging on HEAP table : Bulk inserts : one index
set timing off
set feedback off
drop table ilp_activity_heap;
create table ilp_activity_heap
(
item number not null,
period number not null,
location number not null,
item_type number not null,
sales_units number(*,8),
sales_price number(*,8),
ap_units number (*,8),
ap_price number(*,8),
fc_units number (*,8),
fc_price number(*,8)
)
nologging
storage (initial 10M next 10M pctincrease 0)
;
create index ilp_activity_heap_index on ilp_activity_heap ( item,period,location,item_type)
nologging
storage (initial 10M next 10M )
;
drop type ilp_activity_table
/
create or replace type ilp_activity_type as object
(
item number ,
period number ,
location number ,
item_type number,
sales_units number,
sales_price number,
ap_units number,
ap_price number,
fc_units number ,
fc_price number
)
/
create or replace type ilp_activity_table is table of ilp_activity_type
/
set feedback on
declare
i number;
l_begin_redo_size number;
l_end_redo_size number;
l_generated_redo number;
l_begin_time number;
l_end_time number;
l_elapsed_time number;
type item_tab is table of ilp_activity_heap.item%TYPE;
type period_tab is table of ilp_activity_heap.period%TYPE;
type location_tab is table of ilp_activity_heap.location%TYPE;
type item_type_tab is table of ilp_activity_heap.item_type%TYPE;
type sales_units_tab is table of ilp_activity_heap.sales_units%TYPE;
type sales_price_tab is table of ilp_activity_heap.sales_price%TYPE;
type ap_units_tab is table of ilp_activity_heap.ap_units%TYPE;
type ap_price_tab is table of ilp_activity_heap.ap_price%TYPE;
type fc_units_tab is table of ilp_activity_heap.fc_units%TYPE;
type fc_price_tab is table of ilp_activity_heap.fc_price%TYPE;
l_item_tab item_tab := item_tab ();
l_period_tab period_tab:= period_tab();
l_location_tab location_tab:=location_tab();
l_item_type_tab item_type_tab:=item_type_tab();
l_sales_units_tab sales_units_tab:=sales_units_tab();
l_sales_price_tab sales_price_tab:=sales_price_tab();
l_ap_units_tab ap_units_tab:=ap_units_tab();
l_ap_price_tab ap_price_tab:=ap_price_tab();
l_fc_units_tab fc_units_tab:=fc_units_tab();
l_fc_price_tab fc_price_tab:=fc_price_tab();
l_index number := 1;
begin
l_item_tab.extend (79950);
l_period_tab.extend (79950);
l_location_tab.extend (79950);
l_item_type_tab.extend (79950);
l_sales_units_tab.extend (79950);
l_sales_price_tab.extend (79950);
l_ap_units_tab.extend (79950);
l_ap_price_tab.extend (79950);
l_fc_units_tab.extend (79950);
l_fc_price_tab.extend (79950);
for i in 1 .. 6 loop
for j in 1 .. 5 loop
for k in 1 .. 533 loop
for l in 1 .. 5 loop
l_item_tab (l_index) := i;
l_period_tab (l_index) := j;
l_location_tab (l_index) := k;
l_item_type_tab (l_index) := l;
l_sales_units_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_sales_price_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_ap_units_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_ap_price_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_fc_units_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_fc_price_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_index := l_index +1;
end loop;
end loop;
end loop;
end loop;
select get_my_statistics('redo size') into l_begin_redo_size from dual;
l_begin_time := dbms_utility.get_time;
FORALL j in l_item_tab.first .. l_item_tab.last
insert into ilp_activity_heap
values
(
l_item_tab (j),
l_period_tab (j),
l_location_tab (j) ,
l_item_type_tab (j),
l_sales_units_tab (j),
l_sales_price_tab (j),
l_ap_units_tab (j),
l_ap_price_tab (j) ,
l_fc_units_tab (j) ,
l_fc_price_tab (j)
);
commit;
select get_my_statistics('redo size') into l_end_redo_size from dual;
l_end_time := dbms_utility.get_time;
dbms_output.put_line ('Total redo generated for heap table with no index ==>'||to_char( l_end_redo_size - l_begin_redo_size));
dbms_output.put_line ('Elapsed time in seconds ==>'||to_char(trunc(( l_end_time-l_begin_time)/100, 2 )));
end;
/
prompt Test case : Nologging on HEAP :Bulk inserts with append hint- no index
set timing off
set feedback off
drop table ilp_activity_heap;
create table ilp_activity_heap
(
item number not null,
period number not null,
location number not null,
item_type number not null,
sales_units number(*,8),
sales_price number(*,8),
ap_units number (*,8),
ap_price number(*,8),
fc_units number (*,8),
fc_price number(*,8)
)
nologging
storage (initial 10M next 10M pctincrease 0)
;
create index ilp_activity_index_heap on ilp_activity_heap ( item,period,location,item_type)
nologging
storage (initial 10M next 10M )
;
drop type ilp_activity_table
/
create or replace type ilp_activity_type as object
(
item number ,
period number ,
location number ,
item_type number,
sales_units number,
sales_price number,
ap_units number,
ap_price number,
fc_units number ,
fc_price number
)
/
create or replace type ilp_activity_table is table of ilp_activity_type
/
set feedback on
declare
i number;
l_begin_redo_size number;
l_end_redo_size number;
l_generated_redo number;
l_begin_time number;
l_end_time number;
l_elapsed_time number;
type item_tab is table of ilp_activity_heap.item%TYPE;
type period_tab is table of ilp_activity_heap.period%TYPE;
type location_tab is table of ilp_activity_heap.location%TYPE;
type item_type_tab is table of ilp_activity_heap.item_type%TYPE;
type sales_units_tab is table of ilp_activity_heap.sales_units%TYPE;
type sales_price_tab is table of ilp_activity_heap.sales_price%TYPE;
type ap_units_tab is table of ilp_activity_heap.ap_units%TYPE;
type ap_price_tab is table of ilp_activity_heap.ap_price%TYPE;
type fc_units_tab is table of ilp_activity_heap.fc_units%TYPE;
type fc_price_tab is table of ilp_activity_heap.fc_price%TYPE;
l_item_tab item_tab := item_tab ();
l_period_tab period_tab:= period_tab();
l_location_tab location_tab:=location_tab();
l_item_type_tab item_type_tab:=item_type_tab();
l_sales_units_tab sales_units_tab:=sales_units_tab();
l_sales_price_tab sales_price_tab:=sales_price_tab();
l_ap_units_tab ap_units_tab:=ap_units_tab();
l_ap_price_tab ap_price_tab:=ap_price_tab();
l_fc_units_tab fc_units_tab:=fc_units_tab();
l_fc_price_tab fc_price_tab:=fc_price_tab();
l_index number := 1;
begin
l_item_tab.extend (79950);
l_period_tab.extend (79950);
l_location_tab.extend (79950);
l_item_type_tab.extend (79950);
l_sales_units_tab.extend (79950);
l_sales_price_tab.extend (79950);
l_ap_units_tab.extend (79950);
l_ap_price_tab.extend (79950);
l_fc_units_tab.extend (79950);
l_fc_price_tab.extend (79950);
for i in 1 .. 6 loop
for j in 1 .. 5 loop
for k in 1 .. 533 loop
for l in 1 .. 5 loop
l_item_tab (l_index) := i;
l_period_tab (l_index) := j;
l_location_tab (l_index) := k;
l_item_type_tab (l_index) := l;
l_sales_units_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_sales_price_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_ap_units_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_ap_price_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_fc_units_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_fc_price_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_index := l_index +1;
end loop;
end loop;
end loop;
end loop;
select get_my_statistics('redo size') into l_begin_redo_size from dual;
l_begin_time := dbms_utility.get_time;
FORALL j in l_item_tab.first .. l_item_tab.last
insert /*+ append */ into ilp_activity_heap
values
(
l_item_tab (j),
l_period_tab (j),
l_location_tab (j) ,
l_item_type_tab (j),
l_sales_units_tab (j),
l_sales_price_tab (j),
l_ap_units_tab (j),
l_ap_price_tab (j) ,
l_fc_units_tab (j) ,
l_fc_price_tab (j)
);
commit;
select get_my_statistics('redo size') into l_end_redo_size from dual;
l_end_time := dbms_utility.get_time;
dbms_output.put_line ('Total redo generated with no compression ==>'||to_char( l_end_redo_size - l_begin_redo_size));
dbms_output.put_line ('Elapsed time in seconds ==>'||to_char(trunc(( l_end_time-l_begin_time)/100, 2 )));
end;
/
--#####################################################################################################################################
--
-- Script Name: Cust_Dbinfo.sql
-- Create Date: January 2001
-- Script Version: 2.0
-- Author: David Hansen, Quest Software Professional Services
-- Revised: Aug 13/03
-- Revisions Made: 1) Added new columns to chained row select
-- 2) Added select for nonBasic datatypes.
-- 3) Removed count of sequences per schema as it was a redundant select
-- 4) Removed individual used and free tablespace selects
-- 5) Added new tablespace select to combine total, used and unused in one select. Improved performance.
-- 6) Added timing for total script time.
-- 7) Added timings for individual selects.
-- 8) Removed individual datafiles/sizing select. It's now included in the new tablespace select statement.
-- 9) Added total size of datafiles statement.
--
-- Revised: Sept 25/03
-- Revisions Made: 1) Removed Total Space sum for datafiles. Formula was giving inconsistent results
--
-- Revised: December 31/03
-- Revisions Made: 1) Modified partition sql to pull from dba_tab_partitions to list more partion info including chaining
-- 2) added 3 sql statements to find out information about user defined datatypes. The third selects from
-- dba_type_versions which is only available in Oracle 9i. This sql will fail on 8i instances but it is
-- in here to allow for keeping only one version of this script.
-- 3) changed linesize to 300 to allow for easier to read formatting of the information.
--
-- Revised: Jan 21-26/04
-- Revisions Made: 1) Separated the queries for long and lob for efficiency.
-- 2) DBA_LOBS is now queried to find info about lobs including chunk size and in row.
-- 3) Added a compute sum to tablespace info so information does not have to be interpreted outside of the report.
-- 4) Modified the statement level trigger query to display more detailed information than just a count.
-- 5) Modified the redo log size query to display the value in megabytes for readability.
-- 6) Added a PL/SQL block to Calculate average redo switches and volumes
-- 7) Added a query to highlight and validate the log_parallelism parameter
-- 8) Added a query to highlight and validate the recovery_parallelism parameter
-- 9) Added float as a basic datatype. (float has been supported for years)
-- 10) Added query for bitmap indexes.
--
-- Revised: June 24-28/04
-- Revisions Made: 1) replaced the 3 UDT queries with one simple query that pulls out information about UDTs with nested arrays.
-- 2) added a query for on delete cascades.
-- 3) added a query to find tables with more than 254 columns.
--
-- Revised: July 24-28/04
-- Revisions Made: 1) added prompt for SID to appropriately name output file
--
--
-- Revised: March 31/05
-- Revisions Made: 1) added schemas XDB and MSYS to where owner not in clauses to limit information
-- 2) added query to check for supplemental logging
-- 3) added owner to the query for tables created withing the last 90 days.
--
--
--#####################################################################################################################################
PROMPT
accept CUSTSID prompt 'Please enter the SID or Database Name (only used to name the output file):'
set verify off;
set timing off;
set feedback off;
set linesize 300;
set pagesize 1000;
timing start 'Total Duration';
spool &CUSTSID;
set heading off;
select '********************************************************' from dual;
select '****| Report for Database ' ||upper(substr(name,1,10)) || ' on ' ||substr(to_char(Sysdate,'dd-MON-rr hh:mi:ss'),1,15)|| ' |****' from v$database;
select '****| Oracle version ' ||substr(version,1,10)|| ' on Server ' ||upper(substr(host_name,1,15))|| ' |****' from v$instance;
select '****| Database is in ' ||substr(log_mode,1,20)|| ' mode |****' from v$database;
select '****| Database created since ' ||substr(to_char(created,'dd-MON-rr hh:mi:ss'),1,20)|| ' |****' from v$database;
select '****| Database running since ' ||substr(to_char(startup_time,'dd-MON-rr hh:mi:ss'),1,20)|| ' |****' from v$instance;
select '********************************************************' from dual;
set heading off;
select '******************************************************' from dual;
select '**** Supplemental Logging ****' from dual;
select '******************************************************' from dual;
set heading on;
timing start 'SuppLog';
select lpad(a.SUPPLEMENTAL_LOG_DATA_MIN,7) as Minimal,lpad(a.SUPPLEMENTAL_LOG_DATA_PK,7) as PrimKey,lpad(a.SUPPLEMENTAL_LOG_DATA_UI,7) as UniIndx from v$database a;
timing stop 'SuppLog';
set heading off;
select '******************************************************' from dual;
select '**** List of Objects by Schema Owner ****' from dual;
select '******************************************************' from dual;
set heading on;
timing start 'Schema Obj';
col username for a20
select USERNAME,
substr(count(decode(o.TYPE#, 2,o.OBJ#,'')),1,5) as Tabs,
substr(count(decode(o.TYPE#, 1,o.OBJ#,'')),1,5) as Indx,
substr(count(decode(o.TYPE#, 5,o.OBJ#,'')),1,5) as Syns,
substr(count(decode(o.TYPE#, 4,o.OBJ#,'')),1,5) as Views,
substr(count(decode(o.TYPE#, 6,o.OBJ#,'')),1,5) as Seqs,
substr(count(decode(o.TYPE#, 7,o.OBJ#,'')),1,5) as Procs,
substr(count(decode(o.TYPE#, 8,o.OBJ#,'')),1,5) as Funcs,
substr(count(decode(o.TYPE#, 9,o.OBJ#,'')),1,5) as Pkgs,
substr(count(decode(o.TYPE#,12,o.OBJ#,'')),1,5) as Trigs,
substr(count(decode(o.TYPE#,10,o.OBJ#,'')),1,5) as Deps
from sys.obj$ o, dba_users u
where u.USER_ID = o.OWNER# (+)
and o.TYPE# is NOT NULL
and u.username not in ('SYS','SYSTEM','OUTLN','XDB','WMSYS')
group by USERNAME
order by USERNAME;
timing stop 'Schema Obj';
set heading off;
select '************************************************************' from dual;
select '**** List of Tables with more than 254 columns ****' from dual;
select '************************************************************' from dual;
timing start '254ormore';
set heading on;
select owner,table_name,count(table_name) as "NumCols" from dba_tab_columns where owner not in ('SYS','SYSTEM','OUTLN','XDB','WMSYS') group by owner,table_name having count(table_name) > 254;
timing stop '254ormore';
set heading off;
select '************************************************************' from dual;
select '**** List of Tables that contain LONG data types ****' from dual;
select '************************************************************' from dual;
timing start 'Long Lob';
set heading on;
select owner,table_name,column_name,data_type from dba_tab_columns where data_type in ('LONG')
and owner not in ('SYS','SYSTEM','OUTLN','XDB','WMSYS');
timing stop 'Long Lob';
set heading off;
select '************************************************************' from dual;
select '**** List LOB table, columns and definitions ****' from dual;
select '************************************************************' from dual;
timing start 'Lobdef';
set heading on;
col Owner for a20;
col Table for a35;
col column for a61;
select substr(owner,1,20) as "Owner",substr(table_name,1,30) as "Table",substr(column_name,1,60) as "Column",chunk,lpad(in_row,8) as "In Row" from dba_lobs where owner not in ('SYS','SYSTEM','OUTLN','XDB','WMSYS');
timing stop 'Lobdef';
set heading off;
select '********************************************************' from dual;
select '**** List of Partitioned Tables and their Partitions ****' from dual;
select '********************************************************' from dual;
timing start Partitons;
set heading on;
select table_owner,table_name, partition_name,subpartition_count,num_rows, blocks, empty_blocks, avg_space, chain_cnt, avg_row_len,
last_analyzed from DBA_TAB_PARTITIONS where table_owner not in ('SYS','SYSTEM','OUTLN','XDB','WMSYS');
timing stop Partitions;
set heading off;
select '******************************************************' from dual;
select '**** Listing of Index Organized Tables ****' from dual;
select '******************************************************' from dual;
timing start IOTs;
set heading on;
select owner,table_name,iot_type from dba_tables where iot_type = 'IOT' and owner not in ('SYS','SYSTEM','OUTLN','XDB','WMSYS');
timing stop IOTs;
set heading off;
select '******************************************************' from dual;
select '**** Listing of Bitmap Indexes ****' from dual;
select '******************************************************' from dual;
timing start Bitmaps;
set heading on;
select owner,index_name,table_owner,table_name from dba_indexes where index_type = 'BITMAP';
timing stop Bitmaps;
set heading off;
select '******************************************************' from dual;
select '**** List of Data Types Contained in the Database ****' from dual;
select '******************************************************' from dual;
timing start Datatypes;
set heading on;
select distinct data_type from dba_tab_columns where owner not in ('SYS','SYSTEM','OUTLN','XDB','WMSYS');
timing stop Datatypes;
set heading off;
select '**************************************************************' from dual;
select '**** List of non-basic Data Types Contained in the Database ****' from dual;
select '**************************************************************' from dual;
timing start 'NonBasic Datatypes';
set heading on;
select a.owner, a.table_name, a.column_name,a.data_type from dba_tab_columns a, dba_objects b
where data_type not in ('VARCHAR','VARCHAR2','DATE','NUMBER','LONG VARCHAR','LOB','BLOB','CLOB','LONG','LONG RAW','CHAR','ROWID','RAW','FLOAT') and
a.owner not in ('SYS','SYSTEM','OUTLN','XDB','WMSYS')
and a.table_name = b.object_name
and b.object_type = 'TABLE';
timing stop 'NonBasic Datatypes';
set heading off;
select '**************************************************************' from dual;
select '**** List of Nested Arrays ****' from dual;
select '**************************************************************' from dual;
timing start 'NestArray';
Set heading on;
select b.owner,b.attr_type_name as "Nested Array", b.type_name as "Nested In Type", b.attr_name as "Nested in Column" from dba_type_attrs b where b.attr_type_name in (select a.type_name from dba_types a where a.owner not in ('SYS','SYSTEM','OUTLN','MDSYS','CTXSYS','ORDSYS','XDB','WMSYS') and typecode = 'COLLECTION');
timing stop 'NestArray';
set heading off;
select '********************************************************' from dual;
select '**** List of Tables with more than 500 Chained Rows ****' from dual;
select '********************************************************' from dual;
timing start Chaining;
Set heading on;
select owner,table_name,num_rows,chain_cnt,empty_blocks, avg_row_len, last_analyzed, row_movement, buffer_pool,iot_type from dba_tables where chain_cnt > 500 and owner not in ('SYS','SYSTEM','OUTLN','XDB','WMSYS');
timing stop Chaining;
set heading off;
select '********************************************************' from dual;
select '**** List of Analyzed dates 90 days ****' from dual;
select '********************************************************' from dual;
timing start Analyzed;
set heading on;
select distinct(to_char(last_analyzed,'DD-MON-RR')) as "Analyzed" from dba_tables where last_analyzed is not NULL and
last_analyzed > sysdate-90 and rownum < 20 order by "Analyzed";
timing stop Analyzed;
set heading off;
select '********************************************************' from dual;
select '**** List of Tables Created in the last 60 Days ****' from dual;
select '********************************************************' from dual;
timing start Created;
set heading on;
col "Table_Nm" for a30;
select owner, substr(object_name,1,30) as "Table_Nm",created from dba_objects where object_type = 'TABLE' and created > sysdate-60 and owner not in ('SYS','SYSTEM','OUTLN','XDB','WMSYS');
timing stop Created;
set heading off;
select '*****************************************************************' from dual;
select '**** Count of triggers by Row Level and then Statement Level ****' from dual;
select '*****************************************************************' from dual;
timing start Triggers;
set heading on;
select count(trigger_type) as "Row Level" from dba_triggers where trigger_type like '%ROW%' and owner not in ('SYS','SYSTEM','OUTLN','XDB','WMSYS');
set heading off;
select '**** Statement Level ****' from dual;
set heading on;
select owner,trigger_name,trigger_type,table_owner,table_name from dba_triggers where trigger_type not like '%ROW%' and owner not in ('SYS','SYSTEM','OUTLN','XDB','WMSYS');
timing stop Triggers;
set heading off;
select '******************************************************' from dual;
select '**** List Constraints with On-Delete Cascades ****' from dual;
select '******************************************************' from dual;
timing start OnDelCasc;
set heading on;
select owner,constraint_name from dba_constraints where delete_rule = 'CASCADE'
and owner not in ('SYS','SYSTEM','OUTLN','XDB','WMSYS');
timing stop OnDelCasc;
set heading off;
select '******************************************************' from dual;
select '**** Tablespace Info ****' from dual;
select '******************************************************' from dual;
timing start 'Tablespace Info';
set heading on;
set heading on;
break on report
compute sum of "total MB" on report
col "total MB" format 999,999,999,999,990
compute sum of "Free MB" on report
col "Free MB" format 999,999,999,999,990
compute sum of "Used MB" on report
col "Used MB" format 999,999,999,999,990
select
d.tablespace_name,
SUBSTR(d.file_name,1,50) "Datafile name",
ROUND(MAX(d.bytes)/1024/1024,2) as "total MB",
DECODE(SUM(f.bytes), null, 0, ROUND(SUM(f.Bytes)/1024/1024,2)) as "Free MB" ,
DECODE( SUM(f.Bytes), null, 0, ROUND((MAX(d.bytes)/1024/1024) - (SUM(f.bytes)/1024/1024),2)) as "Used MB"
from
DBA_FREE_SPACE f , DBA_DATA_FILES d
where
f.tablespace_name(+) = d.tablespace_name
and f.file_id(+) = d.file_id
group by
d.tablespace_name,d.file_name;
clear breaks
timing stop 'Tablespace Info';
set heading off;
select '*********************************************************' from dual;
select '**** List of Locally Managed Tablespaces ****' from dual;
select '*********************************************************' from dual;
timing start LMTs;
set heading on;
col Tablespace for a15;
select substr(tablespace_name,1,15) as "TableSpace",initial_extent,next_extent,status,contents,logging,extent_management,allocation_type,plugged_in
from dba_tablespaces where extent_management = 'LOCAL';
timing stop LMTs;
set heading off;
select '******************************************************' from dual;
select '**** Redo Log Files and Sizing ****' from dual;
select '******************************************************' from dual;
timing start 'Redo Sizing';
set heading on;
col "File Name" for a80;
col "Size in MB" format 999,999,999,999,990
select substr(a.member,1,80) as "File Name",b.bytes/1024/1024 as "Size in MB" from v$logfile a,v$log b where a.group#=b.group#;
timing stop 'Redo Sizing';
set heading off;
select '******************************************************' from dual;
select '**** Redolog Switch Rate by Date and Hour ****' from dual;
select '******************************************************' from dual;
timing start Redo;
set heading on;
col Total for a5;
col h00 for a3;
col h01 for a3;
col h02 for a3;
col h03 for a3;
col h04 for a3;
col h05 for a3;
col h06 for a3;
col h07 for a3;
col h08 for a3;
col h09 for a3;
col h10 for a3;
col h11 for a3;
col h12 for a3;
col h13 for a3;
col h14 for a3;
col h15 for a3;
col h16 for a3;
col h17 for a3;
col h18 for a3;
col h19 for a3;
col h20 for a3;
col h21 for a3;
col h22 for a3;
col h23 for a3;
col h24 for a3;
break on report
compute max of "Total" on report
compute max of "h00" on report
compute max of "h01" on report
compute max of "h02" on report
compute max of "h03" on report
compute max of "h04" on report
compute max of "h05" on report
compute max of "h06" on report
compute max of "h07" on report
compute max of "h08" on report
compute max of "h09" on report
compute max of "h10" on report
compute max of "h11" on report
compute max of "h12" on report
compute max of "h13" on report
compute max of "h14" on report
compute max of "h15" on report
compute max of "h16" on report
compute max of "h17" on report
compute max of "h18" on report
compute max of "h19" on report
compute max of "h20" on report
compute max of "h21" on report
compute max of "h22" on report
compute max of "h23" on report
SELECT trunc(first_time) "Date",
to_char(first_time, 'Dy') "Day",
substr(count(1),1,5) as "Total",
substr(SUM(decode(to_char(first_time, 'hh24'),'00',1,0)),1,3) as "h00",
substr(SUM(decode(to_char(first_time, 'hh24'),'01',1,0)),1,3) as "h01",
substr(SUM(decode(to_char(first_time, 'hh24'),'02',1,0)),1,3) as "h02",
substr(SUM(decode(to_char(first_time, 'hh24'),'03',1,0)),1,3) as "h03",
substr(SUM(decode(to_char(first_time, 'hh24'),'04',1,0)),1,3) as "h04",
substr(SUM(decode(to_char(first_time, 'hh24'),'05',1,0)),1,3) as "h05",
substr(SUM(decode(to_char(first_time, 'hh24'),'06',1,0)),1,3) as "h06",
substr(SUM(decode(to_char(first_time, 'hh24'),'07',1,0)),1,3) as "h07",
substr(SUM(decode(to_char(first_time, 'hh24'),'08',1,0)),1,3) as "h08",
substr(SUM(decode(to_char(first_time, 'hh24'),'09',1,0)),1,3) as "h09",
substr(SUM(decode(to_char(first_time, 'hh24'),'10',1,0)),1,3) as "h10",
substr(SUM(decode(to_char(first_time, 'hh24'),'11',1,0)),1,3) as "h11",
substr(SUM(decode(to_char(first_time, 'hh24'),'12',1,0)),1,3) as "h12",
substr(SUM(decode(to_char(first_time, 'hh24'),'13',1,0)),1,3) as "h13",
substr(SUM(decode(to_char(first_time, 'hh24'),'14',1,0)),1,3) as "h14",
substr(SUM(decode(to_char(first_time, 'hh24'),'15',1,0)),1,3) as "h15",
substr(SUM(decode(to_char(first_time, 'hh24'),'16',1,0)),1,3) as "h16",
substr(SUM(decode(to_char(first_time, 'hh24'),'17',1,0)),1,3) as "h17",
substr(SUM(decode(to_char(first_time, 'hh24'),'18',1,0)),1,3) as "h18",
substr(SUM(decode(to_char(first_time, 'hh24'),'19',1,0)),1,3) as "h19",
substr(SUM(decode(to_char(first_time, 'hh24'),'20',1,0)),1,3) as "h20",
substr(SUM(decode(to_char(first_time, 'hh24'),'21',1,0)),1,3) as "h21",
substr(SUM(decode(to_char(first_time, 'hh24'),'22',1,0)),1,3) as "h22",
substr(SUM(decode(to_char(first_time, 'hh24'),'23',1,0)),1,3) as "h23"
FROM V$log_history
group by trunc(first_time), to_char(first_time, 'Dy')
Order by 1;
clear breaks
timing stop Redo;
set heading off;
select '******************************************************' from dual;
select '**** Redolog Daily and Hourly volume calculated ****' from dual;
select '******************************************************' from dual;
timing start Redovol;
--#######################################################################################
--## PL/SQL used here to gather and display average redo volumes ##
--#######################################################################################
set serveroutput on;
declare
v_log number;
v_days number;
v_logsz number;
v_adsw number;
V_advol number;
v_ahsw number;
v_ahvol number;
begin
select count(first_time) into v_log from v$log_history;
select count(distinct(to_char(first_time,'dd-mon-rrrr'))) into v_days from v$log_history;
select max(bytes)/1024/1024 into v_logsz from v$log;
v_adsw := round(v_log / v_days);
v_advol := round(v_adsw * v_logsz);
v_ahsw := round(v_adsw / 24);
v_ahvol := round((v_adsw / 24 )) * v_logsz;
dbms_output.put ('Total Switches' || ' '||v_log||' ==> ');
dbms_output.put ('Total Days' || ' '|| v_days||' ==> ');
dbms_output.put_line ('Redo Size' || ' ' || v_logsz);
dbms_output.put ('Avg Daily Switches' || ' ' || v_adsw||' ==> ');
dbms_output.put_line ('Avg Daily Volume in Meg' || ' ' || v_advol);
dbms_output.put ('Avg Hourly Switches' || ' ' || v_ahsw||' ==> ');
dbms_output.put_line ('Avg Hourly Volume in Meg' || ' ' || v_ahvol);
end;
/
--#######################################################################################
--## END of PL/SQL routine ##
--#######################################################################################
timing stop Redovol;
set heading off;
select '******************************************************' from dual;
select '**** Rollback Segment Sizing Statistics ****' from dual;
select '******************************************************' from dual;
timing start Rollback;
set heading on;
col Name for a20;
select substr(a.segment_name,1,20) as "Name", a.initial_extent,a.next_extent,b.OPTSIZE,a.status,b.shrinks from dba_rollback_segs a,v$rollstat b
where a.SEGMENT_ID = b.USN;
timing stop Rollback;
set heading off;
timing start Params;
select '******************************************************' from dual;
select '**** PARALLELISM Settings ****' from dual;
select '******************************************************' from dual;
select decode(value,1,'LOG PARALLELISM OK','LOG PARALLELISM IS NOT 1') from v$parameter where name = 'log_parallelism';
select decode(value,0,'RECOVERY PARALLELISM OK','RECOVERY PARALLELISM IS NOT 0') from v$parameter where name = 'recovery_parallelism';
select '******************************************************' from dual;
select '**** Database Parameter Settings ****' from dual;
select '******************************************************' from dual;
set heading on;
col Parameter for a35;
col Setting for a50;
select substr(name,1,35) as "Parameter", substr(value,1,50) as "Setting" from v$parameter order by name;
timing stop Params;
timing stop 'Total Duration';
spool off;
set verify on;
-- - - - - - - - - - - - - - - - Script begins here - - - - - - - - - - - - - - - -
-- NAME: RACDIAG.SQL
-- SYS OR INTERNAL USER, CATPARR.SQL ALREADY RUN, PARALLEL QUERY OPTION ON
-- ------------------------------------------------------------------------
-- AUTHOR:
-- Michael Polaski - Oracle Support Services - DataServer Group
-- Copyright 2002, Oracle Corporation
-- ------------------------------------------------------------------------
-- PURPOSE:
-- This script is intended to provide a user friendly guide to troubleshoot RAC
-- hung sessions or slow performance scenerios. The script includes information
-- to gather a variety of important debug information to determine the cause of an
-- RAC hang. The script will create a file called racdiag_.out
-- in your local directory while dumping hang analyze dumps in the user_dump_dest(s)
-- and background_dump_dest(s) on all nodes.
--
-- ------------------------------------------------------------------------
-- DISCLAIMER:
-- This script is provided for educational purposes only. It is NOT
-- supported by Oracle World Wide Technical Support.
-- The script has been tested and appears to work as intended.
-- You should always run new scripts on a test instance initially.
-- ------------------------------------------------------------------------
-- Script output is as follows:
set echo off
set feedback off
column timecol new_value timestamp
column spool_extension new_value suffix
select to_char(sysdate,'Mondd_hhmi') timecol,
'.out' spool_extension from sys.dual;
column output new_value dbname
select value || '_' output
from v$parameter where name = 'db_name';
spool racdiag_&&dbname&?tamp&&suffix
set lines 200
set pagesize 35
set trim on
set trims on
alter session set nls_date_format = 'MON-DD-YYYY HH24:MI:SS';
alter session set timed_statistics = true;
set feedback on
select to_char(sysdate) time from dual;
set numwidth 5
column host_name format a20 tru
select inst_id, instance_name, host_name, version, status, startup_time
from gv$instance
order by inst_id;
set echo on
-- Taking Hang Analyze dumps
-- This may take a little while...
oradebug setmypid
oradebug unlimit
oradebug -g all hanganalyze 3
-- This part may take the longest, you can monitor bdump or udump to see if the
-- file is being generated.
oradebug -g all dump systemstate 266
-- WAITING SESSIONS:
-- The entries that are shown at the top are the sessions that have
-- waited the longest amount of time that are waiting for non-idle wait
-- events (event column). You can research and find out what the wait
-- event indicates (along with its parameters) by checking the Oracle
-- Server Reference Manual or look for any known issues or documentation
-- by searching Metalink for the event name in the search bar. Example
-- (include single quotes): [ 'buffer busy due to global cache' ].
-- Metalink and/or the Server Reference Manual should return some useful
-- information on each type of wait event. The inst_id column shows the
-- instance where the session resides and the SID is the unique identifier
-- for the session (gv$session). The p1, p2, and p3 columns will show
-- event specific information that may be important to debug the problem.
-- To find out what the p1, p2, and p3 indicates see the next section.
-- Items with wait_time of anything other than 0 indicate we do not know
-- how long these sessions have been waiting.
--
set numwidth 10
column state format a7 tru
column event format a25 tru
column last_sql format a40 tru
select sw.inst_id, sw.sid, sw.state, sw.event, sw.seconds_in_wait seconds,
sw.p1, sw.p2, sw.p3, sa.sql_text last_sql
from gv$session_wait sw, gv$session s, gv$sqlarea sa
where sw.event not in
('rdbms ipc message','smon timer','pmon timer',
'SQL*Net message from client','lock manager wait for remote message',
'ges remote message', 'gcs remote message', 'gcs for action', 'client message',
'pipe get', 'null event', 'PX Idle Wait', 'single-task message',
'PX Deq: Execution Msg', 'KXFQ: kxfqdeq - normal deqeue',
'listen endpoint status','slave wait','wakeup time manager')
and sw.seconds_in_wait > 0
and (sw.inst_id = s.inst_id and sw.sid = s.sid)
and (s.inst_id = sa.inst_id and s.sql_address = sa.address)
order by seconds desc;
-- EVENT PARAMETER LOOKUP:
-- This section will give a description of the parameter names of the
-- events seen in the last section. p1test is the parameter value for
-- p1 in the WAITING SESSIONS section while p2text is the parameter
-- value for p3 and p3 text is the parameter value for p3. The
-- parameter values in the first section can be helpful for debugging
-- the wait event.
--
column event format a30 tru
column p1text format a25 tru
column p2text format a25 tru
column p3text format a25 tru
select distinct event, p1text, p2text, p3text
from gv$session_wait sw
where sw.event not in ('rdbms ipc message','smon timer','pmon timer',
'SQL*Net message from client','lock manager wait for remote message',
'ges remote message', 'gcs remote message', 'gcs for action', 'client message',
'pipe get', 'null event', 'PX Idle Wait', 'single-task message',
'PX Deq: Execution Msg', 'KXFQ: kxfqdeq - normal deqeue',
'listen endpoint status','slave wait','wakeup time manager')
and seconds_in_wait > 0
order by event;
-- GES LOCK BLOCKERS:
-- This section will show us any sessions that are holding locks that
-- are blocking other users. The inst_id will show us the instance that
-- the session resides on while the sid will be a unique identifier for
-- the session. The grant_level will show us how the GES lock is granted to
-- the user. The request_level will show us what status we are trying to obtain.
-- The lockstate column will show us what status the lock is in. The last column
-- shows how long this session has been waiting.
--
set numwidth 5
column state format a16 tru;
column event format a30 tru;
select dl.inst_id, s.sid, p.spid, dl.resource_name1,
decode(substr(dl.grant_level,1,8),'KJUSERNL','Null','KJUSERCR','Row-S (SS)',
'KJUSERCW','Row-X (SX)','KJUSERPR','Share','KJUSERPW','S/Row-X (SSX)',
'KJUSEREX','Exclusive',request_level) as grant_level,
decode(substr(dl.request_level,1,8),'KJUSERNL','Null','KJUSERCR','Row-S (SS)',
'KJUSERCW','Row-X (SX)','KJUSERPR','Share','KJUSERPW','S/Row-X (SSX)',
'KJUSEREX','Exclusive',request_level) as request_level,
decode(substr(dl.state,1,8),'KJUSERGR','Granted','KJUSEROP','Opening',
'KJUSERCA','Canceling','KJUSERCV','Converting') as state,
s.sid, sw.event, sw.seconds_in_wait sec
from gv$ges_enqueue dl, gv$process p, gv$session s, gv$session_wait sw
where blocker = 1
and (dl.inst_id = p.inst_id and dl.pid = p.spid)
and (p.inst_id = s.inst_id and p.addr = s.paddr)
and (s.inst_id = sw.inst_id and s.sid = sw.sid)
order by sw.seconds_in_wait desc;
-- GES LOCK WAITERS:
-- This section will show us any sessions that are waiting for locks that
-- are blocked by other users. The inst_id will show us the instance that
-- the session resides on while the sid will be a unique identifier for
-- the session. The grant_level will show us how the GES lock is granted to
-- the user. The request_level will show us what status we are trying to obtain.
-- The lockstate column will show us what status the lock is in. The last column
-- shows how long this session has been waiting.
--
set numwidth 5
column state format a16 tru;
column event format a30 tru;
select dl.inst_id, s.sid, p.spid, dl.resource_name1,
decode(substr(dl.grant_level,1,8),'KJUSERNL','Null','KJUSERCR','Row-S (SS)',
'KJUSERCW','Row-X (SX)','KJUSERPR','Share','KJUSERPW','S/Row-X (SSX)',
'KJUSEREX','Exclusive',request_level) as grant_level,
decode(substr(dl.request_level,1,8),'KJUSERNL','Null','KJUSERCR','Row-S (SS)',
'KJUSERCW','Row-X (SX)','KJUSERPR','Share','KJUSERPW','S/Row-X (SSX)',
'KJUSEREX','Exclusive',request_level) as request_level,
decode(substr(dl.state,1,8),'KJUSERGR','Granted','KJUSEROP','Opening',
'KJUSERCA','Cancelling','KJUSERCV','Converting') as state,
s.sid, sw.event, sw.seconds_in_wait sec
from gv$ges_enqueue dl, gv$process p, gv$session s, gv$session_wait sw
where blocked = 1
and (dl.inst_id = p.inst_id and dl.pid = p.spid)
and (p.inst_id = s.inst_id and p.addr = s.paddr)
and (s.inst_id = sw.inst_id and s.sid = sw.sid)
order by sw.seconds_in_wait desc;
-- LOCAL ENQUEUES:
-- This section will show us if there are any local enqueues. The inst_id will
-- show us the instance that the session resides on while the sid will be a
-- unique identifier for. The addr column will show the lock address. The type
-- will show the lock type. The id1 and id2 columns will show specific parameters
-- for the lock type.
--
set numwidth 12
column event format a12 tru
select l.inst_id, l.sid, l.addr, l.type, l.id1, l.id2,
decode(l.block,0,'blocked',1,'blocking',2,'global') block,
sw.event, sw.seconds_in_wait sec
from gv$lock l, gv$session_wait sw
where (l.sid = sw.sid and l.inst_id = sw.inst_id)
and l.block in (0,1)
order by l.type, l.inst_id, l.sid;
-- LATCH HOLDERS:
-- If there is latch contention or 'latch free' wait events in the WAITING
-- SESSIONS section we will need to find out which proceseses are holding
-- latches. The inst_id will show us the instance that the session resides
-- on while the sid will be a unique identifier for. The username column
-- will show the session's username. The os_user column will show the os
-- user that the user logged in as. The name column will show us the type
-- of latch being waited on. You can search Metalink for the latch name in
-- the search bar. Example (include single quotes):
-- [ 'library cache' latch ]. Metalink should return some useful information
-- on the type of latch.
--
set numwidth 5
select distinct lh.inst_id, s.sid, s.username, p.username os_user, lh.name
from gv$latchholder lh, gv$session s, gv$process p
where (lh.sid = s.sid and lh.inst_id = s.inst_id)
and (s.inst_id = p.inst_id and s.paddr = p.addr)
order by lh.inst_id, s.sid;
-- LATCH STATS:
-- This view will show us latches with less than optimal hit ratios
-- The inst_id will show us the instance for the particular latch. The
-- latch_name column will show us the type of latch. You can search Metalink
-- for the latch name in the search bar. Example (include single quotes):
-- [ 'library cache' latch ]. Metalink should return some useful information
-- on the type of latch. The hit_ratio shows the percentage of time we
-- successfully acquired the latch.
--
column latch_name format a30 tru
select inst_id, name latch_name,
round((gets-misses)/decode(gets,0,1,gets),3) hit_ratio,
round(sleeps/decode(misses,0,1,misses),3) "SLEEPS/MISS"
from gv$latch
where round((gets-misses)/decode(gets,0,1,gets),3) < .99
and gets != 0
order by round((gets-misses)/decode(gets,0,1,gets),3);
-- No Wait Latches:
--
select inst_id, name latch_name,
round((immediate_gets/(immediate_gets+immediate_misses)), 3) hit_ratio,
round(sleeps/decode(immediate_misses,0,1,immediate_misses),3) "SLEEPS/MISS"
from gv$latch
where round((immediate_gets/(immediate_gets+immediate_misses)), 3) < .99
and immediate_gets + immediate_misses > 0
order by round((immediate_gets/(immediate_gets+immediate_misses)), 3);
-- GLOBAL CACHE CR PERFORMANCE
-- This shows the average latency of a consistent block request.
-- AVG CR BLOCK RECEIVE TIME should typically be about 15 milliseconds depending
-- on your system configuration and volume, is the average latency of a
-- consistent-read request round-trip from the requesting instance to the holding
-- instance and back to the requesting instance. If your CPU has limited idle time
-- and your system typically processes long-running queries, then the latency may
-- be higher. However, it is possible to have an average latency of less than one
-- millisecond with User-mode IPC. Latency can be influenced by a high value for
-- the DB_MULTI_BLOCK_READ_COUNT parameter. This is because a requesting process
-- can issue more than one request for a block depending on the setting of this
-- parameter. Correspondingly, the requesting process may wait longer. Also check
-- interconnect badwidth, OS tcp settings, and OS udp settings if
-- AVG CR BLOCK RECEIVE TIME is high.
--
set numwidth 20
column "AVG CR BLOCK RECEIVE TIME (ms)" format 9999999.9
select b1.inst_id, b2.value "GCS CR BLOCKS RECEIVED",
b1.value "GCS CR BLOCK RECEIVE TIME",
((b1.value / b2.value) * 10) "AVG CR BLOCK RECEIVE TIME (ms)"
from gv$sysstat b1, gv$sysstat b2
where b1.name = 'global cache cr block receive time' and
b2.name = 'global cache cr blocks received' and b1.inst_id = b2.inst_id
or b1.name = 'gc cr block receive time' and
b2.name = 'gc cr blocks received' and b1.inst_id = b2.inst_id ;
-- GLOBAL CACHE LOCK PERFORMANCE
-- This shows the average global enqueue get time.
-- Typically AVG GLOBAL LOCK GET TIME should be 20-30 milliseconds. the elapsed
-- time for a get includes the allocation and initialization of a new global
-- enqueue. If the average global enqueue get (global cache get time) or average
-- global enqueue conversion times are excessive, then your system may be
-- experiencing timeouts. See the 'WAITING SESSIONS', 'GES LOCK BLOCKERS',
-- 'GES LOCK WAITERS', and 'TOP 10 WAIT EVENTS ON SYSTEM' sections if the
-- AVG GLOBAL LOCK GET TIME is high.
--
set numwidth 20
column "AVG GLOBAL LOCK GET TIME (ms)" format 9999999.9
select b1.inst_id, (b1.value + b2.value) "GLOBAL LOCK GETS",
b3.value "GLOBAL LOCK GET TIME",
(b3.value / (b1.value + b2.value) * 10) "AVG GLOBAL LOCK GET TIME (ms)"
from gv$sysstat b1, gv$sysstat b2, gv$sysstat b3
where b1.name = 'global lock sync gets' and
b2.name = 'global lock async gets' and b3.name = 'global lock get time'
and b1.inst_id = b2.inst_id and b2.inst_id = b3.inst_id
or b1.name = 'global enqueue gets sync' and
b2.name = 'global enqueue gets async' and b3.name = 'global enqueue get time'
and b1.inst_id = b2.inst_id and b2.inst_id = b3.inst_id;
-- RESOURCE USAGE
-- This section will show how much of our resources we have used.
--
set numwidth 8
select inst_id, resource_name, current_utilization, max_utilization,
initial_allocation
from gv$resource_limit
where max_utilization > 0
order by inst_id, resource_name;
-- DLM TRAFFIC INFORMATION
-- This section shows how many tickets are available in the DLM. If the
-- TCKT_WAIT columns says "YES" then we have run out of DLM tickets which could
-- cause a DLM hang. Make sure that you also have enough TCKT_AVAIL.
--
set numwidth 5
select * from gv$dlm_traffic_controller
order by TCKT_AVAIL;
-- DLM MISC
--
set numwidth 10
select * from gv$dlm_misc;
-- LOCK CONVERSION DETAIL:
-- This view shows the types of lock conversion being done on each instance.
--
select * from gv$lock_activity;
-- TOP 10 WRITE PINGING/FUSION OBJECTS
-- This view shows the top 10 objects for write pings accross instances.
-- The inst_id column shows the node that the block was pinged on. The name
-- column shows the object name of the offending object. The file# shows the
-- offending file number (gc_files_to_locks). The STATUS column will show the
-- current status of the pinged block. The READ_PINGS will show us read converts
-- and the WRITE_PINGS will show us objects with write converts. Any rows that
-- show up are objects that are concurrently accessed across more than 1 instance.
--
set numwidth 8
column name format a20 tru
column kind format a10 tru
select inst_id, name, kind, file#, status, BLOCKS,
READ_PINGS, WRITE_PINGS
from (select p.inst_id, p.name, p.kind, p.file#, p.status,
count(p.block#) BLOCKS, sum(p.forced_reads) READ_PINGS,
sum(p.forced_writes) WRITE_PINGS
from gv$ping p, gv$datafile df
where p.file# = df.file# (+)
group by p.inst_id, p.name, p.kind, p.file#, p.status
order by sum(p.forced_writes) desc)
where rownum < 11
order by WRITE_PINGS desc;
-- TOP 10 READ PINGING/FUSION OBJECTS
-- This view shows the top 10 objects for read pings. The inst_id column shows
-- the node that the block was pinged on. The name column shows the object name
-- of the offending object. The file# shows the offending file number
-- (gc_files_to_locks). The STATUS column will show the current status of the
-- pinged block. The READ_PINGS will show us read converts and the WRITE_PINGS
-- will show us objects with write converts. Any rows that show up are objects
-- that are concurrently accessed across more than 1 instance.
--
set numwidth 8
column name format a20 tru
column kind format a10 tru
select inst_id, name, kind, file#, status, BLOCKS,
READ_PINGS, WRITE_PINGS
from (select p.inst_id, p.name, p.kind, p.file#, p.status,
count(p.block#) BLOCKS, sum(p.forced_reads) READ_PINGS,
sum(p.forced_writes) WRITE_PINGS
from gv$ping p, gv$datafile df
where p.file# = df.file# (+)
group by p.inst_id, p.name, p.kind, p.file#, p.status
order by sum(p.forced_reads) desc)
where rownum < 11
order by READ_PINGS desc;
-- TOP 10 FALSE PINGING OBJECTS
-- This view shows the top 10 objects for false pings. This can be avoided by
-- better gc_files_to_locks configuration. The inst_id column shows the node
-- that the block was pinged on. The name column shows the object name of the
-- offending object. The file# shows the offending file number
-- (gc_files_to_locks). The STATUS column will show the current status of the
-- pinged block. The READ_PINGS will show us read converts and the WRITE_PINGS
-- will show us objects with write converts. Any rows that show up are objects
-- that are concurrently accessed across more than 1 instance.
--
set numwidth 8
column name format a20 tru
column kind format a10 tru
select inst_id, name, kind, file#, status, BLOCKS,
READ_PINGS, WRITE_PINGS
from (select p.inst_id, p.name, p.kind, p.file#, p.status,
count(p.block#) BLOCKS, sum(p.forced_reads) READ_PINGS,
sum(p.forced_writes) WRITE_PINGS
from gv$false_ping p, gv$datafile df
where p.file# = df.file# (+)
group by p.inst_id, p.name, p.kind, p.file#, p.status
order by sum(p.forced_writes) desc)
where rownum < 11
order by WRITE_PINGS desc;
-- INITIALIZATION PARAMETERS:
-- Non-default init parameters for each node.
--
set numwidth 5
column name format a30 tru
column value format a50 wra
column description format a60 tru
select inst_id, name, value, description
from gv$parameter
where isdefault = 'FALSE'
order by inst_id, name;
-- TOP 10 WAIT EVENTS ON SYSTEM
-- This view will provide a summary of the top wait events in the db.
--
set numwidth 10
column event format a25 tru
select inst_id, event, time_waited, total_waits, total_timeouts
from (select inst_id, event, time_waited, total_waits, total_timeouts
from gv$system_event where event not in ('rdbms ipc message','smon timer',
'pmon timer', 'SQL*Net message from client','lock manager wait for remote message',
'ges remote message', 'gcs remote message', 'gcs for action', 'client message',
'pipe get', 'null event', 'PX Idle Wait', 'single-task message',
'PX Deq: Execution Msg', 'KXFQ: kxfqdeq - normal deqeue',
'listen endpoint status','slave wait','wakeup time manager')
order by time_waited desc)
where rownum < 11
order by time_waited desc;
-- SESSION/PROCESS REFERENCE:
-- This section is very important for most of the above sections to find out
-- which user/os_user/process is identified to which session/process.
--
set numwidth 7
column event format a30 tru
column program format a25 tru
column username format a15 tru
select p.inst_id, s.sid, s.serial#, p.pid, p.spid, p.program, s.username,
p.username os_user, sw.event, sw.seconds_in_wait sec
from gv$process p, gv$session s, gv$session_wait sw
where (p.inst_id = s.inst_id and p.addr = s.paddr)
and (s.inst_id = sw.inst_id and s.sid = sw.sid)
order by p.inst_id, s.sid;
-- SYSTEM STATISTICS:
-- All System Stats with values of > 0. These can be referenced in the
-- Server Reference Manual
--
set numwidth 5
column name format a60 tru
column value format 9999999999999999999999999
select inst_id, name, value
from gv$sysstat
where value > 0
order by inst_id, name;
-- CURRENT SQL FOR WAITING SESSIONS:
-- Current SQL for any session in the WAITING SESSIONS list
--
set numwidth 5
column sql format a80 wra
select sw.inst_id, sw.sid, sw.seconds_in_wait sec, sa.sql_text sql
from gv$session_wait sw, gv$session s, gv$sqlarea sa
where sw.sid = s.sid (+)
and sw.inst_id = s.inst_id (+)
and s.sql_address = sa.address
and sw.event not in ('rdbms ipc message','smon timer','pmon timer',
'SQL*Net message from client','lock manager wait for remote message',
'ges remote message', 'gcs remote message', 'gcs for action', 'client message',
'pipe get', 'null event', 'PX Idle Wait', 'single-task message',
'PX Deq: Execution Msg', 'KXFQ: kxfqdeq - normal deqeue',
'listen endpoint status','slave wait','wakeup time manager')
and seconds_in_wait > 0
order by sw.seconds_in_wait desc;
-- Taking Hang Analyze dumps
-- This may take a little while...
oradebug setmypid
oradebug unlimit
oradebug -g all hanganalyze 3
-- This part may take the longest, you can monitor bdump or udump to see if the
-- file is being generated.
oradebug -g all dump systemstate 266
set echo off
select to_char(sysdate) time from dual;
spool off
-- ---------------------------------------------------------------------------
Prompt;
Prompt racdiag output files have been written to:;
Prompt;
host pwd
Prompt alert log and trace files are located in:;
column host_name format a12 tru
column name format a20 tru
column value format a60 tru
select distinct i.host_name, p.name, p.value
from gv$instance i, gv$parameter p
where p.inst_id = i.inst_id (+)
and p.name like '%_dump_dest'
and p.name != 'core_dump_dest';
-- - - - - - - - - - - - - - - - Script ends here - - - - - - - - - - - - - - - -
-------------------------------------------------------------------------------------------------
-- Script : compression_effect_02.sql
-------------------------------------------------------------------------------------------------
-- THIS SCRIPT DEMONSTRATES THE EFFECT OF COMPRESSION, FOR BULK INSERTS
--
-- Author : Riyaj Shamsudeen
-- No implied or explicit warranty !
-------------------------------------------------------------------------------------------------
set serveroutput on size 1000000
prompt Test case : IOTs to reduce redo : Bulk inserts
set timing off
set feedback off
drop table ilp_activity_heap;
create table ilp_activity_heap
(
item number not null,
period number not null,
location number not null,
item_type number not null,
sales_units number(*,8),
sales_price number(*,8),
ap_units number (*,8),
ap_price number(*,8),
fc_units number (*,8),
fc_price number(*,8)
)
nologging
storage (initial 10M next 10M pctincrease 0)
;
create unique index ilp_act_heap_i1 on ilp_activity_heap ( item,location,period,item_type) nologging;
alter table ilp_activity_heap add (constraint ilp_activity_heap_pk primary key ( item,location,period,item_type) );
drop type ilp_activity_table
/
create or replace type ilp_activity_type as object
(
item number ,
period number ,
location number ,
item_type number,
sales_units number,
sales_price number,
ap_units number,
ap_price number,
fc_units number ,
fc_price number
)
/
create or replace type ilp_activity_table is table of ilp_activity_type
/
set feedback on
declare
i number;
l_begin_redo_size number;
l_end_redo_size number;
l_generated_redo number;
l_begin_com_clnout number;
l_end_com_clnout number;
l_begin_time number;
l_end_time number;
l_elapsed_time number;
type item_tab is table of ilp_activity_heap.item%TYPE;
type period_tab is table of ilp_activity_heap.period%TYPE;
type location_tab is table of ilp_activity_heap.location%TYPE;
type item_type_tab is table of ilp_activity_heap.item_type%TYPE;
type sales_units_tab is table of ilp_activity_heap.sales_units%TYPE;
type sales_price_tab is table of ilp_activity_heap.sales_price%TYPE;
type ap_units_tab is table of ilp_activity_heap.ap_units%TYPE;
type ap_price_tab is table of ilp_activity_heap.ap_price%TYPE;
type fc_units_tab is table of ilp_activity_heap.fc_units%TYPE;
type fc_price_tab is table of ilp_activity_heap.fc_price%TYPE;
l_item_tab item_tab := item_tab ();
l_period_tab period_tab:= period_tab();
l_location_tab location_tab:=location_tab();
l_item_type_tab item_type_tab:=item_type_tab();
l_sales_units_tab sales_units_tab:=sales_units_tab();
l_sales_price_tab sales_price_tab:=sales_price_tab();
l_ap_units_tab ap_units_tab:=ap_units_tab();
l_ap_price_tab ap_price_tab:=ap_price_tab();
l_fc_units_tab fc_units_tab:=fc_units_tab();
l_fc_price_tab fc_price_tab:=fc_price_tab();
l_index number := 1;
begin
l_item_tab.extend (25000);
l_period_tab.extend (25000);
l_location_tab.extend (25000);
l_item_type_tab.extend (25000);
l_sales_units_tab.extend (25000);
l_sales_price_tab.extend (25000);
l_ap_units_tab.extend (25000);
l_ap_price_tab.extend (25000);
l_fc_units_tab.extend (25000);
l_fc_price_tab.extend (25000);
for i in 1 .. 2 loop
for j in 1 .. 5 loop
for k in 1 .. 500 loop
for l in 1 .. 5 loop
l_item_tab (l_index) := i;
l_period_tab (l_index) := j;
l_location_tab (l_index) := k;
l_item_type_tab (l_index) := l;
l_sales_units_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_sales_price_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_ap_units_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_ap_price_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_fc_units_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_fc_price_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_index := l_index +1;
end loop;
end loop;
end loop;
end loop;
select get_my_statistics('redo size'), get_my_statistics('redo entries')
into l_begin_redo_size , l_begin_com_clnout from dual;
l_begin_time := dbms_utility.get_time;
FORALL j in l_item_tab.first .. l_item_tab.last
insert into ilp_activity_heap
values
(
l_item_tab (j),
l_period_tab (j),
l_location_tab (j) ,
l_item_type_tab (j),
l_sales_units_tab (j),
l_sales_price_tab (j),
l_ap_units_tab (j),
l_ap_price_tab (j) ,
l_fc_units_tab (j) ,
l_fc_price_tab (j)
);
commit;
select get_my_statistics('redo size'), get_my_statistics('redo entries')
into l_end_redo_size , l_end_com_clnout from dual;
l_end_time := dbms_utility.get_time;
dbms_output.put_line ('Total redo generated for heap with primary key, using bulk insert ==>'||to_char( l_end_redo_size - l_begin_redo_size));
dbms_output.put_line ('Total redo entries generated ==>'||to_char( l_end_com_clnout - l_begin_com_clnout));
dbms_output.put_line ('Elapsed time in seconds ==>'||to_char(trunc(( l_end_time-l_begin_time)/100, 2 )));
end;
/
set feedback off
drop table ilp_activity_iot;
create table ilp_activity_iot
(
item number not null,
period number not null,
location number not null,
item_type number not null,
sales_units number(*,8),
sales_price number(*,8),
ap_units number (*,8),
ap_price number(*,8),
fc_units number (*,8),
fc_price number(*,8),
constraint ilp_activity_iot_pk primary key ( item, location, period, item_type )
)
organization index
;
drop type ilp_activity_table
/
create or replace type ilp_activity_type as object
(
item number ,
period number ,
location number ,
item_type number,
sales_units number,
sales_price number,
ap_units number,
ap_price number,
fc_units number ,
fc_price number
)
/
create or replace type ilp_activity_table is table of ilp_activity_type
/
set feedback on
declare
i number;
l_begin_redo_size number;
l_end_redo_size number;
l_generated_redo number;
l_begin_com_clnout number;
l_end_com_clnout number;
l_begin_time number;
l_end_time number;
l_elapsed_time number;
type item_tab is table of ilp_activity_heap.item%TYPE;
type period_tab is table of ilp_activity_heap.period%TYPE;
type location_tab is table of ilp_activity_heap.location%TYPE;
type item_type_tab is table of ilp_activity_heap.item_type%TYPE;
type sales_units_tab is table of ilp_activity_heap.sales_units%TYPE;
type sales_price_tab is table of ilp_activity_heap.sales_price%TYPE;
type ap_units_tab is table of ilp_activity_heap.ap_units%TYPE;
type ap_price_tab is table of ilp_activity_heap.ap_price%TYPE;
type fc_units_tab is table of ilp_activity_heap.fc_units%TYPE;
type fc_price_tab is table of ilp_activity_heap.fc_price%TYPE;
l_item_tab item_tab := item_tab ();
l_period_tab period_tab:= period_tab();
l_location_tab location_tab:=location_tab();
l_item_type_tab item_type_tab:=item_type_tab();
l_sales_units_tab sales_units_tab:=sales_units_tab();
l_sales_price_tab sales_price_tab:=sales_price_tab();
l_ap_units_tab ap_units_tab:=ap_units_tab();
l_ap_price_tab ap_price_tab:=ap_price_tab();
l_fc_units_tab fc_units_tab:=fc_units_tab();
l_fc_price_tab fc_price_tab:=fc_price_tab();
l_index number := 1;
begin
l_item_tab.extend (25000);
l_period_tab.extend (25000);
l_location_tab.extend (25000);
l_item_type_tab.extend (25000);
l_sales_units_tab.extend (25000);
l_sales_price_tab.extend (25000);
l_ap_units_tab.extend (25000);
l_ap_price_tab.extend (25000);
l_fc_units_tab.extend (25000);
l_fc_price_tab.extend (25000);
for i in 1 .. 2 loop
for j in 1 .. 5 loop
for k in 1 .. 500 loop
for l in 1 .. 5 loop
l_item_tab (l_index) := i;
l_period_tab (l_index) := j;
l_location_tab (l_index) := k;
l_item_type_tab (l_index) := l;
l_sales_units_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_sales_price_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_ap_units_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_ap_price_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_fc_units_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_fc_price_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_index := l_index +1;
end loop;
end loop;
end loop;
end loop;
select get_my_statistics('redo size'), get_my_statistics('redo entries')
into l_begin_redo_size , l_begin_com_clnout from dual;
l_begin_time := dbms_utility.get_time;
FORALL j in l_item_tab.first .. l_item_tab.last
insert into ilp_activity_iot
values
(
l_item_tab (j),
l_period_tab (j),
l_location_tab (j) ,
l_item_type_tab (j),
l_sales_units_tab (j),
l_sales_price_tab (j),
l_ap_units_tab (j),
l_ap_price_tab (j) ,
l_fc_units_tab (j) ,
l_fc_price_tab (j)
);
commit;
select get_my_statistics('redo size'), get_my_statistics('redo entries')
into l_end_redo_size , l_end_com_clnout from dual;
l_end_time := dbms_utility.get_time;
dbms_output.put_line ('Total redo generated for iot with zero compression, using bulk insert ==>'||to_char( l_end_redo_size - l_begin_redo_size));
dbms_output.put_line ('Total redo entries generated ==>'||to_char( l_end_com_clnout - l_begin_com_clnout));
dbms_output.put_line ('Elapsed time in seconds ==>'||to_char(trunc(( l_end_time-l_begin_time)/100, 2 )));
end;
/
set feedback off
drop table ilp_activity_iot;
create table ilp_activity_iot
(
item number not null,
period number not null,
location number not null,
item_type number not null,
sales_units number(*,8),
sales_price number(*,8),
ap_units number (*,8),
ap_price number(*,8),
fc_units number (*,8),
fc_price number(*,8),
constraint ilp_activity_iot_pk primary key ( item, location, period, item_type )
)
organization index
compress 1
;
drop type ilp_activity_table
/
create or replace type ilp_activity_type as object
(
item number ,
period number ,
location number ,
item_type number,
sales_units number,
sales_price number,
ap_units number,
ap_price number,
fc_units number ,
fc_price number
)
/
create or replace type ilp_activity_table is table of ilp_activity_type
/
set feedback on
declare
i number;
l_begin_redo_size number;
l_end_redo_size number;
l_generated_redo number;
l_begin_com_clnout number;
l_end_com_clnout number;
l_begin_time number;
l_end_time number;
l_elapsed_time number;
type item_tab is table of ilp_activity_heap.item%TYPE;
type period_tab is table of ilp_activity_heap.period%TYPE;
type location_tab is table of ilp_activity_heap.location%TYPE;
type item_type_tab is table of ilp_activity_heap.item_type%TYPE;
type sales_units_tab is table of ilp_activity_heap.sales_units%TYPE;
type sales_price_tab is table of ilp_activity_heap.sales_price%TYPE;
type ap_units_tab is table of ilp_activity_heap.ap_units%TYPE;
type ap_price_tab is table of ilp_activity_heap.ap_price%TYPE;
type fc_units_tab is table of ilp_activity_heap.fc_units%TYPE;
type fc_price_tab is table of ilp_activity_heap.fc_price%TYPE;
l_item_tab item_tab := item_tab ();
l_period_tab period_tab:= period_tab();
l_location_tab location_tab:=location_tab();
l_item_type_tab item_type_tab:=item_type_tab();
l_sales_units_tab sales_units_tab:=sales_units_tab();
l_sales_price_tab sales_price_tab:=sales_price_tab();
l_ap_units_tab ap_units_tab:=ap_units_tab();
l_ap_price_tab ap_price_tab:=ap_price_tab();
l_fc_units_tab fc_units_tab:=fc_units_tab();
l_fc_price_tab fc_price_tab:=fc_price_tab();
l_index number := 1;
begin
l_item_tab.extend (25000);
l_period_tab.extend (25000);
l_location_tab.extend (25000);
l_item_type_tab.extend (25000);
l_sales_units_tab.extend (25000);
l_sales_price_tab.extend (25000);
l_ap_units_tab.extend (25000);
l_ap_price_tab.extend (25000);
l_fc_units_tab.extend (25000);
l_fc_price_tab.extend (25000);
for i in 1 .. 2 loop
for j in 1 .. 5 loop
for k in 1 .. 500 loop
for l in 1 .. 5 loop
l_item_tab (l_index) := i;
l_period_tab (l_index) := j;
l_location_tab (l_index) := k;
l_item_type_tab (l_index) := l;
l_sales_units_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_sales_price_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_ap_units_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_ap_price_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_fc_units_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_fc_price_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_index := l_index +1;
end loop;
end loop;
end loop;
end loop;
select get_my_statistics('redo size'), get_my_statistics('redo entries')
into l_begin_redo_size , l_begin_com_clnout from dual;
l_begin_time := dbms_utility.get_time;
FORALL j in l_item_tab.first .. l_item_tab.last
insert into ilp_activity_iot
values
(
l_item_tab (j),
l_period_tab (j),
l_location_tab (j) ,
l_item_type_tab (j),
l_sales_units_tab (j),
l_sales_price_tab (j),
l_ap_units_tab (j),
l_ap_price_tab (j) ,
l_fc_units_tab (j) ,
l_fc_price_tab (j)
);
commit;
select get_my_statistics('redo size'), get_my_statistics('redo entries')
into l_end_redo_size , l_end_com_clnout from dual;
l_end_time := dbms_utility.get_time;
dbms_output.put_line ('Total redo generated for iot with compression 1, using bulk insert ==>'||to_char( l_end_redo_size - l_begin_redo_size));
dbms_output.put_line ('Total redo entries generated ==>'||to_char( l_end_com_clnout - l_begin_com_clnout));
dbms_output.put_line ('Elapsed time in seconds ==>'||to_char(trunc(( l_end_time-l_begin_time)/100, 2 )));
end;
/
set feedback off
drop table ilp_activity_iot;
create table ilp_activity_iot
(
item number not null,
period number not null,
location number not null,
item_type number not null,
sales_units number(*,8),
sales_price number(*,8),
ap_units number (*,8),
ap_price number(*,8),
fc_units number (*,8),
fc_price number(*,8),
constraint ilp_activity_iot_pk primary key ( item, location, period, item_type )
)
organization index
compress 2
;
drop type ilp_activity_table
/
create or replace type ilp_activity_type as object
(
item number ,
period number ,
location number ,
item_type number,
sales_units number,
sales_price number,
ap_units number,
ap_price number,
fc_units number ,
fc_price number
)
/
create or replace type ilp_activity_table is table of ilp_activity_type
/
set feedback on
declare
i number;
l_begin_redo_size number;
l_end_redo_size number;
l_generated_redo number;
l_begin_com_clnout number;
l_end_com_clnout number;
l_begin_time number;
l_end_time number;
l_elapsed_time number;
type item_tab is table of ilp_activity_heap.item%TYPE;
type period_tab is table of ilp_activity_heap.period%TYPE;
type location_tab is table of ilp_activity_heap.location%TYPE;
type item_type_tab is table of ilp_activity_heap.item_type%TYPE;
type sales_units_tab is table of ilp_activity_heap.sales_units%TYPE;
type sales_price_tab is table of ilp_activity_heap.sales_price%TYPE;
type ap_units_tab is table of ilp_activity_heap.ap_units%TYPE;
type ap_price_tab is table of ilp_activity_heap.ap_price%TYPE;
type fc_units_tab is table of ilp_activity_heap.fc_units%TYPE;
type fc_price_tab is table of ilp_activity_heap.fc_price%TYPE;
l_item_tab item_tab := item_tab ();
l_period_tab period_tab:= period_tab();
l_location_tab location_tab:=location_tab();
l_item_type_tab item_type_tab:=item_type_tab();
l_sales_units_tab sales_units_tab:=sales_units_tab();
l_sales_price_tab sales_price_tab:=sales_price_tab();
l_ap_units_tab ap_units_tab:=ap_units_tab();
l_ap_price_tab ap_price_tab:=ap_price_tab();
l_fc_units_tab fc_units_tab:=fc_units_tab();
l_fc_price_tab fc_price_tab:=fc_price_tab();
l_index number := 1;
begin
l_item_tab.extend (25000);
l_period_tab.extend (25000);
l_location_tab.extend (25000);
l_item_type_tab.extend (25000);
l_sales_units_tab.extend (25000);
l_sales_price_tab.extend (25000);
l_ap_units_tab.extend (25000);
l_ap_price_tab.extend (25000);
l_fc_units_tab.extend (25000);
l_fc_price_tab.extend (25000);
for i in 1 .. 2 loop
for j in 1 .. 5 loop
for k in 1 .. 500 loop
for l in 1 .. 5 loop
l_item_tab (l_index) := i;
l_period_tab (l_index) := j;
l_location_tab (l_index) := k;
l_item_type_tab (l_index) := l;
l_sales_units_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_sales_price_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_ap_units_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_ap_price_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_fc_units_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_fc_price_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_index := l_index +1;
end loop;
end loop;
end loop;
end loop;
select get_my_statistics('redo size'), get_my_statistics('redo entries')
into l_begin_redo_size , l_begin_com_clnout from dual;
l_begin_time := dbms_utility.get_time;
FORALL j in l_item_tab.first .. l_item_tab.last
insert into ilp_activity_iot
values
(
l_item_tab (j),
l_period_tab (j),
l_location_tab (j) ,
l_item_type_tab (j),
l_sales_units_tab (j),
l_sales_price_tab (j),
l_ap_units_tab (j),
l_ap_price_tab (j) ,
l_fc_units_tab (j) ,
l_fc_price_tab (j)
);
commit;
select get_my_statistics('redo size'), get_my_statistics('redo entries')
into l_end_redo_size , l_end_com_clnout from dual;
l_end_time := dbms_utility.get_time;
dbms_output.put_line ('Total redo generated for iot with compression 2, using bulk insert ==>'||to_char( l_end_redo_size - l_begin_redo_size));
dbms_output.put_line ('Total redo entries generated ==>'||to_char( l_end_com_clnout - l_begin_com_clnout));
dbms_output.put_line ('Elapsed time in seconds ==>'||to_char(trunc(( l_end_time-l_begin_time)/100, 2 )));
end;
/
set feedback off
drop table ilp_activity_iot;
create table ilp_activity_iot
(
item number not null,
period number not null,
location number not null,
item_type number not null,
sales_units number(*,8),
sales_price number(*,8),
ap_units number (*,8),
ap_price number(*,8),
fc_units number (*,8),
fc_price number(*,8),
constraint ilp_activity_iot_pk primary key ( item, location, period, item_type )
)
organization index
compress 3
;
drop type ilp_activity_table
/
create or replace type ilp_activity_type as object
(
item number ,
period number ,
location number ,
item_type number,
sales_units number,
sales_price number,
ap_units number,
ap_price number,
fc_units number ,
fc_price number
)
/
create or replace type ilp_activity_table is table of ilp_activity_type
/
set feedback on
declare
i number;
l_begin_redo_size number;
l_end_redo_size number;
l_generated_redo number;
l_begin_com_clnout number;
l_end_com_clnout number;
l_begin_time number;
l_end_time number;
l_elapsed_time number;
type item_tab is table of ilp_activity_heap.item%TYPE;
type period_tab is table of ilp_activity_heap.period%TYPE;
type location_tab is table of ilp_activity_heap.location%TYPE;
type item_type_tab is table of ilp_activity_heap.item_type%TYPE;
type sales_units_tab is table of ilp_activity_heap.sales_units%TYPE;
type sales_price_tab is table of ilp_activity_heap.sales_price%TYPE;
type ap_units_tab is table of ilp_activity_heap.ap_units%TYPE;
type ap_price_tab is table of ilp_activity_heap.ap_price%TYPE;
type fc_units_tab is table of ilp_activity_heap.fc_units%TYPE;
type fc_price_tab is table of ilp_activity_heap.fc_price%TYPE;
l_item_tab item_tab := item_tab ();
l_period_tab period_tab:= period_tab();
l_location_tab location_tab:=location_tab();
l_item_type_tab item_type_tab:=item_type_tab();
l_sales_units_tab sales_units_tab:=sales_units_tab();
l_sales_price_tab sales_price_tab:=sales_price_tab();
l_ap_units_tab ap_units_tab:=ap_units_tab();
l_ap_price_tab ap_price_tab:=ap_price_tab();
l_fc_units_tab fc_units_tab:=fc_units_tab();
l_fc_price_tab fc_price_tab:=fc_price_tab();
l_index number := 1;
begin
l_item_tab.extend (25000);
l_period_tab.extend (25000);
l_location_tab.extend (25000);
l_item_type_tab.extend (25000);
l_sales_units_tab.extend (25000);
l_sales_price_tab.extend (25000);
l_ap_units_tab.extend (25000);
l_ap_price_tab.extend (25000);
l_fc_units_tab.extend (25000);
l_fc_price_tab.extend (25000);
for i in 1 .. 2 loop
for j in 1 .. 5 loop
for k in 1 .. 500 loop
for l in 1 .. 5 loop
l_item_tab (l_index) := i;
l_period_tab (l_index) := j;
l_location_tab (l_index) := k;
l_item_type_tab (l_index) := l;
l_sales_units_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_sales_price_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_ap_units_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_ap_price_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_fc_units_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_fc_price_tab (l_index) := trunc(dbms_random.value(1, 100),8);
l_index := l_index +1;
end loop;
end loop;
end loop;
end loop;
select get_my_statistics('redo size'), get_my_statistics('redo entries')
into l_begin_redo_size , l_begin_com_clnout from dual;
l_begin_time := dbms_utility.get_time;
FORALL j in l_item_tab.first .. l_item_tab.last
insert into ilp_activity_iot
values
(
l_item_tab (j),
l_period_tab (j),
l_location_tab (j) ,
l_item_type_tab (j),
l_sales_units_tab (j),
l_sales_price_tab (j),
l_ap_units_tab (j),
l_ap_price_tab (j) ,
l_fc_units_tab (j) ,
l_fc_price_tab (j)
);
commit;
select get_my_statistics('redo size'), get_my_statistics('redo entries')
into l_end_redo_size , l_end_com_clnout from dual;
l_end_time := dbms_utility.get_time;
dbms_output.put_line ('Total redo generated for iot with compression 3, using bulk insert ==>'||to_char( l_end_redo_size - l_begin_redo_size));
dbms_output.put_line ('Total redo entries generated ==>'||to_char( l_end_com_clnout - l_begin_com_clnout));
dbms_output.put_line ('Elapsed time in seconds ==>'||to_char(trunc(( l_end_time-l_begin_time)/100, 2 )));
end;
/
cat status_oem.sh
-- =================================
-- CHECKS STATUS
-- =================================
export ORACLE_SID=oemcc
export ORACLE_UNQNAME=oemcc
export ORACLE_GLOBAL_NAME=OEMCC.LAB
export ORACLE_BASE=/u01/app/oracle
export ORACLE_HOME=$ORACLE_BASE/product/19.3.0/dbhome_1
export ORACLE_HOSTNAME=EMCC
export AGENT_HOME=/u01/app/oracle/agent/agent_13.5.0.0.0
export OMS_HOME=/u01/app/oracle/middleware
sleep 2;
echo '==STATUS:LISTENER============================================'
$ORACLE_HOME/bin/lsnrctl status
sleep 2;
echo '==STATUS:DATABASE============================================'
$ORACLE_HOME/bin/sqlplus /nolog <
connect / as sysdba
SELECT name,open_mode,log_mode FROM v\$database ;
exit;
EOF
sleep 2;
echo '==STATUS:MANAGEMENT-SERVICE=================================='
$OMS_HOME/bin/emctl status oms
sleep 2;
echo '==STATUS:AGENTE=============================================='
$AGENT_HOME/bin/emctl status agent
sleep 2;
echo '====FIM--STATUS=============================================='
######===EXECUTION::OUTPUT===################################################
status_oem.sh
==STATUS:LISTENER============================================
LSNRCTL for Linux: Version 19.0.0.0.0 - Production on 31-JUL-2024 14:27:49
Copyright (c) 1991, 2023, Oracle. All rights reserved.
Connecting to (DESCRIPTION=(ADDRESS=(PROTOCOL=TCP)(HOST=EMCC)(PORT=1521)))
STATUS of the LISTENER
------------------------
Alias LISTENER
Version TNSLSNR for Linux: Version 19.0.0.0.0 - Production
Start Date 12-MAR-2024 13:58:22
Uptime 141 days 0 hr. 29 min. 26 sec
Trace Level off
Security ON: Local OS Authentication
SNMP OFF
Listener Parameter File /u01/app/oracle/product/19.3.0/dbhome_1/network/admin/listener.ora
Listener Log File /u01/app/oracle/diag/tnslsnr/EMCC/listener/alert/log.xml
Listening Endpoints Summary...
(DESCRIPTION=(ADDRESS=(PROTOCOL=tcp)(HOST=EMCC)(PORT=1521)))
(DESCRIPTION=(ADDRESS=(PROTOCOL=ipc)(KEY=EXTPROC1521)))
Services Summary...
Service "oemcc.lab" has 1 instance(s).
Instance "oemcc", status READY, has 1 handler(s) for this service...
Service "oemccXDB.lab" has 1 instance(s).
Instance "oemcc", status READY, has 1 handler(s) for this service...
The command completed successfully
==STATUS:DATABASE============================================
SQL*Plus: Release 19.0.0.0.0 - Production on Wed Jul 31 14:27:51 2024
Version 19.19.0.0.0
Copyright (c) 1982, 2022, Oracle. All rights reserved.
SQL> Connected.
NAME OPEN_MODE LOG_MODE
-------- -------------------- ------------
OEMCC READ WRITE NOARCHIVELOG
SQL> Disconnected from Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.19.0.0.0
==STATUS:MANAGEMENT-SERVICE==================================
Oracle Enterprise Manager Cloud Control 13c Release 5
Copyright (c) 1996, 2021 Oracle Corporation. All rights reserved.
WebTier is Up
Oracle Management Server is Up
JVMD Engine is Up
==STATUS:AGENTE==============================================
Oracle Enterprise Manager Cloud Control 13c Release 5
Copyright (c) 1996, 2021 Oracle Corporation. All rights reserved.
---------------------------------------------------------------
Agent Version : 13.5.0.0.0
OMS Version : 13.5.0.0.0
Protocol Version : 12.1.0.1.0
Agent Home : /u01/app/oracle/agent/agent_inst
Agent Log Directory : /u01/app/oracle/agent/agent_inst/sysman/log
Agent Binaries : /u01/app/oracle/agent/agent_13.5.0.0.0
Core JAR Location : /u01/app/oracle/agent/agent_13.5.0.0.0/jlib
Agent Process ID : 2185201
Parent Process ID : 2185136
Agent URL : https://EMCC:3872/emd/main/
Local Agent URL in NAT : https://EMCC:3872/emd/main/
Repository URL : https://EMCC:4903/empbs/upload
Started at : 2024-03-12 14:02:11
Started by user : oracle
Operating System : Linux version 5.4.17-2136.315.5.el8uek.x86_64 (amd64)
Number of Targets : 36
Last Reload : (none)
Last successful upload : 2024-07-31 14:25:06
Last attempted upload : 2024-07-31 14:25:06
Total Megabytes of XML files uploaded so far : 276.6
Number of XML files pending upload : 0
Size of XML files pending upload(MB) : 0
Available disk space on upload filesystem : 65.34%
Collection Status : Collections enabled
Heartbeat Status : Ok
Last attempted heartbeat to OMS : 2024-07-31 14:27:15
Last successful heartbeat to OMS : 2024-07-31 14:27:15
Next scheduled heartbeat to OMS : 2024-07-31 14:28:15
---------------------------------------------------------------
Agent is Running and Ready
====FIM--STATUS==============================================
cat stop_oem.sh
-- =================================
-- STOP SERVICES
-- =================================
export ORACLE_SID=oemcc
export ORACLE_UNQNAME=oemcc
export ORACLE_GLOBAL_NAME=oemcc.LAB
export ORACLE_BASE=/u01/app/oracle
export ORACLE_HOME=$ORACLE_BASE/product/19.3.0/dbhome_1
export ORACLE_HOSTNAME=EMCC
export AGENT_HOME=/u01/app/oracle/agent/agent_13.5.0.0.0
export OMS_HOME=/u01/app/oracle/middleware
sleep 2;
echo '==STOP:LISTENER============================================'
$ORACLE_HOME/bin/lsnrctl stop
sleep 2;
echo '==STOP:BANCO==============================================='
$ORACLE_HOME/bin/sqlplus /nolog < Connected.
SQL> Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> Disconnected from Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.19.0.0.0
==STOP:MANAGEMENT SERVICE==================================
Oracle Enterprise Manager Cloud Control 13c Release 5
Copyright (c) 1996, 2021 Oracle Corporation. All rights reserved.
Stopping Oracle Management Server...
WebTier Successfully Stopped
Oracle Management Server Successfully Stopped
AdminServer Successfully Stopped
Oracle Management Server is Down
JVMD Engine is Down
==STOP:AGENTE==============================================
Oracle Enterprise Manager Cloud Control 13c Release 5
Copyright (c) 1996, 2021 Oracle Corporation. All rights reserved.
Stopping agent ... stopped.
====FIM--STOP===============================================
cat start_oem.sh
-- =================================
-- START SERVICES
-- =================================
export ORACLE_SID=oemcc
export ORACLE_UNQNAME=oemcc
export ORACLE_GLOBAL_NAME=oemcc.LAB
export ORACLE_BASE=/u01/app/oracle
export ORACLE_HOME=$ORACLE_BASE/product/19.3.0/dbhome_1
export ORACLE_HOSTNAME=EMCC
export AGENT_HOME=/u01/app/oracle/agent/agent_13.5.0.0.0
export OMS_HOME=/u01/app/oracle/middleware
sleep 2;
echo '==START:LISTENER============================================'
$ORACLE_HOME/bin/lsnrctl start
sleep 2;
echo '==START:DATABASE============================================='
$ORACLE_HOME/bin/sqlplus /nolog < Connected to an idle instance.
SQL> ORACLE instance started.
Total System Global Area 8589930576 bytes
Fixed Size 13664336 bytes
Variable Size 2969567232 bytes
Database Buffers 5586812928 bytes
Redo Buffers 19886080 bytes
Database mounted.
Database opened.
SQL>
NAME OPEN_MODE LOG_MODE
------- -------------------- ------------
oemcc READ WRITE NOARCHIVELOG
SQL> Disconnected from Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.19.0.0.0
==START:MANAGEMENT SERVICE==================================
Oracle Enterprise Manager Cloud Control 13c Release 5
Copyright (c) 1996, 2021 Oracle Corporation. All rights reserved.
Starting Oracle Management Server...
WebTier Successfully Started
Oracle Management Server Successfully Started
Oracle Management Server is Up
JVMD Engine is Up
==START:AGENT===============================================
Oracle Enterprise Manager Cloud Control 13c Release 5
Copyright (c) 1996, 2021 Oracle Corporation. All rights reserved.
Starting agent ............. started.
====FIM--START==============================================
oerr
Usage: oerr facility error
Facility is identified by the prefix string in the error message.
For example, if you get ORA-7300, "ora" is the facility and "7300"
is the error. So you should type "oerr ora 7300".
If you get LCD-111, type "oerr lcd 111", and so on.
--=================================
--## For ORA- errors:
--=================================
$ oerr ora 00600
// *Cause: ...
// *Action: ...
--=================================
--## For RMAN- errors:
--=================================
$ oerr rman 03002
// *Cause: ...
// *Action: ...
--=================================
--## For TNS- errors
--=================================
$ oerr tns 12514
// *Cause: ...
// *Action: ...
Criacao de Users no ambiente ORACLE ( PRDORA / PRDCORP / PRDCRIT );
Criacao de Users no ambiente ORACLE ( DSVORA / HMGORA / TSTORA/ TREORA );
--SEMPRE VERIFICAR QUAL O DATAFILE PARA CRIAR A TABLESPACE
select * from v$datafile
-- CRIAR A TABLESPACE PARA ARMAZENAR OS OBJETOS/DADOS DO OWNER DO PROJETO
CREATE TABLESPACE DB DATAFILE '/db_01.dbf' SIZE 100M AUTOEXTEND ON NEXT 100 M MAXSIZE 10048M;
EX:
CREATE TABLESPACE DBFIES_POSGRADUACAO DATAFILE '/oradata/tstora/dbfies_posgraduacao_01.dbf' SIZE 100M AUTOEXTEND ON NEXT 100 M MAXSIZE 10048M ;
-- USUARIO OWNER DOS OBJETOS DB
CREATE USER "DB" IDENTIFIED BY "DC01XJ01EG" ACCOUNT UNLOCK DEFAULT TABLESPACE "TABLESPACEPROJETO" TEMPORARY TABLESPACE "TEMP" PROFILE "DEFAULT";
EX:
CREATE USER "DB" IDENTIFIED BY "DC01XJ01EG" ACCOUNT UNLOCK DEFAULT TABLESPACE "DBFIES_POSGRADUACAO" TEMPORARY TABLESPACE "TEMP" PROFILE "DEFAULT";
-- USUARIO DA APLICACAO
CREATE USER "SYSDB" IDENTIFIED BY "DC01XJ01EG" ACCOUNT UNLOCK DEFAULT TABLESPACE "TABLESPACEPROJETO" TEMPORARY TABLESPACE "TEMP" PROFILE "DEFAULT";
EX:
CREATE USER "SYSDBFIES_POSGRADUACAO" IDENTIFIED BY "DC01XJ01EG" ACCOUNT UNLOCK DEFAULT TABLESPACE "DBFIES_POSGRADUACAO" TEMPORARY TABLESPACE "TEMP" PROFILE "DEFAULT";
-- GRANTS PARA ACESSO
GRANT CREATE SESSION, CONNECT, RESOURCE TO "";
GRANT CREATE SESSION, CONNECT, RESOURCE TO "SYSDBFIESPOSGRADUACAO";
GRANT CREATE SESSION, CONNECT, RESOURCE TO "DBFIES_POSGRADUACAO";
-- EXECUTAR COMO SYSDBA:
GRANT EXECUTE on DBMS_CRYPTO to SYSDBSISU;
GRANT EXECUTE on DBMS_CRYPTO to ISNCRICAO;
GRANT EXECUTE on DBMS_CRYPTO to DBPROUNI_INSCRICAO;
GRANT EXECUTE on DBMS_CRYPTO to SYSDBPROUNIINSCRICAO;
-- CREATE ROLES RO__READ OU RO__WRITE
CREATE ROLE RO_NOMESISTEMA_READ;
CREATE ROLE RO_NOMESISTEMA_WRITE;
-- Script Gerar Grants:
-- Grant nas tabelas
SELECT 'GRANT SELECT, INSERT, UPDATE, DELETE ON '||OWNER||'.'||TABLE_NAME||' TO RDBSISUS;' FROM DBA_TABLES WHERE OWNER='DBSISU';
SELECT 'GRANT SELECT ON '||OWNER||'.'||TABLE_NAME||' TO FELIPELYRA;' FROM DBA_TABLES WHERE OWNER='DBSIGPET';
-- Grant nas views
SELECT 'GRANT SELECT ON '||OWNER||'.'||VIEW_NAME||' TO RDBSISUG;' FROM dba_views WHERE OWNER='DBSISU';
-- Grant nas sequences
SELECT 'GRANT SELECT ON '||SEQUENCE_OWNER||'.'||SEQUENCE_NAME||' TO RDBSISUG;' FROM dba_sequences WHERE SEQUENCE_OWNER='DBSISU';
SELECT 'GRANT SELECT ON '||SEQUENCE_OWNER||'.'||SEQUENCE_NAME||' TO RDBSISUS;' FROM dba_sequences WHERE SEQUENCE_OWNER='DBSISU';
-- Grant execute procedure\fuction
SELECT 'GRANT EXECUTE ON '||OWNER||'.'||OBJECT_NAME||' TO RDBSISUS;' FROM dba_objects WHERE OWNER='DBSISU' AND OBJECT_TYPE IN ('PROCEDURE','FUNCTION');
-- Grant/Revoke system privileges:
grant create any type to "DBPORTALESTUDANTE";
grant unlimited tablespace to "DBPORTALESTUDANTE";
grant unlimited tablespace to ENEM;
grant execute on DBMS_CRYPTO to DBPROUNI_INSCRICAO;
grant create any type to ENEM;
-- Somente ambiente de PRODUCAO
-- Trigger dos sistemas para nao onerar o ambiente de producao.
create or replace
trigger sys.TG_USUARIOS_DG
after logon
on database when (user not in ('SYS','SYSTEM','DBSNMP','SYSDBPORTAL','SYSDBSISU','SYSDBDBSIPI','SYSDBPORTAL','SYSDBPROUNIINSCRICAO','SYSDBPROUNIGESTAO','SYSDBSISUTEC','SYSDBSISUTEC_CONSULTA','SYSDBISF','SYSDBISFGESTAOBI','SYSDBDUMP','SYSDBEGAT','SYSDBISFGESTAO','SYSDBSONAR','SYSEXECUTAETL','USR_INEP','SYSDBSISUMONITOR'))
declare
v_dbrole varchar2(16);
v_rptg_user number;
begin
select database_role into v_dbrole from v$database;
select count(*) into v_rptg_user from dba_role_privs
where grantee = user and granted_role = 'RO_USUARIO_DG';
if ( v_dbrole = 'PRIMARY' and v_rptg_user > 0)
then
raise_application_error(-20022, 'Usuario nao autorizado a conectar ao Banco de Dados Primario.');
end if;
end TG_USUARIOS_DG;
-- Role para bloquer acesso ao ambiente de PRODUCAO;
GRANT RO_USUARIO_DG TO ;
Ex:
GRANT RO_USUARIO_DG TO fernandocardona;
-- string de conexao
TSTORA =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP)(HOST = dsv-oracle.mec.gov.br)(PORT = 1521))
(CONNECT_DATA =
(SERVER = DEDICATED)
(SERVICE_NAME = tstora)
)
)
--=================================
-- Tradicional
--=================================
-- AMBIENTE ORIGEM
## 1) Descobrir a instancia para export ORACLE_SID
[oracle@sisu-ldo-01 ~]$ ps -ef | grep pmon
oracle 4480 1 0 Jul19 ? 01:16:31 ora_pmon_prdora1
## 2) Exportar ORACLE_SID obtido no item 1
export ORACLE_SID=prdora1
## 4) Configurar a instancia:
SQL> SELECT * FROM dba_directories WHERE directory_name = 'TEMP_DIR';
sem registros.
-- Criação do ambiente --
CREATE DIRECTORY TEMP_DIR as '/oratmp';
GRANT READ, WRITE ON DIRECTORY TEMP_DIR TO USER;
-- Verificação
SELECT * FROM dba_directories WHERE directory_name = 'TEMP_DIR';
OWNER DIRECTORY_NAME DIRECTORY_PATH
----------- -------------------- --------------------------------------
SYS TEMP_DIR /oratmp
## 5) Processo de Exportação
expdp userid=\'/ as sysdba\' DIRECTORY=TEMP_DIR DUMPFILE=arquivo.dmp LOGFILE=arquivo.log SCHEMAS=exemplo
## 6) Copiar o backup feito para a maquina destino conforme resultado abaixo
scp arquivo.dmp oracle@11.22.33.44:/oratmp
-- AMBIENTE DESTINO
## 5) ? DROPANDO OS OBJETOS EXISTENTES ATRAV?S
--SELECT PARA DROPAR OBJETOS N?O SE ESQUE?A DE MUDAR O PARAMETRO OWNER
SELECT 'drop '||X.object_type||' '||x.owner||'.'||x.object_name||
CASE WHEN X.object_type = 'TABLE' THEN ' CASCADE CONSTRAINTS' ELSE '' END ||';' as comando
FROM all_objects x where x.owner IN('nomedoschema') and X.object_type <> 'INDEX';
## 6) AMBIENTE DESTINO - Descobrir a instancia para export ORACLE_SID
[oracle@dsv-oracle-ld-01 ~]$ ps -ef | grep pmon
oracle 17748 17712 0 09:31 pts/0 00:00:00 grep pmon
oracle 24870 1 0 Sep29 ? 00:00:19 ora_pmon_desenvolvimento1
oracle 25404 1 0 Sep29 ? 00:00:07 ora_pmon_desenvolvimento2
oracle 26241 1 0 Sep29 ? 00:00:12 ora_pmon_desenvolvimento3
oracle 26771 1 0 Sep29 ? 00:00:19 ora_pmon_homologacao1
oracle 27206 1 0 Sep29 ? 00:00:07 ora_pmon_homologacao1
## 7) AMBIENTE DESTINO - Exportar ORACLE_SID
export ORACLE_SID=ora_pmon_desenvolvimento3
## 8) AMBIENTE DESTINO - Fazer restore na base destino
impdp userid=\'/ as sysdba\' dumpfile=arquivo.dmp logfile=arquivo.log directory=TEMP_DIR TABLE_EXISTS_ACTION=TRUNCATE
--=================================
-- PARFILE
--=================================
---> EXPORT NO ORACLE
-- 1. Entre no servidor especifico = ssh rac-ldo-01-s
sudo su - oracle
ps -ef | grep pmon
-- 2. Verificar nome da instancia setar o profile na instancia desejada
echo $ORACLE_SID (CONFIRMA SE ESTA NA INSTANCIA )
-- 3. Acessar o diretorio
cd /oratmp/parfile
-- 4. criar o parfile de export com o numero do chamado.
expdp parfile =/oratmp/parfile/expdp_exemplo.par
SELECT 'drop '||X.object_type||' '||x.owner||'.'||x.object_name||
CASE WHEN X.object_type = 'TABLE' THEN ' CASCADE CONSTRAINTS' ELSE '' END ||';' as comando
FROM all_objects x where x.owner IN('ISF2') and X.object_type <> 'INDEX';
***************************************************************************************
---> IMPORT NO ORACLE
-- 5. criar o parfile de import com o numero do chamado
-- 6. entrar no banco de destino
-- 7. drop do schema na base de destino
impdp parfile=/oratmp/parfile/impdp__exemplo.par
***************************************************************************************
sintaxe de somente a estrutura - expdp -
userid='/ as sysdba'
directory=TEMP_DIR
DUMPFILE=exp_exemplo.dmp
LOGFILE=exp_exemplo.log
SCHEMAS=EXEMPLO
CONTENT=ALL
-- ALL :This is the default value and loads all data and metadata contained in the source.
-- DATA_ONLY :You can load only table row data into existing tables without any metadata with this option.
-- METADATA_ONLY :You can load only database object metadata ( definition ) without table row data
CONSISTENT=Y
COMPRESSION=ALL
/oratmp/backup_db_expdp/parfile.par
***************************************************************************************
--set linesize 121
----------------------------------------------------------------------------------------
-- free.sql
--
-- This SQL Plus script lists freespace by tablespace
------------------------------------------------------------------------------------------
column dummy noprint
column pct_used format 999.9 heading "%|Used"
column name format a35 heading "Tablespace Name"
column Mbytes format 9,999,999,999 heading "Mbytes"
column used format 9,999,999,999 heading "Used"
column free format 9,999,999,999 heading "Free"
column largest format 9,999,999,999 heading "Largest"
col MBYTES_PROVIDEED format 999,999,999 heading "Mbytes Provideed"
column max_size format 9,999,999,999,999 heading "MaxPoss|Mbytes"
column pct_max_used format 999.9 heading "%|Max|Used"
break on report
compute sum of Mbytes on report
compute sum of free on report
compute sum of used on report
compute sum of Max_Size on report
compute sum of mbytes_provideed on report
select (select decode(extent_management, 'LOCAL', '*', ' ') ||
decode(segment_space_management, 'AUTO', 'a ', 'm ')
from dba_tablespaces
where tablespace_name = b.tablespace_name) ||
nvl(b.tablespace_name, nvl(a.tablespace_name, 'UNKOWN')) name,
mbytes_alloc mbytes,
mbytes_alloc - nvl(mbytes_free, 0) used,
nvl(mbytes_free, 0) free,
((mbytes_alloc - nvl(mbytes_free, 0)) / mbytes_alloc) * 100 pct_used,
nvl(largest, 0) largest,
round(mbytes_provideed,2) mbytes_provideed ,
nvl(mbytes_max, mbytes_alloc) Max_Size,
decode(mbytes_max, 0, 0, (mbytes_alloc / mbytes_max) * 100) pct_max_used
from (select sum(bytes) / 1024 /1024 Mbytes_free,
max(bytes) / 1024 /1024 largest,
tablespace_name
from sys.dba_free_space
group by tablespace_name) a,
(select sum(bytes) / 1024 / 1024 Mbytes_alloc,
sum(decode(autoextensible,'YES',maxbytes,bytes)) / 1024 / 1024 Mbytes_max,
(sum(decode(autoextensible,'YES',maxbytes,bytes)) / 1024 / 1024) - (sum(bytes) / 1024 / 1024) mbytes_provideed,
tablespace_name
from sys.dba_data_files
group by tablespace_name
union all
select sum(bytes) / 1024 / 1024 Mbytes_alloc,
sum(decode(autoextensible,'YES',maxbytes,bytes)) / 1024 / 1024 Mbytes_max,
(sum(decode(autoextensible,'YES',maxbytes,bytes)) / 1024 / 1024) - (sum(bytes) / 1024 / 1024) mbytes_provideed,
tablespace_name
from sys.dba_temp_files
group by tablespace_name) b
where a.tablespace_name(+) = b.tablespace_name
order by 1
/
Tablespace Name Mbytes Used Free Used Largest Mbytes Provideed Mbytes Used
----------------------------------- -------------- -------------- -------------- ------ -------------- ---------------- ------------------ ------
*a SYSAUX 2,460 2,297 163 93.4 101 30,308 32,768 7.5
*a USERS 5 1 4 20.0 4 32,763 32,768 .0
*m SYSTEM 1,860 1,854 6 99.7 5 30,908 32,768 5.7
*m TEMP 173 173 0 100.0 0 32,595 32,768 .5
*m UNDOTBS1 840 37 803 4.5 736 31,928 32,768 2.6
-------------- -------------- -------------- ----------------
sum 5,338 4,363 975 158,502
-- VER DIRETORIOS - ORIGEM - DESTINO
select * from dba_directories
============ EXPORT SCHEMAS = PRD =======================================================
-- CRIAR PARFILE
vi expdp_PRDCRIT_FIES_160218.par
userid='/ as sysdba'
directory=BACKUP_DB_EXPDP
DUMPFILE=expdp_FIES_HMG_%U.dmp
LOGFILE=expdp_FIES_HMG.log
SCHEMAS=FIES_GLOBAL,FIES_SEGURANCA,FIES_PREINSCRICAO,FIES_AUDITORIA,FIES_REMANESCENTE,FIES_FINANCIAMENTO
PARALLEL=9
--fazer dump expdp
expdp parfile=/bkp_prdora_exa/backup_db_expdp/expdp_SISU_231118.par
=========== DESTINO =============================================================================================
=== matar sess?es====
SELECT DISTINCT 'ALTER SYSTEM KILL session '''||s.sid||','||S.SERIAL#||',@'||S.INST_ID||''' immediate;'
FROM gv$session s --gv$lock l
,GV$SQL SA
WHERE username LIKE ('%FIES_PREINSCRICAO%');
============ DROPAR OBJETOS DESTINO = HMG ========================================================
DROP USER FIES_SEGURANCA CASCADE
DROP USER FIES_GLOBAL CASCADE
DROP USER FIES_AUDITORIA CASCADE
DROP USER FIES_PREINSCRICAO CASCADE
DROP USER FIES_REMANESCENTE CASCADE
DROP USER FIES_FINANCIAMENTO CASCADE
========== MOVE DESTINO ===================================================================
scp expdp_FIES_HMG.dmp root@10.94.0.30:/mnt/backup/backup_db/backup_trabalho/DSV_dumps
======== setar instancia ==============================
ps -ef | grep pmon
export ORACLE_SID = hmgora2
echo $ORACLE_SID
============ IMPORTAR SHCEMAS DESTINO = HMG =================================================
create impdp.par:
userid='/ as sysdba'
directory=BKPTRABALHO
DUMPFILE=expdp_FIES_HMG_%U.dmp
LOGFILE=impdp_FIES_HMG.log
SCHEMAS=
FIES_SEGURANCA,
FIES_GLOBAL,
FIES_AUDITORIA,
FIES_PREINSCRICAO,
FIES_REMANESCENTE,
FIES_FINANCIAMENTO
============== EXECUTA IMPDP ===================================================================
sqlplus / as sysdba
impdp parfile=/mnt/backup/backup_db/backup_trabalho/parfile/impdp_FIES_HMG.par
SELECT * FROM DBA_ROLE_PRIVS;
SELECT * FROM ROLE_SYS_PRIVS
-- revoke all
select 'REVOKE ' || GRANTED_ROLE || ' FROM ' || GRANTEE || ';' from dba_role_privs where grantee='SCHEMA';
select 'REVOKE ' || PRIVILEGE || ' FROM ' || GRANTEE || ';' from dba_sys_privs where grantee='SCHEMA';
GRANT CREATE TRIGGER TO SCHEMA;
GRANT CREATE JOB TO SCHEMA;
GRANT CREATE PROCEDURE TO SCHEMA;
GRANT CREATE TABLE TO SCHEMA;
GRANT CREATE CREDENTIAL TO SCHEMA;
GRANT CREATE SEQUENCE TO SCHEMA;
GRANT CREATE SYNONYM TO SCHEMA;
GRANT DEBUG ANY PROCEDURE TO SCHEMA;
GRANT CREATE VIEW TO SCHEMA;
GRANT DEBUG CONNECT SESSION TO SCHEMA;
GRANT ALTER SESSION TO SCHEMA;
GRANT CREATE SESSION TO SCHEMA;
--collation
SELECT name,value$ FROM sys.props$ where name = 'NLS_NCHAR_CHARACTERSET' or name = 'NLS_CHARACTERSET' or name = 'NLS_RDBMS_VERSION';
SELECT df.tablespace_name TABLESPACE, df.total_space TOTAL_SPACE,
fs.free_space FREE_SPACE, df.total_space_mb TOTAL_SPACE_MB,
(df.total_space_mb - fs.free_space_mb) USED_SPACE_MB,
fs.free_space_mb FREE_SPACE_MB,
ROUND(100 * (fs.free_space / df.total_space),2) PCT_FREE
FROM (SELECT tablespace_name, SUM(bytes) TOTAL_SPACE,
ROUND(SUM(bytes) / 1048576) TOTAL_SPACE_MB
FROM dba_data_files
GROUP BY tablespace_name) df,
(SELECT tablespace_name, SUM(bytes) FREE_SPACE,
ROUND(SUM(bytes) / 1048576) FREE_SPACE_MB
FROM dba_free_space
GROUP BY tablespace_name) fs
WHERE df.tablespace_name = fs.tablespace_name(+)
ORDER BY fs.tablespace_name;
SELECT df.tablespace_name TABLESPACE, df.total_space TOTAL_SPACE,
fs.free_space FREE_SPACE, df.total_space_mb TOTAL_SPACE_MB,
(df.total_space_mb - fs.free_space_mb) USED_SPACE_MB,
fs.free_space_mb FREE_SPACE_MB,
ROUND(100 * (fs.free_space / df.total_space),2) PCT_FREE
FROM (SELECT tablespace_name, SUM(bytes) TOTAL_SPACE,
ROUND(SUM(bytes) / 1048576) TOTAL_SPACE_MB
FROM dba_data_files
GROUP BY tablespace_name) df,
(SELECT tablespace_name, SUM(bytes) FREE_SPACE,
ROUND(SUM(bytes) / 1048576) FREE_SPACE_MB
FROM dba_free_space
GROUP BY tablespace_name) fs
WHERE df.tablespace_name = fs.tablespace_name(+)
ORDER BY fs.tablespace_name;
column dummy noprint
column pct_used format 999.9 heading "%|Used"
column name format a33 heading "Tablespace Name"
column Mbytes format 9,999,999,999 heading "Mbytes"
column used format 9,999,999,999 heading "Used"
column free format 9,999,999,999 heading "Free"
break on report
compute sum of Mbytes on report
compute sum of free on report
compute sum of used on report
select nvl(b.tablespace_name, nvl(a.tablespace_name, 'UNKOWN')) name,
mbytes_alloc mbytes,
mbytes_alloc - nvl(mbytes_free, 0) used,
nvl(mbytes_free, 0) free,
((mbytes_alloc - nvl(mbytes_free, 0)) / mbytes_alloc) * 100 pct_used
from (select sum(bytes) / 1024 /1024 Mbytes_free ,tablespace_name from sys.dba_free_space group by tablespace_name) a,
(select sum(bytes) / 1024 / 1024 Mbytes_alloc ,tablespace_name from sys.dba_data_files group by tablespace_name
union all
select sum(bytes) / 1024 / 1024 Mbytes_alloc ,tablespace_name from sys.dba_temp_files group by tablespace_name) b
where a.tablespace_name(+) = b.tablespace_name
order by 1
/
Tablespace Name Mbytes Used Free Used
--------------------------------- -------------- -------------- -------------- ------
SYSAUX 2,460 2,293 167 93.2
SYSTEM 1,860 1,854 6 99.7
TEMP 173 173 0 100.0
UNDOTBS1 840 35 805 4.2
USERS 5 1 4 20.0
-------------- -------------- --------------
sum 5,338 4,357 981
SELECT * FROM DBA_PROFILES
WHERE RESOURCE_NAME='PASSWORD_LIFE_TIME';
--WHERE PROFILE = 'SISTEMA';
ALTER USER SYSDBPOWERCENTERFIES PROFILE SISTEMA;
SELECT * FROM DBA_USERS WHERE USERNAME = 'SYSDBPOWERCENTERFIES';
---------------------------------------------------------
--script create
select 'CREATE USER "' || s.NAME || DECODE(s.PASSWORD,'EXTERNAL','" identified EXTERNALLY','" identified by values ''' || s.PASSWORD || '''') ||' DEFAULT TABLESPACE '|| u.DEFAULT_TABLESPACE ||' TEMPORARY TABLESPACE '||u.TEMPORARY_TABLESPACE ||' PROFILE '||u.PROFILE ||';' as COMMAND_1 from sys.USER$ s, DBA_USERS u
where NAME=USERNAME AND NAME LIKE ('SYSDBPLANOCARREIRA');
-- alterar
alter USER "SYSDBPLANOCARREIRA" identified by values 'D62A12CC705940D2'
-- permissoes
SELECT * FROM USER_SYS_PRIVS;
SELECT * FROM USER_TAB_PRIVS;
SELECT * FROM USER_ROLE_PRIVS;
-- hostaname
select host_name from v$instance;
SELECT DISTINCT 'ALTER SYSTEM KILL session '''||s.sid||','||S.SERIAL#||',@'||S.INST_ID||''' immediate;'
FROM gv$session s --gv$lock l
,GV$SQL SA
WHERE username LIKE ('%FIES_PREINSCRICAO%');
select substr(o.object_name,1,25) objeto,
l.session_id session_id,
l.oracle_username ora_user,
l.os_user_name os_user
from dba_objects o, gv$locked_object l
where l.object_id = o.object_id
order by 1,3,4;
select sid, SERIAL#, USERNAME, status from v$session where sid = 16438;
alter system kill session '16438, 5509' immediate;
SELECT p.INST_ID, p.pid, p.serial#, p.spid, p.program
FROM gv$process p
WHERE p.spid is not null
AND NOT EXISTS (SELECT 1 FROM gv$session s WHERE s.inst_id = p.inst_id and s.paddr = p.addr)
AND p.pname is null
ORDER BY p.inst_id
/
SELECT s.username,
s.osuser,
s.sid,
s.serial#,
p.spid,
s.status,
s.machine,
s.program,
TO_CHAR(s.logon_Time,'DD-MON-YYYY HH24:MI:SS') AS logon_time,
s.inst_id
FROM gv$session s
inner join v$process p
on s.paddr = p.addr
WHERE s.status = 'ACTIVE'
and s.type <> 'BACKGROUND';
ALTER SYSTEM KILL SESSION '12345,56789,@2' immediate;
ALTER SYSTEM KILL SESSION '56789,12345,@2' immediate;
SELECT LO.SESSION_ID, LO.PROCESS, LO.ORACLE_USERNAME, O.OWNER, O.OBJECT_NAME
FROM V$LOCKED_OBJECT LO
JOIN DBA_OBJECTS O
ON O.OBJECT_ID = LO.OBJECT_ID;
undefine username
col privilege format a150
select 'grant '||privilege||' on '||owner||'.'||table_name||' to '||grantee||';' privilege from dba_tab_privs where grantee like upper('&&username');
select 'grant '||privilege||' to '||grantee||decode(admin_option,'NO',' ',' with admin option')||';' privilege from dba_sys_privs where grantee like upper('&username');
select 'grant '||granted_role||' to '||grantee||decode(admin_option,'NO',' ',' with admin option')||';' privilege from dba_role_privs where grantee like upper('&username');
ps -ef | grep pmon
export ORACLE_SID=prdoradg
echo $ORACLE_SID
sqlplus
set pages 400 lines 200;
select * from V$FLASH_RECOVERY_AREA_USAGE;
rman target /
CROSSCHECK ARCHIVELOG ALL;
DELETE OBSOLETE;
-- VER LOGS
adrci
show home
set home diag/rdbms/prdoradg/prdoradg
show alert -tail -f
SELECT s.username,
s.osuser,
s.sid,
s.serial#,
p.spid,
s.status,
s.machine,
s.program,
TO_CHAR(s.logon_Time,'DD-MON-YYYY HH24:MI:SS') AS logon_time
FROM v$session s
inner join v$process p
on s.paddr = p.addr
WHERE s.status = 'ACTIVE'
and osuser <> 'oracle';
-- and s.type <> 'BACKGROUND';
SELECT s.username,
s.osuser,
s.sid,
s.serial#,
p.spid,
s.status,
s.machine,
s.program,
TO_CHAR(s.logon_Time,'DD-MON-YYYY HH24:MI:SS') AS logon_time
FROM v$session s
inner join v$process p
on s.paddr = p.addr
WHERE s.status = 'ACTIVE'
and s.type <> 'BACKGROUND';
ALTER SYSTEM KILL SESSION 'sid,serial' IMMEDIATE;
select * from ALL_INDEXES where owner = 'xxx'and table_name = 'yyy';
select distinct index_owner,table_name,COLUMN_NAME from ALL_IND_COLUMNS where index_owner = 'xxx' and table_name = 'yyy';
select * from v$session where status='ACTIVE';
select 'alter system kill session "'||sid||','||serial#||'";' AS matarSessao
from v$session where status in ('SNIPED','INACTIVE','KILLED') AND seconds_in_wait > 14400
and username is not null;
SELECT COUNT(*),USERNAME,MACHINE,SERVICE,CONNECTION_STATUS FROM GV$CPOOL_CONN_INFO
WHERE CONNECTION_STATUS='IDLE'
GROUP BY (CONNECTION_STATUS,SERVICE,MACHINE,USERNAME)
ORDER BY MACHINE;
select sql_text
from v$session ses,
v$sqltext st
where st.address = ses.sql_address
and st.hash_value=ses.sql_hash_value
order by piece;
# O parâmetro DDL_LOCK_TIMEOUT indica o número de segundos que um comando DDL deve aguardar
# para que os bloqueios fiquem disponíveis antes de lançar a mensagem de erro de recurso ocupado.
# add the following code in it:
set serveroutput on
set feedback off
exec dbms_output.put_line('Parameter value in memory:');
col name format a25
col value format a10
SELECT INST_ID, NAME,VALUE,TYPE,ISSYS_MODIFIABLE, ISINSTANCE_MODIFIABLE FROM GV$PARAMETER WHERE name ='ddl_lock_timeout' ;
exec dbms_output.put_line('Parameter value in SPFILE:');
col sid format a10
SELECT SID,NAME,VALUE,TYPE, ISSPECIFIED FROM V$SPPARAMETER WHERE NAME ='ddl_lock_timeout';
# --------------------------------------
# Display the current scan configuration
# --------------------------------------
$ srvctl config scan
SCAN name: exadata-pscan1, Network: 1
Subnet IPv4: 192.168.16.0/255.255.255.0/bondeth0, static
Subnet IPv6:
SCAN 0 IPv4 VIP: 192.168.16.43
SCAN VIP is enabled.
SCAN VIP is individually enabled on nodes:
SCAN VIP is individually disabled on nodes:
SCAN 1 IPv4 VIP: 192.168.16.41
SCAN VIP is enabled.
SCAN VIP is individually enabled on nodes:
SCAN VIP is individually disabled on nodes:
SCAN 2 IPv4 VIP: 192.168.16.42
SCAN VIP is enabled.
SCAN VIP is individually enabled on nodes:
SCAN VIP is individually disabled on nodes:
# --------------------------------------
# Obtain information about SCAN DNS records.
# --------------------------------------
$ nslookup exadata-pscan1
Server: 192.168.16.20
Address: 192.168.16.20#53
Name: exadata-pscan1
Address: 192.168.16.41
Name: exadata-pscan1
Address: 192.168.16.42
Name: exadata-pscan1
Address: 192.168.16.43
Where: 192.168.16.41, 192.168.16.42 e 192.168.16.43 are the SCAN IPs
# --------------------------------------
# Display Cluster Name
# --------------------------------------
$ cd /u01/app/12-18-19-21.3.0/grid/bin/
$.olsnodes -c
exadata-node-cluster
# --------------------------------------
# Display the PUBLIC and VIP Node name.
# --------------------------------------
$ cd /u01/app/12.1.0.2/grid/bin/
$ .olsnodes -n -i
exadatadm01vm011exadata01vm01-vip
exadatadm02vm012exadata02vm01-vip
$./srvctl config nodeapps -a
Network 1 exists
Subnet IPv4: 192.168.16.0/255.255.255.0/bondeth0, static
Subnet IPv6:
Ping Targets:
Network is enabled
Network is individually enabled on nodes:
Network is individually disabled on nodes:
VIP exists: network number 1, hosting node exadatadm01vm01
VIP Name: exadata01vm01-vip
VIP IPv4 Address: 192.168.16.46
VIP IPv6 Address:
VIP is enabled.
VIP is individually enabled on nodes:
VIP is individually disabled on nodes:
VIP exists: network number 1, hosting node exadatadm02vm01
VIP Name: exadata02vm01-vip
VIP IPv4 Address: 192.168.16.47
VIP IPv6 Address:
VIP is enabled.
VIP is individually enabled on nodes:
VIP is individually disabled on nodes:
# --------------------------------------
# Display Private IP information
# --------------------------------------
$./olsnodes -n -i -l -p
exadatadm01vm011172.16.2.63exadata01vm01-vip
Public and private network information are stored in Oracle Cluster Registry (OCR).
$./oifcfg getif
bondeth0 192.168.16.0 global public
ib0 172.16.0.0 global cluster_interconnect
“cluster_interconnect” — Private Interface in Oracle Clusterware
The iflist command queries the operating system to find which network interfaces are present on this node.
The command iflist shows the available interfaces that you can configure with “setif”.
-p parameter displays the type of interface which can be PRIVATE, PUBLIC or UNKNOWN
-n include the subnet mask
$ ./oifcfg iflist -p -n
eth0 192.168.1.0 PRIVATE 255.255.255.0
bondeth0 192.168.16.0 PRIVATE 255.255.255.0
bondeth1 10.70.156.0 PRIVATE 255.255.255.0
ib0 172.16.0.0 PRIVATE 255.255.252.0
ib0 169.254.0.0 UNKNOWN 255.255.0.0
ib1 172.16.0.0 PRIVATE 255.255.252.0
# --------------------------------------
# Network interface configuration
# --------------------------------------
$ ifconfig |grep 192.168*
Ifconfig uses the ioctl access method to get the full address information, which limits hardware addresses to 8 bytes.
Because Infiniband address has 20 bytes, only the first 8 bytes are displayed correctly.
Ifconfig is obsolete! For replacement check ip.
Ifconfig uses the ioctl access method to get the full address information, which limits hardware addresses to 8 bytes.
Because Infiniband address has 20 bytes, only the first 8 bytes are displayed correctly.
Ifconfig is obsolete! For replacement check ip.
Ifconfig uses the ioctl access method to get the full address information, which limits hardware addresses to 8 bytes.
Because Infiniband address has 20 bytes, only the first 8 bytes are displayed correctly.
Ifconfig is obsolete! For replacement check ip.
inet addr:192.168.16.44 Bcast:192.168.16.255 Mask:255.255.255.0
inet addr:192.168.16.46 Bcast:192.168.16.255 Mask:255.255.255.0
inet addr:192.168.16.41 Bcast:192.168.16.255 Mask:255.255.255.0
inet addr:192.168.16.42 Bcast:192.168.16.255 Mask:255.255.255.0
inet addr:192.168.1.82 Bcast:192.168.1.255 Mask:255.255.255.0
Where:
192.168.16.44 – Data IP address
192.168.16.46 – Virtual IP (VIP) address
192.168.16.41 – SCAN IP address
192.168.16.42 – SCAN IP address
192.168.1.82 – Management IP address
[grid@node1 scripts]$ /u01/app/21.0.0.0/grid/oui/prov/resources/scripts/sshUserSetup.sh -user grid -hosts "node1 node2" -noPromptPassphrase -confirm -advanced
The output of this script is also logged into /tmp/sshUserSetup_2024-06-21-12-23-06.log
Hosts are node1 node2
user is grid
Platform:- Linux
Checking if the remote hosts are reachable
PING node1.localdomain (192.168.1.71) 56(84) bytes of data.
64 bytes from node1.localdomain (192.168.1.71): icmp_seq=1 ttl=64 time=0.016 ms
64 bytes from node1.localdomain (192.168.1.71): icmp_seq=2 ttl=64 time=0.027 ms
64 bytes from node1.localdomain (192.168.1.71): icmp_seq=3 ttl=64 time=0.038 ms
64 bytes from node1.localdomain (192.168.1.71): icmp_seq=4 ttl=64 time=0.026 ms
64 bytes from node1.localdomain (192.168.1.71): icmp_seq=5 ttl=64 time=0.038 ms
--- node1.localdomain ping statistics ---
5 packets transmitted, 5 received, 0% packet loss, time 4102ms
rtt min/avg/max/mdev = 0.016/0.029/0.038/0.008 ms
PING node2.localdomain (192.168.1.72) 56(84) bytes of data.
64 bytes from node2.localdomain (192.168.1.72): icmp_seq=1 ttl=64 time=0.382 ms
64 bytes from node2.localdomain (192.168.1.72): icmp_seq=2 ttl=64 time=0.483 ms
64 bytes from node2.localdomain (192.168.1.72): icmp_seq=3 ttl=64 time=0.498 ms
64 bytes from node2.localdomain (192.168.1.72): icmp_seq=4 ttl=64 time=0.615 ms
64 bytes from node2.localdomain (192.168.1.72): icmp_seq=5 ttl=64 time=0.395 ms
--- node2.localdomain ping statistics ---
5 packets transmitted, 5 received, 0% packet loss, time 4093ms
rtt min/avg/max/mdev = 0.382/0.474/0.615/0.087 ms
Remote host reachability check succeeded.
The following hosts are reachable: node1 node2.
The following hosts are not reachable: .
All hosts are reachable. Proceeding further...
firsthost node1
numhosts 2
The script will setup SSH connectivity from the host node1.localdomain to all
the remote hosts. After the script is executed, the user can use SSH to run
commands on the remote hosts or copy files between this host node1.localdomain
and the remote hosts without being prompted for passwords or confirmations.
NOTE 1:
As part of the setup procedure, this script will use ssh and scp to copy
files between the local host and the remote hosts. Since the script does not
store passwords, you may be prompted for the passwords during the execution of
the script whenever ssh or scp is invoked.
NOTE 2:
AS PER SSH REQUIREMENTS, THIS SCRIPT WILL SECURE THE USER HOME DIRECTORY
AND THE .ssh DIRECTORY BY REVOKING GROUP AND WORLD WRITE PRIVILEGES TO THESE
directories.
Do you want to continue and let the script make the above mentioned changes (yes/no)?
Confirmation provided on the command line
The user chose yes
User chose to skip passphrase related questions.
Creating .ssh directory on local host, if not present already
Creating authorized_keys file on local host
Changing permissions on authorized_keys to 644 on local host
Creating known_hosts file on local host
Changing permissions on known_hosts to 644 on local host
Creating config file on local host
If a config file exists already at /home/grid/.ssh/config, it would be backed up to /home/grid/.ssh/config.backup.
Creating .ssh directory and setting permissions on remote host node1
THE SCRIPT WOULD ALSO BE REVOKING WRITE PERMISSIONS FOR group AND others ON THE HOME DIRECTORY FOR grid. THIS IS AN SSH REQUIREMENT.
The script would create ~grid/.ssh/config file on remote host node1. If a config file exists already at ~grid/.ssh/config, it would be backed up to ~grid/.ssh/config.backup.
The user may be prompted for a password here since the script would be running SSH on host node1.
Warning: Permanently added 'node1,192.168.1.71' (ECDSA) to the list of known hosts.
grid@node1's password:
Done with creating .ssh directory and setting permissions on remote host node1.
Creating .ssh directory and setting permissions on remote host node2
THE SCRIPT WOULD ALSO BE REVOKING WRITE PERMISSIONS FOR group AND others ON THE HOME DIRECTORY FOR grid. THIS IS AN SSH REQUIREMENT.
The script would create ~grid/.ssh/config file on remote host node2. If a config file exists already at ~grid/.ssh/config, it would be backed up to ~grid/.ssh/config.backup.
The user may be prompted for a password here since the script would be running SSH on host node2.
Warning: Permanently added 'node2,192.168.1.72' (ECDSA) to the list of known hosts.
Done with creating .ssh directory and setting permissions on remote host node2.
Copying local host public key to the remote host node1
The user may be prompted for a password or passphrase here since the script would be using SCP for host node1.
grid@node1's password:
Done copying local host public key to the remote host node1
Copying local host public key to the remote host node2
The user may be prompted for a password or passphrase here since the script would be using SCP for host node2.
Done copying local host public key to the remote host node2
Creating keys on remote host node1 if they do not exist already. This is required to setup SSH on host node1.
Creating keys on remote host node2 if they do not exist already. This is required to setup SSH on host node2.
Updating authorized_keys file on remote host node1
Updating known_hosts file on remote host node1
Updating authorized_keys file on remote host node2
Updating known_hosts file on remote host node2
cat: /home/grid/.ssh/known_hosts.tmp: No such file or directory
cat: /home/grid/.ssh/authorized_keys.tmp: No such file or directory
SSH setup is complete.
------------------------------------------------------------------------
Verifying SSH setup
===================
The script will now run the date command on the remote nodes using ssh
to verify if ssh is setup correctly. IF THE SETUP IS CORRECTLY SETUP,
THERE SHOULD BE NO OUTPUT OTHER THAN THE DATE AND SSH SHOULD NOT ASK FOR
PASSWORDS. If you see any output other than date or are prompted for the
password, ssh is not setup correctly and you will need to resolve the
issue and set up ssh again.
The possible causes for failure could be:
1. The server settings in /etc/ssh/sshd_config file do not allow ssh
for user grid.
2. The server may have disabled public key based authentication.
3. The client public key on the server may be outdated.
4. ~grid or ~grid/.ssh on the remote host may not be owned by grid.
5. User may not have passed -shared option for shared remote users or
may be passing the -shared option for non-shared remote users.
6. If there is output in addition to the date, but no password is asked,
it may be a security alert shown as part of company policy. Append the
additional text to the /sysman/prov/resources/ignoreMessages.txt file.
------------------------------------------------------------------------
--node1:--
Running /usr/bin/ssh -x -l grid node1 date to verify SSH connectivity has been setup from local host to node1.
IF YOU SEE ANY OTHER OUTPUT BESIDES THE OUTPUT OF THE DATE COMMAND OR IF YOU ARE PROMPTED FOR A PASSWORD HERE, IT MEANS SSH SETUP HAS NOT BEEN SUCCESSFUL. Please note that being prompted for a passphrase may be OK but being prompted for a password is ERROR.
Fri Jun 21 12:23:29 -03 2024
------------------------------------------------------------------------
--node2:--
Running /usr/bin/ssh -x -l grid node2 date to verify SSH connectivity has been setup from local host to node2.
IF YOU SEE ANY OTHER OUTPUT BESIDES THE OUTPUT OF THE DATE COMMAND OR IF YOU ARE PROMPTED FOR A PASSWORD HERE, IT MEANS SSH SETUP HAS NOT BEEN SUCCESSFUL. Please note that being prompted for a passphrase may be OK but being prompted for a password is ERROR.
Fri Jun 21 12:23:29 -03 2024
------------------------------------------------------------------------
------------------------------------------------------------------------
Verifying SSH connectivity has been setup from node1 to node1
IF YOU SEE ANY OTHER OUTPUT BESIDES THE OUTPUT OF THE DATE COMMAND OR IF YOU ARE PROMPTED FOR A PASSWORD HERE, IT MEANS SSH SETUP HAS NOT BEEN SUCCESSFUL.
Fri Jun 21 12:23:30 -03 2024
------------------------------------------------------------------------
------------------------------------------------------------------------
Verifying SSH connectivity has been setup from node1 to node2
IF YOU SEE ANY OTHER OUTPUT BESIDES THE OUTPUT OF THE DATE COMMAND OR IF YOU ARE PROMPTED FOR A PASSWORD HERE, IT MEANS SSH SETUP HAS NOT BEEN SUCCESSFUL.
Fri Jun 21 12:23:30 -03 2024
------------------------------------------------------------------------
-Verification from complete-
SSH verification complete.
[grid@node1 scripts]$
sudo yum install xorg-x11-xauth
sudo yum install xterm
vi /etc/ssh/sshd_config
# AddressFamily any
AddressFamily inet
...
AllowTcpForwarding yes
X11Forwarding yes
X11DisplayOffset 10
X11UseLocalhost yes
...
:wq << SAVE
service sshd restart
xauth list
xauth list | grep unix`echo $DISPLAY | cut -c10-12` > /tmp/xauth
echo $DISPLAY
localhost:10.0
vi /etc/ssh/sshd_config
# AddressFamily any
AddressFamily inet
...
AllowTcpForwarding yes
X11Forwarding yes
X11DisplayOffset 10
X11UseLocalhost yes
...
:x
systemctl restart sshd
==== AUTHENTICATING FOR org.freedesktop.systemd1.manage-units ===
Authentication is required to manage system services or units.
Authenticating as: root
Password: ****
==== AUTHENTICATION COMPLETE ===
exit
-- =======================================================================
-- The DBMS_METADATA package provides a way for you to retrieve metadata from the database dictionary as XML or creation DDL and to submit the XML to re-create the object.
-- =======================================================================
set line 200
set heading off;
set echo off;
Set pages 1000;
set long 70000;
spool C:\...\ddl_tablespace.sql
select dbms_metadata.get_ddl('TABLESPACE',tablespace_name) from dba_tablespaces where tablespace_name not in ('SYSTEM','SYSAUX','UNDO');
spool off
-- Example 2:
select dbms_metadata.get_ddl('TABLE','TABELAX','SCHEMA') from dual;
CREATE TABLE "SCHEMA"."TABELAX"
( "NOME" VARCHAR2(20),
"DATA" DATE
)
desc dbms_metadata;
-- -----------------------------------------------------------------------------------
-- File Name : https://oracle-base.com/dba/script_creation/view_ddl.sql
-- Author : Tim Hall
-- Description : Creates the DDL for the specified view.
-- Call Syntax : @view_ddl (schema-name) (view-name)
-- Last Modified: 16/03/2013 - Rewritten to use DBMS_METADATA
-- -----------------------------------------------------------------------------------
SET LONG 20000 LONGCHUNKSIZE 20000 PAGESIZE 0 LINESIZE 1000 FEEDBACK OFF VERIFY OFF TRIMSPOOL ON
BEGIN
DBMS_METADATA.set_transform_param (DBMS_METADATA.session_transform, 'SQLTERMINATOR', true);
DBMS_METADATA.set_transform_param (DBMS_METADATA.session_transform, 'PRETTY', true);
END;
/
SELECT DBMS_METADATA.get_ddl ('VIEW', view_name, owner)
FROM all_views
WHERE owner = UPPER('&1')
AND view_name = DECODE(UPPER('&2'), 'ALL', view_name, UPPER('&2'));
SET PAGESIZE 14 LINESIZE 100 FEEDBACK ON VERIFY ON
-- Font: https://oracle-base.com/dba/script?category=script_creation&file=view_ddl.sql
-- Font: https://docs.oracle.com/cd/B19306_01/appdev.102/b14258/d_metada.htm#BGBBIEGA
-- =======================================================================
-- codigo_usuario
-- Esse script irá solicitar o nome do owner e gerar o script de criação já recuperando o hash da senha, default tablespace e temporary_tablespace, além de salvar o profile padrão do usuário, quotas em tablespaces, roles e privilégios de sistema. E também ele gera as permissões do usuário também.
-- =======================================================================
accept var_user prompt 'Usuario: '
set arraysize 10
set verify off
set heading off
set feedback off
--set termout off echo off feedback off pagesize 0 heading off verify off
REM
prompt
prompt
prompt
select 'create user '||a.username||' identified by values '''||b.password||''''||CHR(10)||
' default tablespace '||a.DEFAULT_TABLESPACE||' temporary tablespace '||a.temporary_tablespace || ';'
from dba_users a, sys.user$ b
where a.username = b.name
and a.username like upper('&var_user');
SELECT 'alter user '||username||DECODE(profile, ' default', ';', ' profile '||profile||';')
from dba_users
where username like upper('&var_user');
SELECT 'alter user ' || username || ' quota unlimited on ' || tablespace_name || ';'
from dba_ts_quotas
where username like upper('&var_user')
and max_bytes = -1;
select 'grant '||granted_role||' to '||grantee||';'
from dba_role_privs
where grantee like upper('&var_user');
select 'grant '||privilege||' to '||grantee||';'
from dba_sys_privs
where grantee like upper('&var_user');
-- permissões
select 'grant '||privilege||' on '||owner||'.'||table_name||' to '||grantee||';'
from dba_tab_privs
where grantee like upper('%&var_user%')
/
-- objetos
select object_name, object_type
from dba_objects
where owner = upper('&var_user')
order by object_type
/
set termout on feedback 15 verify on pagesize 20 linesize 80 space 1 heading on
set feedback on
set verify on
set heading on
prompt
prompt
prompt
-- OUTPUT --
create user JOE identified by values '85E62084BF1AAD5F' default tablespace USERS temporary tablespace TEMP;
alter user JOE profile USUARIOS;
grant RL_SAC_USUARIO to JOE;
grant RL_SAC_GERENTE to JOE;
grant RL_SAC_CONSULTA to JOE;
grant RL_ADMSAC to JOE;
grant RL_SRH_CONSULTA to JOE;
grant RL_SRH_SEGURANCA to JOE;
grant RL_SRH_GERENTE to JOE;
grant RL_ENTRADA to JOE;
grant RL_ACESSO_CONSULTA to JOE;
grant CREATE SESSION to JOE;
-- =======================================================================
-- codigo tablespace
-- Esse script irá solicitar parte do nome da(s) tablespace(s) e exibir na tela o script de criação da(s) tablespace(s), inclusive mantendo a mesma quantidade de bytes
-- =======================================================================
set serverout on size 1000000
set head off echo off feedback off verify off
set pagesize 0
set trims on
set serveroutput off
set serveroutput on size 1000000
set linesize 5000
accept tablespace char prompt "Informe parte do nome da tablespace: "
prompt
set pause off
declare
nome dba_data_files.tablespace_name%type;
arq dba_data_files.file_name%type;
tam dba_data_files.bytes%type;
status dba_data_files.status%type;
kbytes smallint;
ult_nome dba_data_files.tablespace_name%type := ' ';
--
cursor c_tbs is
select distinct(d.tablespace_name),d.file_name,d.bytes,d.status
from dba_data_files d,dba_segments s
where d.tablespace_name != 'SYSTEM'
and (d.tablespace_name LIKE upper('&tablespace%'))
order by tablespace_name;
begin
-- dbms_output.enable(50000);
kbytes := 0;
open c_tbs;
loop
fetch c_tbs into nome, arq, tam, status;
exit when c_tbs%notfound;
kbytes := tam/1024;
if ult_nome <> nome then
dbms_output.put_line('CREATE TABLESPACE '||nome||' DATAFILE');
dbms_output.put_line(''''||arq||''''||' SIZE '||kbytes||' K ONLINE; ');
else
dbms_output.put_line('ALTER TABLESPACE '||nome||' ADD DATAFILE');
dbms_output.put_line(''''||arq||''''||' SIZE '||kbytes||' K; ');
end if;
ult_nome := nome;
end loop;
close c_tbs;
end;
/
prompt
set verify on
-- OUTPUT --
CREATE TABLESPACE ADMBASE_128K_I DATAFILE
'/u01/oradata/cdb/alfa/admbase/admbase_128k_i01.dbf' SIZE 513024 K ONLINE;
CREATE TABLESPACE ADMBASE_128K_LOB DATAFILE
'/u01/oradata/cdb/alfa/admbase/admbase_128k_lob01.dbf' SIZE 5120 K ONLINE;
CREATE TABLESPACE ADMBASE_128K_T DATAFILE
'/u01/oradata/cdb/alfa/admbase/admbase_128k_t01.dbf' SIZE 5120 K ONLINE;
-- =======================================================================
-- codigo job
-- Logado com o owner dos jobs que você quer gerar a reversa, esse script irá exibir na tela o DDL de criação de todos os jobs do usuário
-- =======================================================================
set serveroutput on
set verify off
prompt
prompt
declare
job_body VARCHAR2(500);
inststr VARCHAR2(50);
type tipoJob is table of number index by binary_integer;
arrJob tipoJob;
indice number := 1;
begin
for v_registro in (select job from user_jobs)
loop
arrJob(indice) := v_registro.job;
indice := indice + 1;
end loop;
indice := arrJob.first;
loop
exit when indice is null;
dbms_output.put_line(indice || ':' || arrJob(indice));
dbms_job.user_export(arrJob(indice), job_body);
dbms_output.put_line(job_body);
dbms_output.put_line(inststr);
indice := arrJob.next(indice);
end loop;
end;
/
prompt
-- =======================================================================
-- codigo Role
-- Esse script irá solicitar o nome da role e exibir na tela o script de criação da role a atribuição de todas as permissões
-- =======================================================================
set verify off
set echo off
set long 10000000
set linesize 32767
set pages 0
set feedback off
accept role prompt "Role: "
prompt
prompt
select 'create role &role;' from dual
/
prompt
prompt
select 'grant ' || privilege || ' on ' || owner || '.' || table_name || ' to ' || grantee || ';'
from dba_tab_privs
where grantee = upper('&role')
and grantable = 'NO'
order by owner, table_name
/
prompt
prompt
select 'grant ' || privilege || ' on ' || owner || '.' || table_name || ' to ' || grantee || ' with grant option;'
from dba_tab_privs
where grantee = upper('&role')
and grantable != 'NO'
order by owner, table_name
/
prompt
prompt
select 'grant ' || privilege || ' to ' || grantee || ';'
from dba_sys_privs
where grantee = upper('&role')
and admin_option = 'NO'
order by privilege
/
prompt
prompt
select 'grant ' || privilege || ' to ' || grantee || ' with admin option;'
from dba_sys_privs
where grantee = upper('&role')
and admin_option != 'NO'
order by privilege
/
prompt
prompt
select 'grant ' || granted_role || ' to ' || grantee || ';'
from dba_role_privs
where grantee = upper('&role')
order by grantee
/
prompt
prompt
select 'grant ' || granted_role || ' to ' || grantee || ';'
from dba_role_privs
where granted_role = upper('&role')
order by grantee
/
undef role
set verify on
set feedback on
-- =======================================================================
-- codigo Profile
-- Esse script irá solicitar o nome do profile gerar o DDL de criação dele.
-- =======================================================================
set verify off
set heading off
set feedback off
accept var_profile prompt 'Profile: '
select
dbms_metadata.get_ddl('PROFILE', profile) || '/'
from
dba_profiles
where
profile like upper('&var_profile')
group by profile;
undef var_profile
set heading on
set feedback on
set verify on
font: https://dirceuresende.com/en/blog/gerando-engenharia-reversa-ddl-de-criacao-de-usuarios-tablespaces-roles-jobs-e-profiles-no-oracle-database/#
-- ==================================================================
-- ASMCMD Disk Group Management Commands
-- ==================================================================
Command Description
------------- --------------------------------------------
amdu_extract Extracts a file from a disk group.
cd Changes the current directory to the specified directory.
cp Enables you to copy files between disk groups, and between a disk group and the operating system.
du Displays the total disk space occupied by files in the specified Oracle ASM directory and all of its subdirectories, recursively.
find Lists the paths of all occurrences of the specified name (with wildcards) under the specified directory.
ls Lists the contents of an Oracle ASM directory, the attributes of the specified file, or the names and attributes of all disk groups.
lsof Lists the open files.
mkalias Creates an alias for system-generated file names.
mkdir Creates Oracle ASM directories.
pwd Displays the path of the current Oracle ASM directory.
rm Deletes the specified Oracle ASM files or directories.
rmalias Deletes the specified alias, retaining the file that the alias points to.
-- ==================================================================
-- ASMCMD Disk Group Management Commands
-- ==================================================================
Command Description
------------- --------------------------------------------
chdg Changes a disk group (add, drop, rebalance, or migrate on the Exadata appliance).
chkdg Checks or repairs a disk group.
dropdg Drops a disk group.
iostat Displays I/O statistics for disks.
lsattr Lists the attributes of a disk group.
lsdg Lists disk groups and their information.
lsdsk Lists disks Oracle ASM disks.
lsod Lists open devices.
md_backup Creates a backup of the metadata of mounted disk groups.
md_restore Restores disk groups from a backup of the metadata.
mkdg Creates a disk group.
mount Mounts a disk group.
offline Offlines a disk or a failure group.
online Onlines a disk or a failure group.
rebal Rebalances a disk group.
remap Relocates data in a range of physical blocks on a disk.
setsparseparent Sets the parent for a sparse child file.
setattr Sets attributes in a disk group.
stamp Stamps the disk, site, and failure group labels in disk headers.
stamplist Displays the disk, site, and failure group labels in disk headers.
umount Dismounts a disk group.
-- ==================================================================
-- ASMCMD Disk Group Management Commands
-- ==================================================================
Command Description
------------- --------------------------------------------
chtmpl Changes the attributes of a template.
lstmpl Lists disk group templates.
mktmpl Adds a template to a disk group.
rmtmpl Removes a template from a disk group.
-- ==================================================================
-- ASMCMD File Access Control Commands
-- ==================================================================
Command Description
------------- --------------------------------------------
chgrp Changes the user group of a file or list of files.
chmod Changes permissions of a file or list of files.
chown Changes the owner of a file or list of files.
groups Lists the user groups to which a user belongs.
grpmod Adds or removes users from an existing user group.
lsgrp Lists user groups.
lsusr Lists users in a disk group.
mkgrp Creates a new user group.
mkusr Adds a user to disk group.
passwd Changes the password of a user.
rmgrp Deletes a user group.
rmusr Deletes a user from a disk group.
rpusr Replaces one a user with another in a disk group.
-- ==================================================================
-- List all diskgroups:
-- ==================================================================
# To List the current directory.
ASMCMD> ls
ASMCMD> ls -l
State Type Rebal Name
MOUNTED EXTERN N DATA/
MOUNTED EXTERN N FRA/
ASMCMD> lsdg
State Type Rebal Sector Block AU Total_MB Free_MB Req_mir_free_MB Usable_file_MB Offline_disks Voting_files Name
MOUNTED EXTERN N 512 4096 1048576 18426 15138 0 15138 0 N DATA/
# Include dismounted diskgroups:
ASMCMD> lsdg --discovery
# List diskgroups across all nodes of cluster:
ASMCMD> lsdg -g --discovery
# To list a particular diskgroup.
ASMCMD> lsdg DATA
#To list Mounted ASM disks.
ASMCMD> lsdsk
Path
/dev/oracleasm/disks/DATA01
/dev/oracleasm/disks/FRA01
ASMCMD> lsdsk -k
Total_MB Free_MB OS_MB Name Failgroup Library Label UDID Product Redund Path
18426 15138 18426 DATA01 DATA01 ASM Library – Generic Linux, version 2.0.12 (KABI_V2) DATA01 UNKNOWN /dev/oracleasm/disks/DATA01
8189 7654 8189 FRA01 FRA01 ASM Library – Generic Linux, version 2.0.12 (KABI_V2) FRA01 UNKNOWN /dev/oracleasm/disks/FRA01
# List disks of a diskgroup(DATA) with free and total MB
ASMCMD> lsdsk -k -G DATA
Total_MB Free_MB OS_MB Name Failgroup Library Label UDID Product Redund Path
18426 15138 18426 DATA01 DATA01 ASM Library – Generic Linux, version 2.0.12 (KABI_V2) DATA UNKNOWN /dev/oracleasm/disks/DATA01
Now it’s showing details of “DATA01” disk only.
# List disks of a diskgroup(CDATA) with group and disk number
ASMCMD> lsdsk -p -G CDATA
# List disks with disk creation date
ASMCMD> lsdsk -t -G CDATA
# List candidiate disks only
ASMCMD> lsdsk #candidate -k
# List member disks only
ASMCMD> lsdsk #candidate -p
-- ==================================================================
-- Get attributes of ASM diskgroups
-- ==================================================================
# SYNTAX: ASMCMD> lsattr -l +diskgroup/path
ASMCMD> lsattr -lm
# List attribute of specific diskgroup(DMARCH)
ASMCMD> lsattr -lm -G DMARCH
Group_Name Name Value RO Sys
DMARCH access_control.enabled FALSE N Y
DMARCH access_control.umask 066 N Y
DMARCH au_size 1048576 Y Y
DMARCH cell.smart_scan_capable FALSE N N
# List attributes with specific pattern
ASMCMD> lsattr -lm %au_size%
Group_Name Name Value RO Sys
CDATA au_size 1048576 Y Y
BDM au_size 1048576 Y Y
CRMG au_size 1048576 Y Y
PMARCH au_size 1048576 Y Y
BCMS au_size 1048576 Y Y
-- ==================================================================
-- Unmount Diskgroup:
-- ==================================================================
# unmount command works only on the local node.
# So if you want to unmount the diskgroup from all nodes of cluster, then run this command from all the nodes.
# unmount all diskgroups
ASMCMD> umount -a
#- unmount specific diskgroup(ARCH)
ASMCMD> umount ARCH
-- ==================================================================
-- Mount Diskgroup:
-- ==================================================================
#Mount command works only on the local node.
#So if you want to Mount the diskgroup from all nodes of cluster, then run this command from all the nodes.
# mount all diskgroups on local node
ASMCMD> mount -a
#- mount a specific diskgroup on local node
ASMCMD> mount FRA
-- ==================================================================
-- Rebalance a Diskgroup:
-- ==================================================================
# here asm_power_limit is 8 and diskgroup is ARCH
ASMCMD> rebal #power 8 ARCH
Rebal on progress.
# Monitor progress
ASMCMD> lsop
Group_Name Pass State Power EST_WORK EST_RATE EST_TIME
ARCH COMPACT RUN 8 0 16831 0
ARCH REBALANCE DONE 8 0 0 0
-- ==================================================================
-- Get Password File of Database
-- ==================================================================
ASMCMD> pwget #dbuniquename PROD
+CDATA/PROD/PASSWORD/pwdPROD.256.899912377
-- ==================================================================
-- Get Password File of ASM
-- ==================================================================
ASMCMD> pwget #asm
+MGMT/orapwASM
-- ==================================================================
-- Get ASM Template Info of a Diskgroup:
-- ==================================================================
ASMCMD> lstmpl -l -G ARCH
Group_Name Group_Num Name Stripe Sys Redund PriReg MirrReg
ARCH 1 ARCHIVELOG COARSE Y UNPROT COLD COLD
ARCH 1 ASMPARAMETERFILE COARSE Y UNPROT COLD COLD
ARCH 1 AUDIT_SPILLFILES COARSE Y UNPROT COLD COLD
ARCH 1 AUTOBACKUP COARSE Y UNPROT COLD COLD
ARCH 1 AUTOLOGIN_KEY_STORE COARSE Y UNPROT COLD COLD
ARCH 1 BACKUPSET COARSE Y UNPROT COLD COLD
-- ==================================================================
-- Check whether Flex ASM is Enabled or Disable
-- ==================================================================
ASMCMD> showclustermode
ASM cluster : Flex mode disabled
-- ==================================================================
-- Check cluster state
-- ==================================================================
ASMCMD> showclusterstate
Normal
-- ==================================================================
-- View ASM version:
-- ==================================================================
ASMCMD> showversion
ASM version : 12.1.0.2.0
$ asmcmd -V
asmcmd version 11.2.0.0.0
-- ==================================================================
-- Get ASM spfile location:
-- ==================================================================
ASMCMD> spget
+MGMT/PROD-cluster/ASMPARAMETERFILE/registry.253.899644763
#To get information about OracleASM ServerParameter file.
#This will show you the location of spfile for ASM instance.
ASMCMD> spget
+DATA/rc-scan/asmparameterfile/registry.253.986765603
-- ==================================================================
-- Take backup of ASM spfile:
-- ==================================================================
# copy backup of spfile to a specific location
ASMCMD> spbackup +MGMT/PROD-cluster/ASMPARAMETERFILE/registry.253.899644763 /home/oracle/asmspfile.ora
-- ==================================================================
-- Find clients connected to a diskgroup:
-- ==================================================================
ASMCMD> lsct DMARCH
DB_Name Status Software_Version Compatible_version Instance_Name Disk_Group
PROD CONNECTED 12.1.0.2.0 12.1.0.2.0 PROD1 DMARCH
-- ==================================================================
-- Get ASM diskstring
-- ==================================================================
ASMCMD> dsget
parameter:ORCL:*
profile:ORCL:*
-- ==================================================================
-- List ASM users with password
-- ==================================================================
ASMCMD> lspwusr
Username sysdba sysoper sysasm
SYS TRUE TRUE TRUE
ASMSNMP TRUE FALSE FALSE
-- ==================================================================
-- List open files related to a database
-- ==================================================================
ASMCMD>lsof #dbname PROD
ASMCMD>lsof -G ARCH
#To list currently open files by all instances in ASM
ASMCMD [+] > lsof
DB_Name Instance_Name Path
PROD PROD +DATA/PROD/CONTROLFILE/current.265.987302781
PROD PROD +DATA/PROD/DATAFILE/sysaux.269.987302597
PROD PROD +DATA/PROD/DATAFILE/system.261.987302651
PROD PROD +DATA/PROD/DATAFILE/undotbs1.268.987302719
PROD PROD +DATA/PROD/DATAFILE/users.272.987302717
PROD PROD +DATA/PROD/ONLINELOG/group_1.264.987302785
PROD PROD +DATA/PROD/ONLINELOG/group_2.263.987302789
PROD PROD +DATA/PROD/ONLINELOG/group_3.262.987302793
PROD PROD +DATA/PROD/TEMPFILE/temp.273.987302813
PROD PROD +FRA/PROD/CONTROLFILE/current.256.987302781
PROD PROD +FRA/PROD/ONLINELOG/group_1.259.987302787
PROD PROD +FRA/PROD/ONLINELOG/group_2.258.987302791
-- ==================================================================
-- Check filter driver is enabled or not:
-- ==================================================================
ASMCMD> afd_state
ASMCMD-9526: The AFD state is 'NOT INSTALLED' and filtering is 'DEFAULT' on host 'b20e4bay01'
-- ==================================================================
-- List filter driver disks(if enabled)
-- ==================================================================
ASMCMD> afd_lsdsk
-- ==================================================================
-- Get filter driver ASM diskstring
-- ==================================================================
ASMCMD> afd_dsget
AFD discovery string:
-- ==================================================================
-- To get Input/Output State details of disks
-- ==================================================================
ASMCMD> iostat
Group_Name Dsk_Name Reads Writes
DATA DATA01 5450240 12764160
FRA FRA01 98304 4096
#Here Group_Name shows, which ASM diskgroup this disk belongs to. We can see Reads/Writes information in bytes.
ASMCMD> iostat -G FRA
Group_Name Dsk_Name Reads Writes
FRA FRA01 98304 4096
# To retrieve information of Reads/Writes Error.
#This will show you IO erros of disk.
ASMCMD> iostat -e
Group_Name Dsk_Name Reads Writes Read_Err Write_Err
DATA DATA01 5450240 13280256 0 0
FRA FRA01 98304 4096 0 0
# To get Time Statistics, Read Time & Write Time.
ASMCMD> iostat -e -t
Group_Name Dsk_Name Reads Writes Read_Err Write_Err Read_Time Write_Time
DATA DATA01 5450240 13624320 0 0 .811 1.37 FRA FRA01 98304 4096 0 0 .011 0
-- ==================================================================
-- To print current directory path in ASMCMD, using -p argument.
-- ==================================================================
[oracle@node1 ~]$ asmcmd -p
ASMCMD [+] >
We can see It is showing ‘+’ that is Root Directory.
Let’s navigate to sub-directory.
ASMCMD [+] > ls
DATA/
FRA/
ASMCMD [+] > cd +DATA/PROD/DATAFILE
ASMCMD [+DATA/PROD/DATAFILE] > ls
EXAMPLE.264.986768097
SYSAUX.257.986767995
SYSTEM.256.986767993
TBS.269.986769231
UNDOTBS1.258.986767995
UNDOTBS2.265.986768163
USERS.259.986767995
-- ==================================================================
-- To check permissions on file
-- ==================================================================
ASMCMD [+DATA/PROD/DATAFILE] > ls –permission
User Group Permission Name
rw-rw-rw- EXAMPLE.264.986768097
rw-rw-rw- SYSAUX.257.986767995
rw-rw-rw- SYSTEM.256.986767993
rw-rw-rw- TBS.269.986769231
rw-rw-rw- UNDOTBS1.258.986767995
rw-rw-rw- UNDOTBS2.265.986768163
rw-rw-rw- USERS.259.986767995
-- ==================================================================
-- To Check disk usage
-- ==================================================================
ASMCMD [+DATA] > du
Used_MB Mirror_used_MB
3154 3154
-- ==================================================================
-- To Find file with name
-- ==================================================================
#SYNTAX: ASMCMD> find +diskgroup path
ASMCMD [+DATA] > find + system*
+DATA/PROD/DATAFILE/SYSTEM.256.986767993
# Set $GRID_HOME
export GRID_HOME=/u01/app/21.3.0.0/grid/ (or) export GRID_HOME=/u01/app/19.3.0.0/grid/
## ==================================================================
## 01. STOP & START CRS: ( run from ROOT user)
## ==================================================================
$GRID_HOME/bin/crsctl stop crs
CRS-2791: Starting shutdown of Oracle High Availability Services-managed resources on 'node2'
...
CRS-4133: Oracle High Availability Services has been stopped.
$GRID_HOME/bin/crsctl start crs
CRS-4123: Oracle High Availability Services has been started.
## ==================================================================
## 02. ENABLE/DISABLE AUTO RESTART OF CRS:
## ==================================================================
$GRID_HOME/bin/crsctl disable crs
CRS-4621: Oracle High Availability Services autostart is disabled.
$GRID_HOME/bin/crsctl enable crs
CRS-4622: Oracle High Availability Services autostart is enabled.
## ==================================================================
## 03. FIND THE CLUSTER NAME:
## ==================================================================
$GRID_HOME/bin/cemutlo -n
$GRID_HOME/bin/olsnodes -c
node-cluster
## ==================================================================
## 04. FIND GRID VERSION:
## ==================================================================
$GRID_HOME/bin/crsctl query crs softwareversion node1
Oracle Clusterware version on node [node1] is [21.0.0.0.0]
$GRID_HOME/bin/crsctl query crs softwareversion node2
Oracle Clusterware version on node [node2] is [21.0.0.0.0]
$GRID_HOME/bin/crsctl query crs softwareversion -all
Oracle Clusterware version on node [node1] is [21.0.0.0.0]
Oracle Clusterware version on node [node2] is [21.0.0.0.0]
## ==================================================================
## 05. CHECK CLUSTER COMPONENT STATUS:
## ==================================================================
ps -ef | grep d.bin (or) pgrep -lf d.bin
$GRID_HOME/bin/crsctl status resource
$GRID_HOME/bin/crsctl status resource -t (or) $GRID_HOME/bin/crsctl stat resource -t
$GRID_HOME/bin/crsctl check css
CRS-4529: Cluster Synchronization Services is online
$GRID_HOME/bin/crsctl check cssd
CRS-272: This command remains for backward compatibility only
Cluster Synchronization Services is online
$GRID_HOME/bin/crsctl check crsd
CRS-272: This command remains for backward compatibility only
Cluster Ready Services is online
$GRID_HOME/bin/crsctl check ctss
CRS-4700: The Cluster Time Synchronization Service is in Observer mode.
$GRID_HOME/bin/crsctl check evmd
CRS-272: This command remains for backward compatibility only
Event Manager is online
## ==================================================================
## 06. FIND VOTING DISK LOCATION:
## ==================================================================
$GRID_HOME/bin/crsctl query css votedisk
## STATE File Universal Id File Name Disk group
-- ----- ----------------- --------- ---------
1. ONLINE d326053b81f74f20bf72fde9796132ef (/dev/oracleasm/disks/OCR) [OCR]
Located 1 voting disk(s).
## ==================================================================
## 07. FIND OCR LOCATION:
## ==================================================================
$GRID_HOME/bin/ocrcheck
Status of Oracle Cluster Registry is as follows :
Version : 4
Total space (kbytes) : 491684
Used space (kbytes) : 84440
Available space (kbytes) : 407244
ID : 447150934
Device/File Name : +OCR
Device/File integrity check succeeded
Device/File not configured
Cluster registry integrity check succeeded
Logical corruption check succeeded
## ==================================================================
## 08. FIND CLUSTER INTERCONNECT DETAILS:
## ==================================================================
$GRID_HOME/bin/oifcfg getif
enp0s3 212.168.10.0 global cluster_interconnect,asm
enp0s8 212.168.56.0 global public
#USER:ORACLE
sqlplus / as sysdba
SQL> select NAME,IP_ADDRESS from v$cluster_interconnects;
NAME IP_ADDRESS
--------------- -----------------
enp0s3:1 169.254.5.162
## ==================================================================
## 09. CHECK CRS STATUS OF LOCAL NODE:
## ==================================================================
$GRID_HOME/bin/crsctl check crs
CRS-4638: Oracle High Availability Services is online
CRS-4537: Cluster Ready Services is online
CRS-4529: Cluster Synchronization Services is online
CRS-4533: Event Manager is online
$GRID_HOME/bin/crsctl check css
CRS-4529: Cluster Synchronization Services is online
## ==================================================================
## 10. CHECK STATUS OF ALL CRS RESOURCES:
## ==================================================================
$GRID_HOME/bin/crsctl stat res -t
$GRID_HOME/bin/crsctl stat res -t -init
--------------------------------------------------------------------
Name Target State Server State details
--------------------------------------------------------------------
Cluster Resources
--------------------------------------------------------------------
ora.asm
1 ONLINE ONLINE node1 STABLE
ora.cluster_interconnect.haip
1 ONLINE ONLINE node1 STABLE
ora.crf
1 ONLINE ONLINE node1 STABLE
ora.crsd
1 ONLINE ONLINE node1 STABLE
ora.cssd
1 ONLINE ONLINE node1 STABLE
ora.cssdmonitor
1 ONLINE ONLINE node1 STABLE
ora.ctssd
1 ONLINE ONLINE node1 OBSERVER,STABLE
ora.diskmon
1 ONLINE ONLINE STABLE
ora.evmd
1 ONLINE ONLINE node1 STABLE
ora.gipcd
1 ONLINE ONLINE node1 STABLE
ora.gpnpd
1 ONLINE ONLINE node1 STABLE
ora.mdnsd
1 ONLINE ONLINE node1 STABLE
ora.storage
1 ONLINE ONLINE node1 STABLE
--------------------------------------------------------------------
## ==================================================================
## 11. CHECK ACTIVE VERSION OF CLUSTER:
## ==================================================================
$GRID_HOME/bin/crsctl query crs activeversion
Oracle Clusterware active version on the cluster is [21.0.0.0.0]
## ==================================================================
## 12. STOP AND START HIGH AVAILABILITY SERVICE (HAS)
## ==================================================================
$GRID_HOME/bin/crsctl stop has
CRS-2791: Starting shutdown of Oracle High Availability Services-managed resources on 'node1'
...
CRS-4133: Oracle High Availability Services has been stopped.
$GRID_HOME/bin/crsctl start has
CRS-4123: Oracle High Availability Services has been started.
## ==================================================================
## 13. CHECK CRS STATUS OF REMOTE NODES:
## ==================================================================
$GRID_HOME/bin/crsctl check cluster
CRS-4537: Cluster Ready Services is online
CRS-4529: Cluster Synchronization Services is online
CRS-4533: Event Manager is online
$GRID_HOME/bin/crsctl check cluster -all
**************************************************************
node1:
CRS-4537: Cluster Ready Services is online
CRS-4529: Cluster Synchronization Services is online
CRS-4533: Event Manager is online
**************************************************************
node2:
CRS-4537: Cluster Ready Services is online
CRS-4529: Cluster Synchronization Services is online
CRS-4533: Event Manager is online
**************************************************************
## ==================================================================
## 14. DISK TIMEOUT FROM NODE TO VOTING DISK(DISKTIMEOUT):
## ==================================================================
$GRID_HOME/bin/crsctl get css disktimeout
CRS-4678: Successful get disktimeout 200 for Cluster Synchronization Services.
## ==================================================================
## 15. NETWORK LATENCY IN THE NODE INTERCONNECT (MISSCOUNT):
## ==================================================================
$GRID_HOME/bin/crsctl get css misscount
CRS-4678: Successful get misscount 30 for Cluster Synchronization Services.
## ==================================================================
## 16. MOVE VOTING DISK TO ANOTHER DISKGROUP:
## ==================================================================
$GRID_HOME/bin/crsctl replace votedisk +OCRVD
Successful addition of voting disk 2E4DED6CEE504FC8BF0080FB7BE6F.
Successful addition of voting disk 8E87826024E24FFFBF565C011FC66.
Successful addition of voting disk E1BA56DEDFF84FA8BF5E0302FC81E.
Successful deletion of voting disk 2B7CE864C44D4FECBF65A188290AF.
Successfully replaced voting disk group with +OCRVD.
CRS-4266: Voting file(s) successfully replaced
## ==================================================================
## 17. VOTING DISK:
## ==================================================================
#ADD:
$GRID_HOME/bin/crsctl add css votedisk
#DELETE:
$GRID_HOME/bin/crsctl delete css votedisk
## ==================================================================
## 18. GET OCR DISK BACKUP DETAILS:
## ==================================================================
ocrconfig -showbackup
PROT-24: Auto backups for the Oracle Cluster Registry are not available
PROT-25: Manual backups for the Oracle Cluster Registry are not available
## ==================================================================
## 19. FIND NODE ROLES IN CLUSTER:
## ==================================================================
$GRID_HOME/bin/crsctl get node role status -all
Node 'node1' active role is 'hub'
Node 'node2' active role is 'hub'
## ==================================================================
## 20. CHECK WHETHER STANDARD OR FLEX ASM:
## ==================================================================
$GRID_HOME/bin/crsctl get cluster mode status
Cluster is running in "standard" mode (or)
Cluster is running in "flex" mode
## ==================================================================
## 21. CHECK CRS CONFIGUATION:
## ==================================================================
$GRID_HOME/bin/crsctl config crs
CRS-4622: Oracle High Availability Services autostart is enabled.
## ==================================================================
## 22. $GRID_HOME/bin/crsctl HAS COMMANDS FOR STANDALONE GRID INFRASTRCUTURE:
## ==================================================================
$GRID_HOME/bin/crsctl check has
CRS-4638: Oracle High Availability Services is online
$GRID_HOME/bin/crsctl config has
CRS-4622: Oracle High Availability Services autostart is enabled.
$GRID_HOME/bin/crsctl disable has
CRS-4621: Oracle High Availability Services autostart is disabled.
$GRID_HOME/bin/crsctl enable has
CRS-4622: Oracle High Availability Services autostart is enabled.
$GRID_HOME/bin/crsctl query has releaseversion
Oracle High Availability Services release version on the local node is [21.0.0.0.0]
$GRID_HOME/bin/crsctl query has softwareversion
Oracle High Availability Services version on the local node is [21.0.0.0.0]
## ==================================================================
## 23. FIND CLUSTER CONFIGURATION INFORMATION:
## ==================================================================
$GRID_HOME/bin/crsctl get cluster configuration
Name : node-cluster
Configuration : Cluster
Class : Standalone Cluster
Type : flex
The cluster is not extended.
--------------------------------------------------------------------------------
MEMBER CLUSTER INFORMATION
Name Version GUID Deployed Deconfigured
================================================================================
...
================================================================================
-- ==================================================================
-- 00. STATUS DATABASE:
-- ==================================================================
srvctl status database -database DB_UNIQUE_NAME (or)
srvctl status database -db DB_UNIQUE_NAME (or)
srvctl status database -d DB_UNIQUE_NAME
-- ==================================================================
-- 01. STOP DATABASE:
-- ==================================================================
# SYNTAX: srvctl stop database -database db_unique_name [-o stopoption] where stop_options is [ normal | immediate | transactional | abort ]
srvctl stop database -database DB_UNIQUE_NAME -stopoption normal (or)
srvctl stop database -db DB_UNIQUE_NAME -o normal (or)
srvctl stop database -d DB_UNIQUE_NAME -o normal
srvctl stop database -d DB_UNIQUE_NAME -o immediate
srvctl stop database -d DB_UNIQUE_NAME -o transactional
srvctl stop database -d DB_UNIQUE_NAME -o abort
-- ==================================================================
-- 02. START DATABASE:
-- ==================================================================
# SYNTAX: srvctl start database -database db_unique_name [-o startoption] where start_option is [ nomount | mount | open | force | open recover ]
srvctl start database -d DB_UNIQUE_NAME -o nomount
srvctl start database -d DB_UNIQUE_NAME -o mount
srvctl start database -d DB_UNIQUE_NAME -o open
srvctl start database -d DB_UNIQUE_NAME -o open
srvctl start database -database DB_UNIQUE_NAME -startoption force
srvctl start database -database DB_UNIQUE_NAME -startoption "open,recover"
-- ==================================================================
-- 03. STOP AN INSTANCE:
-- ==================================================================
# SYNTAX: srvctl stop instance -d DB_UNIQUE_NAME [-i “instance_name_list”]} [-o stop_options] [-f|-force]
srvctl stop instance -d DB_UNIQUE_NAME -i INSTANCE_NAME -o NORMAL
srvctl stop instance -d DB_UNIQUE_NAME -i INSTANCE_NAME -o TRANSACTIONAL
srvctl stop instance -d DB_UNIQUE_NAME -i INSTANCE_NAME -o IMMEDIATE
srvctl stop instance -d DB_UNIQUE_NAME -i INSTANCE_NAME -o ABORT
-- ==================================================================
-- 04. START AN INSTANCE:
-- ==================================================================
# SYNTAX: srvctl start instance -d DB_UNIQUE_NAME [-i “instance_name_list”} [-o start_options]
srvctl start instance -d DB_UNIQUE_NAME -i INSTANCE_NAME -o OPEN
srvctl start instance -d DB_UNIQUE_NAME -i INSTANCE_NAME -o MOUNT
srvctl start instance -d DB_UNIQUE_NAME -i INSTANCE_NAME -o NOMOUNT
-- ==================================================================
-- 05. REMOVING DB FROM CRS:
-- ==================================================================
# SYNTAX: srvctl remove database -d DB_UNIQUE_NAME [-f] [-y] [-v]
srvctl remove database -d DB_UNIQUE_NAME -f -y
-- ==================================================================
-- 06. ADDING DB IN CRS :
-- ==================================================================
# SYNTAX: srvctl add database -d DB_UNIQUE_NAME -o ORACLE_HOME [-p spfile]
srvctl add database -d DB_UNIQUE_NAME -o /u01/app/oracle/product/12.1.0.2/dbhome_1 -p +DATA/PRODDB/parameterfile/spfileDB_UNIQUE_NAME.ora
-- ==================================================================
-- 07. REMOVING AN INSTANCE FROM CRS:
-- ==================================================================
# SYNTAX: srvctl remove instance -d DB_UNIQUE_NAME -i INSTANCE_NAME
srvctl remove instance -d DB_UNIQUE_NAME - I DB_UNIQUE_NAME1
-- ==================================================================
-- 08. ADDING AN INSTANCE TO CRS:
-- ==================================================================
# SYNTAX: srvctl add instance –d DB_UNIQUE_NAME –i inst_name -n node_name
srvctl add instance -d DB_UNIQUE_NAME - i DB_UNIQUE_NAME1 -n rachost1
-- ==================================================================
-- 09. ENABLE/DISABLE AUTO RESTART OF THE INSTANCE
-- ==================================================================
srvctl enable instance -d DB_UNIQUE_NAME -i INSTANCE_NAME
srvctl disable instance -d DB_UNIQUE_NAME -i INSTANCE_NAME
-- ==================================================================
-- 10. ENABLE/DISABLE AUTO RESTART OF THE DATABASE
-- ==================================================================
srvctl enable database -d DB_UNIQUE_NAME
srvctl disable database -d DB_UNIQUE_NAME
-- ==================================================================
-- 11. ADDING A SERVICE:
-- ==================================================================
# SYNTAX: srvctl add servicec -d {DB_NAME} -s {SERVICE_NAME} -r {“preferred_list”} -a {“available_list”} [-P {BASIC | NONE | PRECONNECT}]
srvctl add service -d DB_NAME -s SERVICE_NAME -r "DB_NAME1,DB_NAME2" -a "DB_NAME2" -P BASIC
-- ==================================================================
-- 12.REMOVING A SERVICE:
-- ==================================================================
# SYNTAX: srvctl remove service -d {DB_NAME} -s {SERVICE_NAME}
srvctl remove service -d DB_NAME -s SERVICE_NAME
-- ==================================================================
-- 13. START A SERVICE
-- ==================================================================
# SYNTAX: srvctl start servicec -d {DB_NAME} -s {SERVICE_NAME}
srvctl start service -d DB_NAME -s SERVICE_NAME
-- ==================================================================
-- 14. STOP A SERVICE
-- ==================================================================
# SYNTAX: srvctl stop servicec -d {DB_NAME} -s {SERVICE_NAME}
srvctl stop service -d DB_NAME -s SERVICE_NAME
-- ==================================================================
-- 15. RELOCATE A SERVICE
-- ==================================================================
# SYNTAX: srvctl relocate service -d {database_name} -s {service_name} -i {old_inst_name} -r {new_inst_name}
EXAMPLE: (Relocating service SERVICE_NAME from DB_NAME2 to DB_NAME1)
srvctl relocate service -d DB_NAME -s SERVICE_NAME -i DB_NAME2 -t DB_NAME1
-- ==================================================================
-- 16. CHECK THE STATUS OF SERVICE
-- ==================================================================
# SYNTAX: srvctl status service -d {database_name} -s {service_name}
srvctl status service -d DB_NAME -s SERVICE_NAME
-- ==================================================================
-- 17. CHECK THE CONFIGURATION OF SERVICE
-- ==================================================================
# SYNTAX: srvctl config service -d {database_name} -s {service_name}
srvctl config service -d DB_NAME -s SERVICE_NAME
-- ==================================================================
-- 18. CHECK SCAN LISTENER CONFIGURATION
-- ==================================================================
srvctl config scan_listener
SCAN Listener LISTENER_SCAN1 exists. Port: TCP:1522
Registration invited nodes:
Registration invited subnets:
SCAN Listener is enabled.
SCAN Listener is individually enabled on nodes:
SCAN Listener is individually disabled on nodes:
SCAN Listener LISTENER_SCAN2 exists. Port: TCP:1522
Registration invited nodes:
Registration invited subnets:
SCAN Listener is enabled.
SCAN Listener is individually enabled on nodes:
SCAN Listener is individually disabled on nodes:
SCAN Listener LISTENER_SCAN3 exists. Port: TCP:1522
Registration invited nodes:
Registration invited subnets:
SCAN Listener is enabled.
SCAN Listener is individually enabled on nodes:
SCAN Listener is individually disabled on nodes:
-- ==================================================================
-- 19. MODIFY SCAN_LISTENER PORT:
-- ==================================================================
srvctl modify scan_listener -p {new-SCAN-port}
srvctl modify scan_listener -p 1523
$GRID_HOME/bin/srvctl stop scan_listener
$GRID_HOME/bin/srvctl start scan_listener
Alter system set remote_listener='orcl-scan.stc.com.sa:1523' scope=both sid='*';
-- ==================================================================
-- 20. MANAGE MGMTDB IN ORACLE 12C:
-- ==================================================================
srvctl status mgmtdb
Database is enabled
Instance -MGMTDB is running on node node12-1
#--~~ stop and start MGMT db.~~--#
srvctl stop mgmtdb
srvctl start mgmtdb
-- ==================================================================
-- 21. ENABLE TRACE FOR SRVCTL COMMANDS:
-- ==================================================================
#--~~ set this to enable trace at os ~~--#
SRVM_TRACE=true
export SRVM_TRACE
##--~~ run any srvctl command ~~--#
srvctl status database -d ORACL
-- ==================================================================
-- 22. SET ENVIRONMENT VARIABLES THROUGH SRVCTL.
-- ==================================================================
#--~~ setenv to set env variables.(ORCL is the DB_UNIQUE_NAME)~~--#
srvctl setenv database -db ORCL -env "ORACLE_HOME=/oracle/app/oracle/product/12.1.0.2/dbhome_1"
srvctl setenv database -db ORCL -env "TNS_ADMIN=/oracle/app/oracle/product/12.1.0.2/dbhome_1/network/admin"
#--~~getenv to view the env setting:~~--#
srvctl getenv database -db ORCL
ORCL:
ORACLE_HOME=/oracle/app/oracle/product/12.1.0.2/dbhome_1
TNS_ADMIN=/oracle/app/oracle/product/12.1.0.2/dbhome_1/network/admin
-- ==================================================================
-- 23. CHECK STATUS AND CONFIG OF ASM INSTANCE:
-- ==================================================================
srvctl config asm
ASM home:
Password file: +MGMT/orapwASM
ASM listener: LISTENER
srvctl status asm
ASM is running on ses11-4,ses11-5
-- ==================================================================
-- 24. STOP AND START SERVICES RUNNING FROM ORACLE_HOME
-- ==================================================================
srvctl stop home -oraclehome /oracle/product/12.1.0.2/dbhome_1 -statefile /home/oracle/state.txt -node dbhost-1
srvctl start home -oraclehome /oracle/product/12.1.0.2/dbhome_1 -statefile /home/oracle/state.txt -node dbhost-1
-- ==================================================================
-- 25. CREATE A TAF POLICY
-- ==================================================================
srvctl add service -db ORCLDB -service TAF_ORCL -preferred ORCLDB1 -available ORCLDB2 -tafpolicy BASIC -failovertype SELECT srvctl start service -db OMDB_NAME -service TAF_ORCL
FONT:
https://docs.oracle.com/cd/E24696_01/doc/rac.11203/e16795/srvctladmin.htm
--Verify Interconnect Settings
SELECT * FROM GV$CLUSTER_INTERCONNECTS ORDER BY Inst_id;
SELECT * FROM GV$CONFIGURED_INTERCONNECTS; ORDER BY Inst_id;
-- Verifica os waits do Global Cache
select b1.inst_id, b2.value "GCS CR BLOCKS RECEIVED",
b1.value "GCS CR BLOCK RECEIVE TIME",
round(((b1.value / b2.value) * 10),2) "AVG CR BLOCK RECEIVE TIME (ms)"
from gv$sysstat b1, gv$sysstat b2
where b1.name = 'global cache cr block receive time' and
b2.name = 'global cache cr blocks received' and b1.inst_id = b2.inst_id
or b1.name = 'gc cr block receive time' and
b2.name = 'gc cr blocks received' and b1.inst_id = b2.inst_id order by inst_id;
select b1.inst_id, (b1.value + b2.value) "GLOBAL LOCK GETS",
b3.value "GLOBAL LOCK GET TIME",
round((b3.value / (b1.value + b2.value) * 10),2) "AVG GLOBAL LOCK GET TIME (ms)"
from gv$sysstat b1, gv$sysstat b2, gv$sysstat b3
where b1.name = 'global lock sync gets' and
b2.name = 'global lock async gets' and b3.name = 'global lock get time'
and b1.inst_id = b2.inst_id and b2.inst_id = b3.inst_id
or b1.name = 'global enqueue gets sync' and
b2.name = 'global enqueue gets async' and b3.name = 'global enqueue get time'
and b1.inst_id = b2.inst_id and b2.inst_id = b3.inst_id order by inst_id;
-- ==========================================================
-- STATUS DAS INSTANCES
-- ==========================================================
SET ECHO OFF
ALTER SESSION SET NLS_DATE_FORMAT='DD-MM-YY HH24:MI';
ALTER SYSTEM CHECKPOINT;
ALTER SYSTEM SWITCH LOGFILE;
SET linesize 300
SELECT inst_id,
instance_number inst_no,
instance_name inst_name,
parallel,
status,
database_status db_status,
active_state state,
host_name host,
startup_time
FROM gv$instance
ORDER BY inst_id;
-- ==========================================================
-- VERIFICAR AS SESSÕES ATIVAS EM CADA NO
-- ==========================================================
break on instance_name skip 1
compute SUM of sessions on instance_name
SELECT
i.instance_name,
s.status,
COUNT(*) sessions
FROM
gv$instance i,
gv$session s
WHERE
i.inst_id = s.inst_id
AND s.username IS NOT NULL
GROUP BY
i.instance_name,
s.status
ORDER BY
i.instance_name,
s.status;
CLEAR break
CLEAR compute
-- ==========================================================
-- TABLESPACES
-- ==========================================================
CLEAR COLumns Computes Breaks
SET lines 200
SET pages 200
COL file_name for a50
COL tablespace_name for a30
COL status for a21
compute SUM of "Total(Mb)" on report
compute SUM of "Free(Mb)" on report
break on report
SELECT t.tablespace_name,
ts.CONTENTS,
ts.status,
Round(Nvl(t.bytes, 0) / 1024 / 1024, 1) "Total(Mb)",
Round(( Nvl(Nvl(f.free, ft.free), 0) / 1024 / 1024 ), 1) "Free(Mb)",
Round(( Nvl(Nvl(f.free, ft.free), 0) * 100 / t.bytes ), 1) "% Free",
Decode(( CASE
WHEN Round(( Nvl(Nvl(f.free, ft.free), 0) / 1024 / 1024 / 1024 )) >= 5
THEN 'OK'
ELSE 'NOK'
END ), 'OK', 'OK',
Decode(CONTENTS, 'UNDO', 'OK - UNDO TABLESPACE',
Decode(CONTENTS, 'TEMPORARY', 'OK - TEMP TABLESPACE',
Decode( Round( ( Nvl(Nvl(f.free, ft.free), 0) * 100 ) / t.bytes),
'0', 'CRITICAL',
'1', 'CRITICAL',
'2', 'CRITICAL',
'3', 'CRITICAL',
'4', 'CRITICAL',
'5', 'WARNING',
'6', 'WARNING',
'7', 'WARNING',
'8', 'WARNING',
'9', 'WARNING',
'OK')
)
)
) STATUS
FROM (SELECT d.tablespace_name,
SUM(d.bytes) bytes
FROM dba_data_files d
GROUP BY tablespace_name
UNION
SELECT d.tablespace_name,
SUM(d.bytes) bytes
FROM dba_temp_files d
GROUP BY tablespace_name) t,
(SELECT tablespace_name,
SUM(bytes) free
FROM dba_free_space
GROUP BY tablespace_name) f,
(SELECT tablespace_name,
SUM(bytes_free) free
FROM v$temp_space_header
GROUP BY tablespace_name) ft,
dba_tablespaces ts
WHERE t.tablespace_name = f.tablespace_name(+)
AND t.tablespace_name = ft.tablespace_name(+)
AND t.tablespace_name = ts.tablespace_name
ORDER BY 5;
-- ==========================================================
TAMANHO DO BANCO
-- ==========================================================
CLEAR COLumns
COL dados for a10
COL undo for a12
COL redo for a12
COL temp for a12
COL livre for a12
COL total for a12
SELECT to_char(SUM(dados) / 1048576, 'fm99g999g990') dados,
to_char(SUM(undo) / 1048576, 'fm99g999g990') undo,
to_char(SUM(redo) / 1048576, 'fm99g999g990') redo,
to_char(SUM(temp) / 1048576, 'fm99g999g990') temp,
to_char(SUM(free) / 1048576, 'fm99g999g990') livre,
to_char(SUM(dados + undo + redo + temp) / 1048576, 'fm99g999g990') total
FROM (
SELECT SUM(decode(substr(t.contents, 1, 1), 'P', bytes, 0)) dados,
SUM(decode(substr(t.contents, 1, 1), 'U', bytes, 0)) undo,
0 redo,
0 temp,
0 free
FROM dba_data_files f, dba_tablespaces t
WHERE f.tablespace_name = t.tablespace_name
UNION ALL
SELECT 0 dados,
0 undo,
0 redo,
SUM(bytes) temp,
0 free
FROM dba_temp_files f, dba_tablespaces t
WHERE f.tablespace_name = t.tablespace_name(+)
UNION ALL
SELECT 0 dados,
0 undo,
SUM(bytes * members) redo,
0 temp,
0 free
FROM v$log
UNION ALL
SELECT 0 dados,
0 undo,
0 redo,
0 temp,
SUM(bytes) free
FROM dba_free_space f, dba_tablespaces t
WHERE f.tablespace_name = t.tablespace_name AND
substr(t.contents, 1, 1) = 'P'
);
--
-- ==========================================================
-- STATUS DOS DATAFILES
-- ==========================================================
SET lines 1000
SET pages 2000
COL tablespace_name for a15
COL name for a60
COL status1 for a12
COL status2 for a12
COL status3 for a12
COL online_status for a12
COL status_backup for a12
COL recover for a7
COL error for a5
COL "FILE#" for 9999
SELECT df.tablespace_name,
d.FILE#,
d.NAME,
df.autoextensible,
df.bytes/1024/1024 "Total(Mb)",
d.status status1,
dh.STATUS status2,
df.status status3,
--df.online_status,
b.STATUS status_backup,
dh.RECOVER,
dh.ERROR
FROM v$datafile d,
dba_data_files df,
v$backup b,
v$datafile_header dh
WHERE d.FILE# = dh.FILE#(+)
AND d.FILE# = b.FILE#(+)
AND d.FILE# = df.file_id(+)
ORDER BY df.tablespace_name,d.NAME;
-- ==========================================================
-- CAMINHO DOS ARCHIVES / VALIDAR A AREA DE ARCHIVE
-- ==========================================================
archive log list;
-- ==========================================================
-- VERIFICAÇÃO DE OBJETOS INVÁLIDOS
-- ==========================================================
CLEAR COLumns
SELECT
owner,
object_type,
count(*) "QTD_INVALIDOS"
FROM dba_objects
WHERE status ='INVALID'
GROUP BY owner, object_type;
-- ==========================================================
-- ESTATISTICAS DAS TABELAS
-- ==========================================================
SELECT
owner,
trunc(last_analyzed) LAST_ANALYZED,
count(*)
FROM DBA_TABLES
GROUP BY owner, trunc(last_analyzed)
ORDER BY OWNER, LAST_ANALYZED;
-- ==========================================================
-- SESSOES WAIT
-- ==========================================================
CLEAR COLumns
SET LINESIZE 200
SET PAGESIZE 1000
COLUMN username FORMAT A20
COLUMN event FORMAT A30
SELECT NVL(s.username, '(oracle)') AS username,
s.sid,
s.serial#,
sw.event,
sw.wait_time,
sw.seconds_in_wait,
sw.state
FROM gv$session_wait sw,
gv$session s
WHERE s.sid = sw.sid AND sw.event not like 'SQL%' AND sw.event not like 'rdbms%'
ORDER BY sw.seconds_in_wait DESC;
-- ==========================================================
-- SESSOES COM MAIOR I/O
-- ==========================================================
CLEAR COLumns
COL sid for 9999
COL username for A16 heading 'Username'
COL osuser for A20 heading 'OS user'
COL logical_reads for 999,999,999,990 heading 'Logical reads'
COL physical_reads for 999,999,999,990 heading 'Physical reads'
COL hr for A6 heading 'HR'
SELECT s.sid,
s.username,
s.osuser,
i.block_gets + i.consistent_gets logical_reads,
i.physical_reads,
to_char(
(i.block_gets + i.consistent_gets - i.physical_reads) /
(i.block_gets + i.consistent_gets) * 100, '9990') || '%' hr
FROM gv$sess_io i, gv$session s
WHERE i.INST_ID = s.INST_ID AND
i.sid = s.sid AND
i.block_gets + i.consistent_gets > 200000
ORDER BY logical_reads;
-- ==========================================================
LISTA DE JOBS AGENDADOS NA DBA_JOBS BROKEN = N
-- ==========================================================
SET lines 100 pages 999
COL schema_user format a15
COL fails format 999
COL job for 999999
SELECT
job,
schema_user,
to_char(last_date, 'hh24:mi dd/mm/yy') last_run,
to_char(next_date, 'hh24:mi dd/mm/yy') next_run,
failures fails,
broken,
substr(what, 1, 15) what
FROM dba_jobs
WHERE BROKEN='N'
ORDER BY 4
/
-- ==========================================================
-- JOBS EM EXECUCAO AGENDADOS NA DBA_JOBS
-- ==========================================================
CLEAR COLUMNS
COL job FORM 999999
COL interval FORM a40
COL schema_user FORM a15
COL failures FORM 9999
ALTER SESSION SET nls_date_format='dd/mm/yyyy hh24:mi:ss';
SELECT sid,
job,
last_date,
last_sec,
this_date,
this_sec,
failures,
instance
FROM dba_jobs_running
ORDER BY job;
-- ==========================================================
LISTA DE JOBS AGENDADOS NA DBA_SCHEDULER_JOBS
-- ==========================================================
SELECT
JOB_NAME,
ENABLED,
TO_CHAR(NEXT_RUN_DATE,'DD-MM-YYHH24:MI:SS') PROXIMA_DATA,
RUN_COUNT,
FAILURE_COUNT
FROM DBA_SCHEDULER_JOBS ;
-- ==========================================================
JOBS EM EXECUCAO NA V$SCHEDULER_RUNNING_JOBS
-- ==========================================================
CLEAR COLUMNS
SET lines 1000 trims on
SELECT * FROM GV$SCHEDULER_RUNNING_JOBS ;
-- ==========================================================
-- ULTIMOS BACKUPS EXECUTADOS
-- ==========================================================
SELECT
substr(OPERATION, 1, 12) operation,
substr(STATUS, 1, 10) status,
MBYTES_PROCESSED,
INPUT_BYTES,
OUTPUT_BYTES,
substr(OPTIMIZED, 1, 10) optimized,
substr(OBJECT_TYPE, 1, 10) object_type,
substr(OUTPUT_DEVICE_TYPE, 1, 10) output_device_type,
START_TIME,
END_TIME,
rpad(round ((end_time - start_time) *1440 , 2), 8, ' ') Minutos,
lpad(round ((end_time - start_time) *1440 / 60 , 2) , 8, ' ') Horas
FROM
V$RMAN_STATUS
WHERE
start_time BETWEEN sysdate - 1 AND sysdate
ORDER BY
START_TIME;
-- ==========================================================
-- VERIFICACAO SE OS TABLESPACES ESTAO EM BEGIN BACLKUP
-- ==========================================================
SELECT DISTINCT status FROM v$backup;
-- ==========================================================
-- VERIFICAR SE EXISTE BACKUP EM EXECUCAO E O PROGRESSO
-- ==========================================================
SET lines 1000 trims on
SELECT
sid,
serial #,
sofar,
totalwork,
opname,
Round(sofar / totalwork * 100, 2) " % completado",
Round(time_remaining / 60) REMAINING,
Round(elapsed_seconds / 60) ELAPSED
FROM
gv$session_longops
WHERE
opname LIKE 'RMAN%'
AND opname NOT LIKE '%aggregate%'
AND totalwork != 0
AND sofar <> totalwork;
-- ==========================================================
-- Processos da instancia
-- ==========================================================
SET LINESIZE 190
COLUMN spid FORMAT A10
COLUMN username FORMAT A14
COLUMN PROGRAM FORMAT A40
COLUMN PROGRAM MACHINE A40
SELECT s.inst_id,
s.sid,
s.serial#,
p.spid,
s.username,
s.program, s.status, s.machine, to_char(s.LOGON_TIME,'dd-mm-yyyy HH24:MM') LOGON_TIME
FROM gv$session s
JOIN gv$process p ON p.addr = s.paddr AND p.inst_id = s.inst_id
WHERE s.type != 'BACKGROUND' ORDER BY s.STATUS;
-- ==========================================================
-- TRANSACOES LONGAS
-- ==========================================================
SET term on
SET verify off
SET feed on
CLEAR COLumns
COL sid form 999
COL serial# form 9999999999
COL sofar form 999,999,999
COL time_remaining form 999,999,999
COL username form a30
SELECT sid,
serial#,
totalwork,
sofar,
to_char(start_time,'dd/mm/yyyy hh24:mi:ss') start_time,
time_remaining "TEMPO_RESTANTE(S)",
time_remaining/60 "TEMPO_RESTANTE(MIN)",
time_remaining/60/60 "TEMPO_RESTANTE(HS)",
substr(username,1,20) username,
sql_address,
sql_id,
sql_hash_value
FROM gv$session_longops
WHERE time_remaining > 0
ORDER BY 6 desc ;
-- ==========================================================
-- VERIFICA LOCKS NO BANCO DE DADOS RAC
-- ==========================================================
SET lines 300
SET pages 50000
COL username format a12
COL sid format 999999
COL inst_id format 99999
COL sql_text format a36
COL status format a8
SELECT
f.INST_ID,
f.sid,
f.username,
f.STATUS,
f.BLOCKING_INSTANCE,
f.blocking_session,
f.lockwait,
f.SECONDS_IN_WAIT,
f.LAST_CALL_ET,
s.SQL_TEXT,
s.hash_value
FROM
(
SELECT
INST_ID,
sid,
username,
STATUS,
BLOCKING_INSTANCE,
blocking_session,
lockwait,
SECONDS_IN_WAIT,
LAST_CALL_ET,
SQL_HASH_VALUE
FROM
gv$session
WHERE
blocking_session IS NOT NULL
AND SECONDS_IN_WAIT > 0
UNION ALL
SELECT
A.INST_ID,
A.sid,
A.username,
A.STATUS,
a.BLOCKING_INSTANCE,
A.blocking_session,
A.lockwait,
A.SECONDS_IN_WAIT,
A.LAST_CALL_ET,
A.SQL_HASH_VALUE
FROM
gv$session A,
gv$session B
WHERE
A.sid = B.blocking_session
AND A.INST_ID = b.BLOCKING_INSTANCE
)
f,
gv$sqlarea s
WHERE
f.inst_id = s.inst_id
AND
f.sql_hash_value = s.hash_value;
-- ==========================================================
-- TOP 10 SESSIONS PARA O NÓ 1
-- ==========================================================
SET LINESIZE 500
SET PAGESIZE 1000
SET VERIFY OFF
COLUMN username FORMAT A15
COLUMN machine FORMAT A25
COLUMN logon_time FORMAT A30
COL osuser for a10
SELECT NVL(a.username, '(oracle)') AS username,
a.osuser,
a.sid,
a.serial#,
a.lockwait,
a.status,
a.machine,
a.program,
TO_CHAR(a.logon_Time,'DD-MON-YYYY HH24:MI:SS') AS logon_time
FROM Gv$session a,
v$sesstat c,
v$statname d
WHERE a.sid = c.sid
AND A.INST_ID=1
AND c.statistic# = d.statistic#
AND d.name = DECODE(UPPER('c.value'), 'READS', 'session logical reads',
'EXECS', 'execute count',
'CPU', 'CPU used by this session',
'CPU used by this session')
AND rownum < 11
ORDER BY c.value DESC;
-- ==========================================================
-- TOP 10 SESSIONS PARA O NÓ 2
-- ==========================================================
SET LINESIZE 500
SET PAGESIZE 1000
SET VERIFY OFF
COLUMN username FORMAT A15
COLUMN machine FORMAT A25
COLUMN logon_time FORMAT A30
COL osuser for a10
SELECT NVL(a.username, '(oracle)') AS username,
a.osuser,
a.sid,
a.serial#,
a.lockwait,
a.status,
a.machine,
a.program,
TO_CHAR(a.logon_Time,'DD-MON-YYYY HH24:MI:SS') AS logon_time
FROM Gv$session a,
v$sesstat c,
v$statname d
WHERE a.sid = c.sid
AND A.INST_ID=2
AND c.statistic# = d.statistic#
AND d.name = DECODE(UPPER('c.value'), 'READS', 'session logical reads',
'EXECS', 'execute count',
'CPU', 'CPU used by this session',
'CPU used by this session')
AND rownum < 11
ORDER BY c.value DESC;
-- ==========================================================
-- MEMORIA ALOCADA POR SESSAO PARA O NÓ 1
-- ==========================================================
SET LINESIZE 200
COLUMN username FORMAT A20
COLUMN module FORMAT A30
SELECT NVL(a.username,'(oracle)') AS username,
a.module,
A.OSUSER,
a.program,
Trunc(b.value/1024/1024) AS memory_MB
FROM gv$session a,
v$sesstat b,
v$statname c
WHERE a.sid = b.sid
AND b.statistic# = c.statistic#
AND c.name = 'session pga memory'
AND a.program IS NOT NULL AND Trunc(b.value/1024/1024) > 0 AND a.inst_id=1
ORDER BY b.value DESC;
-- ==========================================================
-- MEMORIA ALOCADA POR SESSAO PARA O NÓ 2
-- ==========================================================
SET LINESIZE 200
COLUMN username FORMAT A20
COLUMN module FORMAT A30
SELECT NVL(a.username,'(oracle)') AS username,
a.module,
A.OSUSER,
a.program,
Trunc(b.value/1024/1024) AS memory_MB
FROM gv$session a,
v$sesstat b,
v$statname c
WHERE a.sid = b.sid
AND b.statistic# = c.statistic#
AND c.name = 'session pga memory'
AND a.program IS NOT NULL AND Trunc(b.value/1024/1024) > 0 AND a.inst_id=2
ORDER BY b.value DESC;
-- ==========================================================
-- VERIFICACAO DOS LOGFILES PARA O NÓ 1
-- ==========================================================
CLEAR COLUMNS
COL member for a60
SET pagesize 5000
SET lines 1000 trims on
SELECT
f.MEMBER,
f.GROUP #,
l.members,
l.bytes,
l.SEQUENCE #,
f.status status_1,
l.status status_2,
f.IS_RECOVERY_DEST_FILE
FROM
gv $ logfile f
JOIN
gv $ log l
ON l.GROUP # = f.GROUP #
AND l.inst_id = 1
AND f.inst_id = 1
ORDER BY
GROUP # ;
-- ==========================================================
-- VERIFICACAO DOS LOGFILES PARA O NÓ 2
-- ==========================================================
CLEAR COLUMNS
COL member for a60
SET pagesize 5000
SET lines 1000 trims on
SELECT
f.MEMBER,
f.GROUP #,
l.members,
l.bytes,
l.SEQUENCE #,
f.status status_1,
l.status status_2,
f.IS_RECOVERY_DEST_FILE
FROM
gv $ logfile f
JOIN
gv $ log l
ON l.GROUP # = f.GROUP #
AND l.inst_id = 1
AND f.inst_id = 2
ORDER BY
GROUP # ;
-- Remember that this document is a quick reference, and not an exhaustive list of all commands for managing your RAC environment.
-- =======================================================================
-- Cluster Related Commands
-- =======================================================================
crs_stat -t Shows HA resource status (hard to read)
crsstat Ouptut of crs_stat -t formatted nicely
ps -ef|grep d.bin crsd.bin evmd.bin ocssd.bin
crsctl check crs CSS,CRS,EVM appears healthy
crsctl stop crs Stop crs and all other services
crsctl disable crs* Prevents CRS from starting on reboot
crsctl enable crs* Enables CRS start on reboot
crs_stop -all Stops all registered resources
crs_start -all Starts all registered resources
crsctl stop cluster -all Stops the cluster in all nodes
crsctl start cluster -all Starts the cluster in all nodes
* These commands update the file /etc/oracle/scls_scr/[node]/root/crsstart which contains the string “enable” or “disable” as appropriate.
-- =======================================================================
-- Database Related Commands
-- =======================================================================
srvctl start instance -d [db_name] -i [inst_name] Starts an instance
srvctl start database -d [db_name] Starts all instances
srvctl stop database -d [db_name] Stops all instances, closes database
srvctl stop instance -d [db_name] -i [inst_name] Stops an instance
srvctl start service -d [db_name] -s [service_name] Starts a service
srvctl stop service -d [db_name] -s [service_name] Stops a service
srvctl status service -d [db_name] Checks status of a service
srvctl status instance -d [db_name] -i [inst_name] Checks an individual instance
srvctl status database -d [db_name] Checks status of all instances
srvctl start nodeapps -n [node_name] Starts gsd, vip, listener, and ons
srvctl stop nodeapps -n [node_name] Stops gsd, vip and listener
-- =======================================================================
-- Basic RAC Management Commands
-- =======================================================================
ps -ef|grep d.bin Command to verify that the CRS background processes are actually running
crs_stat -t Command shows us the status of each registered resource in the cluster
crsstat Command shows output of crs_stat t formatted nicely
crsctl check crs Command verifies that the above background daemons are functioning
crsctl enable crs Root user to run this command. command to enable automatic re-start of CRS
crsctl disable crs Root user to run this command. Command will prevent CRS from starting on a reboot. Note there is no return output from the command.
crsctl stop crs Root user to run this command. It will stop all HA resources on the local node, and it will also stop the above mentioned background daemons
crsctl start crs Root user to run this command. It will start all HA resources on the local node
crs_stop -all script that stops the registered resources and leaves the CRS running. This includes all services in the cluster, so it will bring down all registered resources on all nodes
srvctl start nodeapps -n (node) command can shut down the nodeapps by replacing start with stop.
srvctl start asm -n (node)
srvctl start instance -d (database) -I (instance)
srvctl start service -d (database) -s (service)
-- =======================================================================
-- Starting the Oracle RAC Environment
-- =======================================================================
srvctl start nodeapps -n [hostname1]
srvctl start nodeapps -n [hostname2]
srvctl start asm -n [hostname1]
srvctl start asm -n [hostname2]
srvctl start instance -d db_name -i instancename1
srvctl start instance -d db_name -i instancename2
srvctl start database -d [database name]
srvctl start service -d [database name] -s [service name]
emctl start dbconsole
crs_stat -t
-- =======================================================================
-- Stopping the Oracle RAC Environment
-- =======================================================================
/* The first step is to stop the Oracle instance. Once the instance (and related services) are down, then bring down the ASM instance. Finally, shut down the node applications (Virtual IP, GSD, TNS Listener, and ONS). */
emctl stop dbconsole
srvctl stop service -d [database name] -s [service name]
srvctl stop instance -d db_name -i instancename1
srvctl stop instance -d db_name -i instancename2
or
srvctl stop database -d db_name -o immediate to bring all instances down
srvctl stop listener -n hostname1
srvctl stop listener -n hostname2
srvctl stop asm -n [hostname1]
srvctl stop asm -n [hostname2]
srvctl stop nodeapps -n [hostname1]
srvctl stop nodeapps -n [hostname2]
crs_stat -t
-- =======================================================================
-- Grid Control Agent
-- =======================================================================
Set environment to ‘agent’ using . oraenv
$ORACLE_HOME/bin/emctl start agent
$ORACLE_HOME/bin/emctl stop agent
-- =======================================================================
-- Verify and Explore the RAC Cluster and RAC Database Environment
-- =======================================================================
-- Check the status of application resources --
crs_stat -t
Name Type Target State Host
------------------------------------------------------------
ora.devdb.db application ONLINE ONLINE rac1
ora....b1.inst application ONLINE ONLINE rac1
ora....b2.inst application ONLINE ONLINE rac2
ora....SM1.asm application ONLINE ONLINE rac1
ora....C1.lsnr application ONLINE ONLINE rac1
ora.rac1.gsd application ONLINE ONLINE rac1
ora.rac1.ons application ONLINE ONLINE rac1
ora.rac1.vip application ONLINE ONLINE rac1
ora....SM2.asm application ONLINE ONLINE rac2
ora....C2.lsnr application ONLINE ONLINE rac2
ora.rac2.gsd application ONLINE ONLINE rac2
ora.rac2.ons application ONLINE ONLINE rac2
ora.rac2.vip application ONLINE ONLINE rac2
-- Status of all instances and services --
srvctl status database -d devdb
Instance devdb1 is running on node rac1
Instance devdb2 is running on node rac2
-- Status of a single instance --
srvctl status instance -d devdb -i devdb2
Instance devdb2 is running on node rac2
-- Status of node applications on a particular node --
srvctl status nodeapps -n rac1
VIP is running on node: rac1
GSD is running on node: rac1
Listener is running on node: rac1
ONS daemon is running on node: rac1
srvctl status nodeapps -n rac2
VIP is running on node: rac2
GSD is running on node: rac2
Listener is running on node: rac2
ONS daemon is running on node: rac2
-- Status of an ASM instance --
srvctl status asm -n rac1
ASM instance +ASM1 is running on node rac1.
srvctl status asm -n rac2
ASM instance +ASM2 is running on node rac2.
-- List all configured databases --
srvctl config database
devdb
-- Display configuration for our RAC database --
srvctl config database -d devdb
rac1 devdb1 /u01/app/oracle/product/10.2.0/db_1
rac2 devdb2 /u01/app/oracle/product/10.2.0/db_1
-- Display the configuration for node applications - (VIP, GSD, ONS, Listener) --
srvctl config nodeapps -n rac1 -a -g -s -l
VIP exists.: /rac1-vip/192.168.2.31/255.255.255.0/eth0
GSD exists.
ONS daemon exists.
Listener exists.
-- Display the configuration for the ASM instance(s) --
srvctl config asm -n rac1
+ASM1 /u01/app/oracle/product/10.2.0/db_1
-- Check the status of Oracle Clusterware --
[rac1-]crsctl check crs
CSS appears healthy
CRS appears healthy
EVM appears healthy
[rac2-] crsctl check crs
CSS appears healthy
CRS appears healthy
EVM appears healthy
-- List the RAC instances --
SELECT inst_id, instance_number inst_no, instance_name inst_name, parallel, status, database_status db_status, active_state state, host_name host
FROM gv$instance ORDER BY inst_id;
INST_ID INST_NO INST_NAME PARALLEL STATUS DB_STATUS STATE HOST
__________ __________ ____________ ___________ _________ ____________ _________ ____________
1 1 cdbprod1 YES OPEN ACTIVE NORMAL rac1
2 2 cdbprod2 YES OPEN ACTIVE NORMAL rac2
-- Check connectivity --
/* Verify that you are able to connect to the instances and service on each node. */
sqlplus system@devdb1
sqlplus system@devdb2
sqlplus system@devdb
-- Check database configuration --
[rac1-]export ORACLE_SID=devdb1
[rac1-]sqlplus / as sysdba
show sga
Total System Global Area 209715200 bytes
Fixed Size 1218556 bytes
Variable Size 104859652 bytes
Database Buffers 100663296 bytes
Redo Buffers 2973696 bytes
-- Check all data files which are in the disk group --
select name from v$datafile
union
select member from v$logfile
union
select name from v$controlfile
union
select name from v$tempfile;
NAME
______________________________________________________________
++RECOVERYDEST/devdb/controlfile/current.256.578676737
++RECOVERYDEST/devdb/onlinelog/group_1.257.578676745
++RECOVERYDEST/devdb/onlinelog/group_2.258.578676759
++RECOVERYDEST/devdb/onlinelog/group_3.259.578682963
++RECOVERYDEST/devdb/onlinelog/group_4.260.578682987
++DG1/devdb/controlfile/current.256.578676735
++DG1/devdb/datafile/example.263.578676853
++DG1/devdb/datafile/indx.270.578685723
++DG1/devdb/datafile/sysaux.261.578676829
++DG1/devdb/datafile/system.259.578676767
++DG1/devdb/datafile/undotbs1.260.578676809
++DG1/devdb/datafile/undotbs1.271.578685941
++DG1/devdb/datafile/undotbs2.264.578676867
++DG1/devdb/datafile/undotbs2.272.578685977
++DG1/devdb/datafile/users.265.578676887
++DG1/devdb/datafile/users.269.578685653
++DG1/devdb/onlinelog/group_1.257.578676739
++DG1/devdb/onlinelog/group_2.258.578676753
++DG1/devdb/onlinelog/group_3.266.578682951
++DG1/devdb/onlinelog/group_4.267.578682977
++DG1/devdb/tempfile/temp.262.578676841
select file_name,bytes/1024/1024 from dba_data_files;
FILE_NAME BYTES/1024/1024
_______________________________________________ __________________
/ora01/oradata/cdbprod/cdbprod/users01.dbf 5
+DG1/devdb/datafile/users.259.606468449 5
+DG1/devdb/datafile/sysaux.257.606468447 240
+DG1/devdb/datafile/undotbs1.258.606468449 30
+DG1/devdb/datafile/system.256.606468445 480
+DG1/devdb/datafile/undotbs2.264.606468677 25
select group#, type, member, is_recovery_dest_file from v$logfile order by group#;
GROUP# TYPE MEMBER IS_RECOVERY_DEST_FILE
_________ ________ ___________________________________________________ ________________________
1 ONLINE +RECOVERYDEST/devdb/onlinelog/group_1.257.606468581 YES
1 ONLINE +DG1/devdb/onlinelog/group_1.261.606468575 NO
2 ONLINE +RECOVERYDEST/devdb/onlinelog/group_2.258.606468589 YES
2 ONLINE +DG1/devdb/onlinelog/group_2.262.606468583 NO
3 ONLINE +DG1/devdb/onlinelog/group_3.265.606468865 NO
3 ONLINE +RECOVERYDEST/devdb/onlinelog/group_3.259.606468875 YES
4 ONLINE +DG1/devdb/onlinelog/group_4.266.606468879 NO
4 ONLINE +RECOVERYDEST/devdb/onlinelog/group_4.260.606468887 YES
[rac1-] export ORACLE_SID=+ASM1
[rac1-] sqlplus / as sysdba
SQL] show sga
Total System Global Area 92274688 bytes
Fixed Size 1217884 bytes
Variable Size 65890980 bytes
ASM Cache 25165824 bytes
SQL] show parameter asm_disk
NAME TYPE VALUE
------------------------------ ----------- ------------------------
asm_diskgroups string DG1, RECOVERYDEST
asm_diskstring string
select group_number, name, allocation_unit_size alloc_unit_size, state, type, total_mb, usable_file_mb from v$asm_diskgroup;
ALLOC USABLE
GROUP UNIT TOTAL FILE
NUMBER NAME SIZE STATE TYPE MB MB
------ ------------ -------- ------- ------ ------ -------
1 DG1 1048576 MOUNTED NORMAL 6134 1868
2 RECOVERYDEST 1048576 MOUNTED EXTERN 2047 1713
select name, path, header_status, total_mb free_mb, trunc(bytes_read/1024/1024) read_mb,trunc(bytes_written/1024/1024) write_mb from v$asm_disk;
NAME PATH HEADER_STATU FREE_MB READ_MB WRITE_MB
-------- ------------------ ------------------------ ----------------- ----------------- -----------------
VOL1 ORCL:VOL1 MEMBER 3067 229 1242
VOL2 ORCL:VOL2 MEMBER 3067 164 1242
VOL3 ORCL:VOL3 MEMBER 2047 11 354
-- Check flash recovery area space usage --
select * from v$recovery_file_dest;
NAME SPACE_LIMIT SPACE_USED SPACE_RECLAIMABLE NUMBER_OF_FILES CON_ID
_____________ ________________ ______________ ____________________ __________________ _________
+RECOVERYDEST 1572864000 331366400 0 7 0
select * from v$flash_recovery_area_usage;
FILE_TYPE PERCENT_SPACE_USED PERCENT_SPACE_RECLAIMABLE NUMBER_OF_FILES
------------ ------------------ ------------------------- ---------------
CONTROLFILE .97 0 1
ONLINELOG 20 0 6
ARCHIVELOG 0 0 0
BACKUPPIECE 0 0 0
IMAGECOPY 0 0 0
FLASHBACKLOG 0 0 0
set lines 300
set pages 50000
col username format a12
col sid format 999999
col inst_id format 99999
col sql_text format a36
col status format a8
SELECT
f.INST_ID,
f.sid,
f.username,
f.STATUS,
f.BLOCKING_INSTANCE,
f.blocking_session,
f.lockwait,
f.SECONDS_IN_WAIT,
f.LAST_CALL_ET,
s.SQL_TEXT,
s.hash_value
FROM (SELECT
INST_ID,
sid,
username,
STATUS,
BLOCKING_INSTANCE,
blocking_session,
lockwait,
SECONDS_IN_WAIT,
LAST_CALL_ET,
SQL_HASH_VALUE
FROM gv$session WHERE blocking_session is not null and SECONDS_IN_WAIT > 0
UNION ALL
SELECT
A.INST_ID,
A.sid,
A.username,
A.STATUS,
A.BLOCKING_INSTANCE,
A.blocking_session,
A.lockwait,
A.SECONDS_IN_WAIT,
A.LAST_CALL_ET,
A.SQL_HASH_VALUE
FROM gv$session A, gv$session B
WHERE
A.sid = B.blocking_session
AND
A.INST_ID = b.BLOCKING_INSTANCE) f,
gv$sqlarea s
WHERE
f.inst_id = s.inst_id and f.sql_hash_value = s.hash_value;
SELECT 'ALTER ' || OBJECT_TYPE || ' ' || OWNER || '.' || OBJECT_NAME || ' COMPILE;' FROM ALL_OBJECTS WHERE STATUS = 'INVALID' AND OWNER = 'SCOTT' AND OBJECT_TYPE != 'PACKAGE BODY';
SELECT 'ALTER PACKAGE ' || OWNER || '.' || OBJECT_NAME || ' COMPILE BODY;' FROM ALL_OBJECTS WHERE STATUS = 'INVALID' AND OWNER = 'SCOTT' AND OBJECT_TYPE = 'PACKAGE BODY';
SQL> @$ORACLE_HOME/rdbms/admin/utlrp.sql
COL OBJECT_NAME FORMAT A30
SET ECHO OFF FEED OFF HEAD OFF VERIFY OFF TERMOUT OFF
SPOOL C:\RECOMP.SQL
SELECT 'ALTER ' || DECODE( OBJECT_TYPE, 'PACKAGE BODY',
'PACKAGE ' || OWNER || '.' || OBJECT_NAME || ' COMPILE BODY;',
OBJECT_TYPE || ' ' || OWNER || '.' || OBJECT_NAME || ' COMPILE;' ) INVALIDOS
FROM DBA_OBJECTS
WHERE STATUS = 'INVALID'
AND OWNER = UPPER( '&&1.' )
/
SPOOL OFF
SET ECHO OFF FEED 6 HEAD ON
SPOOL C:\RECOMP.LOG
@c:\recomp.sql
HOST DEL C:\RECOMP.SQL
SPOOL OFF
SET ECHO OFF FEED OFF HEAD OFF VERIFY OFF TERMOUT ON
SPOOL C:\RECOMP.SQL
SELECT 'SHOW ERROR ' ||OBJECT_TYPE || ' ' || OWNER || '.' || OBJECT_NAME || ';' || CHR(10)||'PROMPT' INVALIDOS
FROM DBA_OBJECTS
WHERE STATUS = 'INVALID'
AND OWNER = UPPER( '&&1.' )
/
SPOOL OFF
SET ECHO OFF FEED 6 HEAD ON
SPOOL C:\SHOWERROR.LOG
@c:\recomp.sql
HOST DEL C:\RECOMP.SQL
SPOOL OFF
SELECT object_name, object_type, owner
FROM dba_objects
WHERE status = 'INVALID'
AND OWNER = UPPER( '&&1.' )
/
SET VERIFY ON
DELETE PLAN_TABLE WHERE STATEMENT_ID = '&1.'
/
INSERT INTO PLAN_TABLE
(
ACCESS_PREDICATES,BYTES,CARDINALITY,COST,CPU_COST,DISTRIBUTION,FILTER_PREDICATES,ID,IO_COST
,OBJECT_NAME,OBJECT_NODE,OBJECT_OWNER,OPERATION,OPTIMIZER,OPTIONS,OTHER,OTHER_TAG,PARENT_ID,PARTITION_ID
,PARTITION_START,PARTITION_STOP,POSITION,SEARCH_COLUMNS,TEMP_SPACE,STATEMENT_ID,REMARKS,TIMESTAMP
)
SELECT
ACCESS_PREDICATES,BYTES,CARDINALITY,COST,CPU_COST,DISTRIBUTION,FILTER_PREDICATES,ID,IO_COST
,OBJECT_NAME,OBJECT_NODE,OBJECT_OWNER,OPERATION,OPTIMIZER,OPTIONS,OTHER,OTHER_TAG,PARENT_ID,PARTITION_ID
,PARTITION_START,PARTITION_STOP,POSITION,SEARCH_COLUMNS,TEMP_SPACE,HASH_VALUE,ADDRESS,SYSDATE
FROM V$SQL_PLAN
WHERE HASH_VALUE = '&1.' AND ADDRESS = '&2.' -- AND CHILD_NUMBER = 0 -- PEGANDO A PRIMEIRA CÓPIA? PROBLEMAS DE PERFORMANCE QUANDO HÁ MUITAS COPIAS
AND CHILD_NUMBER = (SELECT MAX(CHILD_NUMBER) FROM V$SQL_PLAN WHERE HASH_VALUE = '&1.' AND ADDRESS = '&2.' )
/
SET VERIFY OFF FEED OFF LINES 180
COL "USER" FORMAT A40
COL OPNAME FORMAT A35 HEAD "OPERACAO"
COL INICIO FORMAT A11
COL RESTANTE FORMAT A11
COL PASSADO FORMAT A11
COL PERCENTUAL FORMAT A7
COL OBJETO FORMAT A50
BREAK ON USER SKIP PAGE
CLEAR BREAK
SELECT
RPAD( USERNAME || ' '''||SID||','||SERIAL#||'''', 40, ' ' ) "USER"
,UPPER(OPNAME) OPNAME
,TO_CHAR(START_TIME, 'DD/MM HH24:MI' ) INICIO
,TO_CHAR(TRUNC(TIME_REMAINING/3600),'fm9900')||':'||TO_CHAR(TO_DATE('1','J')+(MOD(TIME_REMAINING,3600)/86400),'MI:SS') RESTANTE
,TO_CHAR(TRUNC(ELAPSED_SECONDS/3600),'fm9900')||':'||TO_CHAR(TO_DATE('1','J')+(MOD(ELAPSED_SECONDS,3600)/86400),'MI:SS') PASSADO
,TO_CHAR(SOFAR*100/DECODE(TOTALWORK, 0, 1, TOTALWORK), '990D00' ) PERCENTUAL
,SUBSTR( TARGET, 1, 40 ) OBJETO
FROM GV$SESSION_LONGOPS
WHERE SOFAR < TOTALWORK
AND USERNAME LIKE UPPER( '&1.' )
ORDER BY USERNAME, OBJETO, PERCENTUAL DESC, START_TIME
/
PROMPT
SET FEED 6 VERIFY ON
set pagesize 200
set linesize 150
column os_username format a25
column username format a25
column userhost format a40
column timestamp format a20
column returncode format 9999999999
SELECT
os_username
,username
,userhost
,to_char(timestamp,'mm/dd/yyyy hh24:mi:ss') timestamp
--,action_name
,returncode
--,terminal
FROM dba_audit_session
WHERE action_name = 'LOGON'
and username like '%FOLHACD%'
and returncode > 0
ORDER BY timestamp
/
set verify off
define p_owner=upper('&1.')
define p_table=upper('&2.')
col table_name format a30
col column_name format a30
col segment_name format a30
with lobs3 as
(
SELECT
a.owner
,a.table_name
,a.column_name
,a.segment_name
,a.tablespace_name
,a.chunk
,a.logging
,a.in_row
,a.cache
,case when bitand(l.flags, 32)=0 then l.pctversion$ else null end pctversion
,case when bitand(l.flags, 32)=32 then l.retention else null end retention
FROM dba_objects o
join sys.lob$ l on (o.object_id = l.lobj#)
join dba_lobs a on ( a.owner= o.owner and a.segment_name = o.object_name )
WHERE owner = &p_owner.
)
SELECT
l.owner
,l.table_name
,l.column_name
,l.pctversion
,l.retention
,l.chunk
,l.in_row
,l.cache
,l.tablespace_name
,l.segment_name
FROM lobs3 l
WHERE l.table_name like &p_table.
/
undefine p_owner p_table 1 2
set verify on
set define on verify off long 200 lines 300 pages 400 feed off
col owner format a23 Head "Owner"
col username format a30 Head "Connects To"
col db_link format a38 Head "Database Link"
col host format a50 word_wrap Head "Connect Description"
col CREATED Head "Created"
SELECT owner, db_link, username, created, host
FROM dba_db_links
WHERE owner LIKE upper( '&1.' )
col host clear
col db_link clear
col username clear
col owner clear
PROMPT
set lines 200
COLUMN ONWER HEADING 'Owner' FORMAT A24
COLUMN ROWNER HEADING 'GroupOwner' FORMAT A24
COLUMN NAME HEADING MV FORMAT A28
COLUMN RNAME HEADING Group FORMAT A28
COLUMN BROKEN HEADING 'Broken?' FORMAT A7
COLUMN next_refresh HEADING 'Next Refresh'
COLUMN INTERVAL HEADING 'Interval' FORMAT a40
SELECT
ROWNER
,RNAME
,BROKEN
,TO_CHAR(NEXT_DATE, 'DD-MON-YYYY HH:MI:SS AM') next_refresh
,INTERVAL
FROM DBA_REFRESH
--WHERE INTERVAL <> 'null'
ORDER BY 1
/
SELECT
OWNER
,RNAME
,NAME
,BROKEN
,TO_CHAR(NEXT_DATE, 'DD-MON-YYYY HH:MI:SS AM') next_refresh
,INTERVAL
FROM DBA_REFRESH_CHILDREN
--WHERE INTERVAL <> 'null'
ORDER BY 1
/
PROMPT
SELECT OWNER, NAME, RNAME, REFGROUP, JOB, NEXT_DATE FROM DBA_REFRESH_CHILDREN WHERE NAME = 'VIWMRHTDEXT';
SELECT * FROM DBA_REFRESH WHERE RNAME = 'SG_CD03FOL_MUITOGRANDES5';
SELECT * FROM DBA_MVIEW_REFRESH_TIMES WHERE NAME = 'VIWMRHTDEXT';
SELECT
QUERY
,REFRESH_MODE
,REFRESH_METHOD
,BUILD_MODE
,FAST_REFRESHABLE
,LAST_REFRESH_TYPE
,LAST_REFRESH_DATE
,STALENESS
FROM DBA_MVIEWS
WHERE MVIEW_NAME = 'VIWMRHTDEXT';
SET ECHO OFF
SET VERIFY OFF
SET LINESIZE 300
COL PRIVILEGE FOR A25
COL GRANTEE FOR A20
COL TABLE_NAME FOR A40
COL OWNER FOR A10
ACCEPT USUARIO PROMPT "Digite o nome do USUÁRIO: "
PROMPT VERIFICA OS PRIVILÉGIOS DO USUÁRIO EM TABELAS, ROLES e de SISTEMA
PROMPT
PROMPT ##
PROMPT PRIVILÉGIOS DE ROLES
PROMPT ##
SELECT GRANTEE, GRANTED_ROLE FROM DBA_ROLE_PRIVS WHERE GRANTEE = UPPER('&USUARIO')
/
PROMPT ##
PROMPT PRIVILÉGIOS DE TABELAS
PROMPT ##
SELECT GRANTEE, OWNER, TABLE_NAME, PRIVILEGE FROM DBA_TAB_PRIVS WHERE GRANTEE = UPPER('&USUARIO')
/
PROMPT ##
PROMPT PRIVILÉGIOS DE SISTEMAS
PROMPT ##
SELECT GRANTEE, PRIVILEGE FROM DBA_SYS_PRIVS WHERE GRANTEE = UPPER('&USUARIO')
/
SET LINES 120
COL RESOURCE_NAME HEADING "Recurso"
COL CURRENT_UTILIZATION HEADING "Valor|Corrente"
COL MAX_UTILIZATION HEADING "Valor|Máximo"
COL INITIAL_ALLOCATION HEADING "Valor|Inicial" JUSTIFY R
COL LIMIT_VALUE HEADING "Valor|Limite" JUSTIFY R
COL "%Curr" FORMAT A7 JUSTIFY R
SELECT V.*
FROM
(
SELECT L.*,
TO_CHAR( NVL( L.CURRENT_UTILIZATION * 100 / DECODE( TRIM(L.LIMIT_VALUE), 'UNLIMITED', NULL, 0,NULL, L.LIMIT_VALUE ), 0 ), '990D00' ) "%Curr"
FROM GV$RESOURCE_LIMIT L
WHERE L.RESOURCE_NAME NOT LIKE 'lm%'
AND L.RESOURCE_NAME <> '_lm_procs'
ORDER BY "%Curr" DESC
) V
WHERE V."%Curr" > 0
ORDER BY RESOURCE_NAME, INST_ID
/
@data
col logon_time for a20
col block for 99
col id1 for 9999999
col ctime for 9999999
col lmode for 99
col request for 99
col username for a15
SELECT /*+rule*/ s.sid, s.username, s.process, s.sql_id, s.prev_sql_id, s.status, s.server, s.logon_time, l.id1, l.lmode, l.request, l.ctime, l.block
FROM v$session s
join v$lock l on (l.sid = s.sid)
WHERE request=6
union
SELECT /*+rule*/ s.sid, s.username, s.process, s.sql_id, s.prev_sql_id, s.status, s.server, s.logon_time, l.id1, l.lmode, l.request, l.ctime, l.block
FROM v$session s
join v$lock l on (l.sid = s.sid)
WHERE id1 in
(SELECT /*+rule*/ id1
FROM v$lock
WHERE request=6)
ORDER BY id1, lmode desc;
COL TABLESPACE_NAME FORMAT A16
COL SEGMENT_NAME FORMAT A30
SET VERIFY OFF
SELECT E.TABLESPACE_NAME, E.SEGMENT_NAME,
TO_CHAR( SUM(E.BYTES)/1048576, '999990D00' ) " SIZE(MB)",
COUNT(*) FRAGS,
TO_CHAR( MAX(S.NEXT_EXTENT)/1048576, '999990D00' ) " NEXT(MB)"
FROM DBA_EXTENTS E, DBA_SEGMENTS S
WHERE E.OWNER=S.OWNER
AND E.SEGMENT_NAME=S.SEGMENT_NAME
AND E.TABLESPACE_NAME=S.TABLESPACE_NAME
AND E.OWNER=UPPER('&1.')
AND S.OWNER=UPPER('&1.')
AND E.TABLESPACE_NAME LIKE UPPER('&2.%')
AND S.TABLESPACE_NAME LIKE UPPER('&2.%')
GROUP BY E.TABLESPACE_NAME, E.SEGMENT_NAME
ORDER BY E.TABLESPACE_NAME, 3
/
SET VERIFY ON
col sql_text format a60 head "SQL Text" trunc
col error_message format a40 head "Error"
col ident format a17 head "User (Sess,@Inst)"
col name format a35
SELECT
(SELECT u.username FROM all_users u WHERE u.user_id = r.user_id)||'('||session_id||',@'||instance_id||')' ident
,to_char( to_date(suspend_time, 'mm/dd/yy hh24:mi:ss' ), 'dd/mm hh24:mi' ) "Suspendido"
,to_char( to_date(resume_time, 'mm/dd/yy hh24:mi:ss' ), 'dd/mm hh24:mi' ) "Reiniciado"
,timeout "TimeOut"
,nullif(error_number||' - '|| error_msg, '0 - ' ) error_message
,trim(sql_text) sql_text
FROM dba_resumable r;
alter session set nls_date_format = 'dd/mm/yyyy hh24:mi:ss'
/
set head off
SELECT '************************************'||chr(10)||
' Maquina : '||host_name||chr(10)||
' Banco : '||instance_name||chr(10)||
' Versao : '||version||chr(10)||
' Aberto em : '||startup_time||chr(10)||
' Usuario : '||sys_context('USERENV','SESSION_USER')||chr(10)||
'************************************'
FROM v$instance
/
set head on
SET VERIFY OFF SERVEROUT ON FEEDBACK OFF UNDERLINE '~' LINES 142
col st1 format a14 heading "Startup Time"
col st2 format a14 heading "System Date"
col st3 format a12 heading "Running Time"
col st4 format a12 heading "Running Secs" noprint
col blocked format a7
SELECT
inst_id, instance_name,
to_char( startup_time, 'dd/mm/yy hh24"h"mi' ) st1,
to_char( sysdate, 'dd/mm/yy hh24"h"mi' ) st2,
lpad( to_char( trunc(sysdate,'YEAR') + (sysdate-startup_time-1),
decode( trunc( sysdate-startup_time, 0 ), 0, '"0d "hh24"h"mi', 'fmddd"d "fmhh24"h"mi' ) ), 12, ' ' ) st3,
to_char( (sysdate-startup_time)*24*60*60, '999g999g990' ) st4
,status
,database_status
--,blocked
,logins
,archiver
FROM gv$instance
ORDER BY INST_ID
/
PROMPT
SET FEEDBACK 6 UNDERLINE '-'
accept ts_ind prompt 'Informe a Tablespace de Indices:'
col owner format a10
col segment_name format a25
col tablespace_name format a20
set linesize 200
set pagesize 1000
SET HEADING OFF
SELECT 'ALTER INDEX '|| Owner||'.'|| segment_name || CHR(10) ||
'REBUILD TABLESPACE ' || UPPER( '&TS_IND' ) || ';'
FROM dba_segments
WHERE segment_type like '%INDEX%'
and owner not in ( 'SYS', 'SYSTEM')
and tablespace_name != UPPER( '&TS_IND' );
SET HEADING ON FEEDBACK ON
SELECT view_definition
FROM v$fixed_view_definition
WHERE view_name='GV$RESOURCE_LIMIT';
SELECT view_definition
FROM v$fixed_view_definition
WHERE view_name='GV$INSTANCE';
SELECT chr(bitand(p1,-16777216)/16777215)||
chr(bitand(p1, 16711680)/65535) "Lock",
bitand(p1, 65536) "Mode"
FROM v$session_wait
WHERE event = 'enqueue'
SELECT SID, TYPE, LMODE, REQUEST, ID1, ID2, BLOCK
FROM V$LOCK WHERE SID IN ( XX, YY, ZZ )
AND BLOCK = 0
AND LMODE = 0
AND ROWNUM < 100
/
DECLARE
l_cursor number;
l_result number;
l_user_id number;
BEGIN
SELECT USER_ID
INTO l_user_id
FROM ALL_USERS
WHERE USERNAME='';
l_cursor := sys.dbms_sys_sql.open_cursor;
sys.dbms_sys_sql.parse_as_user
(
l_cursor,
'CREATE DATABASE LINK nomelink CONNECT TO usuario IDENTIFIED BY "senha" USING ''tns''',
dbms_sql.native, l_user_id
);
l_result := sys.dbms_sys_sql.execute(l_cursor);
sys.dbms_sys_sql.close_cursor(l_cursor);
END;
/
SET SERVEROUT ON VERIFY OFF
DECLARE
TB NUMBER ;
TBY NUMBER ;
UB NUMBER;
UBY NUMBER;
LUEF NUMBER ;
LUEBI NUMBER ;
LUB NUMBER ;
BEGIN
DBMS_SPACE.UNUSED_SPACE( UPPER('&1.'), UPPER('&2.'), UPPER('&3.'), TB, TBY, UB, UBY, LUEF, LUEBI, LUB );
DBMS_OUTPUT.PUT_LINE( CHR(10) || UPPER('&2.') || CHR(10) || CHR(10) || 'TOTAL BLOCKS = ' || to_char( TB, '9999999' ) );
DBMS_OUTPUT.PUT_LINE( 'EMPTY BLOCKS = ' || to_char( UB, '9999999' ) );
DBMS_OUTPUT.PUT_LINE( 'USED BLOCKS = ' || to_char( TB-UB, '9999999' ) );
END;
/
SET SERVEROUT OFF VERIFY ON
col event format a35
col "AVG_WAITS(s)" format 990d0000
col time_waited format a16
set verify off
SELECT event, total_waits,
decode( trunc( time_waited/84600/100, 0 ), 0,
to_char( to_date('31/01/2001', 'dd/mm/yyyy' )+time_waited/8460000, '"00d:"HH24:MI:SS' ),
to_char( to_date('31/01/2001', 'dd/mm/yyyy' )+time_waited/8460000, 'DD"d":HH24:MI:SS' ) ) TIME_WAITED,
round( average_wait/100,4) "AVG_WAITS(s)" FROM
( SELECT * FROM v$session_event
WHERE total_waits > 0
and sid = &1.
ORDER BY total_waits desc )
WHERE rownum < 16
/
set verify on
undefine 1
break on "thread#"
set head off
SELECT 'HISTORICO DA GERACAO DE ARCHIVE NAS ULTIMAS 24HS em ' || instance_name || '@' || host_name
FROM GV$INSTANCE
/
set head on
SELECT
thread# as "thread#"
,to_char(TRUNC(COMPLETION_TIME,'HH'), 'dd/mm hh24:mi' ) HORA
,round(sum(blocks * block_size)/1048576,2) MB
,round(sum(decode(deleted, 'NO', blocks * block_size, 0 ) ) / 1048576, 2 ) EM_DISCO
FROM gv$archived_log
WHERE COMPLETION_TIME > SYSDATE -1
--AND DELETED ='NO'
GROUP BY rollup( thread#, TRUNC(COMPLETION_TIME,'HH') )
ORDER BY thread#, TRUNC(COMPLETION_TIME,'HH')
/
clear break
set verify off feed off
break on chave_pai skip 1
SELECT p.constraint_name chave_pai, r.table_name tabela_dependente, r.constraint_name chave_dependente
FROM dba_constraints p, dba_constraints r
WHERE p.owner=r.r_owner
and p.constraint_name = r.r_constraint_name
and p.owner like upper('&1')
and p.table_name like upper('&2')
ORDER BY 1
/
undefine 1
undefine 2
clear break
set verify on feed on
col owner_name format a15 new_value owner_name
col operation format a15
col job_mode format a10
col state format a20
col username new_value username
col sid new_value sid
col inst_id new_value inst_id
SELECT * FROM dba_datapump_jobs;
set verify off
break on profile skip page on resource_type skip 1
SELECT profile, resource_type, resource_name, limit
FROM dba_profiles
WHERE profile like upper('%&&1.%')
ORDER BY profile, resource_type
/
break on profile skip 1
SELECT profile, username
FROM dba_users WHERE profile like upper('%&&1.%')
ORDER BY profile
/
undefine 1
clear break
set verify on
set pages 200
col coluna format a35
break on table_name on index_name skip 1
SELECT i.table_name, i.index_name, lpad( c.column_position, 2, '0' )|| '-' || c.column_name coluna
FROM dba_indexes i join dba_ind_columns c on ( i.owner = c.index_owner and i.index_name = c.index_name )
WHERE owner='SCHEMA'
ORDER BY i.table_name, i.index_name, c.column_position
/
COL OWNER FORMAT A15
COL SEGMENT_NAME FORMAT A40
SET VERIFY OFF
SELECT
OWNER
,SEGMENT_NAME || DECODE(PARTITION_NAME, NULL, '', '('|| PARTITION_NAME ||')') SEGMENT_NAME
,SEGMENT_TYPE
,TABLESPACE_NAME
FROM DBA_EXTENTS
WHERE FILE_ID = &1.
AND &2. BETWEEN BLOCK_ID AND BLOCK_ID + BLOCKS -1
/
UNDEFINE 1
UNDEFINE 2
SET VERIFY OFF FEED OFF
COL PRIVILEGIOS FORMAT A80
COL QUOTAS FORMAT A80
DEFINE P1=UPPER('&1.')
SELECT 'GRANT ' || PRIVILEGE || ' ON ' || OWNER || '.' || TABLE_NAME || ' TO ' || GRANTEE || ';'
FROM DBA_TAB_PRIVS WHERE TABLE_NAME=&P1.
ORDER BY 1
/
PROMPT
UNDEFINE P1
UNDEFINE 1
SET FEED ON
//-- --REVOKE --------------------------------------------------------------------------------------------
SET VERIFY OFF FEED OFF DEFINE ON PAGES 5000
COL PRIVILEGIOS FORMAT A110
COL QUOTAS FORMAT A80
COL USUARIO FORMAT A80
SELECT 'REVOKE /* OBJPRIV */ ' || PRIVILEGE || ' ON ' || OWNER || '.' || TABLE_NAME || ' FROM ' || GRANTEE || ';' PRIVILEGIOS
FROM DBA_TAB_PRIVS WHERE GRANTEE= UPPER('&1.')
ORDER BY 1
/
PROMPT
SET FEED 6 PAGES 66
COL PRIVILEGIOS CLEAR
COL QUOTAS CLEAR
COL USUARIO CLEAR
SELECT p.addr, p.pname, b.paddr, b.name
FROM v$process p
left outer join v$bgprocess b
on (p.addr = b.paddr and b.paddr <>'00' and p.addr <>'00' )
/
set heading off
set feedback off
spool $ORACLE_BASE/util/sql/kill_session.sql
SELECT 'alter system kill session '''||sid||','||serial#||''';'
FROM v$session
WHERE status = 'SNIPED';
spool off
@$ORACLE_BASE/util/sql/kill_session.sql
exit
//-- --------------------2----------------------------------------------------------------------- //
set verify off
begin
for reg in (SELECT sid, serial# FROM v$session WHERE sid = &1) loop
execute immediate 'alter system kill session '''||reg.sid||','||reg.serial#||''' immediate';
end loop;
end;
/
COL LATCH FORMAT A36
SELECT name latch, gets, misses, 100 - round( misses*100/decode(gets,0,1,gets), 2 ) eficiencia, sleeps
FROM v$latch
WHERE gets > 0 and 100 - round( misses*100/decode(gets,0,1,gets), 2 ) < 100
ORDER BY eficiencia
/
SET VERIFY OFF LINES 270 FEED OFF
COL HASH_VALUE FORMAT 999999999999
COL EXECUTIONS FORMAT 99G999G999 HEAD 'Execucoes'
COL BUFFER_GETS FORMAT 9G999G999G999 HEAD 'Leituras Logicas'
COL GETS_BY_EXEC FORMAT 999G999G999 HEAD 'Leit.Logicas|Por Execucao'
COL LINHAS FORMAT 999G999G999G999 HEAD 'Linhas|Processadas'
COL SQL_TEXT FORMAT A80 HEAD 'Inicio do Texto do SQL' TRUNC
set head off
COL HH FORMAT A50
SELECT 'Hora Atual: ' || TO_CHAR(SYSDATE, 'DD/MM/YYYY HH24:MI:SS' ) HH
FROM DUAL
/
set head on
WITH /* GetCursor */ V AS
(
SELECT
c.sql_id
,c.inst_id
,c.hash_value
,c.user_name
,c.address
FROM GV$OPEN_CURSOR C
WHERE C.SID = &1. AND C.INST_ID = &2.
), CURSORES AS
(
SELECT /*+ ALL_ROWS NO_MERGE(V) */
v.inst_id
,V.SQL_ID
,v.user_name
,S.ROWS_PROCESSED LINHAS, S.EXECUTIONS, S.BUFFER_GETS
,TRUNC(S.BUFFER_GETS/DECODE(S.EXECUTIONS,NULL,1,0,1,S.EXECUTIONS)) GETS_BY_EXEC
,S.SQL_TEXT
--,S.SQL_FULLTEXT
FROM V
LEFT JOIN GV$SQLAREA S ON ( V.sql_id = s.sql_id AND V.inst_id = s.inst_id )
)
SELECT * FROM CURSORES C
WHERE ( C.BUFFER_GETS >= &L_BUF_GET. OR C.GETS_BY_EXEC >= &L_BUF_GET_BY_EXEC. )
ORDER BY C.GETS_BY_EXEC DESC
/
PROMPT ----------------------------------------------------------------------------
PROMPT Resumo de cursores abertos
PROMPT ----------------------------------------------------------------------------
SELECT O.INST_ID, O.SID, O.SQL_ID, SUM(S.OPEN_VERSIONS) open, COUNT(*) qtde
FROM GV$OPEN_CURSOR O
JOIN GV$SQLAREA S ON (O.SQL_ID = S.SQL_ID AND O.inst_id = S.inst_id)
WHERE O.SID=&1.
AND O.INST_ID = &2.
GROUP BY O.INST_ID, O.SID, O.SQL_ID
.
PROMPT
COL HASH_VALUE CLEAR
COL GETS_BY_EXEC CLEAR
COL LINHAS CLEAR
COL SQL_TEXT CLEAR
COL BUFFER_GETS CLEAR
COL EXECUTIONS CLEAR
SET VERIFY ON FEED 6
SELECT USERNAME, ACCOUNT_STATUS || DECODE(LOCK_DATE,NULL,NULL, ' IN ' ||LOCK_DATE) ACCOUNT_STATUS, PROFILE, DEFAULT_TABLESPACE "DEFAULT", TEMPORARY_TABLESPACE TEMPORARIA
FROM DBA_USERS ORDER BY ACCOUNT_STATUS DESC, USERNAME
COL OWNER FORMAT A15 HEAD DONO
COL DIRETORIO FORMAT A30 HEAD DIRETORIO
COL PATH FORMAT A70 HEAD CAMINHO
SELECT
OWNER, DIRECTORY_NAME DIRETORIO, DIRECTORY_PATH PATH, CURSOR (SELECT GRANTEE, PRIVILEGE FROM DBA_TAB_PRIVS WHERE TABLE_NAME = DIRECTORY_NAME)
FROM DBA_DIRECTORIES
ORDER BY PATH
/
COL OWNER CLEAR
COL DIRETORIO CLEAR
COL PATH CLEAR
COL TIPO FORMAT A15
COL NOTNULL FORMAT A7
COL COLUNA FORMAT A30
SET DEFINE ON VERIFY OFF
SELECT column_name "Coluna",
decode( nullable, 'N', 'Sim' ) "NotNull",
data_type ||
decode( data_type, 'DATE', '',
'NUMBER', decode( data_precision, null, '', '('||data_precision||','||data_scale||')'),
'(' || data_length || ')' ) "Tipo"
FROM user_tab_columns
WHERE table_name = upper( '&1' )
ORDER BY 1 --COLUMN_ID
/
SET DEFINE OFF VERIFY ON
set verify off feed off lines 130 pages 150
col dependentes format a130
col privilegiados format a60
define p_owner=&1.
define p_tabela=&2.
with
temp_obj as
(
SELECT object_id FROM all_objects
WHERE owner = upper('&p_owner')
and object_name = upper('&p_tabela')
and object_type in( 'TABLE', 'VIEW', 'MATERIALIZED VIEW' )
),
dependencias as
(
SELECT
level nivel
,p.object_id obj
,p.referenced_object_id refobj
FROM public_dependency p
connect by prior p.object_id = p.referenced_object_id
start with p.referenced_object_id = (SELECT object_id FROM temp_obj)
union all
SELECT 0, t.object_id, null
FROM temp_obj t
),
dependencias2 as
(
SELECT t.nivel, t.obj, t.refobj, ob.object_type, ob.owner, ob.object_name
FROM dependencias t, dba_objects ob
WHERE ob.object_id = t.obj
/* and ob.object_type NOT IN ( 'SYNONYM', 'TRIGGER' ) */
and ob.object_type NOT IN ( 'TRIGGER' )
and not exists
(SELECT 1 FROM dependencias i WHERE i.obj = t.obj and i.refobj = t.refobj and i.nivel < t.nivel )
),
get_privs as
(
SELECT distinct obj, p.grantee grantee
FROM (SELECT distinct obj, owner, object_name FROM dependencias2) t, dba_tab_privs p
WHERE p.owner = t.owner
and p.table_name = t.object_name
),
group_privs as
(
SELECT obj, '-->Privilegios: ' || lower( stragg(grantee) ) grantee
FROM get_privs
group by obj
),
dependencia_privs as
(
SELECT 0, 0 obj, obj refobj, grantee objeto FROM group_privs
union all
SELECT nivel, obj, refobj, object_type||' '||owner||'.'||object_name FROM dependencias2
order by 1, 4
)
SELECT
/* lpad( '|->', 3*(level-1), '| ' ) || t.objeto dependentes */
lpad( ' ', 2*(level-1), ' ' ) || t.objeto dependentes
FROM dependencia_privs t
connect by prior obj = refobj
start with refobj is null
/
prompt
WITH DIRETO AS
(
SELECT DISTINCT DECODE( U.TYPE#, 1, 'USER ', 'ROLE ') || GRANTEE GRANTEE, 'TABLE ' || upper('&p_tabela') GRANTED
FROM DBA_TAB_PRIVS P, SYS.USER$ U
WHERE TABLE_NAME = upper('&p_tabela') AND OWNER= upper('&p_owner')
AND P.GRANTEE= U.NAME
UNION
SELECT 'TABLE ' || upper('&p_tabela'), NULL
FROM DUAL
),
ALL_PRIVS AS
(
SELECT DECODE( U.TYPE#, 1, 'USER ', 'ROLE ') || R.GRANTEE GRANTEE, 'ROLE ' || R.GRANTED_ROLE GRANTED
FROM DBA_ROLE_PRIVS R, SYS.USER$ U
WHERE 'ROLE ' || R.GRANTED_ROLE IN ( SELECT DISTINCT GRANTEE FROM DIRETO )
AND R.GRANTEE = U.NAME
UNION
SELECT * FROM DIRETO
)
SELECT lpad( ' ', 2*(level-1), ' ' ) || p.grantee privilegiados
FROM all_privs p
connect by prior grantee = granted
start with granted is null
/
undefine 1 2 p_owner p_tabela
set verify on feed 6 pages 66
prompt
col dependentes clear
col privilegiados clear
SET LINES 200 VERIFY OFF
COL PROPERTY_NAME FORMAT A30 TRUNC
COL PROPERTY_VALUE FORMAT A30 TRUNC
COL DESCRIPTION FORMAT A60 TRUNC
SELECT PROPERTY_NAME, PROPERTY_VALUE, DESCRIPTION
FROM database_properties
WHERE UPPER(PROPERTY_NAME) LIKE UPPER('%&1.%')
/
SET LINES 200 VERIFY OFF
COL PROPERTY_NAME FORMAT A30 TRUNC
COL PROPERTY_VALUE FORMAT A30 TRUNC
COL DESCRIPTION FORMAT A60 TRUNC
SELECT PROPERTY_NAME, PROPERTY_VALUE, DESCRIPTION
FROM database_properties
WHERE UPPER(PROPERTY_NAME) LIKE UPPER('%&1.%')
/
set termout off
alter session set nls_date_format='dd/mm/yyyy hh24:mi:ss'
/
set termout on
SELECT 'Formato alterado para: ' ||sysdate "Formato de Data" FROM dual
/
SET CHARWIDTH 80
SELECT A.TABLE_NAME || CHR( 9 ) ||
COUNT( B.COLUMN_ID ) || CHR( 9 ) ||
SUM( DECODE( B.DATA_TYPE, 'NUMBER', B.DATA_PRECISION, B.DATA_LENGTH ) ) || CHR( 9 ) ||
MAX( A.NUM_ROWS ) || CHR( 9 ) ||
MAX( A.AVG_ROW_LEN ) || CHR( 9 ) ||
MAX( A.BLOCKS ) || CHR( 9 ) ||
MAX( A.EMPTY_BLOCKS ) || CHR( 9 ) ||
MAX( A.AVG_SPACE )
"Dados das Tabelas"
FROM DBA_TABLES A,
DBA_TAB_COLUMNS B
WHERE A.OWNER = 'OWNER'
AND A.OWNER = B.OWNER
AND A.TABLE_NAME = B.TABLE_NAME
GROUP BY A.TABLE_NAME;
SET CHARWIDTH 100
SELECT A.TABLE_NAME || CHR( 9 ) ||
A.INDEX_NAME || CHR( 9 ) || CHR( 9 ) || CHR( 9 ) ||
COUNT(B.COLUMN_POSITION) || CHR( 9 ) ||
SUM( DECODE( C.DATA_TYPE, 'NUMBER', DATA_PRECISION, DATA_LENGTH ) ) || CHR( 9 ) ||
MAX( A.NUM_ROWS) || CHR(9) ||
MAX( D.BLOCKS)
"Dados dos Indices"
FROM DBA_INDEXES A,
DBA_IND_COLUMNS B,
DBA_TAB_COLUMNS C,
DBA_SEGMENTS D
WHERE A.TABLE_OWNER = B.TABLE_OWNER
AND A.TABLE_NAME = B.TABLE_NAME
AND A.INDEX_NAME = B.INDEX_NAME
AND B.TABLE_OWNER = C.OWNER
AND B.TABLE_NAME = C.TABLE_NAME
AND B.COLUMN_NAME = C.COLUMN_NAME
AND A.TABLE_OWNER = 'ESTCAND2000'
AND A.OWNER = D.OWNER
AND A.INDEX_NAME = D.SEGMENT_NAME
GROUP BY A.TABLE_NAME, A.INDEX_NAME;
SELECT
sum( decode( trunc( executions/5,0), 0, 1, 0 ) ) "0-4",
sum( decode( trunc( executions/5,0), 1, 1, 0 ) ) "5-9",
sum( decode( trunc( executions/5,0), 2, 1, 0 ) ) "10-14",
sum( decode( trunc( executions/5,0), 3, 1, 0 ) ) "15-19",
sum( decode( trunc( executions/5,0), 4, 1, 0 ) ) "20-24",
sum( decode( trunc( executions/25,0), 0, 0, 1 ) ) "25>=",
count(*) "Cursores",
sum(executions) "Execuções",
sum(executions)/count(*) "Exec/Cursor"
FROM v$sqlarea
/
SET HEADING OFF
SET PAGESIZE 80
SET FEED OFF
SELECT 'alter table '||cc.owner||'.'||cc.table_name||chr(10)|| ' disable constraint '||cc.constraint_name||';'
FROM dba_cons_columns cc
WHERE cc.constraint_name in (SELECT c.constraint_name
FROM dba_constraints c
WHERE c.r_constraint_name = 'CONSTRAINT_NOME' and constraint_type='R' and owner = 'SCHEMA')
/
SET HEADING ON
SET FEED ON
--alter table SCHEMA.CONSTRAINT_NOME;
--disable constraint FK_XXX;
set verify off long 540 lines 320
col constraint_name format a30
col table_name format a30
col column_name format a32
col checks format a45
col fk format a35
col status format a22
col constraint_type format a1 heading "T"
SELECT /*+ rule */ cc.table_name
,cc.constraint_name
,c.constraint_type
,c.status|| ' '||c.validated status
,nvl(cc.position, 1) || '-' || cc.column_name column_name
,c.search_condition checks
,c.r_owner ||'.'||c.r_constraint_name fk
,c.deferrable
,c.delete_rule
FROM dba_cons_columns cc, dba_constraints c
-- WHERE cc.table_name LIKE UPPER('&2')
WHERE (cc.table_name LIKE UPPER('&2') or c.constraint_type=upper('&2'))
and cc.owner = upper( '&1' )
and cc.constraint_name = c.constraint_name
and cc.owner = c.owner
ORDER BY cc.table_name, cc.constraint_name, cc.position
/
set verify on
SET SERVEROUT ON
DECLARE
P_OWNER VARCHAR2(200) := '&owner';
P_USER VARCHAR2(200) := '&appuser';
P_ROLCONS VARCHAR2(200) := '&rolcons';
P_ROLATU VARCHAR2(200) := '&rolatu';
BEGIN
FOR R IN
(
SELECT OWNER, OBJECT_TYPE, OBJECT_NAME FROM DBA_OBJECTS
WHERE OWNER=P_OWNER
AND OBJECT_TYPE IN ( 'TABLE', 'VIEW', 'PROCEDURE', 'PACKAGE', 'FUNCTION' , 'SEQUENCE' )
AND OBJECT_NAME NOT LIKE 'DR$%'
AND OBJECT_NAME NOT LIKE 'BIN$%'
ORDER BY OBJECT_TYPE
)
LOOP
BEGIN
EXECUTE IMMEDIATE 'CREATE SYNONYM '||P_USER||'.'||R.OBJECT_NAME||' FOR '||R.OWNER||'.'||R.OBJECT_NAME;
EXCEPTION
WHEN OTHERS THEN
IF SQLCODE IN (-955) THEN
NULL;
ELSE
--RAISE;
DBMS_OUTPUT.PUT_LINE( R.OWNER||'.'||R.OBJECT_NAME||':' );
DBMS_OUTPUT.PUT_LINE( SQLERRM );
END IF;
END;
BEGIN
IF R.OBJECT_TYPE IN ( 'TABLE' ) THEN
EXECUTE IMMEDIATE 'GRANT SELECT ON '||R.OWNER||'.'||R.OBJECT_NAME || ' TO ' || P_ROLCONS;
EXECUTE IMMEDIATE 'GRANT SELECT, INSERT, UPDATE, DELETE ON '||R.OWNER||'.'||R.OBJECT_NAME || ' TO ' || P_ROLATU;
ELSIF R.OBJECT_TYPE IN ( 'VIEW' ) THEN
EXECUTE IMMEDIATE 'GRANT SELECT ON '||R.OWNER||'.'||R.OBJECT_NAME || ' TO ' || P_ROLCONS;
EXECUTE IMMEDIATE 'GRANT SELECT ON '||R.OWNER||'.'||R.OBJECT_NAME || ' TO ' || P_ROLATU;
ELSIF R.OBJECT_TYPE IN ( 'PROCEDURE', 'PACKAGE', 'FUNCTION' ) THEN
EXECUTE IMMEDIATE 'GRANT EXECUTE ON '||R.OWNER||'.'||R.OBJECT_NAME || ' TO ' || P_ROLATU;
ELSIF R.OBJECT_TYPE IN ( 'SEQUENCE' ) THEN
EXECUTE IMMEDIATE 'GRANT SELECT ON '||R.OWNER||'.'||R.OBJECT_NAME || ' TO ' || P_ROLATU;
ELSE
RAISE_APPLICATION_ERROR( -20000, 'TIPO NÃO MAPEADO');
END IF;
EXCEPTION
WHEN OTHERS THEN
IF SQLCODE IN (-30657) THEN
NULL;
ELSE
--RAISE;
DBMS_OUTPUT.PUT_LINE( R.OWNER||'.'||R.OBJECT_NAME||':' );
DBMS_OUTPUT.PUT_LINE( SQLERRM );
END IF;
END;
END LOOP;
END;
/
WHENEVER SQLERROR EXIT SQL.SQLCODE
SET ECHO ON TERM ON FEED OFF PAGES 0 LINES 120 SERVEROUT ON
SELECT count(*)
FROM dba_objects O
JOIN dba_tab_columns C ON (O.OWNER=C.OWNER AND O.OBJECT_NAME=C.TABLE_NAME AND O.OBJECT_TYPE='TABLE')
WHERE INSTR( C.TABLE_NAME, '$' ) = 0
and O.OWNER='P_7236'
AND ( CHAR_USED IS NOT NULL AND CHAR_USED = 'B' )
AND O.CREATED > (SELECT S.CREATED+1/24 FROM ALL_USERS S WHERE S.USER_ID = 0)
/
alter session set events '01 trace name context forever, level 2'
/
BEGIN
FOR R IN
(
SELECT
'ALTER TABLE "' || C.OWNER || '"."' || C.TABLE_NAME || '" MODIFY "' || C.COLUMN_NAME || '" ' || C.DATA_TYPE || ' (' || C.DATA_LENGTH || ' CHAR)' ALT
FROM dba_objects O
JOIN dba_tab_columns C ON (O.OWNER=C.OWNER AND O.OBJECT_NAME=C.TABLE_NAME AND O.OBJECT_TYPE='TABLE')
WHERE INSTR( C.TABLE_NAME, '$' ) = 0
AND ( CHAR_USED IS NOT NULL AND CHAR_USED = 'B' )
AND O.CREATED > (SELECT S.CREATED+1/24 FROM ALL_USERS S WHERE S.USER_ID = 0)
)
LOOP
BEGIN
EXECUTE IMMEDIATE R.ALT;
EXCEPTION
WHEN OTHERS THEN
IF SQLCODE = -24005 THEN
DBMS_OUTPUT.PUT_LINE( 'ORA-24005: ' || R.ALT );
ELSIF SQLCODE = -14265 THEN
DBMS_OUTPUT.PUT_LINE( 'ORA-14265: ' || R.ALT );
ELSE
DBMS_OUTPUT.PUT_LINE( R.ALT );
RAISE;
END IF;
END;
END LOOP;
END;
.
ALTER TABLE USR_SIATE.SIATEPRD MODIFY NOMMUNICIPIOELEITOTAL VARCHAR2(45 CHAR) NULL
/
SELECT count(*)
FROM dba_objects O
JOIN dba_tab_columns C ON (O.OWNER=C.OWNER AND O.OBJECT_NAME=C.TABLE_NAME AND O.OBJECT_TYPE='TABLE')
WHERE INSTR( C.TABLE_NAME, '$' ) = 0
AND ( CHAR_USED IS NOT NULL AND CHAR_USED = 'B' )
AND O.CREATED > (SELECT S.CREATED+1/24 FROM ALL_USERS S WHERE S.USER_ID = 0)
/
EXIT 0
SET LINES 2200 VERIFY OFF
COL LAST_START_DATE FORMAT A20 TRUNC
COL NEXT_RUN_DATE FORMAT A20 TRUNC
COL LAST_RUN_DURATION FORMAT A20 TRUNC
COL JOB_ACTION FORMAT A60 TRUNC
COL REPEAT_INTERVAL FORMAT A40 TRUNC
SELECT
OWNER, JOB_NAME, STATE
,TO_CHAR(NEXT_RUN_DATE, 'DD/MM HH24:MI TZH:TZM') NEXT_RUN_DATE
,REPEAT_INTERVAL
,END_DATE
,FAILURE_COUNT
,TO_CHAR(LAST_START_DATE, 'DD/MM HH24:MI TZH:TZM') LAST_START_DATE
--,TO_CHAR(LAST_START_DATE, 'DD/MM HH24:MI TZH:TZM') LAST_START_DATE
--,TO_CHAR(LAST_RUN_DURATION, 'HH24:MI:SS' ) LAST_RUN_DURATION
,CAST( LAST_RUN_DURATION AS INTERVAL DAY(2) TO SECOND(0) ) LAST_RUN_DURATION
,JOB_ACTION
--, COMMENTS
, JOB_CREATOR
FROM DBA_SCHEDULER_JOBS
WHERE OWNER LIKE upper('&1');
SET LINES 220 VERIFY OFF
SET PAGES 100
TTITLE 'Currently Active FGA Policies|(FROM DBA_AUDIT_POLICIES)'
COL object_schema FORMAT A20 HEADING 'Object|Schema'
COL object_name FORMAT A30 HEADING 'Object Name' WRAP
COL policy_name FORMAT A16 HEADING 'Policy Name' WRAP
COL policy_text FORMAT A24 HEADING 'Policy Text' WRAP
COL policy_column FORMAT A16 HEADING 'Policy Column' WRAP
COL enabled FORMAT A05 HEADING 'On?'
COL siud_options FORMAT A04 HEADING 'SIUD|Set'
SELECT
policy_name
,policy_text
,policy_column
,enabled
,object_schema
,object_name
,DECODE(sel,'YES','Y','N') || DECODE(ins,'YES','Y','N')||
DECODE(upd,'YES','Y','N') || DECODE(del,'YES','Y','N') siud_options
,PF_SCHEMA
,PF_PACKAGE
,PF_FUNCTION
FROM dba_audit_policies;
TTITLE OFF
SET DEFINE ON
DEFINE DONO='&1.'
DEFINE NOME='&2.'
DEFINE TIPO='%'
SET VERIFY OFF TRIMSPOOL ON PAGES 0 FEEDBACK OFF TERMOUT OFF LINES 300
SPOOL xGerarFontes.Sql
SELECT DISTINCT
'PROMPT Gerando ' || TYPE || ' ' || OWNER || ' ' || NAME || CHR(10) ||
'@@Do.GetFontesDBA.Sql "' || TYPE || '" ' || OWNER || ' ' || NAME
FROM DBA_SOURCE
WHERE UPPER ( NAME ) LIKE UPPER( '&NOME' )
AND OWNER LIKE UPPER( '&DONO' )
AND TYPE LIKE UPPER( '&TIPO' )
/
SPOOL OFF
SET PAGES 100 FEEDBACK 6 TERMOUT ON
@xGerarFontes.Sql
HOST DEL xGerarFontes.Sql
//-- --------------2------------------------- //
SET VERIFY OFF TRIMSPOOL ON PAGES 0 FEEDBACK OFF TERMOUT OFF
DEFINE TIPO='&1.'
DEFINE DONO='&2.'
DEFINE NOME='&3.'
COL CNOME NEW_VALUE P_PATH
COL CDONO NEW_VALUE P_DONO
COL CTIPO NEW_VALUE P_TIPO
SELECT
Lower( 'fontes\&dono.\' ||
Decode(UPPER('&tipo'), 'PACKAGE BODY', 'PACKAGE', 'TYPE BODY', 'TYPE', '&tipo' ) || '\&nome..Sql' ||
Decode(UPPER('&tipo'), 'PACKAGE BODY', '.Bdy', 'TYPE BODY', '.Bdy' ) ) cNome,
Lower( '&dono.' ) cDono,
Lower( Decode( UPPER('&tipo'), 'PACKAGE BODY', 'PACKAGE', 'TYPE BODY', 'TYPE', '&tipo' ) ) cTipo
FROM DUAL
/
HOST MKDIR Fontes
HOST MKDIR Fontes\&P_Dono.
HOST MKDIR Fontes\&P_Dono.\&P_Tipo.
SET TERMOUT ON
PROMPT Fonte gerado em &P_Path.
SET TERMOUT OFF
SPOOL &P_Path.
PROMPT -- &P_Path.
PROMPT
PROMPT SET DEFINE OFF
PROMPT
-- VERIFICAR SE WORD WRAP TIRA A IDENTACAO
REM COL TEXTO_FMT FORMAT A500 WORD_WRAP
COL TEXTO_FMT FORMAT A500
/* SELECT /*+ NO_MERGE(V)
DECODE( LINE, 1,
REPLACE(
REPLACE(
REPLACE( TEXT, 'FOR EACH ROW', CHR(10)||'FOR EACH ROW'),
'BEFORE', CHR(10)||'BEFORE' ),
'AFTER', CHR(10)||'AFTER' ), TEXT) TEXTO_FMT
*/
SELECT /*+ NO_MERGE(V) */
TEXT TEXTO_FMT
FROM (
SELECT
NAME, TYPE, LINE,
DECODE( LINE, 1,
'CREATE OR REPLACE '||TYPE||' '||OWNER||'.' ||
REPLACE(REPLACE(TRIM(REPLACE(UPPER(TEXT),TYPE)),'"'),OWNER||'.'), TEXT ) TEXT
FROM DBA_SOURCE
WHERE UPPER ( NAME ) = UPPER( '&NOME' )
AND OWNER = UPPER( '&DONO' )
AND TYPE = UPPER( '&TIPO' )
UNION
SELECT NAME, TYPE, MAX( LINE ) + 1 LINE, '/' TEXT
FROM DBA_SOURCE
WHERE UPPER ( NAME ) = UPPER( '&NOME' )
AND OWNER = UPPER( '&DONO' )
AND TYPE = UPPER( '&TIPO' )
GROUP BY NAME, TYPE
) V
/
COL TEXTO_FMT CLEAR
PROMPT
PROMPT SET DEFINE "&"
SPOOL OFF
SET PAGES 100 FEEDBACK 6 TERMOUT ON
col parametro format a120 word_wrap
set feed off head off
SELECT name || '=' || value parametro
FROM v$parameter WHERE isdefault = 'FALSE'
order by name;
prompt
set feed 6 head on
col qt_inst new_value qt_inst
col vw new_value vw
col exp new_value exp
set termout off verify off pages 1000 feed 1000 lines 200
SELECT
nvl(to_number(p.value), 1 ) qt_inst
,case when nvl(to_number(p.value), 1 ) > 1 then 'gv$parameter2 P' else 'v$parameter2 P' end vw
,case when nvl(to_number(p.value), 1 ) > 1 then '(SELECT instance_name FROM gv$instance i WHERE i.inst_id=p.inst_id)||''.''' else '''''' end exp
FROM v$parameter2 p
cross join v$database d
WHERE p.name='cluster_database_instances'
/
SET LONG 512
COL "=" FORMAT A1
COL NAME FORMAT A44
COL VALUE FORMAT A110 WRAP
set termout on verify off
with global as
(
SELECT isdeprecated, name, value, count(*)
FROM &vw.
WHERE NVL( ISDEFAULT, 'X' ) = 'FALSE' AND name not like '#_#_%' ESCAPE '#'
group by isdeprecated, name, value
having count(*) > 1 and count(*) = &qt_inst.
)
SELECT
CASE WHEN isdeprecated = 'TRUE' THEN '(--)' ELSE ' ' END || '*.' || name NAME
,'=' "="
,NVL(value, ''''||value||'''' ) VALUE
FROM global
UNION ALL
SELECT
CASE WHEN p.isdeprecated = 'TRUE' THEN '(--)' ELSE ' ' END || &exp. || p.name NAME
,'=' "="
,NVL(p.value, ''''||p.value||'''' ) VALUE
FROM &vw.
WHERE NVL( p.isdefault, 'X' ) = 'FALSE'
AND p.name not like '#_#_%' ESCAPE '#'
AND NOT EXISTS ( SELECT 1 FROM global g WHERE g.name = p.name )
ORDER BY 1
/
COL qt_inst CLEAR
COL vw CLEAR
COL exp CLEAR
COL "=" CLEAR
COL NAME CLEAR
COL VALUE CLEAR
PROMPT REM @getpfile
PROMPT
PROMPT
PROMPT ########################################################
PROMPT
PROMPT O plano para esta sentenca nao pode ser recuperado
PROMPT &P_QTCOPIAS. copias na shared pool
PROMPT Isto pode travar o banco.
PROMPT
PROMPT ########################################################
PROMPT
SELECT
hash_value, sum(version_count) versoes,
trunc(sum(sharable_mem)/1048576) memoria, sql_text
FROM v$sqlarea WHERE version_count > 2
group by hash_value, sql_text
order by 2 desc
SET HEAD OFF
PROMPT MOTIVO VALOR
PROMPT -------------------------------- ----------
SELECT
'CHILD CNT' ISSUE ,COUNT(*) VALOR
,'UNBOUND_CURSOR' ISSUE ,SUM( DECODE( UNBOUND_CURSOR , 'Y', 1, 0 ) ) VALOR
,'SQL_TYPE_MISMATCH' ISSUE ,SUM( DECODE( SQL_TYPE_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'OPTIMIZER_MISMATCH' ISSUE ,SUM( DECODE( OPTIMIZER_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'OUTLINE_MISMATCH' ISSUE ,SUM( DECODE( OUTLINE_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'STATS_ROW_MISMATCH' ISSUE ,SUM( DECODE( STATS_ROW_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'LITERAL_MISMATCH' ISSUE ,SUM( DECODE( LITERAL_MISMATCH , 'Y', 1, 0 ) ) VALOR
--,'SEC_DEPTH_MISMATCH' ISSUE ,SUM( DECODE( SEC_DEPTH_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'EXPLAIN_PLAN_CURSOR' ISSUE ,SUM( DECODE( EXPLAIN_PLAN_CURSOR , 'Y', 1, 0 ) ) VALOR
,'BUFFERED_DML_MISMATCH' ISSUE ,SUM( DECODE( BUFFERED_DML_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'PDML_ENV_MISMATCH' ISSUE ,SUM( DECODE( PDML_ENV_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'INST_DRTLD_MISMATCH' ISSUE ,SUM( DECODE( INST_DRTLD_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'SLAVE_QC_MISMATCH' ISSUE ,SUM( DECODE( SLAVE_QC_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'TYPECHECK_MISMATCH' ISSUE ,SUM( DECODE( TYPECHECK_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'AUTH_CHECK_MISMATCH' ISSUE ,SUM( DECODE( AUTH_CHECK_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'BIND_MISMATCH' ISSUE ,SUM( DECODE( BIND_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'DESCRIBE_MISMATCH' ISSUE ,SUM( DECODE( DESCRIBE_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'LANGUAGE_MISMATCH' ISSUE ,SUM( DECODE( LANGUAGE_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'TRANSLATION_MISMATCH' ISSUE ,SUM( DECODE( TRANSLATION_MISMATCH , 'Y', 1, 0 ) ) VALOR
--,'ROW_LEVEL_SEC_MISMATCH' ISSUE ,SUM( DECODE( ROW_LEVEL_SEC_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'INSUFF_PRIVS' ISSUE ,SUM( DECODE( INSUFF_PRIVS , 'Y', 1, 0 ) ) VALOR
,'INSUFF_PRIVS_REM' ISSUE ,SUM( DECODE( INSUFF_PRIVS_REM , 'Y', 1, 0 ) ) VALOR
,'REMOTE_TRANS_MISMATCH' ISSUE ,SUM( DECODE( REMOTE_TRANS_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'LOGMINER_SESSION_MISMATCH' ISSUE ,SUM( DECODE( LOGMINER_SESSION_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'INCOMP_LTRL_MISMATCH' ISSUE ,SUM( DECODE( INCOMP_LTRL_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'OVERLAP_TIME_MISMATCH' ISSUE ,SUM( DECODE( OVERLAP_TIME_MISMATCH , 'Y', 1, 0 ) ) VALOR
--,'SQL_REDIRECT_MISMATCH' ISSUE ,SUM( DECODE( SQL_REDIRECT_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'MV_QUERY_GEN_MISMATCH' ISSUE ,SUM( DECODE( MV_QUERY_GEN_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'USER_BIND_PEEK_MISMATCH' ISSUE ,SUM( DECODE( USER_BIND_PEEK_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'TYPCHK_DEP_MISMATCH' ISSUE ,SUM( DECODE( TYPCHK_DEP_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'NO_TRIGGER_MISMATCH' ISSUE ,SUM( DECODE( NO_TRIGGER_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'FLASHBACK_CURSOR' ISSUE ,SUM( DECODE( FLASHBACK_CURSOR , 'Y', 1, 0 ) ) VALOR
,'ANYDATA_TRANSFORMATION' ISSUE ,SUM( DECODE( ANYDATA_TRANSFORMATION , 'Y', 1, 0 ) ) VALOR
--,'INCOMPLETE_CURSOR' ISSUE ,SUM( DECODE( INCOMPLETE_CURSOR , 'Y', 1, 0 ) ) VALOR
,'TOP_LEVEL_RPI_CURSOR' ISSUE ,SUM( DECODE( TOP_LEVEL_RPI_CURSOR , 'Y', 1, 0 ) ) VALOR
,'DIFFERENT_LONG_LENGTH' ISSUE ,SUM( DECODE( DIFFERENT_LONG_LENGTH , 'Y', 1, 0 ) ) VALOR
,'LOGICAL_STANDBY_APPLY' ISSUE ,SUM( DECODE( LOGICAL_STANDBY_APPLY , 'Y', 1, 0 ) ) VALOR
,'DIFF_CALL_DURN' ISSUE ,SUM( DECODE( DIFF_CALL_DURN , 'Y', 1, 0 ) ) VALOR
,'BIND_UACS_DIFF' ISSUE ,SUM( DECODE( BIND_UACS_DIFF , 'Y', 1, 0 ) ) VALOR
,'PLSQL_CMP_SWITCHS_DIFF' ISSUE ,SUM( DECODE( PLSQL_CMP_SWITCHS_DIFF , 'Y', 1, 0 ) ) VALOR
,'CURSOR_PARTS_MISMATCH' ISSUE ,SUM( DECODE( CURSOR_PARTS_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'STB_OBJECT_MISMATCH' ISSUE ,SUM( DECODE( STB_OBJECT_MISMATCH , 'Y', 1, 0 ) ) VALOR
--,'ROW_SHIP_MISMATCH' ISSUE ,SUM( DECODE( ROW_SHIP_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'PQ_SLAVE_MISMATCH' ISSUE ,SUM( DECODE( PQ_SLAVE_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'TOP_LEVEL_DDL_MISMATCH' ISSUE ,SUM( DECODE( TOP_LEVEL_DDL_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'MULTI_PX_MISMATCH' ISSUE ,SUM( DECODE( MULTI_PX_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'BIND_PEEKED_PQ_MISMATCH' ISSUE ,SUM( DECODE( BIND_PEEKED_PQ_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'MV_REWRITE_MISMATCH' ISSUE ,SUM( DECODE( MV_REWRITE_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'ROLL_INVALID_MISMATCH' ISSUE ,SUM( DECODE( ROLL_INVALID_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'OPTIMIZER_MODE_MISMATCH' ISSUE ,SUM( DECODE( OPTIMIZER_MODE_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'PX_MISMATCH' ISSUE ,SUM( DECODE( PX_MISMATCH , 'Y', 1, 0 ) ) VALOR
,'MV_STALEOBJ_MISMATCH' ISSUE ,SUM( DECODE( MV_STALEOBJ_MISMATCH , 'Y', 1, 0 ) ) VALOR
FROM V$SQL_SHARED_CURSOR
WHERE SQL_ID = '&p_sql_id.'
GROUP BY SQL_ID
/
SET HEAD ON
CREATE OR REPLACE PROCEDURE SYSTEM.SEND_EMAIL
( sender IN VARCHAR2,
recipient IN VARCHAR2,
subject IN VARCHAR2,
message IN VARCHAR2)
AS
mailhost VARCHAR2(100) := 'webmail.xxx.zzz';
mail_conn utl_smtp.connection;
BEGIN
mail_conn :=utl_smtp.open_connection(mailhost,25);
utl_smtp.helo(mail_conn,mailhost);
utl_smtp.mail(mail_conn,sender); -- sender
utl_smtp.rcpt(mail_conn,recipient); -- recipient
utl_smtp.open_data(mail_conn);
utl_smtp.write_data(mail_conn,'FROM : <'||sender||'>'||utl_tcp.CRLF);
utl_smtp.write_data(mail_conn,'To : <'||recipient||'>'||utl_tcp.CRLF);
utl_smtp.write_data(mail_conn,'Subject: '|| subject);
utl_smtp.write_data(mail_conn, utl_tcp.CRLF||message);
utl_smtp.close_data(mail_conn);
utl_smtp.quit(mail_conn);
EXCEPTION
WHEN utl_smtp.transient_error OR utl_smtp.permanent_error THEN
utl_smtp.quit(mail_conn);
raise_application_error(-20000,
'Failed tosend mail due to the following error: ' || sqlerrm);
WHEN OTHERS THEN
raise_application_error(-20001,
'The following error has occured: ' || sqlerrm);
END;
/
col event format a35
col "AVG_WAITS(s)" format 990d0000
col time_waited format a16
set verify off
SELECT event, total_waits,
decode( trunc( time_waited/84600/100, 0 ), 0,
to_char( to_date('31/01/2001', 'dd/mm/yyyy' )+time_waited/8460000, '"00d:"HH24:MI:SS' ),
to_char( to_date('31/01/2001', 'dd/mm/yyyy' )+time_waited/8460000, 'DD"d":HH24:MI:SS' ) ) TIME_WAITED,
round( average_wait/100,4) "AVG_WAITS(s)" FROM
( SELECT * FROM v$session_event
WHERE total_waits > 0
and sid = &1.
order by total_waits desc )
WHERE rownum < 16
/
set verify on
undefine 1
set pages 300 verify off feed off
col name format a80 heading "Estatísticas de Sessão"
col class noprint
col classe format a10
col moving format a50 head "Estatisticas (Variação durante a execução do comando)"
col cls_WHERE new_value cls_WHERE
define p_sid = &1.
define p_classe = &2.
set termout off
SELECT
case when substr( '&p_classe.',1,1 ) = '@'
then 'WHERE lower(classe) like ''%'' || lower( substr(''&p_classe.'',2,100) ) || ''%'''
else 'WHERE lower(name) like ''%'' || lower( ''&p_classe.'' ) || ''%'''
end cls_WHERE
FROM dual
/
set termout on
CREATE GLOBAL TEMPORARY TABLE TMP_S1
AS SELECT
n.statistic#
,n.class
,s.value
,n.name
,decode( n.class, 1, 'User', 2, 'Redo', 4, 'Enqueue', 72, 'Cache',
8, 'Cache', 16, 'OS', 32, 'RAC', 64, 'SQL', 128, 'Debug', 'Outra' ) classe
FROM v$statname n, v$sesstat s
WHERE s.statistic# = n.statistic#
and s.value > 0
and s.sid = &p_sid.
/
CREATE GLOBAL TEMPORARY TABLE TMP_S2
AS SELECT * FROM TMP_S1
/
INSERT INTO TMP_S1
SELECT
n.statistic#
,n.class
,s.value
,n.name
,decode( n.class, 1, 'User', 2, 'Redo', 4, 'Enqueue', 72, 'Cache',
8, 'Cache', 16, 'OS', 32, 'RAC', 64, 'SQL', 128, 'Debug', 'Outra' ) classe
FROM v$statname n, v$sesstat s
WHERE s.statistic# = n.statistic#
and s.value > 0
and s.sid = &p_sid.
/
break on class skip 1
SELECT * FROM
(
SELECT
--n.statistic#,
n.class,
LPAD(
decode(sign(1e+12-s.value), -1, to_char(s.value/1e+09, 'fm999g999g999' ) || 'G',
decode(sign(1e+09-s.value), -1, to_char(s.value/1e+06, 'fm999g999g999' ) || 'M',
decode(sign(1e+06-s.value), -1, to_char(s.value/1e+03, 'fm999g999g999' ) || 'K',
to_char(s.value, 'fm999g999g999' ) ) ) ), 15, ' ' ) || ' of ' || initcap( n.name ) name,
decode( n.class, 1, 'User', 2, 'Redo', 4, 'Enqueue', 72, 'Cache', 8, 'Cache', 16, 'OS', 32, 'RAC', 64, 'SQL', 128, 'Debug', 'Outra' ) classe
FROM v$statname n, v$sesstat s
WHERE s.statistic# = n.statistic#
and s.value > 0
and s.sid = &p_sid.
order by n.class, s.value desc
)
&cls_WHERE.
/
INSERT INTO TMP_S2
SELECT
n.statistic#
,n.class
,s.value
,n.name
,decode( n.class, 1, 'User', 2, 'Redo', 4, 'Enqueue', 72, 'Cache',
8, 'Cache', 16, 'OS', 32, 'RAC', 64, 'SQL', 128, 'Debug', 'Outra' ) classe
FROM v$statname n, v$sesstat s
WHERE s.statistic# = n.statistic#
and s.value > 0
and s.sid = &p_sid.
/
PROMPT DELTA
SELECT
t2.class,
LPAD(
decode(sign(1e+12-t2.value), -1, to_char(t2.value/1e+09, 'fm999g999g999' ) || 'G',
decode(sign(1e+09-t2.value), -1, to_char(t2.value/1e+06, 'fm999g999g999' ) || 'M',
decode(sign(1e+06-t2.value), -1, to_char(t2.value/1e+03, 'fm999g999g999' ) || 'K',
to_char(t2.value, 'fm999g999g999' ) ) ) ), 15, ' ' ) || ' of ' || initcap( t2.name ) name,
t2.classe
FROM TMP_S2 T2
JOIN TMP_S1 T1 ON (T1.STATISTIC# = T2.STATISTIC#)
WHERE NVL(T1.VALUE, 0) <> NVL(T2.VALUE,0)
/
PROMPT DELTA
SELECT
case when sum(t1.value)-sum(t2.value) = 0
then 'Parado em ' || sum(t2.value) || ' estatísticas.'
else 'Durante o comando '|| to_char( sum(t2.value) - sum(t1.value) ) ||' estatísticas.'
end moving
FROM TMP_S2 T2
JOIN TMP_S1 T1 ON (T1.STATISTIC# = T2.STATISTIC#)
/
DROP TABLE TMP_S1;
DROP TABLE TMP_S2;
PROMPT
PROMPT EXECUTADO @sesstat &p_sid. &p_classe.
PROMPT
set pages 66 verify on feed 6
undefine 1 2 p_sid p_classe
col class clear
col name clear
col classe clear
col cls_WHERE clear
undef cls_WHERE
SET LINES 140 FEED OFF
COL "Tablespace" Format A20
COL "File" Format A40
COL "Segment Name" FORMAT A15
COL "XActs" FORMAT 9999
COL "Next" FORMAT 9999
COL "Next" FORMAT 9999
SELECT
TO_CHAR(R.SEGMENT_ID, 'fm00') || ' - ' || R.SEGMENT_NAME "Segment Name"
,INITCAP( NVL(RS.STATUS, R.STATUS) ) "Status"
,RS.XACTS "XActs"
,ROUND(RS.RSSIZE/1048576,0) "Allocated"
,ROUND(RS.HWMSIZE/1048576,0) "Max Used Size"
,ROUND(R.NEXT_EXTENT*R.MAX_EXTENTS/1048576,0) "Limit Size"
,RS.EXTENTS "Extents"
,R.NEXT_EXTENT/1048576 "Next"
,RS.GETS "Gets"
,RS.WAITS "Waits"
,RS.WRAPS "Wraps"
,RS.EXTENDS "Extends"
,RS.SHRINKS "Shrinks"
FROM DBA_ROLLBACK_SEGS R, V$ROLLSTAT RS
WHERE R.SEGMENT_ID = RS.USN(+)
ORDER BY "Allocated" Desc
/
SELECT
TABLESPACE_NAME "Tablespace"
,FILE_NAME "File"
,BYTES/1048576 "Allocated"
,MAXBYTES/1048576 "Limit Size"
,INCREMENT_BY*16/1024 "Next"
,INITCAP(AUTOEXTENSIBLE) "Ext"
FROM DBA_DATA_FILES
WHERE FILE_NAME LIKE '%rbs%'
/
SET FEED ON
SET FEEDBACK OFF LINES 200
Col X noprint
Col NAMESPACE Format A20 Heading "NAMESPACE"
Col GETHITRATIO Format A11 Heading "GETHITRATIO"
Col RP Format A12 Heading "RELOADS/PINS"
Col PINS Format 999G999G999 Heading "PINS"
Col RELOADS Format 999G999 Heading "RELOADS"
Col RCM Format A15 Heading "ROWCACHE MISSES"
Col RCSM Format A20 Heading "ROWCACHE SCAN MISSES"
Col FLUSHES Format A7 Heading "FLUSHES"
Col NAME Format A7 Heading "Buffer|Pool"
Col PHYSICAL_WRITES Format 99G999G999 Heading "Physical|Writes"
Col DB_BLOCK_CHANGE Format 999G999G999 Heading "Buffers|Changed"
Col PHYSICAL_READS Format 999G999G999G999G999 Heading "Physical|Reads"
Col LOGICAL_READS Format 9G999G999G999G999G999 Heading "Logical|Reads"
Col DB_BLOCK_GETS Format 999G999G999 Heading "Buffer|Gets"
Col CONSISTENT_GETS Format 9g999G999G999 Heading "Consistent|Gets"
Col RATIO Format A18 Heading "Buffer|Hit|Ratio" just r
Col WRITE_COMPLETE_WAIT Format 9G999G999 Heading "Write|Complete|Waits"
Col FREE_BUFFER_WAIT Format 9G999G999 Heading "Free|Buffer|Waits"
Col BUFFER_BUSY_WAIT Format 9G999G999 Heading "Buffer|Busy|Waits"
Col DB_HIT Format A24 Heading "Db Cache|Hit Ratio"
Col ENTRIES Format 999G999G999 Heading "Entries"
Col REQUESTS Format 9G999 Heading "Requests"
Col REDO_HIT Format A13 Heading "Redo Log|Hit Ratio" just r
Col MV Format 99G999G999 Heading "Sorts|In Memory"
Col DV Format 999999 Heading "Sorts|In Disk"
Col SORT_HIT Format 990D00 Heading "Sort|Hit Ratio"
Col TYPE Format A17 Heading "Process|Queue"
Col QTOTAL Format 99g999G999G999 Heading "Enqueued|Packets"
Col QWAIT Format 99g999G999G999 Heading "Wait|Time(ms)"
Col AVGRES Format 9990D000 Heading "Agv Wait|Time(ms)"
Col QIDLE Format 99g999G999G999 Heading "Idle|Time(s)"
Col QBUSY Format 99g999G999G999 Heading "Busy|Time(s)"
Col PCT_BUSY Format 9990D00 Heading "Pct|Busy"
Col QTD_PRC Format 9999 Heading "Running|Processes"
Col MC Format 9999 Heading "Max|Circuits"
Col MS Format 9999 Heading "Max|S.Sessions"
Col SH Format 9999 Heading "Max|S.Servers"
Col MSS Format 9999 Heading "Limite|S.Servers"
Col SS Format 9999 Heading "Started|S.Servers"
Col ST Format 9999 Heading "Terminated|S.Servers"
PROMPT
PROMPT -------------------------------------------------------------------------------------------------------------------------------------
col st1 format a14 heading "Startup Time"
col st2 format a14 heading "System Date"
col st3 format a12 heading "Running Time"
col st4 format a12 heading "Running Secs"
SELECT
to_char( startup_time, 'dd/mm/yy hh24"h"mi' ) st1,
to_char( sysdate, 'dd/mm/yy hh24"h"mi' ) st2,
lpad( to_char( trunc(sysdate,'YEAR') + (sysdate-startup_time-1),
decode( trunc( sysdate-startup_time, 0 ), 0, 'fm" 0d "hh24"h"mi', 'fm""dd"d "hh24"h"mi' ) ), 12, ' ' ) st3,
to_char( (sysdate-startup_time)*24*60*60, '999g999g990' ) st4
FROM v$instance;
PROMPT
PROMPT -------------------------------------------------------------------------------------------------------------------------------------
PROMPT SHARED POOL
PROMPT Referência: Library Cache Hit Ratio >= 90% | Reloads/Pins < 1%
PROMPT Referência: RowCache Miss < 15%
PROMPT -------------------------------------------------------------------------------------------------------------------------------------
SELECT 1 X, NAMESPACE, TO_CHAR(GETHITRATIO*100, '999990.00')||'%' GETHITRATIO,
TO_CHAR( DECODE(PINS, 0, DECODE(RELOADS,0,0,1), RELOADS/PINS)*100, '99990.0000')||'%' RP,
RELOADS, PINS, INVALIDATIONS
FROM V$LIBRARYCACHE
UNION ALL
SELECT 3, 'GERAL', TO_CHAR(AVG(GETHITRATIO*100), '999990.00')||'%' GETHITRATIO,
TO_CHAR( AVG(DECODE(PINS, 0, DECODE(RELOADS,0,0,1), RELOADS/PINS)*100), '99990.0000')||'%' "RELOADS/PINS",
SUM(RELOADS), SUM(PINS), SUM(INVALIDATIONS)
FROM V$LIBRARYCACHE
GROUP BY 'GERAL'
ORDER BY X, GETHITRATIO DESC;
SELECT TO_CHAR( SUM(GETMISSES)/DECODE(SUM(GETS),0,1,SUM(GETS))*100, '9999999990.00')||'%' RCM,
TO_CHAR( SUM(SCANMISSES)/DECODE(SUM(SCANS),0,1,SUM(SCANS))*100, '999999999999990.00')||'%' RCSM,
TO_CHAR( COUNT(FLUSHES), '999990' ) FLUSHES
FROM V$ROWCACHE;
PROMPT
PROMPT -------------------------------------------------------------------------------------------------------------------------------------
PROMPT DATABASE BUFFER CACHE
PROMPT Referência: DbCache Hit Ratio > 90%
PROMPT -------------------------------------------------------------------------------------------------------------------------------------
SELECT FIS.VALUE PHYSICAL_READS, (CUR.VALUE+CON.VALUE) LOGICAL_READS,
TO_CHAR( (1-(FIS.VALUE/(CUR.VALUE+CON.VALUE)))*100, '990.00')||'%' RATIO
FROM V$SYSSTAT FIS, V$SYSSTAT CON, V$SYSSTAT CUR
WHERE FIS.NAME = 'physical reads'
AND CON.NAME = 'consistent gets'
AND CUR.NAME = 'db block gets';
SELECT NAME, PHYSICAL_WRITES, DB_BLOCK_CHANGE, PHYSICAL_READS, DB_BLOCK_GETS, CONSISTENT_GETS
,LPAD(ROUND((1-(PHYSICAL_READS/DECODE(DB_BLOCK_GETS+CONSISTENT_GETS,0,1,DB_BLOCK_GETS+CONSISTENT_GETS)))*100, 2), 7, ' ' )||'%' RATIO
,WRITE_COMPLETE_WAIT, FREE_BUFFER_WAIT, BUFFER_BUSY_WAIT
FROM V$BUFFER_POOL_STATISTICS
UNION ALL
SELECT 'TOTAL', SUM(PHYSICAL_WRITES), SUM(DB_BLOCK_CHANGE), SUM(PHYSICAL_READS),
SUM(DB_BLOCK_GETS), SUM(CONSISTENT_GETS)
,LPAD(ROUND(AVG(1-(PHYSICAL_READS/DECODE(DB_BLOCK_GETS+CONSISTENT_GETS,0,1,DB_BLOCK_GETS+CONSISTENT_GETS)))*100, 2), 7, ' ' )||'%'
,SUM(WRITE_COMPLETE_WAIT), SUM(FREE_BUFFER_WAIT), SUM(BUFFER_BUSY_WAIT)
FROM V$BUFFER_POOL_STATISTICS;
PROMPT
PROMPT -------------------------------------------------------------------------------------------------------------------------------------
PROMPT REDO LOG BUFFER
PROMPT Referência: Redo Hit Ratio > 99%
PROMPT -------------------------------------------------------------------------------------------------------------------------------------
SELECT ENT.VALUE ENTRIES, REQ.VALUE REQUESTS,
TO_CHAR( (1-(REQ.VALUE/(REQ.VALUE+ENT.VALUE)))*100, '99999990.00' )||'%' REDO_HIT
FROM V$SYSSTAT ENT, V$SYSSTAT REQ
WHERE REQ.NAME = 'redo log space requests'
AND ENT.NAME = 'redo entries';
PROMPT
PROMPT -------------------------------------------------------------------------------------------------------------------------------------
PROMPT SORT PERFORMANCE
PROMPT Referência: Sorts in Memory > 95%
PROMPT -------------------------------------------------------------------------------------------------------------------------------------
SELECT mem.VALUE MV, dsk.VALUE DV, ROUND((1-(dsk.VALUE/(mem.VALUE+dsk.VALUE)))*100,2) SORT_HIT
FROM V$SYSSTAT mem, V$SYSSTAT dsk
WHERE mem.NAME = 'sorts (memory)'
and dsk.NAME = 'sorts (disk)'
/
SET TERMOUT OFF
Col ttime NEW_VALUE ttime
SELECT to_char( sysdate, 'dd/mm hh24:mi:ss' ) ttime FROM dual;
SET TERMOUT ON
PROMPT
PROMPT -------------------------------------------------------------------------------------------------------------------------------------
PROMPT SHARED SERVER MODEL (&ttime.)
PROMPT Referência: AvgWaitTime 0,10ms ~ 0,30ms | BusyTime < 50%
PROMPT -------------------------------------------------------------------------------------------------------------------------------------
SELECT
PS.TYPE TYPE
,QS.QTOTAL QTOTAL
,QS.QWAIT QWAIT
,ROUND( DECODE(QS.QWAIT, 0, 0, QS.QWAIT/QS.QTOTAL ), 2 ) AVGRES
,PS.IDLE QIDLE
, PS.BUSY QBUSY
, ROUND( PS.BUSY/(PS.BUSY+PS.IDLE) * 100, 2 ) PCT_BUSY
, PS.PROCESS QTD_PRC
FROM
(
SELECT
'SHARED SERVER' TYPE
,SUM(Q.TOTALQ) QTOTAL
,SUM(Q.WAIT)*10 QWAIT
FROM V$QUEUE Q
WHERE Q.TYPE = 'COMMON'
UNION ALL
SELECT
DECODE( D.CONF_INDX, 0, 'DISPATCHER 1521', 1, 'DISPATCHER 1523', 2, 'DISPATCHER 1525', 'DISPATCHER OTHER' ) TYPE
,SUM(Q.TOTALQ) QTOTAL
,SUM(Q.WAIT)*10 QWAIT
FROM V$QUEUE Q, V$DISPATCHER D
WHERE Q.TYPE = 'DISPATCHER'
AND Q.PADDR = D.PADDR
AND D.ACCEPT = 'YES'
GROUP BY DECODE( D.CONF_INDX, 0, 'DISPATCHER 1521', 1, 'DISPATCHER 1523', 2, 'DISPATCHER 1525', 'DISPATCHER OTHER' )
) QS,
(
SELECT 'DISPATCHER 1521' TYPE, TRUNC(SUM(BUSY)/100) BUSY, TRUNC(SUM(IDLE)/100) IDLE, COUNT(*) PROCESS
FROM V$DISPATCHER WHERE CONF_INDX = 0 AND ACCEPT = 'YES'
UNION ALL
SELECT 'DISPATCHER 1523' TYPE, TRUNC(SUM(BUSY)/100) BUSY, TRUNC(SUM(IDLE)/100) IDLE, COUNT(*) PROCESS
FROM V$DISPATCHER WHERE CONF_INDX = 1 AND ACCEPT = 'YES'
UNION ALL
SELECT 'DISPATCHER 1525' TYPE, TRUNC(SUM(BUSY)/100) BUSY, TRUNC(SUM(IDLE)/100) IDLE, COUNT(*) PROCESS
FROM V$DISPATCHER WHERE CONF_INDX = 2 AND ACCEPT = 'YES'
UNION ALL
SELECT 'DISPATCHER OTHER' TYPE, TRUNC(SUM(BUSY)/100) BUSY, TRUNC(SUM(IDLE)/100) IDLE, COUNT(*) PROCESS
FROM V$DISPATCHER WHERE CONF_INDX > 2 AND ACCEPT = 'YES'
UNION ALL
SELECT 'SHARED SERVER', TRUNC(SUM(BUSY)/100), TRUNC(SUM(IDLE)/100), COUNT(*) PROCESS
FROM V$SHARED_SERVER WHERE STATUS <> 'QUIT'
) PS
WHERE QS.TYPE = PS.TYPE
/
SELECT
maximum_connections mc
,maximum_sessions ms
,servers_highwater sh
,to_number((SELECT value FROM v$parameter WHERE name = 'mts_max_servers' )) mss
,servers_started ss
,servers_terminated st
FROM V$MTS
PROMPT
PROMPT -------------------------------------------------------------------------------------------------------------------------------------
PROMPT
SET FEEDBACK ON
UNDEFINE ttime
COL NAME CLEAR
SET VERIFY OFF FEED OFF
COL POS FORMAT A8
COL NAME FORMAT A20
COL TEXT FORMAT A60
SELECT LINE||'/'||POSITION POS, NAME, TYPE, TEXT
FROM DBA_ERRORS
WHERE OWNER LIKE UPPER('&1.') AND NAME LIKE UPPER('&2.')
ORDER BY LINE
/
PROMPT
SET VERIFY ON FEED ON
SET LINES 200 DEFINE ON VERIFY OFF FEED OFF
BREAK ON INST_ID SKIP 1
DEFINE pname=&1.
COL INST_ID HEAD "Inst" FOR 99
COL NAME FORMAT A32 HEAD "Name"
COL VALUE FORMAT A50 TRUNC HEAD "Value"
COL ISDEFAULT HEAD "Default?" FORMAT A8
COL ISMODIFIED HEAD "Modificado?" FORMAT A11
COL ISADJUSTED HEAD "Ajustado?" FORMAT A9
COL ISDEPRECATED HEAD "Obsoleto?" FORMAT A9
COL ISSYS_MODIFIABLE HEAD "SysMod?" FORMAT A10
COL ISSES_MODIFIABLE HEAD "SessMod?" FORMAT A10
SET LINES 330 DEFINE ON VERIFY OFF
SELECT
INST_ID
,NAME
,VALUE
,ISDEFAULT
,ISMODIFIED
,ISADJUSTED
,ISDEPRECATED
,ISSYS_MODIFIABLE
,ISSES_MODIFIABLE
FROM GV$PARAMETER2
WHERE UPPER(NAME) LIKE UPPER('&PNAME.')
ORDER BY INST_ID, NAME, ORDINAL
/
SET LINES 120 DEFINE ON VERIFY ON FEED 6
UNDEFINE pname 1
CLEAR BREAK
SET TERMOUT OFF FEED OFF VERIFY OFF
break on inst_id skip 1
col Pool format a22 Heading "SGA Pool"
col Megas justify right heading "Size(MB)" format a11
col v_cache_size new_value p_cache_size
SELECT DECODE(SUBSTR( VERSION, 1, INSTR(VERSION, '.')-1), '8',
'((SELECT VALUE FROM V$PARAMETER WHERE NAME = ''db_block_size'')*BUFFERS/1048576)',
'CURRENT_SIZE' ) v_cache_size FROM V$INSTANCE
/
SET TERMOUT ON
COL PARAMETRO FORMAT A22 HEAD "Parâmetro"
SELECT inst_id, upper(name) PARAMETRO, To_char( value/1048576, '99g999g999') megas, ISADJUSTED, ISDEPRECATED
FROM gv$parameter2 WHERE name in ( 'sga_max_size', 'sga_target', 'memory_max_target', 'memory_target' )
order by inst_id,
case name
when 'memory_max_target' then 1
when 'memory_target' then 2
when 'sga_max_size' then 3
when 'sga_target' then 4
else 99
end
/
SELECT inst_id, decode( pool, null, decode(name, 'buffer_cache', 'buffer cache total', 'db_block_buffers', 'buffer cache total',
'fixed_sga', 'fixed sga', 'log_buffer', 'log buffer' ), pool ||
decode( substr( name, 1, 4 ), 'free', ' free', ' alloc' ) ) Pool ,
to_char( round(sum(bytes)/1048576,1), '999g990d00' ) Megas
FROM gv$sgastat
group by inst_id, decode( pool, null, decode(name, 'buffer_cache', 'buffer cache total', 'db_block_buffers', 'buffer cache total',
'fixed_sga', 'fixed sga', 'log_buffer', 'log buffer' ), pool ||
decode( substr( name, 1, 4 ), 'free', ' free', ' alloc' ) )
UNION
SELECT inst_id, pool || ' total', to_char( round(sum(bytes)/1048576,1), '999g990d00' )
FROM gv$sgastat
WHERE pool is not null
group by inst_id, pool
UNION
SELECT inst_id, 'total SGA', to_char( round(sum(bytes)/1048576,1), '999g990d00' )
FROM gv$sgastat
group by inst_id
union
SELECT inst_id, 'buffer cache ' || lower( name ), to_char( round(&p_cache_size.,1), '999g990d00' ) Megas
FROM gV$BUFFER_POOL
WHERE &p_cache_size. > 0
order by 1
/
col Pool format a22 Heading "PGA Pool"
SELECT inst_id, POOL, MEGAS
FROM
(
SELECT
inst_id,
TO_CHAR( ROUND(VALUE/1048576,1), '999g990d00') MEGAS,
DECODE( NAME, 'aggregate PGA target parameter', 'PGA Aggregate Target',
'aggregate PGA auto target', 'PGA Internal Target',
'total PGA inuse', 'Total PGA In Use',
'total PGA allocated', 'Total PGA Allocated', 'X' ) POOL
FROM gV$PGASTAT
)
WHERE POOL <> 'X'
order by 1
/
col Pool CLEAR
col Megas CLEAR
col Parametro CLEAR
SET FEED 6 VERIFY ON
PROMPT
-- The Session Snapper v4.34 ( USE AT YOUR OWN RISK !!! )
-- (c) Tanel Poder ( https://tanelpoder.com )
--
--Objetivo: Uma ferramenta de medição de desempenho em nível de sessão Oracle fácil de usar que NÃO requer nenhuma alteração no banco de dados nem a criação de qualquer objetos de banco de dados!
--
-- +-----=====O=== Welcome to The Session Snapper! (Yes, you are looking at a cheap ASCII
-- / imitation of a fish and a fishing rod.
-- | Nevertheless the PL/SQL code below the
-- | fish itself should be helpful for quick
-- | catching of relevant Oracle performance
-- | information.
-- | So I wish you happy... um... snapping?
-- | )
-- | ......
-- | iittii,,....
-- ¿ iiffffjjjjtttt,,
-- ..;;ttffLLLLffLLLLLLffjjtt;;..
-- ..ttLLGGGGGGLLffLLLLLLLLLLLLLLffjjii,, ..ii,,
-- ffGGffLLLLLLjjttjjjjjjjjffLLLLLLLLLLjjii.. ..iijj;;....
-- ffGGLLiittjjttttttiittttttttttffLLLLLLGGffii.. ;;LLLLii;;;;..
-- ffEEGGffiittiittttttttttiiiiiiiittjjjjffLLGGLLii.. iiLLLLLLttiiii,,
-- ;;ffDDLLiiiitt,,ttttttttttttiiiiiiiijjjjjjffLLLLffttiiiiffLLGGLLjjtttt;;..
-- ..ttttjjiitt,,iiiiiittttttttjjjjttttttttjjjjttttjjttttjjjjffLLDDGGLLttii..
-- iittiitttt, ;;iittttttttjjjjjjjjjjttjjjjjjffffffjjjjjjjjjjLLDDGGLLtt;;..
-- jjjjttttii:. ..iiiiffLLGGLLLLLLLLffffffLLLLLLLLLLLLLLLLffffffLLLLLLfftt,,
-- iittttii,,;;,,ttiiiiLLLLffffffjjffffLLLLLLLLffLLffjjttttttttttjjjjffjjii..
-- ,,iiiiiiiiiittttttiiiiiiiiiijjffffLLLLLLLLffLLffttttttii;;;;iiiitttttttt;;..
-- ..iittttttffffttttiiiiiiiiiittttffjjjjffffffffttiittii:: ....,,;;iittii;;
-- ..;;iittttttttttttttttiiiiiittttttttttjjjjjjtttttt;; ..;;ii;;..
-- ..;;;;iittttttjjttiittttttttttttttjjttttttttii.. ....
-- ....;;;;ttjjttttiiiiii;;;;;;iittttiiii..
-- ..;;ttttii;;.... ..;;;;....
-- ..iiii;;..
-- ..;;,,
-- ....
-- https://github.com/tanelpoder/tpt-oracle/blob/master/snapper.sql
--
PROMPT #
PROMPT # 'SINONIMOS PUBLICOS FALTANTES ON INCORRETOS NA xxx - ZZZ'
PROMPT # 'Obs. Exceto SYS, SYSTEM'
PROMPT #
COL "SINONIMOS IRREGULARES" FORMAT A80
SELECT /*+rule*/ 'CREATE PUBLIC SYNONYM ' ||O.OBJECT_NAME|| CHR(10) || 'FOR /* '||
O.OBJECT_TYPE ||' */ ' ||O.OWNER|| '.' ||O.OBJECT_NAME|| ';' "SINONIMOS IRREGULARES"
FROM DBA_OBJECTS O
WHERE O.OWNER IN ( 'SCHEMA' )
AND O.OBJECT_TYPE NOT IN ( 'SYNONYM', 'INDEX', 'INDEX PARTITION', 'TABLE PARTITION', 'DATABASE LINK', 'TRIGGER', 'PACKAGE BODY', 'LOB' )
AND O.OBJECT_NAME NOT LIKE '%$RP'
AND O.OBJECT_NAME NOT LIKE '___NUM_DOC_MULTA_SEQ'
AND O.OBJECT_NAME NOT LIKE 'BIN$%'
AND NOT EXISTS ( SELECT 1
FROM DBA_SYNONYMS
WHERE TABLE_OWNER = O.OWNER
AND TABLE_NAME = O.OBJECT_NAME
AND TABLE_OWNER NOT IN ( 'SYS', 'SYSTEM' ) )
UNION ALL
SELECT /*+rule*/ 'DROP PUBLIC SYNONYM ' || SYNONYM_NAME || ';' "SINONIMOS IRREGULARES"
FROM DBA_SYNONYMS S
WHERE OWNER = 'PUBLIC'
AND TABLE_OWNER NOT IN ( 'SYS', 'SYSTEM' )
AND NOT EXISTS ( SELECT 1
FROM DBA_OBJECTS
WHERE OBJECT_TYPE NOT IN ( 'SYNONYM', 'INDEX', 'DATABASE LINK', 'TRIGGER' )
AND OWNER NOT IN ( 'SYS', 'SYSTEM' )
AND OWNER = S.TABLE_OWNER
AND OBJECT_NAME = S.TABLE_NAME )
/
SET LONG 10000
SET FEEDBACK OFF RECSEP OFF UNDERLINE "~" VERIFY OFF DEFINE "&"
DEFINE TOPS=15
DEFINE USU_SCHEMA = "'SCHEMA', 'SCHEMA2', 'SCHEMA3', 'SCHEMA4','SCHEMA5'"
DEFINE USU_SCHEMA = "'USR_SOAP'"
COL X NOPRINT
COL SERVER FORMAT A19 HEAD "Processes"
COL USERNAME FORMAT A23 HEAD "Users (Top &TOPS.)"
COL STATUS FORMAT A19 HEAD "Status"
COL SESSOES FORMAT 999999999 HEAD "Sessions"
COL PROCESS FORMAT 999999999 HEAD " Quantidade"
COL PERCENT FORMAT 999999D00 HEAD "% Total"
COL SHARED FORMAT 999999999 HEAD " Shared"
COL DEDICADO FORMAT 999999999 HEAD " Dedicated"
COL PGA_USED FORMAT 999990D00 HEAD "PGA|Used (Mb)" JUST L
COL PGA_ALLOC FORMAT 999990D00 HEAD "PGA|Allocated (Mb)" JUST L
COL PGA_FREEABLE FORMAT 999990D00 HEAD "PGA|Freeable (Mb)" JUST L
BREAK ON REPORT
COMPUTE SUM LABEL TOTAL OF PGA_USED PGA_ALLOC PGA_FREEABLE PROCESS PERCENT ON REPORT
SELECT
V1.SERVER, V1.PGA_USED, V1.PGA_ALLOC, V1.PGA_FREEABLE, V1.PROCESS, V1.PROCESS*100/V1.TOT_PROCESS PERCENT
FROM (
SELECT DECODE( P.BACKGROUND, 1, 'BACKGROUND',
DECODE( SUBSTR( P.PROGRAM, INSTR( P.PROGRAM, '(' ) + 1, 2 )
,'PS', 'PSEUDO'
,'SN', 'JOB QUEUE', 'CJ', 'JOB QUEUE'
,'J0', 'JOB QUEUE', 'q0', 'JOB QUEUE'
,'TN', 'DEDICATED', 'or', 'DEDICATED'
,'D0', 'DISPATCHERS','D1', 'DISPATCHERS'
,'S0', 'SHARED SERVERS','S1', 'SHARED SERVERS'
,'P0', 'PARALLEL SERVERS','P1', 'PARALLEL SERVERS' ) ) SERVER
,COUNT(*) PROCESS
,ROUND(SUM(PGA_USED_MEM)/1048576,2) PGA_USED
,ROUND(SUM(PGA_ALLOC_MEM)/1048576,2) PGA_ALLOC
,ROUND(SUM(PGA_FREEABLE_MEM)/1048576,2) PGA_FREEABLE
,( sum(count(*)) over () ) TOT_PROCESS
FROM V$PROCESS P
GROUP BY DECODE( P.BACKGROUND, 1, 'BACKGROUND',
DECODE( SUBSTR( P.PROGRAM, INSTR( P.PROGRAM, '(' ) + 1, 2 )
,'PS', 'PSEUDO'
,'SN', 'JOB QUEUE', 'CJ', 'JOB QUEUE'
,'J0', 'JOB QUEUE', 'q0', 'JOB QUEUE'
,'TN', 'DEDICATED', 'or', 'DEDICATED'
,'D0', 'DISPATCHERS','D1', 'DISPATCHERS'
,'S0', 'SHARED SERVERS','S1', 'SHARED SERVERS'
,'P0', 'PARALLEL SERVERS','P1', 'PARALLEL SERVERS' ) )
ORDER BY PROCESS DESC
) V1
/
CLEAR BREAK
CLEAR COMPUTE
BREAK ON REPORT
COMPUTE SUM LABEL TOTAL OF SESSOES PERCENT SHARED DEDICADO ON REPORT
SELECT V1.USERNAME, V1.SESSOES, V1.SESSOES*100/V1.TOT_SESSOES PERCENT, V1.SHARED, V1.DEDICADO
FROM (
SELECT COUNT(*) SESSOES,
( sum(count(*)) over () ) TOT_SESSOES,
SUM(DECODE( SERVER, 'NONE', 1, 'SHARED', 1, 0 ) ) SHARED,
SUM(DECODE( SERVER, 'DEDICATED', 1, 0 ) ) DEDICADO,
DECODE(USERNAME, NULL, 'BACKGROUND',
DECODE( SUBSTR(USERNAME,3,2), 'BR', 'TIT_ONLINE (xxBR)', USERNAME ) ) USERNAME
FROM V$SESSION
GROUP BY
DECODE(USERNAME, NULL, 'BACKGROUND',
DECODE( SUBSTR(USERNAME,3,2), 'BR', 'TIT_ONLINE (xxBR)', USERNAME ) )
ORDER BY 1 DESC
) V1
WHERE ROWNUM <= &TOPS.
/
CLEAR BREAK
CLEAR COMPUTE
BREAK ON REPORT
COMPUTE SUM LABEL TOTAL OF SESSOES PERCENT SHARED DEDICADO ON REPORT
SELECT V1.USERNAME STATUS, V1.SESSOES, V1.SESSOES*100/V1.TOT_SESSOES PERCENT, V1.SHARED, V1.DEDICADO
FROM (
SELECT COUNT(*) SESSOES,
( sum(count(*)) over () ) TOT_SESSOES,
SUM(DECODE( SERVER, 'NONE', 1, 'SHARED', 1, 0 ) ) SHARED,
SUM(DECODE( SERVER, 'DEDICATED', 1, 0 ) ) DEDICADO,
STATUS USERNAME
FROM V$SESSION
GROUP BY STATUS
ORDER BY 1 DESC
) V1
/
CLEAR BREAK
CLEAR COMPUTE
COL SCHEMA FORMAT A35
col program format a50 head "Programa"
SELECT LOWER ( USERNAME || '.' || MACHINE ) SCHEMA, REGEXP_REPLACE( PROGRAM, '\(P[0..9][0..9][0..9]\)', '' ) PROGRAM, COUNT(*) "Qtde"
FROM V$SESSION
WHERE USERNAME IN ( &USU_SCHEMA )
GROUP BY LOWER ( USERNAME || '.' || MACHINE ), REGEXP_REPLACE( PROGRAM, '\(P[0..9][0..9][0..9]\)', '' )
order by count(*) desc
/
PROMPT
SET VERIFY OFF SERVEROUT ON FEEDBACK OFF
DECLARE
cValue varchar2(8000);
nPosI number := 1;
nPosF number := 0;
BEGIN
dbms_output.put_line( 'Dispatchers Configurados ' );
dbms_output.put_line( lpad( '~', 77, '~' ) );
SELECT distinct TRIM(VALUE) || ',' INTO cValue
FROM V$PARAMETER WHERE NAME in ( 'mts_dispatchers', 'dispatchers' );
LOOP
nPosF := instr(substr( cValue, nPosI), ',' );
dbms_output.put_line( Trim( substr( cValue, nPosI, nPosF-1)) );
nPosI := nPosI + nPosF;
exit when nPosI > length( cValue ) ;
END LOOP;
END;
/
COL LISTENER FORMAT A15 HEAD "Listener"
COL USERNAME FORMAT A31 HEAD "Usuário"
COL SESSOES FORMAT 9999999 HEAD "Sessões|Total"
COL SESSOES_ATIVAS FORMAT 9999999 HEAD "Sessões|Ativas"
COL SESSOES_INATIVAS FORMAT 9999999 HEAD "Sessões|Inativas"
COL SESSOES_SNIPED FORMAT 9999999 HEAD "Sessões|Sniped"
COL SESSOES_KILLED FORMAT 9999999 HEAD "Sessões|Killed"
col program format a50 head "Programa"
SET NULL TOTAL
BREAK ON LISTENER SKIP 1
WITH Nomes AS
(
SELECT
nvl(username, 'BackGround') username,
machine/* , program, server */,
replace( initcap
(
CASE
WHEN USERNAME IS NULL THEN 'BACKGROUND'
WHEN USERNAME = 'CAD_CONS1' THEN 'TELNET'
WHEN substr(username,3,2) = 'BR' THEN 'Titulo_Online'
WHEN USERNAME IN ( &USU_SCHEMA ) THEN decode(lower(substr(machine,1,4)),'xxx\','schema.xxx',username||'.'||machine )
ELSE USERNAME END
),'_','') eqNome
FROM
v$session
--ORDER BY 1
),
sd AS
(
SELECT nomes.username, nomes.eqnome, nomes.machine
FROM nomes
GROUP BY nomes.username, nomes.eqnome, nomes.machine
HAVING count(*) > 4
),
--g as (SELECT eqnome FROM nomes group by eqnome having count(*) > 4 ),
--sd AS
--(
-- SELECT distinct nomes.username, nomes.eqnome, nomes.machine
-- FROM nomes, g
-- WHERE nomes.eqnome = g.eqnome
--),
Circuitos AS
(
SELECT
decode( grouping(d.conf_indx) + grouping( sd.eqnome ), 2, 99, nvl(d.conf_indx+1,0) ) LISTENER
,decode( grouping(d.conf_indx) + grouping( sd.eqnome ), 2, 1, 1, 1, 0 ) ORDEM
,decode( grouping(sd.EqNome), 0, nvl(sd.EqNome, 'Outros' ), 'Total' ) USERNAME
,count(*) SESSOES
,sum( decode( s.status, 'ACTIVE' , 1, 0 ) ) SESSOES_ATIVAS
,sum( decode( s.status, 'INACTIVE', 1, 0 ) ) SESSOES_INATIVAS
,sum( decode( s.status, 'SNIPED' , 1, 0 ) ) SESSOES_SNIPED
,sum( decode( s.status, 'KILLED' , 1, 0 ) ) SESSOES_KILLED
FROM sd, v$session s, v$circuit c, v$dispatcher d
WHERE nvl(s.username, 'BackGround' ) = sd.username(+)
AND s.machine = sd.machine(+)
AND s.saddr = c.saddr(+) and c.dispatcher = d.paddr(+)
GROUP BY ROLLUP( d.conf_indx, sd.eqnome )
)
SELECT
decode( c.listener, 99, 'Total', 0, 'Dedicado', 'Dispatcher' ) LISTENER
,c.username
,c.sessoes
,c.sessoes_ativas
,c.sessoes_inativas
,c.sessoes_sniped
,c.sessoes_killed
FROM
CIRCUITOS C
ORDER BY c.listener, c.ordem, c.sessoes
/
PROMPT
SET FEEDBACK 6 UNDERLINE "-" VERIFY ON NULL ''
CLEAR BREAK
COL SERVER CLEAR
COL STATUS CLEAR
COL PERCENT CLEAR
COL PROCESS CLEAR
COL LISTENER CLEAR
COL USERNAME CLEAR
COL SESSOES CLEAR
COL SESSOES_ATIVAS CLEAR
COL SESSOES_INATIVAS CLEAR
COL SESSOES_SNIPED CLEAR
COL SESSOES_KILLED CLEAR
COL PGA_USED CLEAR
COL PGA_ALLOC CLEAR
COL PGA_FREEABLE CLEAR
COL PROGRAM CLEAR
UNDEFINE USO_SCHEMA
SET LINES 120
COL NEXT FORMAT A30
COL NAME FORMAT A30
SELECT NAME, TO_CHAR(LAST_REFRESH, 'DD/MM HH24:MI"h"' ) "LAST REFRESH",
NEXT, CAN_USE_LOG, STATUS, REFRESH_MODE, PREBUILT
FROM DBA_SNAPSHOTS WHERE OWNER='SCHEMA'
order by prebuilt desc
/
SET DEFINE ON
PROMPT &3 &4 &1
-- CONN &1/&2@(DESCRIPTION=(ADDRESS_LIST=(ADDRESS=(COMMUNITY=TCP.WORLD)(PROTOCOL=TCP)(HOST=&3)(PORT=1521))(ADDRESS=(COMMUNITY=TCP.WORLD)(PROTOCOL=TCP)(HOST=&3)(PORT=1526)))(CONNECT_DATA=(SID=&4)));
CONN &1/&2@(DESCRIPTION=(ADDRESS_LIST=(ADDRESS=(COMMUNITY=TCP.WORLD)(PROTOCOL=TCP)(HOST=&3)(PORT=1521)))(CONNECT_DATA=(SID=&4)));
-- SET SQLPROMPT '&&3 &&4 &&1> '
-- @LOGIN;
SET VERIFY OFF FEED OFF
DEFINE USU = "&1."
PROMPT
PROMPT EXECUTANDO DBMS_UTILITY.COMPILE_SCHEMA( UPPER( '&USU.' ) )
EXEC DBMS_UTILITY.COMPILE_SCHEMA( UPPER( '&USU.' ) )
COL STMT FORMAT A80
SET SERVEROUT ON
DECLARE
CURSOR C IS
SELECT 'ALTER ' ||
DECODE( OWNER, 'PUBLIC', 'PUBLIC ', '' ) ||
DECODE( OBJECT_TYPE, 'PACKAGE BODY', 'PACKAGE', OBJECT_TYPE ) || ' ' ||
DECODE( OWNER, 'PUBLIC', '', OWNER||'.' ) || OBJECT_NAME || ' COMPILE' ||
DECODE( OBJECT_TYPE, 'PACKAGE BODY', ' BODY', '' ) STMT
FROM DBA_OBJECTS
WHERE STATUS <> 'VALID'
AND OWNER = UPPER( '&USU.' )
ORDER BY OBJECT_TYPE;
BEGIN
DBMS_OUTPUT.ENABLE( 100000 );
FOR R IN C LOOP
BEGIN
EXECUTE IMMEDIATE R.STMT;
EXCEPTION
WHEN OTHERS THEN
DBMS_OUTPUT.PUT_LINE( R.STMT );
DBMS_OUTPUT.PUT_LINE( SUBSTR(SQLERRM, 1, 254) || CHR(10) );
END;
END LOOP;
END;
/
SELECT OWNER, OBJECT_TYPE, OBJECT_NAME, STATUS
FROM DBA_OBJECTS
WHERE STATUS <> 'VALID'
AND OWNER = UPPER( '&USU.' );
SELECT COUNT(*) INVALIDOS
FROM DBA_OBJECTS
WHERE STATUS <> 'VALID'
AND OWNER = UPPER( '&USU.' );
SELECT OWNER, OBJECT_TYPE, COUNT(*) FROM
DBA_OBJECTS WHERE STATUS<>'VALID'
GROUP BY OWNER, OBJECT_TYPE
HAVING COUNT(*) >= 3
ORDER BY OWNER
/
SET PAGES 200
BREAK ON OWNER SKIP PAGE
SELECT owner, object_type, object_name, status
FROM dba_objects
WHERE owner in ( 'ADMSADP', 'EUL_OWNER', 'FOLHA', 'LINK', 'MANUTENCAO', 'PARTIDO', 'SIAC', 'SISFARM', 'SRH2' )
and status = 'INVALID'
order by owner, object_type, object_name
PROMPT
COL STMT CLEAR
SET VERIFY ON FEED 6
UNDEFINE 1 USU
define p_owner='&1.'
col objeto format a40
set serverout on verify off
spool checksym.&P_OWNER..log
declare
e_sym_invalid exception;
cursor c1 is
SELECT o.status, s.owner, s.synonym_name, table_owner || '.' || table_name objeto
FROM dba_synonyms s, dba_objects o
WHERE o.object_name = s.synonym_name
and o.owner = s.owner
and o.object_type = 'SYNONYM'
and o.status = 'INVALID'
and s.owner = upper( '&p_owner.');
--and rownum < 3;
--and s.table_owner = 'ADMCAD';
cStmCompile VARCHAR2(200);
cStmRebuild VARCHAR2(200);
cStmDrop VARCHAR2(200);
pragma exception_init( e_sym_invalid, -980 );
begin
dbms_output.enable(1e+6);
for r in c1 loop
if r.owner = 'PUBLIC' then
cStmRebuild := 'create public synonym ' || r.synonym_name || ' for ' || r.objeto;
cStmCompile := 'alter public synonym ' || r.synonym_name || ' compile';
cStmDrop := 'drop public synonym ' || r.synonym_name;
else
cStmRebuild := 'create synonym ' || r.owner ||'.'|| r.synonym_name || ' for ' || r.objeto;
cStmCompile := 'alter synonym ' || r.owner ||'.'|| r.synonym_name || ' compile';
cStmDrop := 'drop synonym ' || r.owner ||'.'|| r.synonym_name;
end if;
begin
execute immediate cStmCompile;
exception
when e_sym_invalid then
dbms_output.put_line( cStmRebuild );
begin
execute immediate cStmDrop;
exception
when others then
dbms_output.put_line( cStmDrop );
end;
when others then
dbms_output.put_line( sqlerrm );
dbms_output.put_line( cStmCompile );
end;
end loop;
end;
/
SELECT o.status, table_owner, count(*)
FROM dba_synonyms s, dba_objects o
WHERE o.object_name = s.synonym_name
and o.owner = s.owner
and o.object_type = 'SYNONYM'
and o.status = 'INVALID'
and s.owner = upper( '&p_owner.')
group by status, table_owner;
spool off
set verify off
alter session set current_schema=&1.;
set verify on
PROMPT
DEFINE USU_SECAD = "'SAE', 'FILIACAO_WEB', 'TITULONET', 'SAECERTIDAO','LOCAL_VOTACAO_WEB'"
--DEBUG DE PROCESSOS QUE NÃO TEM SESSÃO
SELECT P.SPID, P.ADDR, S.PADDR SESPROCESS, B.PADDR BGPROCESS, COUNT(S.PADDR) SESSOES
FROM V$PROCESS P, V$SESSION S, V$BGPROCESS B
WHERE P.ADDR = S.PADDR(+)
AND P.ADDR = B.PADDR(+)
GROUP BY P.SPID, P.ADDR, S.PADDR, B.PADDR
ORDER BY SESSOES
.
SET VERIFY OFF SERVEROUT ON FEEDBACK OFF UNDERLINE '~' LINES 142
col st1 format a14 heading "Startup Time"
col st2 format a14 heading "System Date"
col st3 format a12 heading "Running Time"
col st4 format a12 heading "Running Secs"
COL LISTENER FORMAT A15 Head "Listener"
COL USERNAME FORMAT A30 Head "Usuário"
COL SESSOES FORMAT 9999999 Head "Sessões|Total"
COL SESSOES_ATIVAS FORMAT 9999999 Head "Sessões|Ativas"
COL SESSOES_INATIVAS FORMAT 9999999 Head "Sessões|Inativas"
COL SESSOES_SNIPED FORMAT 9999999 Head "Sessões|Sniped"
COL SESSOES_KILLED FORMAT 9999999 Head "Sessões|Killed"
Col TYPE Format A17 Head "Process|Queue"
Col QTOTAL Format 99g999G999G999 Head "Enqueued|Packets"
Col QWAIT Format 99g999G999G999 Head "Wait|Time(ms)"
Col AVGRES Format 9990D000 Head "Agv Wait|Time(ms)"
Col QIDLE Format 99g999G999G999 Head "Idle|Time(s)"
Col QBUSY Format 99g999G999G999 Head "Busy|Time(s)"
Col PCT_BUSY Format 9990D00 Head "Pct|Busy"
Col QTD_PRC Format 9999 Head "Running|Processes"
Col MC Format 9999 Head "Max|Circuits"
Col MS Format 9999 Head "Max|S.Sessions"
Col SH Format 9999 Head "Max|S.Servers"
Col MSS Format 9999 Head "Limite|S.Servers"
Col SS Format 999g999 Head "Started|S.Servers"
Col ST Format 999g999 Head "Terminated|S.Servers"
SELECT
to_char( startup_time, 'dd/mm/yy hh24"h"mi' ) st1,
to_char( sysdate, 'dd/mm/yy hh24"h"mi' ) st2,
lpad( to_char( trunc(sysdate,'YEAR') + (sysdate-startup_time-1),
decode( trunc( sysdate-startup_time, 0 ), 0, 'fm" 0d "hh24"h"mi', 'fm""ddd"d "hh24"h"mi' ) ), 12, ' ' ) st3,
to_char( (sysdate-startup_time)*24*60*60, '999g999g990' ) st4
FROM v$instance;
PROMPT
DECLARE
cValue VARCHAR2(8000);
nPosI number := 1;
nPosF number := 0;
BEGIN
dbms_output.put_line( 'Dispatchers Configurados ' );
dbms_output.put_line( lpad( '~', 77, '~' ) );
SELECT distinct TRIM(VALUE) || ',' INTO cValue
FROM V$PARAMETER WHERE NAME in ( 'mts_dispatchers', 'dispatchers' );
LOOP
nPosF := instr(substr( cValue, nPosI), ',' );
dbms_output.put_line( Trim( substr( cValue, nPosI, nPosF-1)) );
nPosI := nPosI + nPosF;
exit when nPosI > length( cValue ) ;
END LOOP;
END;
/
SET NULL TOTAL
BREAK ON LISTENER SKIP 1
WITH Nomes AS
(
SELECT
nvl(username, 'BackGround') username,
machine/* , program, server */,
replace( initcap
(
CASE
WHEN USERNAME IS NULL THEN 'BACKGROUND'
WHEN USERNAME = 'CAD_CONS1' THEN 'TELNET'
WHEN substr(username,3,2) = 'BR' THEN 'Titulo_Online'
WHEN USERNAME IN ( &USU_SECAD ) THEN decode(lower(substr(machine,1,4)),'xxx\','sae.xxx',username||'.'||machine )
ELSE USERNAME END
),'_','') eqNome
FROM
v$session
--ORDER BY 1
),
Circuitos AS
(
SELECT
decode( grouping(d.conf_indx) + grouping( sd.eqnome ), 2, 99, nvl(d.conf_indx+1,0) ) LISTENER
,decode( grouping(d.conf_indx) + grouping( sd.eqnome ), 2, 1, 1, 1, 0 ) ORDEM
,decode( grouping(sd.EqNome), 0, nvl(sd.EqNome, 'Outros' ), 'Total' ) USERNAME
,count(*) SESSOES
,sum( decode( s.status, 'ACTIVE' , 1, 0 ) ) SESSOES_ATIVAS
,sum( decode( s.status, 'INACTIVE', 1, 0 ) ) SESSOES_INATIVAS
,sum( decode( s.status, 'SNIPED' , 1, 0 ) ) SESSOES_SNIPED
,sum( decode( s.status, 'KILLED' , 1, 0 ) ) SESSOES_KILLED
FROM
(
SELECT distinct nomes.username, nomes.eqnome, nomes.machine
FROM nomes, (SELECT eqnome FROM nomes group by eqnome having count(*) > 4 ) g
WHERE nomes.eqnome = g.eqnome
) sd, v$session s, v$circuit c, v$dispatcher d
WHERE nvl(s.username, 'BackGround' ) = sd.username(+)
AND s.machine = sd.machine(+)
AND s.saddr = c.saddr(+) and c.dispatcher = d.paddr(+)
GROUP BY ROLLUP( d.conf_indx, sd.eqnome )
)
SELECT
decode( c.listener, 99, 'Total', 0, 'Dedicado', 'Dispatcher' ) LISTENER
,c.username
,c.sessoes
,c.sessoes_ativas
,c.sessoes_inativas
,c.sessoes_sniped
,c.sessoes_killed
FROM
CIRCUITOS C
ORDER BY c.listener, c.ordem, c.sessoes
/
PROMPT
CLEAR BREAK
COL LISTENER CLEAR
COL USERNAME CLEAR
COL SESSOES CLEAR
COL SESSOES_ATIVAS CLEAR
COL SESSOES_INATIVAS CLEAR
COL SESSOES_SNIPED CLEAR
COL SESSOES_KILLED CLEAR
REM SET TERMOUT OFF
REM Col ttime NEW_VALUE ttime
REM SELECT to_char( sysdate, 'dd/mm hh24:mi:ss' ) ttime FROM dual;
REM SET TERMOUT ON
REM PROMPT
REM PROMPT ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
REM PROMPT SHARED SERVER MODEL (&ttime.)
REM PROMPT Referência: AvgWaitTime 0,10ms ~ 0,30ms | BusyTime < 50%
REM PROMPT ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
SELECT
PS.TYPE TYPE
,QS.QTOTAL QTOTAL
,QS.QWAIT QWAIT
,ROUND( DECODE(QS.QWAIT, 0, 0, QS.QWAIT/QS.QTOTAL ), 2 ) AVGRES
,PS.IDLE QIDLE
, PS.BUSY QBUSY
, ROUND( PS.BUSY/(PS.BUSY+PS.IDLE) * 100, 2 ) PCT_BUSY
, PS.PROCESS QTD_PRC
FROM
(
SELECT
'Shared Server' TYPE
,SUM(Q.TOTALQ) QTOTAL
,SUM(Q.WAIT)*10 QWAIT
FROM V$QUEUE Q
WHERE Q.TYPE = 'COMMON'
UNION ALL
SELECT
decode( d.conf_indx, null, 'Dedicado', 'Dispatcher' ) TYPE
,SUM(Q.TOTALQ) QTOTAL
,SUM(Q.WAIT)*10 QWAIT
FROM V$QUEUE Q, V$DISPATCHER D
WHERE Q.TYPE = 'DISPATCHER'
AND Q.PADDR = D.PADDR
AND D.ACCEPT = 'YES'
GROUP BY
decode( d.conf_indx, null, 'Dedicado', 'Dispatcher' )
) QS,
(
SELECT
'Shared Server' TYPE
,TRUNC(SUM(BUSY)/100) BUSY, TRUNC(SUM(IDLE)/100) IDLE, COUNT(*) PROCESS
FROM V$SHARED_SERVER WHERE STATUS <> 'QUIT'
UNION ALL
SELECT
decode( d.conf_indx, null, 'Dedicado', 'Dispatcher' ) TYPE
,TRUNC(SUM(D.BUSY)/100) BUSY, TRUNC(SUM(D.IDLE)/100) IDLE, COUNT(*) PROCESS
FROM V$DISPATCHER D, (SELECT value||'listener=Port 1521)' par FROM v$parameter WHERE name='dispatchers' ) p
WHERE D.ACCEPT = 'YES'
GROUP BY
decode( d.conf_indx, null, 'Dedicado', 'Dispatcher' )
) PS
WHERE QS.TYPE = PS.TYPE
/
SELECT
maximum_connections mc
,maximum_sessions ms
,servers_highwater sh
,to_number((SELECT value FROM v$parameter WHERE name = 'max_shared_servers' )) mss
,servers_started ss
,servers_terminated st
FROM V$SHARED_SERVER_MONITOR
/
SET NULL ''
SELECT STATUS, COUNT(*) "#SS" FROM V$SHARED_SERVER GROUP BY STATUS
/
col sessao format a12 jus r head "Sessao"
col spid format a5 head "SPId"
col username format a18 head "Usuario"
col machine format a25 head "Machine"
col status format a22 head "Status"
col program format a50 head "Programa"
col requests format 999g999g999
col "%BUSY" format 990D00
SELECT /*+rule*/
LPAD( ''''||S.SID||','||S.SERIAL#||'''',12,' ') sessao, p.spid, s.username
,s.status || ' ' || ss.status status
,s.machine, s.program
FROM
v$session s, v$circuit c, v$shared_server ss, v$process p
WHERE s.saddr = c.saddr and c.circuit = ss.circuit
and ss.paddr = p.addr
and ss.status in ( 'WAIT(RECEIVE)', 'EXEC', 'WAIT(SEND)' )
order by 4,6
-- and s.status <> 'ACTIVE'
/
REM PROMPT
REM PROMPT SHARED SERVER STATUS
REM PROMPT ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
SELECT
decode( grouping(s.program), 1, 'TOTAL', NVL(s.program, 'UNKNOW' ) ) program
,s.status || ' ' || ss.status status
,count(*) qtde
,sum(ss.requests) requests
,round(100*(sum(ss.busy)/sum(ss.busy+ss.idle)),2) "%BUSY"
FROM
v$session s, v$circuit c, v$shared_server ss
WHERE s.saddr = c.saddr and c.circuit = ss.circuit
group by grouping sets( (s.program, s.status, ss.status), () )
order by s.program, s.status, ss.status
PROMPT
SET FEEDBACK 6 VERIFY ON NULL '' UNDERLINE '-'
COL PROGRAM CLEAR
UNDEFINE USO_SECAD
col X noprint
col Y format a60 head "Backup DIV2002:UF1"
col Z format a60 head "Restore DIV2002:UF1"
SET VERIFY OFF ECHO OFF FEEDBACK OFF
DEFINE target=c:\oraclass
SELECT sum( megas ) "BackupSize MB"
FROM (
SELECT sum(bytes)/1048576 megas FROM v$datafile
union all
SELECT sum(bytes)/1048576 megas FROM v$tempfile
union all
SELECT 410 megas FROM dual
)
/
SELECT 1 "X", 'mkdir &target.\backup\' "Y" FROM dual
union
SELECT 1, 'mkdir &target.\backup' || substr(name,1,7) FROM v$controlfile
union
SELECT 1, 'mkdir &target.\backup' || substr(name,1,7) FROM v$datafile
union
SELECT 1, 'mkdir &target.\backup' || substr(name,1,7) FROM v$tempfile
union
SELECT 1, 'mkdir &target.\backup' || substr(member,1,7) FROM v$logfile
union
SELECT 1, 'mkdir &target.\backup' || substr(name,1,7)||substr(name,8,instr(substr(name,8,10),'\')) FROM v$controlfile
union
SELECT 1, 'mkdir &target.\backup' || substr(name,1,7)||substr(name,8,instr(substr(name,8,10),'\')) FROM v$datafile
union
SELECT 1, 'mkdir &target.\backup' || substr(name,1,7)||substr(name,8,instr(substr(name,8,10),'\')) FROM v$tempfile
union
SELECT 1, 'mkdir &target.\backup' || substr(member,1,7)||substr(member,8,instr(substr(member,8,10),'\')) FROM v$logfile
union
SELECT 2, '' FROM dual
union
SELECT 3, 'copy ' || substr(name,1,7)||substr(name,8,instr(substr(name,8,10),'/')) || 'div2002/* &target.\backup' || substr(name,1,7)||substr(name,8,instr(substr(name,8,10),'/')) FROM v$controlfile
union
SELECT 3, 'copy ' || substr(name,1,7)||substr(name,8,instr(substr(name,8,10),'/')) || 'div2002/* &target.\backup' || substr(name,1,7)||substr(name,8,instr(substr(name,8,10),'/')) FROM v$datafile
union
SELECT 3, 'copy ' || substr(name,1,7)||substr(name,8,instr(substr(name,8,10),'/')) || 'div2002/* &target.\backup' || substr(name,1,7)||substr(name,8,instr(substr(name,8,10),'/')) FROM v$tempfile
union
SELECT 3, 'copy ' || substr(member,1,7)||substr(member,8,instr(substr(member,8,10),'/')) || 'div2002/* &target.\backup' || substr(member,1,7)||substr(member,8,instr(substr(member,8,10),'/')) FROM v$logfile
union
SELECT 4, '' FROM dual
/
SELECT 0 "X", 'touch \&target.\backup\restore.sh' "Z" FROM dual
union
SELECT 1, 'chmod g+x,u+x \&target.\backup\restore.sh' FROM dual
union
SELECT 2, 'vi \&target.\backup\restore.sh' FROM dual
union
SELECT 3, 'i### Restauracao do banco DIV2002 ###' FROM dual
union
SELECT 4, 'cp &target.\backup' || substr(name,1,7)||substr(name,8,instr(substr(name,8,10),'/')) || '* ' || substr(name,1,7)||substr(name,8,instr(substr(name,8,10),'/')) || 'div2002/' FROM v$controlfile
union
SELECT 4, 'cp &target.\backup' || substr(name,1,7)||substr(name,8,instr(substr(name,8,10),'/')) || '* ' || substr(name,1,7)||substr(name,8,instr(substr(name,8,10),'/')) || 'div2002/' FROM v$datafile
union
SELECT 4, 'cp &target.\backup' || substr(name,1,7)||substr(name,8,instr(substr(name,8,10),'/')) || '* ' || substr(name,1,7)||substr(name,8,instr(substr(name,8,10),'/')) || 'div2002/' FROM v$tempfile
union
SELECT 4, 'cp &target.\backup' || substr(member,1,7)||substr(member,8,instr(substr(member,8,10),'/')) || '* ' || substr(member,1,7)||substr(member,8,instr(substr(member,8,10),'/')) || 'div2002/' FROM v$logfile
union
SELECT 5, '' FROM dual
/
col X clear
col Y clear
col Z clear
SET VERIFY ON ECHO OFF FEEDBACK ON
UNDEFINE target
SELECT
D.GROUP_NUMBER
,D.HEADER_STATUS ST_HEADER
,( SELECT G.NAME FROM V$ASM_DISKGROUP G WHERE G.GROUP_NUMBER = D.GROUP_NUMBER ) GROUP_NAME
,D.DISK_NUMBER
,D.NAME DISK_NAME
,D.PATH
,D.FAILGROUP
,D.MODE_STATUS ST_MODE
,D.FAILGROUP_TYPE
,RPAD(CASE WHEN D.VOTING_FILE = 'Y' THEN 'YES' ELSE 'no' END,6, ' ' ) VOTING
FROM V$ASM_DISK D
WHERE D.GROUP_NUMBER = 2
ORDER BY GROUP_NUMBER, DISK_NUMBER
/
===============> DG_GRID (this configuration does not work during the test scenario)
G# ST_HEADER GROUP_NAME D# DISK_NAME PATH FGROUP ST_MODE FAILGRO VOTING
-- --------- ----------- -- ------------ ------------------------------ ------- ------- ------- ------
2 MEMBER DG_GRID 0 DG_GRID_A01 ORCL:DG_GRID_A01 SITE1 ONLINE REGULAR YES
2 MEMBER DG_GRID 1 DG_GRID_A02 ORCL:DG_GRID_A02 SITE1 ONLINE REGULAR no
2 MEMBER DG_GRID 2 DG_GRID_B01 ORCL:DG_GRID_B01 SITE2 ONLINE REGULAR YES
2 MEMBER DG_GRID 3 DG_GRID_B02 ORCL:DG_GRID_B02 SITE2 ONLINE REGULAR no
2 MEMBER DG_GRID 4 DG_GRID_C01 /prg/voting/vote_file SITE3 ONLINE QUORUM YES
===============> DG_GRID (this the final configuration)
G# ST_HEADER GROUP_NAME D# DISK_NAME PATH FGROUP ST_MODE FAILGRO VOTING
-- --------- ----------- -- ------------ ------------------------------ ------- ------- ------- ------
2 MEMBER DG_GRID 0 DG_GRID_A01 ORCL:DG_GRID_A01 SITE1 ONLINE REGULAR YES
2 MEMBER DG_GRID 2 DG_GRID_B01 ORCL:DG_GRID_B01 SITE2 ONLINE REGULAR YES
2 MEMBER DG_GRID 4 DG_GRID_C01 /prg/voting/vote_file SITE3 ONLINE QUORUM YES
SET LINES 1000 FEED OFF
COL PATH FORMAT A50
COL FAILGROUP FORMAT A20
COL LABEL FORMAT A20
COL GROUP_NUMBER FORMAT 999 HEAD "G#"
COL DISK_NUMBER FORMAT 999 HEAD "D#"
COL FILE_NUMBER FORMAT 9999 HEAD "F#"
COL COMPATIBILITY FORMAT A12
COL DATABASE_COMPATIBILITY FORMAT A12
COL FILE_NAME FORMAT A34
COL FILE_TYPE FORMAT A20
COL GROUP_NAME FORMAT A20
COL DISK_NAME FORMAT A20
PROMPT
PROMPT ===============> ASM DISKGROUPS
SELECT
GROUP_NUMBER
,NAME GROUP_NAME
,STATE
,TYPE
,ROUND(TOTAL_MB/1024) TOTAL_GB
,ROUND(FREE_MB/1024) FREE_GB
,SECTOR_SIZE
,BLOCK_SIZE
,ALLOCATION_UNIT_SIZE
FROM V$ASM_DISKGROUP
ORDER BY 1
/
PROMPT
PROMPT ===============> ASM CLIENTS
SELECT
dg.name GROUP_NAME
,SUBSTR(c.instance_name,1,12) AS instance
,rpad(c.db_name,12,' ') DB_CLIENT
FROM V$ASM_DISKGROUP dg
JOIN V$ASM_CLIENT c ON (dg.group_number = c.group_number)
/
PROMPT
PROMPT ===============> ASM DISKS
SELECT
D.GROUP_NUMBER
,D.HEADER_STATUS
,( SELECT G.NAME FROM V$ASM_DISKGROUP G WHERE G.GROUP_NUMBER = D.GROUP_NUMBER ) GROUP_NAME
,D.DISK_NUMBER
,D.NAME DISK_NAME
,D.FAILGROUP
,D.PATH
,ROUND(D.FREE_MB/1024) USABLE_GB
,D.MODE_STATUS
,D.STATE
,D.READS
,D.WRITES
,D.READ_TIME
,D.WRITE_TIME
,D.LABEL
,D.REDUNDANCY
,D.CREATE_DATE
,D.MOUNT_DATE
FROM V$ASM_DISK D
ORDER BY GROUP_NUMBER, DISK_NUMBER
/
PROMPT
PROMPT ===============> ASM FILES
SELECT
A.GROUP_NUMBER
,( SELECT G.NAME FROM V$ASM_DISKGROUP G WHERE G.GROUP_NUMBER = A.GROUP_NUMBER ) GROUP_NAME
,A.FILE_NUMBER
,F.TYPE FILE_TYPE
,A.NAME FILE_NAME
,ROUND(F.BYTES/1024/1024) SIZE_MB
,ROUND(F.SPACE/1024/1024) SPACE_MB
,F.BLOCK_SIZE
,F.BLOCKS
,F.REDUNDANCY
,F.STRIPED
,F.CREATION_DATE
,F.MODIFICATION_DATE
,A.ALIAS_INDEX
,A.ALIAS_INCARNATION
,A.SYSTEM_CREATED
,A.ALIAS_DIRECTORY
,A.FILE_INCARNATION
FROM V$ASM_FILE F
JOIN V$ASM_ALIAS A
ON ( A.GROUP_NUMBER = F.GROUP_NUMBER AND A.FILE_NUMBER = F.FILE_NUMBER AND A.FILE_INCARNATION = F.INCARNATION )
WHERE A.SYSTEM_CREATED = 'Y'
ORDER BY 1, 3
/
PROMPT
PROMPT ===============> TABLESPACES
REM @DBAFREESPACE %
SET LINES 1000 FEED OFF
COL PATH FORMAT A30
COL LABEL FORMAT A20
COL GROUP_NUMBER FORMAT 99 HEAD "G#"
COL VOLUME_NUMBER FORMAT 99 HEAD "V#"
COL NUM_VOL FORMAT 99 HEAD "V#"
COL DISK_NUMBER FORMAT 99 HEAD "D#"
COL FILE_NUMBER FORMAT 999 HEAD "F#"
COL FS_NAME FORMAT A30
COL MOUNTPATH FORMAT A30
COL VOLUME_DEVICE FORMAT A30
COL FAILGROUP FORMAT A11 HEAD FGROUP
COL COMPATIBILITY FORMAT A12
COL DATABASE_COMPATIBILITY FORMAT A12
COL FILE_NAME FORMAT A34
COL FILE_TYPE FORMAT A20
COL GROUP_NAME FORMAT A17
COL DISK_NAME FORMAT A28 HEAD DISK_NAME
COL LABEL_NAME FORMAT A28 HEAD LABEL_NAME
COL VOLUME_NAME FORMAT A20 HEAD VOLUME_NAME
COL VOTING FORMAT A6
COL INSTANCE FORMAT A12
COL DB_CLIENT FORMAT A12
COL SOFTWARE FORMAT A12
COL COMPATIBLE FORMAT A12
COL COMPATIBLE_ASM FORMAT A11 HEAD "COMPATIBLE|ASM"
COL COMPATIBLE_RDBMS FORMAT A11 HEAD "COMPATIBLE|RDBMS"
COL COMPATIBLE_ADVM FORMAT A11 HEAD "COMPATIBLE|ADVM"
COL REPAIR_TIME FORMAT A7 HEAD "REPAIR|TIME"
PROMPT
PROMPT ===============> ASM DISKGROUPS <===============
PROMPT
-- sql original
SELECT
GROUP_NUMBER
,NAME GROUP_NAME
,STATE
,TYPE
,ROUND(TOTAL_MB/1024) TOTAL_GB
,ROUND(FREE_MB/1024) FREE_GB
,ROUND(COLD_USED_MB/1024) COLD_USED_GB
,ROUND(USABLE_FILE_MB/1024) USABLE_GB
,SECTOR_SIZE
,BLOCK_SIZE
,ALLOCATION_UNIT_SIZE
,REQUIRED_MIRROR_FREE_MB
,OFFLINE_DISKS
,COMPATIBILITY
,DATABASE_COMPATIBILITY
,VOTING_FILES
FROM V$ASM_DISKGROUP
ORDER BY 1
/
-- sql alterado
SELECT
D.GROUP_NUMBER
,D.NAME GROUP_NAME
,CASE D.STATE WHEN 'CONNECTED' THEN 'MOUNTED' ELSE D.STATE END STATE
,D.TYPE
,ROUND(D.TOTAL_MB/1024) OS_TOTAL_GB
,ROUND(D.TOTAL_MB/1024/2) TOTAL_GB
,ROUND(D.COLD_USED_MB/1024/2) USED_GB
,ROUND(D.FREE_MB/1024/2) FREE_GB
,ROUND(D.REQUIRED_MIRROR_FREE_MB/1024/2) MIRROR_GB
,ROUND(D.USABLE_FILE_MB/1024) USABLE_GB
,(SELECT VALUE FROM V$ASM_ATTRIBUTE A WHERE D.GROUP_NUMBER = A.GROUP_NUMBER AND NAME = 'disk_repair_time' ) REPAIR_TIME
,(SELECT VALUE FROM V$ASM_ATTRIBUTE A WHERE D.GROUP_NUMBER = A.GROUP_NUMBER AND NAME = 'compatible.asm' ) COMPATIBLE_ASM
,(SELECT VALUE FROM V$ASM_ATTRIBUTE A WHERE D.GROUP_NUMBER = A.GROUP_NUMBER AND NAME = 'compatible.rdbms' ) COMPATIBLE_RDBMS
,(SELECT VALUE FROM V$ASM_ATTRIBUTE A WHERE D.GROUP_NUMBER = A.GROUP_NUMBER AND NAME = 'compatible.advm' ) COMPATIBLE_ADVM
FROM V$ASM_DISKGROUP D
ORDER BY 1
/
PROMPT
PROMPT ===============> ASM VOLUMES <===============
PROMPT
SELECT
GROUP_NUMBER
,VOLUME_NUMBER
,VOLUME_NAME
,ROUND(SIZE_MB/1024) SIZE_GB
,VOLUME_DEVICE
,MOUNTPATH
,STATE
,REDUNDANCY
,STRIPE_COLUMNS
,STRIPE_WIDTH_K
,COMPOUND_INDEX
,FILE_NUMBER
,INCARNATION
,DRL_FILE_NUMBER
,RESIZE_UNIT_MB
,USAGE
FROM V$ASM_VOLUME
/
PROMPT
PROMPT ===============> ASM FILESYSTEMS <===============
PROMPT
SELECT
NUM_VOL
,FS_NAME
,AVAILABLE_TIME
,BLOCK_SIZE
,STATE
,CORRUPT
,ROUND(TOTAL_SIZE/1024) SIZE_GB
,ROUND(TOTAL_FREE/1024) FREE_GB
,TOTAL_SNAP_SPACE_USAGE
FROM V$ASM_FILESYSTEM
/
PROMPT
PROMPT ===============> ASM CLIENTS <===============
PROMPT
SELECT
dg.name GROUP_NAME
,SUBSTR(c.instance_name,1,12) AS instance
,rpad(c.db_name,12,' ') DB_CLIENT
,SUBSTR(c.SOFTWARE_VERSION,1,12) AS software
,SUBSTR(c.COMPATIBLE_VERSION,1,12) AS compatible
FROM V$ASM_DISKGROUP dg
JOIN V$ASM_CLIENT c ON (dg.group_number = c.group_number)
/
PROMPT
PROMPT ===============> ASM DISKS <===============
PROMPT
SELECT
D.GROUP_NUMBER
,D.HEADER_STATUS ST_HEADER
,( SELECT G.NAME FROM V$ASM_DISKGROUP G WHERE G.GROUP_NUMBER = D.GROUP_NUMBER ) GROUP_NAME
,D.DISK_NUMBER
,D.NAME DISK_NAME
--,D.LABEL LABEL_NAME
,D.PATH
,D.FAILGROUP
,ROUND(D.OS_MB/1024) OS_GB
,ROUND(D.FREE_MB/1024) USABLE_GB
,D.MODE_STATUS ST_MODE
,D.FAILGROUP_TYPE
,RPAD(CASE WHEN D.VOTING_FILE = 'Y' THEN 'YES' ELSE 'no' END,6, ' ' ) VOTING
,D.STATE
,D.READS
,D.WRITES
,D.READ_TIME
,D.WRITE_TIME
,D.SECTOR_SIZE
,D.REDUNDANCY
,D.CREATE_DATE
,D.MOUNT_DATE
FROM V$ASM_DISK D
ORDER BY GROUP_NUMBER, DISK_NUMBER
/
PROMPT
PROMPT ===============> ASM FILES <===============
PROMPT
SELECT
A.GROUP_NUMBER
,( SELECT G.NAME FROM V$ASM_DISKGROUP G WHERE G.GROUP_NUMBER = A.GROUP_NUMBER ) GROUP_NAME
,A.FILE_NUMBER
,F.TYPE FILE_TYPE
,A.NAME FILE_NAME
,ROUND(F.BYTES/1024/1024) SIZE_MB
,ROUND(F.SPACE/1024/1024) SPACE_MB
,F.PERMISSIONS
,F.BLOCK_SIZE
,F.BLOCKS
,F.REDUNDANCY
,F.STRIPED
,F.CREATION_DATE
,F.MODIFICATION_DATE
,F.PRIMARY_REGION
,F.MIRROR_REGION
,A.ALIAS_INDEX
,A.ALIAS_INCARNATION
,A.SYSTEM_CREATED
,A.ALIAS_DIRECTORY
,A.FILE_INCARNATION
FROM V$ASM_FILE F
JOIN V$ASM_ALIAS A
ON ( A.GROUP_NUMBER = F.GROUP_NUMBER AND A.FILE_NUMBER = F.FILE_NUMBER AND A.FILE_INCARNATION = F.INCARNATION )
WHERE A.SYSTEM_CREATED = 'Y'
ORDER BY 1, 3
/
PROMPT
PROMPT ===============> ASM OPERATIONS <===============
PROMPT
SELECT * FROM GV$ASM_OPERATION;
PROMPT
SET LINES 300 PAGES 300
COL PATH FORMAT A30
COL LABEL FORMAT A30
SELECT GROUP_NUMBER, NAME, STATE FROM V$ASM_DISKGROUP
ORDER BY GROUP_NUMBER;
PROMPT
SET LINES 300 PAGES 300
COL LABEL_PATH FORMAT A40
SELECT
NVl(LABEL, 'PATH:' || PATH ) LABEL_PATH,
CREATE_DATE,
MOUNT_DATE,
DISK_NUMBER,
MOUNT_STATUS,
HEADER_STATUS,
MODE_STATUS,
STATE,
FAILGROUP_TYPE
FROM V$ASM_DISK
--WHERE GROUP_NUMBER = 0
ORDER BY GROUP_NUMBER, HEADER_STATUS;
declare
cursor tblspc_cursor is
SELECT dtf.tablespace_name, replace(replace(replace(replace(replace(dtf.file_name,'/ora00/','/ora01/'),'/ora02/','/ora01/'),'/ora03/','/ora01/'),'/ora04/','/ora01/'),'/ora07/','/ora01/') file_name,
round(sum(nvl(segs.bytes/1024,10240))*1.1) kbytes
FROM dba_segments segs, dba_data_files dtf
WHERE segs.tablespace_name(+) = dtf.tablespace_name
and dtf.file_name = (SELECT min(file_name) FROM dba_data_files WHERE tablespace_name = dtf.tablespace_name)
and dtf.tablespace_name not in ('SYSTEM','RBS','TEMP')
group by dtf.tablespace_name, dtf.file_name;
aux varchar2(30) := '12345';
begin
dbms_output.enable(1000000);
dbms_output.put_line('spool &p_bd._tablespaces.sql.out');
dbms_output.put_line(chr(10)||'prompt Criando tablespaces....'||chr(10));
for rec_tblspc in tblspc_cursor loop
if (aux <> rec_tblspc.tablespace_name and aux <> '12345') then
dbms_output.put_line('autoextend on maxsize unlimited');
dbms_output.put_line('extent management local autoallocate');
dbms_output.put_line('segment space management auto;'||chr(10));
end if;
if aux <> rec_tblspc.tablespace_name then
dbms_output.put_line('create tablespace '||rec_tblspc.tablespace_name);
dbms_output.put_line('datafile '''||rec_tblspc.file_name||''' size '||rec_tblspc.kbytes||'k reuse');
else
dbms_output.put_line(', '''||rec_tblspc.file_name||''' size '||rec_tblspc.kbytes||'k reuse');
end if;
aux := rec_tblspc.tablespace_name;
end loop;
dbms_output.put_line('autoextend on maxsize unlimited');
dbms_output.put_line('extent management local autoallocate');
dbms_output.put_line('segment space management auto;'||chr(10));
dbms_output.put_line('spool off');
end;
/
spool adm_tablespaces.sql.out
prompt Criando tablespaces....
create tablespace CADOFF_RW
datafile '/ora01/oradata/adm/cadoff_rw01.dbf' size 4646k reuse
autoextend on maxsize unlimited
extent management local autoallocate
segment space management auto;
create tablespace SYSAUX
datafile '/ora01/oradata/adm/sysaux01.dbf' size 374106k reuse
autoextend on maxsize unlimited
extent management local autoallocate
segment space management auto;
create tablespace UNDOTBS1
datafile '/ora01/oradata/adm/undotbs01.dbf' size 26541k reuse
autoextend on maxsize unlimited
extent management local autoallocate
segment space management auto;
spool off
CREATE UNDO TABLESPACE UNDOTBS3
DATAFILE '+DG_PRD1N_DATA' SIZE 2048M
EXTENT MANAGEMENT LOCAL
/
CREATE UNDO TABLESPACE UNDOTBS4
DATAFILE '+DG_PRD1N_DATA' SIZE 2048M
EXTENT MANAGEMENT LOCAL
/
ALTER DATABASE DATAFILE '+DG_PRD1N_DATA/prd1n/datafile/undotbs1.267.723831121'AUTOEXTEND ON NEXT 128M MAXSIZE 4G;
ALTER DATABASE DATAFILE '+DG_PRD1N_DATA/prd1n/datafile/undotbs2.258.723831133'AUTOEXTEND ON NEXT 128M MAXSIZE 4G;
ALTER DATABASE DATAFILE '+DG_PRD1N_DATA/prd1n/datafile/undotbs3.273.724256891'AUTOEXTEND ON NEXT 128M MAXSIZE 4G;
ALTER DATABASE DATAFILE '+DG_PRD1N_DATA/prd1n/datafile/undotbs4.264.724256967'AUTOEXTEND ON NEXT 128M MAXSIZE 4G;
ALTER DATABASE DATAFILE '+DG_PRD1N_DATA/prd1n/datafile/undotbs1.267.723831121' RESIZE 2G;
ALTER DATABASE DATAFILE '+DG_PRD1N_DATA/prd1n/datafile/undotbs2.258.723831133' RESIZE 2G;
ALTER DATABASE
ADD LOGFILE THREAD 3 GROUP 7 ( '+DG_PRD1N_DATA/prd1n/redo07.log' ) SIZE 512M
/
ALTER DATABASE
ADD LOGFILE THREAD 3 GROUP 8 ( '+DG_PRD1N_DATA/prd1n/redo08.log' ) SIZE 512M
/
ALTER DATABASE
ADD LOGFILE THREAD 3 GROUP 9 ( '+DG_PRD1N_DATA/prd1n/redo09.log' ) SIZE 512M
/
ALTER DATABASE
ADD LOGFILE THREAD 4 GROUP 10 ( '+DG_PRD1N_DATA/prd1n/redo10.log' ) SIZE 512M REUSE
/
ALTER DATABASE
ADD LOGFILE THREAD 4 GROUP 11 ( '+DG_PRD1N_DATA/prd1n/redo11.log' ) SIZE 512M REUSE
/
ALTER DATABASE
ADD LOGFILE THREAD 4 GROUP 12 ( '+DG_PRD1N_DATA/prd1n/redo12.log' ) SIZE 512M REUSE
/
alter system set instance_number=3 sid='prd1n3' scope=spfile
/
alter system set thread=3 sid='prd1n3' scope=spfile
/
alter system set undo_tablespace='UNDOTBS3' sid='prd1n3' scope=spfile
/
alter system set instance_number=4 sid='prd1n4' scope=spfile
/
alter system set thread=4 sid='prd1n4' scope=spfile
/
alter system set undo_tablespace='UNDOTBS4' sid='prd1n4' scope=spfile
/
COL MEGAS FORMAT 9G999G999G999
COL EXTENTS FORMAT 999G999
COL TEMPFILE FORMAT A40
COL USERNAME FORMAT A20
BREAK ON TEMPFILE SKIP 1
SET FEED OFF VERIFY OFF
COL "Tablespace" FORMAT A10
COL "ExtentsCnt" FORMAT A10
COL "CurrSizeMb" FORMAT A10
COL "CurrFreeMb" FORMAT A10
COL "TbsMaxSizeMb" FORMAT A12
COL "MaxUsedMb" FORMAT A9
COL "MaxSortMb" FORMAT A9
COL "Extent/Segment Management" FORMAT A30
SELECT
S.TABLESPACE_NAME "Tablespace"
/* ,S.CURRENT_USERS "ActvUsers"
,LPAD( TO_CHAR( S.TOTAL_EXTENTS, 'fm999g999' ), 10, ' ' ) "ExtentsCnt" */
,LPAD( TO_CHAR( S.TOTAL_BLOCKS * T.BLOCK_SIZE / 1048576, 'fm999g999' ), 10, ' ' ) "CurrSizeMb"
,LPAD( TO_CHAR( S.FREE_BLOCKS * T.BLOCK_SIZE / 1048576, 'fm999g999' ), 10, ' ' ) "CurrFreeMb"
,(SELECT LPAD( TO_CHAR( SUM(GREATEST(F.MAXBLOCKS, F.BLOCKS))*T.BLOCK_SIZE/1048576, 'fm999g999' ), 12, ' ' )
FROM DBA_TEMP_FILES F WHERE F.TABLESPACE_NAME = S.TABLESPACE_NAME) "TbsMaxSizeMb"
/* ,LPAD( TO_CHAR( S.MAX_USED_BLOCKS * T.BLOCK_SIZE / 1048576, 'fm999g999' ), 9, ' ' ) "MaxUsedMb"
,LPAD( TO_CHAR( S.MAX_SORT_BLOCKS * T.BLOCK_SIZE / 1048576, 'fm999g999' ), 9, ' ' ) "MaxSortMb" */
,T.EXTENT_MANAGEMENT || ' ' || T.ALLOCATION_TYPE || ' ' ||
TO_CHAR( S.EXTENT_SIZE * T.BLOCK_SIZE / 1048576, 'fm9g999' ) || 'Mb, ' ||
T.SEGMENT_SPACE_MANAGEMENT "Extent/Segment Management"
FROM V$SORT_SEGMENT S, DBA_TABLESPACES T
WHERE S.TABLESPACE_NAME = T.TABLESPACE_NAME
/
COL TABLESPACE CLEAR
PROMPT
PROMPT TOP 5 CONSUMERS
SELECT
(SELECT SID FROM V$SESSION WHERE V.SESSION_ADDR = SADDR ) SID
, V.SESSION_NUM "SERIAL#"
, V.USERNAME
, V.MEGAS
FROM
(
SELECT SESSION_ADDR, SESSION_NUM, USERNAME, SUM(BLOCKS) * 8 / 1024 megas
FROM V$SORT_USAGE
group by SESSION_ADDR, SESSION_NUM, USERNAME
order by megas desc
) V
WHERE ROWNUM < 6;
PROMPT
PROMPT DETALHES POR TEMPFILE
SET PAGES 300
WITH SU AS
(
SELECT
USERNAME, SEGFILE#, SEGRFNO#, SESSION_ADDR,
SUM(BLOCKS) BLOCKS, SUM(EXTENTS) EXTENTS
FROM V$SORT_USAGE GROUP BY USERNAME, SEGFILE#, SEGRFNO#, SESSION_ADDR
),
PARAMETRO AS
(
SELECT TO_NUMBER(VALUE) BLOCKSIZE
FROM V$PARAMETER WHERE NAME = 'db_block_size'
)
SELECT /*+ALL_ROWS*/
T.NAME TEMPFILE,U.USERNAME, SUM(S.BLOCKS*P.BLOCKSIZE)/1024/1024 MEGAS, SUM(S.EXTENTS)EXTENTS,
DECODE(GROUPING(T.NAME)+GROUPING(U.USERNAME),1,'TOTAL DO TEMPFILE', 2, 'TOTAL DO TABLESPACE') TOTAL
FROM
SU S,
PARAMETRO P,
V$SESSION U,
V$TEMPFILE T
WHERE U.SADDR = S.SESSION_ADDR
AND T.RFILE# = S.SEGRFNO#
GROUP BY ROLLUP(T.NAME,U.USERNAME)
/
SET PAGES 66
PROMPT
SET FEED 6 VERIFY ON
SET ECHO ON TERM ON SERVEROUT ON SIZE 1000000 SQLP SQL>;
SPO sqltcompare.log;
REM
REM $Header: 215187.1 sqltcompare.sql 11.2.1 2008/09/21 csierra $
REM
REM Copyright (c) 2008, Oracle Corporation. All rights reserved.
REM
REM SCRIPT
REM sqltcompare.sql
REM
REM DESCRIPTION
REM This script compares initialization parameters and CBO
REM statistics FROM two executions of the SQLTXPLAIN over one SQL
REM on same or different systems. Those init.ora parameters and CBO
REM stats are associated to each SQL for which the SQLTXPLAIN is
REM executed. The SQLTXPLAIN takes snapshots of this information.
REM
REM PRE-REQUISITES
REM Steps 1 to 5 are necessary if SQLs to compare are FROM
REM different systems.
REM 1. Install SQLTXPLAIN tool in both sources and in destination
REM systems as per instructions.txt provided
REM 2. Execute SQLTXPLAIN (any method) in source systems for the
REM one SQL statement that will be compared
REM 3. Export tables FROM both source systems using command below:
REM # exp sqltxplain/[pwd] tables=sqlt% file=sqlt.dmp
REM 4. Transfer BINARY file sqlt.dmp FROM sources to destination
REM system
REM 5. Import these tables into destination system using commands:
REM # imp sqltxplain/[pwd] tables='sqlt$_statement' file=sqlt.dmp ignore=y
REM # imp sqltxplain/[pwd] tables='sqlt$_plan_table' file=sqlt.dmp ignore=y
REM # imp sqltxplain/[pwd] tables='sqlt$_stattab' file=sqlt.dmp ignore=y
REM # imp sqltxplain/[pwd] tables='sqlt$_parameter2' file=sqlt.dmp ignore=y
REM 6. The user that executes this script can be SQLTXPLAIN or the
REM application user
REM
REM PARAMETERS
REM 1. Statement ID 1 as per SQLTXPLAIN for SQL in source system
REM (required). A list of statement ids is presented to the user
REM executing this script.
REM 2. Statement ID 2 as per SQLTXPLAIN for SQL in source system
REM (required). A list of statement ids is presented to the user
REM executing this script.
REM
REM EXECUTION
REM 1. Navigate to sqlt/run directory
REM 2. Start SQL*Plus connecting as SQLTXPLAIN or application user
REM 3. Execute script sqltcompare.sql passing statement id and
REM schema (parameters can be passed inline or until requested)
REM
REM EXAMPLE
REM # cd sqlt/run
REM # sqlplus sqltxplain/[sqltxplain pwd]
REM SQL> start sqltcompare.sql [statement id 1] [statement id 2];
REM SQL> start sqltcompare.sql s2263_olc510_apperf02 s2597_scmx7st;
REM SQL> start sqltcompare.sql s2263 s2597;
REM SQL> start sqltcompare.sql;
REM
REM NOTES
REM 1. For possible errors see sqltcompare.log
REM
SET ECHO OFF;
EXEC sqltxplain.sqlt$r.initialization;
SELECT statement_id
FROM sqltxplain.sqlt$_parameter2
UNION
SELECT statid statement_id
FROM sqltxplain.sqlt$_stattab
WHERE statid LIKE 's%';
PRO
PRO Parameter 1: Statement id 1 to be compared (required)
PRO Parameter 2: Statement id 2 to be compared (required)
PRO
DEF statement1 = '&1';
DEF statement2 = '&2';
PRO
PRO Value passed to sqltcompare.sql:
PRO ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
PRO STATEMENT 1: &&statement1
PRO STATEMENT 2: &&statement2
PRO
SET TERM OFF;
COL connected_as_user NEW_V connected_as_user FOR A32;
SELECT USER connected_as_user FROM DUAL;
SET TERM ON;
PRO
PRO ... generating sqlt compare report for &&statement1 and &&statement2
PRO
SET TERM OFF;
VAR v_output_filename VARCHAR2(256);
BEGIN
sqltxplain.sqlt$r.compare_report (
p_statement_id1 => '&&statement1',
p_statement_id2 => '&&statement2',
x_output_filename => :v_output_filename );
END;
/
CL COL;
COL server_directory NOPRI NEW_V server_directory FOR A512;
COL copy_file_name NOPRI NEW_V copy_file_name FOR A256;
SELECT :v_output_filename copy_file_name, sqltxplain.sqlt$d.get_param('output_directory', 'I') server_directory FROM DUAL;
SET TERM ON;
PRO
PRO ... sqlt_&©_file_name._compare.html file has been created into server directory:
PRO ... &&server_directory
PRO ... copying now generated file into local directory
PRO
SET TERM OFF ECHO OFF BLO ON DEF ON FEED OFF FLU OFF HEA OFF LIN 32767 NEWP NONE PAGES 0 RECSEP OFF SHOW OFF SQLBL ON SQLC MIX TAB OFF TRIMS ON VER OFF SERVEROUT ON SIZE 1000000 FOR TRU TIM OFF ARRAY 100 SQLP SQL>;
SPO OFF;
SPO sqlt_&©_file_name._compare.html;
SELECT column_value FROM TABLE(sqltxplain.sqlt$r.display_file('COMPARE', :v_output_filename));
SPO OFF;
SET TERM ON;
CL COL;
UNDEFINE 1 2;
SET ECHO ON TERM ON LIN 32767 TRIMS ON SERVEROUT ON SIZE 1000000 TIM OFF SQLP SQL>;
SPO sqltimp.log;
REM
REM $Header: 215187.1 sqltimp.sql 11.2.1 2008/09/21 csierra $
REM
REM Copyright (c) 2008, Oracle Corporation. All rights reserved.
REM
REM SCRIPT
REM sqltimp.sql
REM
REM DESCRIPTION
REM This script restores into the data dictionary the set of CBO
REM statistics for all the tables referenced by one SQL statement,
REM together with the CBO statistics for the indexes of those same
REM tables, their partitions, subpartitions, columns and
REM histograms.
REM The CBO statistics to be restored, are those associated to one
REM SQL statement previously analyzed by the SQLTXPLAIN in the same
REM or different system
REM
REM PRE-REQUISITES
REM 1. Install SQLTXPLAIN tool in both, source and destination
REM systems as per instructions.txt provided
REM 2. Execute SQLTXPLAIN (any method) in source system for one SQL
REM statement
REM 3. Export CBO stats FROM source system using command below:
REM # exp sqltxplain/[pwd] tables=sqlt% file=sqlt.dmp
REM 4. Transfer BINARY file sqlt.dmp FROM source to destination
REM system
REM 5. Import CBO stats into destination system using command below:
REM # imp sqltxplain/[pwd] tables='sqlt$_stattab' file=sqlt.dmp ignore=y
REM 6. The user that executes this script can be SQLTXPLAIN or the
REM application user in source that owns the schema objects for
REM which the CBO statistics are being restored
REM
REM PARAMETERS
REM 1. Statement ID as per SQLTXPLAIN for SQL in source system
REM (required). A list of statement ids is presented to the user
REM executing this script.
REM 2. Schema owner of those objects for which the CBO statistics
REM are being restored. This parameter is required if the same
REM objects in source instance belong to different schema owners
REM and the destination instance consolidates all those objects
REM into just one schema (this). If the owners in source and
REM destination are the same (they are not being changed), then
REM skip this parameter by entering NULL or just hit enter when
REM asked for the schema owner. In other words, this parameter
REM is for renaming schema owner of dependent objects.
REM
REM EXECUTION
REM 1. Navigate to sqlt/run directory
REM 2. Start SQL*Plus connecting as SQLTXPLAIN or application user
REM 3. Execute script sqltimp.sql passing statement id and schema
REM (parameters can be passed inline or until requested)
REM
REM EXAMPLE
REM # cd sqlt/run
REM # sqlplus sqltxplain/[sqltxplain pwd]
REM SQL> start sqltimp.sql [statement id] [new schema_owner];
REM SQL> start sqltimp.sql s2263_olc510_apperf02 mytest;
REM SQL> start sqltimp.sql s2263 NULL;
REM SQL> start sqltimp.sql;
REM
REM NOTES
REM 1. For possible errors see sqltimp.log
REM
SET ECHO OFF;
EXEC sqltxplain.sqlt$r.initialization;
SELECT g.statid statement_id,
COUNT(*) stats_rows,
(SELECT COUNT(*) FROM sqltxplain.sqlt$_stattab t WHERE t.statid = g.statid AND t.type = 'T') tables,
(SELECT COUNT(*) FROM sqltxplain.sqlt$_stattab i WHERE i.statid = g.statid AND i.type = 'I') indexes,
(SELECT COUNT(*) FROM sqltxplain.sqlt$_stattab c WHERE c.statid = g.statid AND c.type = 'C') columns,
(SELECT ROUND(AVG(SYSDATE - a.d1), 1) FROM sqltxplain.sqlt$_stattab a WHERE a.statid = g.statid AND a.type = 'T') avg_age_days
FROM sqltxplain.sqlt$_stattab g
WHERE statid LIKE 's%'
GROUP BY g.statid
ORDER BY g.statid;
PRO
PRO Parameter 1: Statement id to restore CBO stats FROM (required)
PRO Parameter 2: Renamed schema owner for which stats are restored (opt)
PRO
DEF statement_id = '&1';
DEF schema_owner = '&2';
PRO
PRO ... restoring cbo stats FROM statement id &&statement_id and schema &&schema_owner
PRO
EXEC sqltxplain.sqlt$d.import_cbo_stats(p_statement_id => '&&statement_id', p_schema_owner => '&&schema_owner');
PRO
SPOOL OFF;
PRO NOTE:
PRO SQLTIMP complete. Please check sqltimp.log for any errors.
PRO
CL COL
UNDEFINE 1 2
REM
SET ECHO ON TERM ON LIN 32767 TRIMS ON SERVEROUT ON SIZE 1000000 TIM OFF SQLP SQL>;
SPO sqltimpfo.log;
REM
REM $Header: 215187.1 sqltimpfo.sql 11.2.1 2008/09/21 csierra $
REM
REM Copyright (c) 2008, Oracle Corporation. All rights reserved.
REM
REM SCRIPT
REM sqltimpfo.sql
REM
REM DESCRIPTION
REM This script restores into the data dictionary the set of CBO
REM statistics for all fixed objects.
REM
REM PRE-REQUISITES
REM 1. Install SQLTXPLAIN tool in both, source and destination
REM systems as per instructions.txt provided
REM 2. Execute SQLTXPLAIN (any method) in source system for one SQL
REM statement
REM 3. Export CBO stats FROM source system using command below:
REM # exp sqltxplain/[pwd] tables=sqlt% file=sqlt.dmp
REM 4. Transfer BINARY file sqlt.dmp FROM source to destination
REM system
REM 5. Import CBO stats into destination system using command below:
REM # imp sqltxplain/[pwd] tables='sqlt$_stattab' file=sqlt.dmp ignore=y
REM 6. The user that executes this script can be SQLTXPLAIN or the
REM application user in source that owns the schema objects for
REM which the CBO statistics are being restored
REM
REM PARAMETERS
REM 1. Statement ID as per SQLTXPLAIN for SQL in source system
REM (required). A list of statement ids is presented to the user
REM executing this script.
REM
REM EXECUTION
REM 1. Navigate to sqlt/run directory
REM 2. Start SQL*Plus connecting as SQLTXPLAIN or application user
REM 3. Execute script sqltimpfo.sql passing statement id
REM (parameter can be passed inline or until requested)
REM
REM EXAMPLE
REM # cd sqlt/run
REM # sqlplus sqltxplain/[sqltxplain pwd]
REM SQL> start sqltimpfo.sql [statement id];
REM SQL> start sqltimpfo.sql f2263_olc510_apperf02;
REM SQL> start sqltimpfo.sql f2263;
REM SQL> start sqltimpfo.sql;
REM
REM NOTES
REM 1. For possible errors see sqltimpfo.log
REM
SET ECHO OFF;
EXEC sqltxplain.sqlt$r.initialization;
SELECT g.statid statement_id,
COUNT(*) stats_rows,
(SELECT COUNT(*) FROM sqltxplain.sqlt$_stattab t WHERE t.statid = g.statid AND t.type = 'T') tables,
(SELECT COUNT(*) FROM sqltxplain.sqlt$_stattab c WHERE c.statid = g.statid AND c.type = 'C') columns,
(SELECT ROUND(AVG(SYSDATE - a.d1), 1) FROM sqltxplain.sqlt$_stattab a WHERE a.statid = g.statid AND a.type = 'T') avg_age_days
FROM sqltxplain.sqlt$_stattab g
WHERE statid LIKE 'f%'
GROUP BY g.statid
ORDER BY g.statid;
PRO
PRO Parameter 1: Statement id to restore fixed objects CBO stats FROM (required)
PRO
DEF statement_id = '&1';
PRO
PRO ... restoring fixed objects cbo stats FROM statement id &&statement_id
PRO
EXEC sqltxplain.sqlt$d.import_cbo_stats_fixed_objects(p_statement_id => '&&statement_id');
PRO
SPOOL OFF;
PRO NOTE:
PRO SQLTIMP complete. Please check sqltimpfo.log for any errors.
PRO
CL COL
UNDEFINE 1
REM
SET ECHO ON TERM ON SERVEROUT ON SIZE 1000000 SQLP SQL>;
SPO sqltxecute.log;
REM
REM $Header: 215187.1 sqltxecute.sql 11.2.1 2008/09/21 csierra $
REM
REM Copyright (c) 2008, Oracle Corporation. All rights reserved.
REM
REM SCRIPT
REM sqltxecute.sql
REM
REM DESCRIPTION
REM This sqltxecute.sql takes as input the name of a SCRIPT file
REM and proceeds to execute the one SQL contained in it, then it
REM generates a set of comprehensive reports with query tuning
REM diagnostic details.
REM
REM The SCRIPT file whose name is provided as an inline execution
REM parameter to sqltxecute.sql, is a custom script similar to
REM example provided script1.txt. Besides the one SQL that will be
REM executed and explained, it also contains the bind variables
REM referenced by the SQL (declaration and value assignment).
REM
REM The SQL text provided with the SCRIPT file must include a tag
REM /* &&unique_id */ within a comment in any place. Please see
REM script1.txt provided as an example.
REM
REM PRE-REQUISITES
REM 1. Install SQLTXPLAIN tool as per instructions.txt provided
REM 2. Create a custom script very similar to script1.txt.
REM o Read instructions included in example file script1.txt
REM o Put in your custom script file the one SQL you want to
REM analyze. Include your environment setup if needed.
REM 3. The user that executes this method must comply with:
REM o Be the application schema owner that originated the SQL
REM o Must be granted the following list (installation script
REM created all these grants for main application schema)
REM GRANT SELECT_CATALOG_ROLE TO
REM GRANT EXECUTE ON SYS.DBMS_METADATA TO
REM GRANT ADVISOR TO (10g or 11g)
REM GRANT ADMINISTER SQL TUNING SET TO (10g or 11g)
REM 4. Install Trace Analyzer (Note:224270.1) Highly recommended
REM but not mandatory
REM
REM PARAMETERS
REM 1. Name of SCRIPT that has the SQL to be executed and analyzed
REM (required)
REM
REM EXECUTION
REM 1. Place your file with one SQL into sqlt/run server directory
REM 2. Navigate to sqlt/run server directory
REM 3. Start SQL*Plus in server connecting as application user
REM 4. Execute script sqltxecute.sql passing name of script with
REM one SQL and its bind variables
REM 5. Provide all generated files to the requestor
REM
REM EXAMPLE
REM # cd sqlt/run
REM # sqlplus [apps user]/[apps pwd]
REM SQL> start sqltxecute.sql [name of script with one SQL]
REM SQL> start sqltxecute.sql script1.txt <== script file
REM
REM NOTES
REM 1. It invokes Trace Analyzer (Note:224270.1) if previously
REM installed (recommended)
REM 2. The SQL text provided with the SCRIPT file must include a tag
REM /* &&unique_id */ within a comment in any place. Please see
REM script1.txt provided as an example.
REM 3. If requested by Support provide a BINARY export:
REM # exp sqltxplain/ tables=sqlt% file=sqlt.dmp
REM 4. For possible errors see sqltxecute.log
REM
SET ECHO OFF;
PRO
PRO Parameter 1:
PRO Name of SCRIPT file that contains SQL to be executed (required)
DEF script_with_sql = '&1';
PRO
PRO Value passed to sqltxecute.sql:
PRO ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
PRO SCRIPT_WITH_SQL: &&script_with_sql
PRO
SET TERM OFF;
WHENEVER SQLERROR EXIT SQL.SQLCODE;
PRO
COL library FOR A64 HEA 'Libraries';
SELECT object_type||' '||object_name||' ('||status||')' library
FROM all_objects
WHERE owner = 'SQLTXPLAIN'
AND object_type IN ('PACKAGE BODY', 'PROCEDURE', 'FUNCTION')
ORDER BY
object_type, object_name;
COL connected_as_user NEW_V connected_as_user FOR A32;
SELECT USER connected_as_user FROM DUAL;
SET TERM ON;
PRO
PRO NOTE:
PRO You must be executing this script connected as
PRO the application user that executed original SQL.
PRO You are now connected as &&connected_as_user
PRO
SET TERM OFF;
VAR v_execution_id VARCHAR2(8);
VAR v_unique_id VARCHAR2(32);
BEGIN
sqltxplain.sqlt$i.sqltxecute_begin (
x_execution_id => :v_execution_id,
x_unique_id => :v_unique_id );
END;
/
COL unique_id NEW_V unique_id FOR A32;
SELECT :v_unique_id unique_id FROM DUAL;
@&&script_with_sql
VAR v_statement_id VARCHAR2(16);
BEGIN
sqltxplain.sqlt$i.sqltxecute_end (
p_unique_id => :v_unique_id,
p_execution_id => :v_execution_id,
x_statement_id => :v_statement_id );
END;
/
CL COL;
COL statement_id NEW_V statement_id FOR A16;
COL server_directory NOPRI NEW_V server_directory FOR A512;
COL copy_file_name NOPRI NEW_V copy_file_name FOR A256;
SELECT :v_statement_id statement_id, sqltxplain.sqlt$d.get_param('output_directory', 'I') server_directory FROM DUAL;
SET TERM ON;
PRO
PRO ... sqlt_s&&statement_id._* files have been created into server directory:
PRO ... &&server_directory
PRO ... copying now generated files into local directory
PRO
SET TERM OFF ECHO OFF BLO ON DEF ON FEED OFF FLU OFF HEA OFF LIN 32767 NEWP NONE PAGES 0 RECSEP OFF SHOW OFF SQLBL ON SQLC MIX TAB OFF TRIMS ON VER OFF SERVEROUT ON SIZE 1000000 FOR TRU TIM OFF ARRAY 100 SQLP SQL>;
WHENEVER OSERROR CONTINUE;
WHENEVER SQLERROR CONTINUE;
SPO OFF;
SELECT NVL(file_sqlt_main, 'sqlt_s&&statement_id._main.html') copy_file_name FROM sqltxplain.sqlt$_statement WHERE statement_id = :v_statement_id;
SPO &©_file_name.;
SELECT column_value FROM TABLE(sqltxplain.sqlt$r.display_file('MAIN', NULL, :v_statement_id));
SPO OFF;
SELECT NVL(file_sqlt_frames, 'sqlt_s&&statement_id._frames.html') copy_file_name FROM sqltxplain.sqlt$_statement WHERE statement_id = :v_statement_id;
SPO &©_file_name.;
SELECT column_value FROM TABLE(sqltxplain.sqlt$r.display_file('FRAMES', NULL, :v_statement_id));
SPO OFF;
SELECT NVL(file_sqlt_metadata, 'sqlt_s&&statement_id._metadata.sql') copy_file_name FROM sqltxplain.sqlt$_statement WHERE statement_id = :v_statement_id;
SPO &©_file_name.;
SELECT column_value FROM TABLE(sqltxplain.sqlt$r.display_file('METADATA', NULL, :v_statement_id));
SPO OFF;
SELECT NVL(file_sqlt_trace, 'sqlt_s&&statement_id._trace.html') copy_file_name FROM sqltxplain.sqlt$_statement WHERE statement_id = :v_statement_id;
SPO &©_file_name.;
SELECT column_value FROM TABLE(sqltxplain.sqlt$r.display_file('TRACE', NULL, :v_statement_id));
SPO OFF;
SELECT NVL(file_sqlt_lite, 'sqlt_s&&statement_id._lite.txt') copy_file_name FROM sqltxplain.sqlt$_statement WHERE statement_id = :v_statement_id;
SPO &©_file_name.;
SELECT column_value FROM TABLE(sqltxplain.sqlt$r.display_file('LITE', NULL, :v_statement_id));
SPO OFF;
SELECT NVL(file_trcanlzr_html, 'sqlt_s&&statement_id._trcanlzr.log') copy_file_name FROM sqltxplain.sqlt$_statement WHERE statement_id = :v_statement_id;
SPO &©_file_name.;
SELECT column_value FROM TABLE(sqltxplain.sqlt$r.display_file('TRCAHTML', NULL, :v_statement_id));
SPO OFF;
SELECT NVL(file_trcanlzr_txt, 'sqlt_s&&statement_id._trcanlzr.log') copy_file_name FROM sqltxplain.sqlt$_statement WHERE statement_id = :v_statement_id;
SPO &©_file_name.;
SELECT column_value FROM TABLE(sqltxplain.sqlt$r.display_file('TRCATXT', NULL, :v_statement_id));
SPO OFF;
SELECT NVL(file_trcanlzr_log, 'sqlt_s&&statement_id._trcanlzr.log') copy_file_name FROM sqltxplain.sqlt$_statement WHERE statement_id = :v_statement_id;
SPO &©_file_name.;
SELECT column_value FROM TABLE(sqltxplain.sqlt$r.display_file('TRCALOG', NULL, :v_statement_id));
SPO OFF;
SET TERM ON
PRO
PRO ... exporting SQLT tables needed to create a test case
ACC sqltxplain_password PROMPT '...please enter SQLTXPLAIN password: ' hide;
HO exp sqltxplain/&sqltxplain_password tables=sqlt% file=sqlt_s&&statement_id..dmp statistics=none
UNDEFINE SQLTXPLAIN_PASSWORD
PRO
PRO ... if sqlt_s&&statement_id..dmp was not created, please execute manually FROM server:
PRO ... # exp sqltxplain/ tables=sqlt% file=sqlt_s&&statement_id..dmp statistics=none
PRO
PRO ... generating now a zip with all generated files
HO zip sqlt_s&&statement_id. sqlt_s&&statement_id.*
PRO
PRO ... if sqlt_s&&statement_id..zip was not created, please execute manually:
PRO ... # zip sqlt_s&&statement_id. sqlt_s&&statement_id.*
PRO
CL COL;
UNDEFINE 1;
set feed off verify off termout off
define tops=20
col st1 format a14 heading "Startup Time"
col st2 format a14 heading "System Date"
col st3 format a12 heading "Running Time"
col st4 format a12 heading "Running Secs"
col TM new_value p_order_by
SELECT decode( value, 'FALSE', 'total_waits', 'time_waited' ) TM
FROM v$parameter WHERE name='timed_statistics'
/
set termout on
SELECT
to_char( startup_time, 'dd/mm/yy hh24"h"mi' ) st1,
to_char( sysdate, 'dd/mm/yy hh24"h"mi' ) st2,
lpad( to_char( trunc(sysdate,'YEAR') + (sysdate-startup_time-1),
decode( trunc( sysdate-startup_time, 0 ), 0, 'fm" 0d "hh24"h"mi', 'fm""dd"d "hh24"h"mi' ) ), 12, ' ' ) st3,
to_char( (sysdate-startup_time)*24*60*60, '999g999g990' ) st4
FROM v$instance;
col "EVENT" format a40 Heading "Evento"
col "TOTAL_WAITS" format 9G999G999G990 Heading "Total Waits"
col "TIME_WAITED (hms)" format a17 Heading "Time Waited (hms)"
col "TIME_WAITED (s)" format 9G999G990 Heading "Time Waited (s)"
col "SECONDS_WAITED" format 9G999G990 Heading "Seconds Waited"
col "AVG_WAITS(ms)" format 999G999G990 Heading "Avg Wait (ms)"
SELECT event "EVENT", total_waits "TOTAL_WAITS",
decode( trunc( time_waited/84600/100, 0 ), 0,
to_char( to_date('31/01/2001', 'dd/mm/yyyy' )+time_waited/8460000, '"00d:"HH24:MI:SS' ),
to_char( to_date('31/01/2001', 'dd/mm/yyyy' )+time_waited/8460000, 'DD"d":HH24:MI:SS' ) ) "TIME_WAITED (hms)",
round( time_waited/100,2) "TIME_WAITED (s)",
round( average_wait*10,0) "AVG_WAITS(ms)"
FROM
( SELECT * FROM v$system_event
WHERE total_waits > 0
and event not in -- Eventos considerados idle na versão 8.1.7
( 'smon timer', 'pmon timer', 'rdbms ipc message', 'Null event', 'parallel query dequeue',
'pipe get', 'client message', 'SQL*Net message to client', 'SQL*Net message FROM client',
'SQL*Net more data FROM client', 'SQL*Net more data to client', 'dispatcher timer',
'virtual circuit status', 'lock manager wait for remote message', 'PX Idle Wait',
'wakeup time manager' )
order by &p_order_by. desc
)
WHERE rownum <= &tops.
UNION ALL
SELECT event "EVENT", total_waits "TOTAL_WAITS",
decode( trunc( time_waited/84600/100, 0 ), 0,
to_char( to_date('31/01/2001', 'dd/mm/yyyy' )+time_waited/8460000, '"00d:"HH24:MI:SS' ),
to_char( to_date('31/01/2001', 'dd/mm/yyyy' )+time_waited/8460000, 'DD"d":HH24:MI:SS' ) ) "TIME_WAITED (hms)",
round( time_waited/100,2) "TIME_WAITED (s)",
round( average_wait*10,0) "AVG_WAITS(ms)"
FROM
( SELECT 'Outros' Event, vtot.total_waits-vdif.total_waits total_waits,
vtot.time_waited-vdif.time_waited time_waited,
vtot.average_wait-vdif.average_wait average_wait
FROM
(
SELECT sum(total_waits) total_waits, sum(time_waited) time_waited, null average_wait
FROM v$system_event
WHERE total_waits > 0
and event not in -- Eventos considerados idle na versão 8.1.7
( 'smon timer', 'pmon timer', 'rdbms ipc message', 'Null event', 'parallel query dequeue',
'pipe get', 'client message', 'SQL*Net message to client', 'SQL*Net message FROM client',
'SQL*Net more data FROM client', 'SQL*Net more data to client', 'dispatcher timer',
'virtual circuit status', 'lock manager wait for remote message', 'PX Idle Wait',
'wakeup time manager' )
) vtot,
(
SELECT sum(total_waits) total_waits, sum(time_waited) time_waited, null average_wait
FROM
( SELECT vdif2.*
FROM
(
SELECT total_waits, time_waited, average_wait
FROM v$system_event
WHERE total_waits > 0
and event not in -- Eventos considerados idle na versão 8.1.7
( 'smon timer', 'pmon timer', 'rdbms ipc message', 'Null event', 'parallel query dequeue',
'pipe get', 'client message', 'SQL*Net message to client', 'SQL*Net message FROM client',
'SQL*Net more data FROM client', 'SQL*Net more data to client', 'dispatcher timer',
'virtual circuit status', 'lock manager wait for remote message', 'PX Idle Wait',
'wakeup time manager' )
order by &p_order_by. desc
) vdif2
WHERE rownum <= &tops.
) vdif1
) vdif
)
UNION ALL
SELECT event "EVENT", total_waits "TOTAL_WAITS",
decode( trunc( time_waited/84600/100, 0 ), 0,
to_char( to_date('31/01/2001', 'dd/mm/yyyy' )+time_waited/8460000, '"00d:"HH24:MI:SS' ),
to_char( to_date('31/01/2001', 'dd/mm/yyyy' )+time_waited/8460000, 'DD"d":HH24:MI:SS' ) ) "TIME_WAITED (hms)",
round( time_waited/100,2) "TIME_WAITED (s)",
round( average_wait*10,0) "AVG_WAITS(ms)"
FROM
( SELECT 'Total' Event, sum(total_waits) total_waits, sum(time_waited) time_waited, null average_wait
FROM v$system_event
WHERE total_waits > 0
and event not in -- Eventos considerados idle na versão 8.1.7
( 'smon timer', 'pmon timer', 'rdbms ipc message', 'Null event', 'parallel query dequeue',
'pipe get', 'client message', 'SQL*Net message to client', 'SQL*Net message FROM client',
'SQL*Net more data FROM client', 'SQL*Net more data to client', 'dispatcher timer',
'virtual circuit status', 'lock manager wait for remote message', 'PX Idle Wait',
'wakeup time manager' )
)
/
prompt
set feed on verify on
SELECT
'CREATE SYNONYM ' || OWNER || '.' || SYNONYM_NAME || ' FOR ' ||
TABLE_OWNER || '.' || TABLE_NAME || DECODE( DB_LINK, NULL, NULL, '@' ) || DB_LINK || ';' SINONIMO
FROM
DBA_SYNONYMS
WHERE OWNER=&P1. AND SYNONYM_NAME = '&SINONIMOS.'
/
set lines 200 feed off
col text for a120
col exec for 9999999
var n number
exec :n := &1
Prompt Resumo de consultas ativas - Leituras Físicas e Lógicas (Absoluto e por Execucao)
SELECT executions exec, round("LFporEx") "LFporEx", sql_id, text
FROM
(
SELECT sql.sql_id, substr(sql.sql_text,1,120) text, sql.executions, sql.disk_reads/decode(sql.executions,0,1,sql.executions) "LFporEx"
FROM v$sqlarea sql
join (SELECT distinct sql_id FROM v$session WHERE status='ACTIVE') s on (s.sql_id = sql.sql_id)
--WHERE sql.executions > 0
order by sql.disk_reads/decode(sql.executions,0,1,sql.executions) desc
)
WHERE rownum <= :n;
SELECT executions exec, round("LFisicas") "LFisicas", sql_id, text
FROM
(
SELECT sql.sql_id, substr(sql.sql_text,1,120) text, sql.executions, sql.disk_reads "LFisicas"
FROM v$sqlarea sql
join (SELECT distinct sql_id FROM v$session WHERE status='ACTIVE') s on (s.sql_id = sql.sql_id)
--WHERE sql.executions > 0
order by sql.disk_reads desc
)
WHERE rownum <= :n;
SELECT executions exec, round("LLporEx") "LLporEx", sql_id, text
FROM
(
SELECT sql.sql_id, substr(sql.sql_text,1,120) text, sql.executions executions, sql.buffer_gets/decode(sql.executions,0,1,sql.executions) "LLporEx"
FROM v$sqlarea sql
join (SELECT distinct sql_id FROM v$session WHERE status='ACTIVE') s on (s.sql_id = sql.sql_id)
--WHERE sql.executions > 0
order by sql.buffer_gets/decode(sql.executions,0,1,sql.executions) desc
)
WHERE rownum <= :n;
SELECT executions exec, round("LLogicas") "LLogicas", sql_id, text
FROM
(
SELECT sql.sql_id, substr(sql.sql_text,1,120) text, sql.executions executions, sql.buffer_gets "LLogicas"
FROM v$sqlarea sql
join (SELECT distinct sql_id FROM v$session WHERE status='ACTIVE') s on (s.sql_id = sql.sql_id)
--WHERE sql.executions > 0
order by sql.buffer_gets desc
)
WHERE rownum <= :n;
set feed off
COL MACHINE FORMAT A26
COL STATUS FORMAT A8
SELECT *
FROM
(
SELECT S.MACHINE, W.SID, W.EVENT, W.WAIT_TIME, W.SECONDS_IN_WAIT, W.STATE, S.STATUS
FROM V$SESSION S INNER JOIN V$SESSION_WAIT W ON (S.SID=W.SID)
WHERE USERNAME ='SAE' AND W.SECONDS_IN_WAIT > 3600 AND S.STATUS <> 'KILLED'
ORDER BY W.SECONDS_IN_WAIT DESC
)
WHERE ROWNUM < 200
/
--Ajustar estes valores no sqlnet.ora para gerar trace no cliente:
TRACE_DIRECTORY_CLIENT = c:
TRACE_UNIQUE_CLIENT = on
TRACE_FILE_CLIENT = sqlnet.trc
TRACE_LEVEL_CLIENT = SUPPORT
--Executar estes passos para gerar trace de sql:
1) garantir que o usuário conecte de forma dedicada (modificar tnsnames.ora):
(CONNECT_DATA = (SERVER = DEDICATED)(SID = adm))
2) Identificar a conexão do usuário usando script S:\TOPS.SQL
3) Ajustar o trace usando os dados sid e serial#
EXEC DBMS_SYSTEM.SET_SQL_TRACE_IN_SESSION( SID, SERIAL#, TRUE );
4) Procurar o trace gerado no diretório udump (procurar pelo valor do spid retornado no tops)
5) Desabilitar o trace
EXEC DBMS_SYSTEM.SET_SQL_TRACE_IN_SESSION( SID, SERIAL#, FALSE );
SET FEED 10 LINES 150
col sid for 99999
col username format a20
var bdia number;
var btime number;
var bdone number;
var edia number;
var etime number;
var done number;
var total number;
var esttime number;
col st1 format a14 heading "Startup Time"
col st2 format a14 heading "System Date"
col st3 format a12 heading "Running Time"
col st4 format a12 heading "Running Secs"
define v1=0
define v2=0
col undoblocksdone new_value v1
col undoblockstotal new_value v2
select
to_char( startup_time, 'dd/mm/yy hh24"h"mi' ) st1,
to_char( sysdate, 'dd/mm/yy hh24"h"mi' ) st2,
lpad( to_char( trunc(sysdate,'YEAR') + (sysdate-startup_time-1),
decode( trunc( sysdate-startup_time, 0 ), 0, 'fm" 0d "hh24"h"mi', 'fm""dd"d "hh24"h"mi' ) ), 12, ' ' ) st3,
to_char( (sysdate-startup_time)*24*60*60, '999g999g990' ) st4
from v$instance;
PROMPT
PROMPT ###### DADOS DE UNDO ##########
with blocos as
(
SELECT SUM(UNDOBLKS) TOTAL, SUM(ACTIVEBLKS) ATIVOS, SUM(UNEXPIREDBLKS) UNEXPIRED, SUM(EXPIREDBLKS) EXPIRED
FROM V$UNDOSTAT
),
prop as
(
SELECT MAX(BLOCK_SIZE) BLOCK_SIZE, 1048576 MEGA FROM DBA_TABLESPACES WHERE CONTENTS = 'UNDO'
)
SELECT
/* trunc(b.total * p.block_size / p.mega ) "Total"
, */trunc(b.ativos * p.block_size / p.mega ) "Ativo"
,trunc(b.unexpired * p.block_size / p.mega ) "Não Expirado"
,trunc(b.expired * p.block_size / p.mega ) "Expirado"
FROM BLOCOS B
CROSS JOIN PROP P
/
PROMPT
PROMPT ########## ATIVAS ##########
SELECT
(SELECT SID FROM V$SESSION WHERE SADDR = SES_ADDR) SID,
(SELECT USERNAME FROM V$SESSION WHERE SADDR = SES_ADDR) USERNAME,
XIDUSN USN, XIDSLOT SLOT, XIDSQN SEQUENCE, STATUS, START_TIME, USED_UBLK, USED_UREC, LOG_IO, PHY_IO, TRUNC( USED_UBLK * 8 / 1024 ) UNDO_MB
FROM V$TRANSACTION
/
PROMPT ########## RECUPERANDO ##########
SELECT PID, USN, SLT SLOT, SEQ SEQUENCE, STATE STATUS, UNDOBLOCKSDONE, UNDOBLOCKSTOTAL, ROUND(UNDOBLOCKSDONE*100/UNDOBLOCKSTOTAL,2 ) SOFAR
FROM V$FAST_START_TRANSACTIONS
/
set feed off serverout on verify off
declare
dtime number;
ddone number;
begin
if :bdia is null then
:bdia := to_char( sysdate, 'j' );
:btime := to_char( sysdate, 'sssss' );
:bdone := &v1.;
else
:edia := to_char( sysdate, 'j' );
:etime := to_char( sysdate, 'sssss' );
:done := &v1.;
:total := &v2.;
dtime := (:edia*86400+:etime) - (:bdia*86400+:btime);
ddone := :done - :done;
:esttime := dtime * :total / ddone;
end if;
end;
/
undefine v1 v2
set feed 6 serverout off verify off
SET VERIFY OFF FEED OFF
COL "TRIGGER" FORMAT A40
COL TRIGGER_TYPE FORMAT A16
COL TRIGGERING_EVENT FORMAT A40
SELECT OWNER || '.' || TRIGGER_NAME "TRIGGER", TRIGGERING_EVENT, TRIGGER_TYPE, STATUS
FROM DBA_TRIGGERS
WHERE TABLE_OWNER LIKE UPPER('&1.') AND TABLE_NAME LIKE UPPER('&2.')
ORDER BY 1
/
PROMPT
COL "TRIGGER" CLEAR
COL TRIGGER_TYPE CLEAR
COL TRIGGERING_EVENT CLEAR
SET VERIFY ON FEED 6
SET VERIFY OFF
COL OBJETO FORMAT A8
--COL OWNER FORMAT A15
SELECT 'TABELA' OBJETO, LAST_ANALYZED, TABLE_NAME OBJET_NAME, NUM_ROWS, NULL BLEVEL, NULL DISTINCT_KEYS, CHAIN_CNT, INI_TRANS
FROM DBA_TABLES WHERE OWNER= UPPER( '&&1.' ) AND TABLE_NAME LIKE UPPER( '&&2.')
UNION ALL
SELECT 'INDICE', LAST_ANALYZED, INDEX_NAME, NUM_ROWS, BLEVEL, DISTINCT_KEYS, NULL, INI_tRANS
FROM DBA_INDEXES
WHERE TABLE_OWNER= UPPER( '&1.' ) AND TABLE_NAME LIKE UPPER( '&2.')
AND INDEX_NAME NOT LIKE 'SYS_IL%'
ORDER BY 1 DESC, 2 DESC
/
SET VERIFY ON
COL OBJETO CLEAR
--COL OWNER CLEAR
UNDEFINE 1 2
SET LINES 134 FEED OFF
COL USN FORMAT 999 HEAD "USN"
COL NAME FORMAT A11 HEAD "SegName"
COL "Wrp/Srh/Ext" FORMAT A11
COL STATUS FORMAT A7 HEAD "Status"
COL GETS FORMAT 99G999G999 HEAD "Gets"
COL WAITS FORMAT 999G999 HEAD "Waits"
COL XACTS FORMAT 999 HEAD "XActs"
COL EXTENTS FORMAT 99999 HEAD "Extents"
COL MHWMSIZE FORMAT 999G999 HEAD "HWMSizeMb"
COL MRSSIZE FORMAT 999G999 HEAD "RSSizeMb"
COL MWRITES FORMAT 999G999 HEAD "WritesMb"
COL MAVEACTIVE FORMAT 999G999 HEAD "AvgActvMb"
COL MOPTSIZE FORMAT 999G999 NOPRINT
COL "Tablespace" FORMAT A10
COL "ExtentsCnt" FORMAT A10
COL "CurrSizeMb" FORMAT A10
COL "CurrFreeMb" FORMAT A10
COL "TbsMaxSizeMb" FORMAT A12
COL "MaxUsedMb" FORMAT A9
COL "MaxSortMb" FORMAT A9
COL "Extent/Segment Management" FORMAT A30
WITH filet AS
(
SELECT
F.TABLESPACE_NAME
,SUM(F.BYTES)/1048576 BYTES
,SUM(F.USER_BYTES)/1048576 USERBYTES
,SUM(GREATEST(F.BYTES, F.MAXBYTES))/1048576 MAXBYTES
,(SELECT SUM(L.BYTES/1048576) FROM DBA_FREE_SPACE L WHERE F.TABLESPACE_NAME = L.TABLESPACE_NAME ) FREEBYTES
FROM DBA_DATA_FILES F
WHERE F.TABLESPACE_NAME IN (SELECT TABLESPACE_NAME FROM DBA_TABLESPACES WHERE CONTENTS = 'UNDO' )
GROUP BY F.TABLESPACE_NAME
)
SELECT
T.TABLESPACE_NAME "Tablespace"
/* ,S.CURRENT_USERS "ActvUsers"
,LPAD( TO_CHAR( S.TOTAL_EXTENTS, 'fm999g999' ), 10, ' ' ) "ExtentsCnt"*/
,LPAD( TO_CHAR( F.BYTES, 'fm999g999' ), 10, ' ' ) "CurrSizeMb"
,LPAD( TO_CHAR( F.FREEBYTES, 'fm999g999' ), 10, ' ' ) "CurrFreeMb"
,LPAD( TO_CHAR( F.MAXBYTES, 'fm999g999' ), 12, ' ' ) "TbsMaxSizeMb"
/* ,LPAD( TO_CHAR( S.MAX_USED_BLOCKS * T.BLOCK_SIZE / 1048576, 'fm999g999' ), 9, ' ' ) "MaxUsedMb"
,LPAD( TO_CHAR( S.MAX_SORT_BLOCKS * T.BLOCK_SIZE / 1048576, 'fm999g999' ), 9, ' ' ) "MaxSortMb" */
,T.EXTENT_MANAGEMENT || ' ' || T.ALLOCATION_TYPE || ' ' ||
DECODE( T.NEXT_EXTENT, NULL, 'AutoAlloc, ', TO_CHAR( T.NEXT_EXTENT * T.BLOCK_SIZE / 1048576, 'fm9g999' ) || 'Mb, ' ) ||
T.SEGMENT_SPACE_MANAGEMENT "Extent/Segment Management"
FROM DBA_TABLESPACES T, FILET F
WHERE T.TABLESPACE_NAME = F.TABLESPACE_NAME
/
with blocos as
(
SELECT SUM(UNDOBLKS) TOTAL, SUM(ACTIVEBLKS) ATIVOS, SUM(UNEXPIREDBLKS) UNEXPIRED, SUM(EXPIREDBLKS) EXPIRED
FROM V$UNDOSTAT
),
prop as
(
SELECT MAX(BLOCK_SIZE) BLOCK_SIZE, 1048576 MEGA FROM DBA_TABLESPACES WHERE CONTENTS = 'UNDO'
)
SELECT
/* trunc(b.total * p.block_size / p.mega ) "Total"
, */trunc(b.ativos * p.block_size / p.mega ) "Ativo"
,trunc(b.unexpired * p.block_size / p.mega ) "Não Expirado"
,trunc(b.expired * p.block_size / p.mega ) "Expirado"
FROM BLOCOS B
CROSS JOIN PROP P
/
select n.usn, n.name, s.xacts, s.extents,
lpad(s.wraps,3,' ')||'|'||lpad(s.shrinks,3,' ')||'|'||lpad(s.extends,3,' ') "Wrp/Srh/Ext",
s.gets, s.waits,
status,
trunc(s.aveactive/1048576) maveactive,
trunc(s.rssize/1048576) mrssize,
trunc(s.hwmsize/1048576) mhwmsize,
trunc(s.writes/1048576) mwrites,
trunc(s.optsize/1048576) moptsize
from v$rollstat s, v$rollname n
where n.usn = s.usn
order by n.USN
/
PROMPT
SET FEED 6
COL MOPTSIZE CLEAR
-- @S:\upd.rman.estat.sql
CREATE OR REPLACE PROCEDURE SYS.UPD_RMAN_ESTAT
IS
vTobjlist DBMS_STATS.ObjectTab;
vAux varchar2(60);
vCRLF varchar2(2) := chr(13)||chr(10);
vParte number := 1;
vSender varchar2(30) := 'rman.gaivota@xxx.zzz';
vRcpt varchar2(30) := 'sabd@xxx.zzz';
vSubj varchar2(50) := 'Cálculo de estatísticas para rman@rman.gaivota';
vMessage varchar2(32000):=null;
/*
GRANT ANALYZE ANY TO SYS
/
ALTER SESSION SET NLS_TERRITORY='AMERICA';
ALTER SESSION SET NLS_LANGUAGE='AMERICAN';
DECLARE
JOBNO NUMBER;
BEGIN
DBMS_JOB.SUBMIT(
JOBNO, 'SYS.UPD_RMAN_ESTAT;',
sysdate+1/1440,
'trunc(next_day(sysdate,''SATURDAY''))+23/24' );
COMMIT;
END;
/
*/
BEGIN
EXECUTE IMMEDIATE 'ALTER SESSION SET OPTIMIZER_MODE=ALL_ROWS';
-- para calcular as estatísticas
DBMS_STATS.GATHER_SCHEMA_STATS
(
ownname => 'RMAN' ,
method_opt => 'FOR ALL INDEXED COLUMNS SIZE 1',
--estimate_percent=> 50, -- null significa compute (+preciso +demorado), em vez de estimate sobre 50%
--block_sample => true,
--cascade => true, -- calcula inclusive nos índices
objlist => vTobjlist, -- lista objetos onde foram calculadas estatísticas
options => 'GATHER AUTO' -- tabelas sem estats ou com estats desatualizada (ver alter table ...monitoring)
);
-- para mandar um email com informação sobre quais objetos foram atualizados
for i in vTobjlist.first..vTobjlist.last loop
vAux := vTobjlist(i).objtype||'-'||vTobjlist(i).objname||vCRLF;
if nvl(length(vMessage),0)+nvl(length(vAux),0) < 32000 then
vMessage := vMessage || vAux;
else
system.send_email(vSender, vRcpt, vSubj||' Parte '||to_char(vParte), vMessage);
vParte := vParte + 1;
vMessage := vAux;
end if;
end loop;
if vParte > 1 then
vSubj := vSubj || ' Parte '||to_char(vParte);
end if;
DBMS_UTILITY.COMPILE_SCHEMA('RMAN');
system.send_email(vSender, vRcpt, vSubj, vMessage);
END UPD_RMAN_ESTAT;
/
col bd new_value p_bd noprint
col uf new_value p_uf noprint
set define on verify off feed off termout off trimspool on head off pages 1000 serverout on
select instance_name bd, substr(host_name,1,2) uf from v$instance;
spool D:\temp\&p_bd._users.sql
declare
cursor usu_cursor is
select username,decode(password,'EXTERNAL','EXTERNALLY','BY VALUES '''||password||'''') password,
default_tablespace, 'profile '||profile profile, ' account '||decode(account_status,'LOCKED','LOCK','UNLOCK') account
from sys.dba_users
where username not in ('SYS','SYSTEM','OUTLN','DBSNMP','OEM','ODSCOMMON','ODS','NAMES','PUBLIC','ECO_IRM','CTXSYS','EXFSYS','MGMT_VIEW','ORACLE_OCM','SYSMAN','TSMSYS','WMSYS','ADMPSSTSE')
order by username;
cursor quota_cursor (p_usuario varchar2) is
select username, tablespace_name, max_bytes
from sys.dba_ts_quotas
where username = p_usuario
and tablespace_name not in ('SYSTEM','TEMP','RBS');
-- Atribui roles a roles e/ou usuários
cursor atr_role is
select 'grant '||granted_role||' to "'||grantee||'";'||chr(10) cmd
from dba_role_privs
where grantee not in ('SYS','SYSTEM','OUTLN','DBSNMP','OEM','ODSCOMMON','ODS','NAMES','PUBLIC','ECO_IRM','CTXSYS','EXFSYS','MGMT_VIEW','ORACLE_OCM','SYSMAN','TSMSYS','WMSYS','ADMPSSTSE');
-- Atribui privilégios de sistema a roles
cursor atr_sys_privs is
select 'grant '||privilege||' to "'||grantee||'";'||chr(10) cmd
from dba_sys_privs
where grantee not in ('PUBLIC','SYS','ECO_IRM','_NEXT_USER','AQ_ADMINISTRATOR_ROLE','AQ_USER_ROLE','CONNECT','DBA','DELETE_CATALOG_ROLE','EXECUTE_CATALOG_ROLE',
'EXP_FULL_DATABASE','HS_ADMIN_ROLE','IMP_FULL_DATABASE','OEM_MONITOR','RECOVERY_CATALOG_OWNER','RESOURCE','SELECT_CATALOG_ROLE','SNMPAGENT',
'OEM','ECO_IRM','ADMPSSTSE');
-- Atribui privilégios aos objetos do SYS
cursor atr_sys_obj is
select 'grant ' || privilege || ' on sys.' || table_name || ' to ' || grantee || ';' cmd
from dba_tab_privs a, dba_objects b
where a.owner='SYS'
and a.grantee not in ( 'PUBLIC', 'SNMPAGENT', 'OUTLN', 'SYSTEM', 'DBA' )
and a.grantee not like '%ROLE'
and a.grantee not like '%_FULL_DATABASE'
and table_name = object_name
and object_type != 'DIRECTORY';
cursor atr_sys_dir is
select 'grant ' || privilege || ' on directory sys.' || table_name || ' to "' || grantee || '";' cmd
from dba_tab_privs a, dba_objects b
where a.owner='SYS'
and a.grantee not in ( 'PUBLIC', 'SNMPAGENT', 'OUTLN', 'SYSTEM', 'DBA' )
and a.grantee not like '%ROLE'
and a.grantee not like '%_FULL_DATABASE'
and table_name = object_name
and object_type = 'DIRECTORY';
begin
dbms_output.enable(1000000);
dbms_output.put_line('spool &p_bd._users.sql.out');
dbms_output.put_line(chr(10)||'prompt Criando usuários....'||chr(10));
for rec_usu in usu_cursor loop
-- dbms_output.put_line('create user '||rec_usu.username||' identified '||rec_usu.password);
dbms_output.put_line('alter user "'||rec_usu.username||'"') ;
dbms_output.put_line('default tablespace '||rec_usu.default_tablespace||' temporary tablespace TEMP');
-- dbms_output.put_line('default tablespace users2 temporary tablespace TEMP');
dbms_output.put_line(rec_usu.profile||' '||rec_usu.account);
for rec_quota in quota_cursor(rec_usu.username) loop
dbms_output.put_line('quota '||replace(rec_quota.max_bytes,'-1','unlimited')||' on '||rec_quota.tablespace_name);
end loop;
dbms_output.put_line('/');
end loop;
for rec_atr_role in atr_role loop
dbms_output.put_line(rec_atr_role.cmd);
end loop;
for rec_atr_sys_privs in atr_sys_privs loop
dbms_output.put_line(rec_atr_sys_privs.cmd);
end loop;
for rec_atr_sys_obj in atr_sys_obj loop
dbms_output.put_line(rec_atr_sys_obj.cmd);
end loop;
for rec_atr_sys_dir in atr_sys_dir loop
dbms_output.put_line(rec_atr_sys_dir.cmd);
end loop;
dbms_output.put_line(chr(10)||'spool off');
end;
/
spool off
set define "&" feed on termout on head on pages 60
break on usuario skip 1
with u as (
select distinct grantee as usuario, privilege as priv from DBA_SYS_PRIVS
where grantee like 'P#_%' escape '#' and privilege not in ('CREATE SESSION')
union
select distinct grantee as usuario, PRIVILEGE||' on ' || owner || '.' ||table_name as priv from DBA_TAB_PRIVS
where grantee like 'P#_%' escape '#'
union
select distinct grantee as usuario, granted_role as priv from DBA_ROLE_PRIVS
where grantee like 'P#_%' escape '#'
and granted_role not in ('DBA', 'CONNECT', 'ROLCOPAGCONSULTA', 'ROLSICODCONSULTAGESTORES')
and granted_role not like 'WF#_%' escape '#'
and granted_role not like '%CECIN%'
)
select 'REVOKE '||priv||' from '||usuario||';' from u
where usuario not in ('P_7777','SYS', 'WKSYS', 'CTXSYS', 'SYSMAN', 'SYSTEM', 'USR_DBA','P_1978');
with u as (
select distinct grantee as usuario from DBA_SYS_PRIVS
where grantee like 'P#_%' escape '#' and privilege not in ('CREATE SESSION', 'CONNECT')
union
select distinct grantee as usuario from DBA_TAB_PRIVS
where grantee like 'P#_%' escape '#'
union
select distinct grantee as usuario from DBA_ROLE_PRIVS
where grantee like 'P#_%' escape '#'
and granted_role not in ('DBA', 'CONNECT')
and granted_role not like 'WF#_%' escape '#'
and granted_role not like '%CECIN%'
)
select DISTINCT usuario from u
where usuario not in ('P_7777','SYS', 'WKSYS', 'CTXSYS', 'SYSMAN', 'SYSTEM', 'USR_DBA');
DEFINE ORIGEM=&1.
DEFINE DEST=&2.
COL DATA_TYPE FORMAT A15
COL OWNER FORMAT A15
SET VERIFY OFF
(
SELECT '&origem.' ORIGEM, OWNER, TABLE_NAME, COLUMN_ID, COLUMN_NAME, DATA_TYPE||'('||
DECODE( DATA_PRECISION, NULL, TO_CHAR(DATA_LENGTH), TO_CHAR(NVL(DATA_PRECISION,0)||','||NVL(DATA_SCALE,0)) ) ||')' DATA_TYPE
FROM DBA_TAB_COLUMNS@&origem. O
WHERE OWNER = 'SCHEMA'
AND EXISTS
(
SELECT 1 FROM DBA_TABLES@&dest. WHERE OWNER = 'SCHEMA'
AND O.TABLE_NAME = TABLE_NAME
)
MINUS
SELECT '&origem.', 'SCHEMA', TABLE_NAME, COLUMN_ID, COLUMN_NAME, DATA_TYPE||'('||
DECODE( DATA_PRECISION, NULL, TO_CHAR(DATA_LENGTH), TO_CHAR(NVL(DATA_PRECISION,0)||','||NVL(DATA_SCALE,0)) ) ||')' DATA_TYPE
FROM DBA_TAB_COLUMNS@&dest.
WHERE OWNER = 'SCHEMA'
)
UNION ALL
(
SELECT '&dest.', OWNER, TABLE_NAME, COLUMN_ID, COLUMN_NAME, DATA_TYPE||'('||
DECODE( DATA_PRECISION, NULL, TO_CHAR(DATA_LENGTH), TO_CHAR(NVL(DATA_PRECISION,0)||','||NVL(DATA_SCALE,0)) ) ||')' DATA_TYPE
FROM DBA_TAB_COLUMNS@&dest. O
WHERE OWNER = 'SCHEMA'
AND EXISTS
(
SELECT 1 FROM DBA_TABLES@&origem. WHERE OWNER = 'SCHEMA'
AND O.TABLE_NAME = TABLE_NAME
)
MINUS
SELECT '&dest.', 'SCHEMA', TABLE_NAME, COLUMN_ID, COLUMN_NAME, DATA_TYPE||'('||
DECODE( DATA_PRECISION, NULL, TO_CHAR(DATA_LENGTH), TO_CHAR(NVL(DATA_PRECISION,0)||','||NVL(DATA_SCALE,0)) ) ||')' DATA_TYPE
FROM DBA_TAB_COLUMNS@&origem.
WHERE OWNER = 'SCHEMA'
)
ORDER BY OWNER, TABLE_NAME, COLUMN_NAME, 1
/
SET VERIFY ON
UNDEFINE 1
UNDEFINE 2
UNDEFINE ORIGEM
UNDEFINE DEST
SELECT
T.TABLESPACE_NAME
,NVL(ROUND((SELECT SUM(BYTES)/1048576 FROM DBA_SEGMENTS@TESTE S WHERE S.TABLESPACE_NAME=T.TABLESPACE_NAME),2),0) MEGAS
FROM DBA_TABLESPACES@TESTE T
WHERE NOT EXISTS
(
SELECT 1 FROM DBA_TABLESPACES L
WHERE L.TABLESPACE_NAME=T.TABLESPACE_NAME
)
/
WITH LOCAL AS
(
SELECT TABLESPACE_NAME, NVL(ROUND(SUM(MAXBYTES)/1048576,2),0) MAXSIZE
FROM DBA_DATA_FILES
GROUP BY TABLESPACE_NAME
), REMOTO AS
(
SELECT S.TABLESPACE_NAME, NVL(ROUND(SUM(BYTES)/1048576,2),0) SEGS
FROM DBA_SEGMENTS@TESTE S
GROUP BY TABLESPACE_NAME
)
SELECT
L.*, R.SEGS
FROM LOCAL L
LEFT JOIN REMOTO R ON (L.TABLESPACE_NAME=R.TABLESPACE_NAME )
WHERE L.MAXSIZE < R.SEGS
/
SELECT SID, EVENT
, P1TEXT||DECODE(P1TEXT, NULL, '', '='||P1 ) P1
, P2TEXT||DECODE(P2TEXT, NULL, '', '='||P2 ) P2
, P3TEXT||DECODE(P3TEXT, NULL, '', '='||P3 ) P3
, LPAD( WAIT_TIME || 's', 7, ' ' ) INW
FROM V$SESSION_WAIT_HISTORY
WHERE EVENT NOT IN -- Eventos considerados idle na versão 8.1.7
( 'smon timer', 'pmon timer', 'rdbms ipc message', 'Null event', 'parallel query dequeue',
'pipe get', 'client message', 'SQL*Net message to client', 'SQL*Net message from client',
'SQL*Net more data from client', 'SQL*Net more data to client', 'dispatcher timer',
'virtual circuit status', 'lock manager wait for remote message', 'PX Idle Wait',
'wakeup time manager' );
SELECT SID, EVENT
, TOTAL_WAITS QTDE
, TOTAL_TIMEOUTS QTDE_TIMEOUTS
, CASE
WHEN NULLIF(e.time_waited,0)/100 < 60
THEN e.time_waited/100 || ' segundos'
WHEN NULLIF(e.time_waited,0)/100 < 3600
THEN round(e.time_waited/100/60,2) || ' minutos'
WHEN NULLIF(e.time_waited,0)/100 >= 3600
THEN round(e.time_waited/100/3600,2) || ' horas'
ELSE
'n/a'
END tempo_total
FROM V$SESSION_EVENT e
WHERE 1 = 1
ORDER BY time_waited desc;
SELECT sesion.sid,
sql_text
FROM v$sqlarea sqlarea, v$session sesion
WHERE sesion.sql_hash_value = sqlarea.hash_value
AND sesion.sql_address = sqlarea.address;
COL "Who Am I?" FORMAT A120
alter session set nls_date_format = 'dd/mm/yyyy hh24:mi:ss'
/
select 'Você é o usuário ' || USER || ', conectado à base ' || upper(instance_name) || ', iniciada às '|| startup_time || ', (' || VERSION ||
') da máquina ' || upper(host_name) || /* ' - '|| platform_name || */ '.' "Who Am I?"
from v$instance, v$database
/
Database Options/Packs Usage Reporting
-- nota descreve como verificar o uso de Oracle Database Options/Management Packs licenciados separadamente
-- DOWNLOAD LINK: https://support.oracle.com/knowledge/Oracle%20Database%20Products/1317265_1.html
options_packs_usage_statistics.sql
-- Alternative ------------------------>
-- Get Features usage:
SELECT u1.name,
u1.detected_usages,
u1.currently_used,
u1.version
FROM dba_feature_usage_statistics u1
WHERE u1.version = (select max(u2.version)
from dba_feature_usage_statistics u2
where u2.name = u1.name)
AND u1.detected_usages > 0
AND u1.dbid = (select dbid from v$database)
ORDER BY name;
-- Get Options usage:
col parameter for a50
SELECT parameter,
value
FROM V$option
WHERE value='TRUE';
-- Information about Session license limits:
SELECT sessions_max s_max,
sessions_warning s_warning,
sessions_current s_current,
sessions_highwater s_high,
users_max
FROM v$license;
-- Information about CPU license limits:
SELECT CPU_COUNT_CURRENT,
CPU_CORE_COUNT_CURRENT,
CPU_SOCKET_COUNT_CURRENT,
CPU_COUNT_HIGHWATER,
CPU_CORE_COUNT_HIGHWATER,
CPU_SOCKET_COUNT_HIGHWATER
FROM V$LICENSE;
-- Purpose: NLS: Show valid NLS parameters (TERRITORY, CHARACTERSET) from v$nls_valid_values
-- ##################################################################
--
spool show_nls_valid_values.lst
ttitle left 'Show valid NLS parameters (TERRITORY, CHARACTERSET)' skip 2
set feed off
set pagesize 30000
set linesize 200
COLUMN parameter format A15
COLUMN value format A15
SELECT parameter,value
FROM v$nls_valid_values
WHERE parameter = 'CHARACTERSET'
ORDER BY value;
spool off;
-- Purpose: NLS: Show valid NLS parameters (TERRITORY, CHARACTERSET) from v$nls_valid_values
-- ##################################################################
--
spool show_nls_valid_values.lst
ttitle left 'Show valid NLS parameters (TERRITORY, CHARACTERSET)' skip 2
set feed off
set pagesize 30000
set linesize 200
COLUMN parameter format A15
COLUMN value format A15
SELECT parameter,value
FROM v$nls_valid_values
WHERE parameter = 'CHARACTERSET'
ORDER BY value;
spool off;
-- Purpose: NLS: Show current NLS database settings from sys.props$
-- ##################################################################
--
spool show_nls_current_settings.lst
ttitle left 'Show current NLS database settings' skip 2
set feed off
set pagesize 30000
set linesize 200
column name format a25
column VALUE$ format a35
SELECT name,value$ FROM sys.props$;
spool off;
-- Purpose: Monitor Sort Activities (Sorts in Memory, Sorts on Disk)
-- ##################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
set termout on;
column STATISTIC# format 999 heading 'Id'
column NA format a32 heading 'Parameter'
column NAME format a32 heading 'Statistik'
column VA format a8 heading 'Value'
column VALUE format 9999999990
ttitle left 'Monitor Sort Activities' skip 2
spool monitor_sort_activities.log
select rpad (NAME, 32, '.') as NA, VALUE as VA
from V$PARAMETER
where NAME like '%sort%'
/
ttitle off
select NAME,
VALUE
from V$SYSSTAT
where NAME in ('sorts (rows)',
'sorts (memory)',
'sorts (disk)')
/
spool off;
-- Purpose: Monitor SQL*Net communication activities
-- Use: Needs Oracle DBA Access
-- ##################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
set termout on;
column NA format a39 heading 'STATISTIC'
column VALUE format 99999999990 heading 'VALUE'
spool monitor_sqlnet_activities.log
select rpad (NAME, 39, '.') as NA, VALUE
from V$SYSSTAT
where NAME like ('%SQL*Net%')
order by NA
/
spool off;
-- Purpose: Monitor Private SQL Areas and PL/SQL space in the UGA and SGA
--
-- PL/SQL allocates most memory from the UGA which is
-- located in the SGA when shared servers are used
--
-- UGA = User Global Area
-- SGA = System Global Area
--
-- Use: Needs Oracle DBA Access--
-- ##################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
set termout on;
column NA head 'STATISTIC' format a29
column NR_SESS head '#USERS' format 9999
column C1 head 'SUM|[kbyte]' format 99999990.90
column C2 head 'AVG|[kbyte]' format 99999990.90
column C3 head 'MIN|[kbyte]' format 99999990.90
column C4 head 'MAX|[kbyte]' format 99999990.90
ttitle left 'Monitor Private SQL Areas and PL/SQL space' skip 2
spool monitor_private_SQL_areas.log
select rpad (B.NAME, 29, '.') as NA,
COUNT(*) as NR_SESS,
SUM(A.VALUE)/1024.0 as C1,
AVG(A.VALUE)/1024.0 as C2,
MIN(A.VALUE)/1024.0 as C3,
MAX(A.VALUE)/1024.0 as C4
from V$SESSTAT A,
V$STATNAME B
where A.STATISTIC# = B.STATISTIC#
and (B.NAME like '%pga%'
or B.NAME like '%uga%'
or B.NAME like '%stored%')
group by B.NAME
/
-- Purpose: Monitor Data Access Activities (Full Table and Index Scans, Chained Rows)
-- Use: Needs Oracle DBA Access
-- ##################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
set termout on;
column STATISTIC# form 999 head 'Id'
column NA form a32 head 'Statistic'
column RIA form 990.90 head 'Row Access via????Index [%]'
column RTS form 990.90 head 'Row Access via????Table Scan [%]'
column RA form 9999999990 head 'Rows accessed'
column PCR form 990.90 head 'Chained????Rows [%]'
colum CL form 990.90 head 'Cluster????Length'
ttitle left 'Monitor Data Access Activities' skip 2
spool monitor_data_activites.log
select
rpad (NAME, 32, '.') as NA,VALUE
from V$SYSSTAT
where
NAME like '%table scan%' or
NAME like '%table fetch%' or
NAME like '%cluster%';
ttitle off
select
A.VALUE + B.VALUE as RA,
A.VALUE / (A.VALUE + B.VALUE) * 100.0 as RIA,
B.VALUE / (A.VALUE + B.VALUE) * 100.0 as RTS,
C.VALUE / (A.VALUE + B.VALUE) * 100.0 as PCR,
E.VALUE / D.VALUE as CL
from
V$SYSSTAT A,
V$SYSSTAT B,
V$SYSSTAT C,
V$SYSSTAT D,
V$SYSSTAT E
where
A.NAME = 'table fetch by rowid' and
B.NAME = 'table scan rows gotten' and
C.NAME = 'table fetch continued row' and
D.NAME = 'cluster key scans' and
E.NAME = 'cluster key scan block gets'
/
-- Purpose: Generate Script to coalesce free Space in cluttered Tablespaces
-- ##################################################################
SELECT a1.tablespace_name,COUNT(*) nbr_cont_wholes
FROM sys.dba_free_space a1, sys.dba_free_space a2
WHERE a1.tablespace_name=a2.tablespace_name
AND a1.block_id+a1.blocks = a2.block_id
GROUP BY A1.tablespace_name
/
set heading off
spool alter_ts_coal.sql
SELECT 'ALTER TABLESPACE '||a1.tablespace_name||' COALESCE;'
FROM sys.dba_free_space a1, sys.dba_free_space a2
WHERE a1.tablespace_name=a2.tablespace_name
AND a1.block_id+a1.blocks = a2.block_id
GROUP BY A1.tablespace_name
/
SPOOL OFF
set heading on
@alter_ts_coal.sql
-- Purpose: Buffer Cache Analysis - Slot Status (Analysis of V$CACHE)
-- Use: Needs Oracle DBA Access
-- ##################################################################
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
set termout on;
ttitle left 'Buffer Cache Analysis - Slot Status' skip 2
spool buffer_cache_analysis_slots.log
select
decode (STATUS, 'free', 'FREE',
'xcur', 'INST EXCL',
'scur', 'INST SHAR',
'cr', 'CONS READ',
'read', 'DISK READ',
'mrec', 'MED RECO',
'irec', 'INS RECO', 'OTHER') "Slot Status",
count(*) "Counts"
from V$CACHE
group by
STATUS
/
spool off;
-- Purpose: Buffer Cache Analysis - Objects (Analysis of V$CACHE)
-- Use: Needs Oracle DBA Access
-- ##################################################################
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan off;
set verify off;
set termout on;
column BT format a29 heading 'Block Type'
column KIND format a12 heading 'Object Type'
column CB format 99990 heading 'Nr of Blocks'
column NAME format a24 heading 'Object Name'
ttitle left 'Buffer Cache Analysis - Objects' skip 2
spool buffer_cache_analysis_obj.log
select
NAME,
KIND,
decode (CLASS#,0, 'FREE',
1, 'DATA INDEX',
2, 'SORT',
3, 'SAVE UNDO',
4, 'SEG HEADER',
5, 'SAVE UNDO SH',
6, 'FREELIST BLOCK',
'OTHER') as BT,
count (BLOCK#) as CB
from V$CACHE
group by
NAME,
KIND,
CLASS#
order by
CB desc,
NAME,
KIND
/
spool off;
-- PURPOSE: ANALYZE table with estimate or compute, depending on table size, se e SIGN(n)
-- Use: Any table less than 10 MB in total size has STATISTICS COMPUTED
-- while tables larger than 10 MB have STATISTICS ESTIMATED.
-- SIGN(n) ==> if n < 0 the function returns -1
-- if n = 0 the functions returns 0
-- if n > 0 the functions returns 1
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
spool compute_or_estimate.sql
--
SELECT 'ANALYZE TABLE '||owner||'.'||table_name||' '||DECODE(SIGN(10485760 - initial_extent),1,'COMPUTE STATISTICS;','ESTIMATE STATISTICS;')
FROM sys.dba_tables WHERE owner NOT IN ('SYS','SYSTEM');
/
--
spool off;
set feed on;
@compute_or_estimate.sql
-- ==================================================================
-- 00. Configure a variavel $PATH com o caminho do OPatch:
-- ==================================================================
[oracle@host ~]$ vi .bash_profile
...
export PATH=$PATH:$ORACLE_HOME/OPatch
...
[oracle@host ~]$ . .bash_profile
[oracle@host ~]$ which opatch
/u01/app/oracle/product/19.0.0/dbhome_1/OPatch/opatch
-- ==================================================================
-- 01. Verificar a versão do Opatch:
-- ==================================================================
opatch version
OPatch Version: 12.2.0.1.XX
OPatch succeeded.
opatch lspatches
29585399;OCW RELEASE UPDATE 19.3.0.0.0 (29585399)
29517242;Database Release Update : 19.3.0.0.190416 (29517242)
opatch lsinventory
Oracle Interim Patch Installer version 12.2.0.1.XX
Copyright (c) 2023, Oracle Corporation. All rights reserved.
Oracle Home : /u01/app/oracle/product/19.3.0/dbhome_1
Central Inventory : /u01/app/oraInventory
from : /u01/app/oracle/product/19.3.0/dbhome_1/oraInst.loc
OPatch version : 12.2.0.1.XX
OUI version : 12.2.0.7.0
-- ==================================================================
-- 02. DOWNLOAD OPatch and CRITICAL PATCH UPDATES
-- ==================================================================
OPatch Tool: https://updates.oracle.com/download/6880880.html
Critical Patch Updates: https://www.oracle.com/security-alerts/
-- ==================================================================
-- 03. RENAME folder OPatch to OPatch_OLD
-- ==================================================================
mv -v /u01/app/oracle/product/19.0.0/dbhome_1/OPatch /u01/app/oracle/product/19.0.0/dbhome_1/OPatch_old
-- ==================================================================
-- 04. DESCOMPACTAR OPatch
-- ==================================================================
unzip -q p6880880_190000_Linux-x86-64.zip -d /u01/app/oracle/product/19.3.0/dbhome_1
-- ==================================================================
-- 05. Verify the OPatch has been upgraded
-- ==================================================================
/u01/app/oracle/product/19.3.0/dbhome_1/OPatch/opatch version
OPatch Version: 12.2.0.1.XX
OPatch succeeded.
-- ==================================================================
-- 06. Encerre o banco de dados
-- ==================================================================
sqlplus /nolog
CONNECT / AS SYSDBA
SHUTDOWN IMMEDIATE;
QUIT
-- Comando Alternativo ------
dbshut
-- ==================================================================
-- 07. Verfificando o serviço
-- ==================================================================
ps -ef | grep smon | grep -v grep
echo $?
## 1 --> Onde 1 significa que a instância não existe. ##
-- ==================================================================
-- 08. Backup Oracle Home (Opcional )
-- ==================================================================
export ORACLE_HOME=/u01/app/oracle/product/19.3.0/dbhome_1
cd /u01/app/oracle/product/19.3.0
## Comando para compactar: ##
tar -zcvf /home/oracle/software/DB_HOME_`date +%Y%m%d`.tar.gz dbhome_1 > /home/oracle/software/DB_HOME_`date +%Y%m%d`_tar_backup.log
## Em outra ABA: ##
tail -f /home/oracle/software/DB_HOME_20230215_tar_backup.log
-- ==================================================================
-- 09. Verifique a integridade do arquivo:
-- ==================================================================
unzip -t p36522340_190000_Linux-x86-64.zip
Archive: p36522340_190000_Linux-x86-64.zip
testing: 36522340/ OK
...
testing: PatchSearch.xml OK
No errors detected in compressed data of p99999999_190000_Linux-x86-64.zip.
-- ==================================================================
-- 10. Descompactar o patch e Acessar o diretório:
-- ==================================================================
unzip -q p99999999_190000_Linux-x86-64.zip
cd 99999999
-- ==================================================================
-- 08:Verificando os pre requisitos:
-- ==================================================================
opatch prereq CheckConflictAgainstOHWithDetail -ph ./
-- Comando Alternativo ------
$ORACLE_HOME/OPatch/opatch prereq CheckConflictAgainstOHWithDetail -ph ./
opatch prereq CheckConflictAgainstOHWithDetail -ph ./
Oracle Interim Patch Installer version 12.2.0.1.XX
Copyright (c) 2023, Oracle Corporation. All rights reserved.
PREREQ session
Oracle Home : /u01/app/oracle/product/19.3.0/dbhome_1
Central Inventory : /u01/app/oraInventory
from : /u01/app/oracle/product/19.3.0/dbhome_1/oraInst.loc
OPatch version : 12.2.0.1.XX
OUI version : 12.2.0.7.0
Log file location : /u01/app/oracle/product/19.3.0/dbhome_1/cfgtoollogs/opatch/opatch2023-02-15_14-20-35PM_1.log
Invoking prereq "checkconflictagainstohwithdetail"
Prereq "checkConflictAgainstOHWithDetail" passed.
OPatch succeeded.
-- ==================================================================
-- 09:Aplicando o patch:
-- ==================================================================
[oracle@host 99999999]$ opatch apply
Oracle Interim Patch Installer version 12.2.0.1.XX
Copyright (c) 2023, Oracle Corporation. All rights reserved.
Oracle Home : /u01/app/oracle/product/19.3.0/dbhome_1
Central Inventory : /u01/app/oraInventory
from : /u01/app/oracle/product/19.3.0/dbhome_1/oraInst.loc
OPatch version : 12.2.0.1.XX
OUI version : 12.2.0.7.0
Log file location : /u01/app/oracle/product/19.3.0/dbhome_1/cfgtoollogs/opatch/opatch-xxxx_1.log
Verifying environment and performing prerequisite checks...
Do you want to proceed? [Y]
Is the local system ready for patching? [Y]
## Comando Alternativo -- FORMA SILENCIOSA ##
$ORACLE_HOME/OPatch/opatch apply -silent
-- ==================================================================
-- 10. Verificando o novo patch e inventório:
-- ==================================================================
opatch lspatches
opatch lsinventory
-- ==================================================================
-- 11. Inicie o Banco de dados
-- ==================================================================
sqlplus /nolog
CONNECT / AS SYSDBA
STARTUP QUIET
ALTER PLUGGABLE DATABASE ALL OPEN;
QUIT
## Comando Alternativo ##
dbstart $ORACLE_HOME
### Em Data Guard esse procedimento deverá ser feito apenas no Primary ###
-- ==================================================================
-- 12. Ele informará se o seu ambiente de banco de dados está pronto para correção de SQL ou não… .
-- ==================================================================
$ORACLE_HOME/OPatch/datapatch -sanity_checks
SQL Patching sanity checks version 19.24.0.0.0
Copyright (c) 2021, 2024, Oracle. All rights reserved.
Checks completed. Printing report:
...
Check: Locale - OK
SQL Patching sanity checks completed.
-- ==================================================================
-- 13. Ele carrega dados SQL modificados.
-- ==================================================================
$ORACLE_HOME/OPatch/datapatch -verbose
Copyright (c) 2012, 2024, Oracle. All rights reserved.
...
SQL Patching tool complete
-- ==================================================================
-- 14. Verificar o nível do patch SQL consultando
-- ==================================================================
sqlplus / as sysdba
SELECT DESCRIPTION FROM DBA_REGISTRY_SQLPATCH ORDER BY ACTION_TIME DESC;
-- ==================================================================
-- 15. Recompilar Objetos Inválidos
-- ==================================================================
@?/rdbms/admin/utlrp.sql
-- ==================================================================
-- 16. Verifique os patches do SQLPLUS conectando-se ao SYSDBA
-- ==================================================================
SELECT * FROM SYS.REGISTRY$HISTORY;
SELECT DBMS_QOPATCH.GET_OPATCH_LIST FROM DUAL;
##-- SYS.REGISTRY$HISTORY-- ##
COLUMN action_time FORMAT A20
COLUMN action FORMAT A20
COLUMN version FORMAT A10
COLUMN comments FORMAT A30
COLUMN bundle_series FORMAT A10
SELECT
TO_CHAR(ACTION_TIME, 'DD-MON-YYYY HH24:MI:SS') AS ACTION_TIME,
ACTION, VERSION, ID, COMMENTS, BUNDLE_SERIES
FROM SYS.REGISTRY$HISTORY
ORDER BY ACTION_TIME;
##--DBA_REGISTRY_SQLPATCH-- ##
COL ACTION_TIME FOR A28
COL ACTION FOR A8
COL TARGET_VERSION FOR A8
COL COMMENTS FOR A30
COL STATUS FOR A10
SET LINE 999 PAGES 999
SELECT
PATCH_ID, TARGET_VERSION, STATUS, ACTION, ACTION_TIME
FROM DBA_REGISTRY_SQLPATCH
ORDER BY ACTION_TIME;
-- ==================================================================
-- 17. Verifique se o patch foi aplicado ou não com o pacote DBMS
-- ==================================================================
##--Put patch number which you want to check -- ##
SELECT
XMLTRANSFORM(DBMS_QOPATCH.IS_PATCH_INSTALLED ('XXXX'),
DBMS_QOPATCH.GET_OPATCH_XSLT) "PATCH INSTALLED?"
FROM DUAL;
##-- VERIFIQUE TODOS OS PATCHES APLICADOS DO DBMS --##
SET SERVEROUT ON;
EXEC DBMS_QOPATCH.GET_SQLPATCH_STATUS;
-- ==================================================================
-- LISTA DE COMANDOS RÁPIDOS
-- ==================================================================
opatch version
opatch lspatches
opatch lsinventory
$ORACLE_HOME/OPatch/opatch prereq CheckConflictAgainstOHWithDetail -ph ./
$ORACLE_HOME/OPatch/opatch apply -silent
sqlplus /nolog
CONNECT / AS SYSDBA
STARTUP QUIET
ALTER PLUGGABLE DATABASE ALL OPEN;
QUIT
$ORACLE_HOME/OPatch/datapatch -sanity_checks
$ORACLE_HOME/OPatch/datapatch -verbose
### login as GRID ###
-- ==================================================================
-- 0. Patch Installation Checks
-- ==================================================================
### BEFORE APPLYING THE PATCH ###
cluvfy stage -pre patch
This software is "1204" days old.
It is a best practice to update the CRS home by downloading and applying the latest release update.
Refer to MOS note 2731675.1 for more details.
CVU operation performed: stage -pre patch
Date: Oct 24, 2024 9:07:55 PM
Clusterware version: 21.0.0.0.0
CVU home: /u01/app/21.3.0.0/grid
Grid home: /u01/app/21.3.0.0/grid
User: grid
Operating system: Linux4.18.0-553.8.1.el8_10.x86_64
### AFTER APPLYING THE PATCH ###
cluvfy stage -post patch
Performing following verification checks ...
cluster upgrade state ...
Oracle Clusterware active patch level is "0".
Node Name Software Patch Software Patch Release Patch
Level(OCR) Level(OLR) Level
------------------------------------------------------------------------
node1 2018261355 2018261355 2018261355
node2 2018261355 2018261355 2018261355
CVU operation performed: stage -post patch
Date: Oct 24, 2024 11:26:27 PM
CVU version: 21.16.0.0.0 (100824x8664)
Clusterware version: 21.0.0.0.0
CVU home: /u01/app/21.3.0.0/grid
Grid home: /u01/app/21.3.0.0/grid
User: grid
Operating system: Linux4.18.0-553.8.1.el8_10.x86_64
### login as ROOT ###
-- ==================================================================
-- 1. Check the release of OPatch Grid e Database:
-- ==================================================================
/u01/app/21.3.0.0/grid/OPatch/opatch version
OPatch Version: 12.2.0.1.26
OPatch succeeded.
/u01/app/oracle/product/21.3.0/dbhome_1/OPatch/opatch version
OPatch Version: 12.2.0.1.26
OPatch succeeded.
-- ==================================================================
-- 2. Check folder softwares:
-- ==================================================================
[root@node1 softwares]# ls -1
p6880880_210000_Linux-x86-64.zip ---> OPatch Tool
p36990664_210000_Linux-x86-64.zip ---> Patch GI Release
p36991631_210000_Linux-x86-64.zip ---> Patch Database Release
-- ==================================================================
-- 3. Rename the existing OPatch folder from the GI home and Oracle database home.
-- ==================================================================
mv -v /u01/app/21.3.0.0/grid/OPatch /u01/app/21.3.0.0/grid/OPatch_old
renamed ..
mv -v /u01/app/oracle/product/21.3.0/dbhome_1/OPatch /u01/app/oracle/product/21.3.0/dbhome_1/OPatch_old
renamed..
-- ==================================================================
-- 02. DOWNLOAD OPatch and CRITICAL PATCH UPDATES
-- ==================================================================
OPatch Tool: https://updates.oracle.com/download/6880880.html
Critical Patch Updates: https://www.oracle.com/security-alerts/
-- ==================================================================
-- 3. Unzip the Patch
-- ==================================================================
cd /softwares
unzip -q p6880880_210000_Linux-x86-64.zip -d /u01/app/21.3.0.0/grid/
unzip -q p6880880_210000_Linux-x86-64.zip -d /u01/app/oracle/product/21.3.0/dbhome_1
-- ==================================================================
-- 4. Change the ownership of the Opatch directory files to the home owner/group
-- ==================================================================
chown -R grid:oinstall /u01/app/21.3.0.0/grid/OPatch
chown -R oracle:oinstall /u01/app/oracle/product/21.3.0/dbhome_1/OPatch
-- ==================================================================
-- 5. Verify the OPatch has been upgraded
-- ==================================================================
/u01/app/21.3.0.0/grid/OPatch/opatch version
OPatch Version: 12.2.0.1.44
OPatch succeeded.
/u01/app/oracle/product/21.3.0/dbhome_1/OPatch/opatch version
OPatch Version: 12.2.0.1.44
OPatch succeeded.
-- ==================================================================
-- 6. Remove the existing OPatch folder from the GI home and Oracle database home
-- ==================================================================
rm -fr /u01/app/21.3.0.0/grid/OPatch_old
rm -fr /u01/app/oracle/product/21.3.0/dbhome_1/OPatch_old
-- ==================================================================
-- 7. Repeat the same procedure in the other nodes
-- ==================================================================
ssh node2
/u01/app/21.3.0.0/grid/OPatch/opatch version
/u01/app/oracle/product/21.3.0/dbhome_1/OPatch/opatch version
mv -v /u01/app/21.3.0.0/grid/OPatch /u01/app/21.3.0.0/grid/OPatch_old
mv -v /u01/app/oracle/product/21.3.0/dbhome_1/OPatch /u01/app/oracle/product/21.3.0/dbhome_1/OPatch_old
unzip -q /softwares/p6880880_210000_Linux-x86-64.zip -d /u01/app/21.3.0.0/grid/
unzip -q /softwares/p6880880_210000_Linux-x86-64.zip -d /u01/app/oracle/product/21.3.0/dbhome_1
chown -R grid:oinstall /u01/app/21.3.0.0/grid/OPatch
chown -R oracle:oinstall /u01/app/oracle/product/21.3.0/dbhome_1/OPatch
/u01/app/21.3.0.0/grid/OPatch/opatch version
/u01/app/oracle/product/21.3.0/dbhome_1/OPatch/opatch version
rm -fr /u01/app/21.3.0.0/grid/OPatch_old
rm -fr /u01/app/oracle/product/21.3.0/dbhome_1/OPatch_old
-- ==================================================================
-- 8. Validate the OPatch can retrieve the stack components and their versions.
-- ==================================================================
## If the following commands fail, stop at this step.
## You cannot proceed with applying the PSU and you need to receive Oracle support to look into the issue.
su - grid
$ORACLE_HOME/OPatch/opatch lsinventory -detail
su - oracle
$ORACLE_HOME/OPatch/opatch lsinventory
-- ==================================================================
-- 9. Unzip the Patchs
-- ==================================================================
[root@node1]# cd /softwares; ls -1
p36990664_210000_Linux-x86-64.zip ---> Patch GI Release
unzip -oq /softwares/p36990664_210000_Linux-x86-64.zip
## Patch 36990664 - GI Release Update 21.16.0.0.241015 ##
36990664/
36772575/
36949613/
36991631/ ===> ## Patch 36991631 - Database Release Update 21.16.0.0.241015 ##
36999645/
37157122/
-- ==================================================================
-- 10. Change Owner e permission
-- ==================================================================
chown -R grid:oinstall /softwares/36990664
chown -R oracle:oinstall /softwares/36991631
chmod 775 -R /softwares
[root@node1 softwares]# ll
drwxrwxr-x. 9 grid oinstall 36990664
drwxrwxr-x. 5 oracle oinstall 36991631
-- ==================================================================
-- 11. Run OPatch Conflict Check :: GRID
-- ==================================================================
# SINTAX: $ORACLE_HOME/OPatch/opatch prereq CheckConflictAgainstOHWithDetail -phBaseDir /GGGGGGG/NNNNNN
/u01/app/21.3.0.0/grid/OPatch/opatch prereq CheckConflictAgainstOHWithDetail -phBaseDir /softwares/36990664/36991631
/u01/app/21.3.0.0/grid/OPatch/opatch prereq CheckConflictAgainstOHWithDetail -phBaseDir /softwares/36990664/36999645
/u01/app/21.3.0.0/grid/OPatch/opatch prereq CheckConflictAgainstOHWithDetail -phBaseDir /softwares/36990664/37157122
/u01/app/21.3.0.0/grid/OPatch/opatch prereq CheckConflictAgainstOHWithDetail -phBaseDir /softwares/36990664/36772575
/u01/app/21.3.0.0/grid/OPatch/opatch prereq CheckConflictAgainstOHWithDetail -phBaseDir /softwares/36990664/36949613
/u01/app/21.3.0.0/grid/OPatch/opatch prereq CheckConflictAgainstOHWithDetail -phBaseDir /softwares/36990664/36718064
Oracle Interim Patch Installer version 12.2.0.1.44
Copyright (c) 2024, Oracle Corporation. All rights reserved.
PREREQ session
Oracle Home : /u01/app/21.3.0.0/grid
Central Inventory : /u01/app/oraInventory
from : /u01/app/21.3.0.0/grid/oraInst.loc
OPatch version : 12.2.0.1.44
OUI version : 12.2.0.9.0
Log file location : /u01/app/21.3.0.0/grid/cfgtoollogs/opatch/opatch2024-10-24_20-48-39PM_1.log
Invoking prereq "checkconflictagainstohwithdetail"
Prereq "checkConflictAgainstOHWithDetail" passed.
OPatch succeeded.
-- ==================================================================
-- 12. Run OPatch opatchauto Apply Analyze
-- ==================================================================
### As the ROOT home user: ###
export PATH=$PATH:/u01/app/21.3.0.0/grid/OPatch
cd /softwares/36990664/
opatchauto apply -analyze
OPatchauto session is initiated at Thu Oct 24 20:26:37 2024
System initialization log file is /u01/app/21.3.0.0/grid/cfgtoollogs/opatchautodb/systemconfig2024-10-24_08-26-44PM.log.
Session log file is /u01/app/21.3.0.0/grid/cfgtoollogs/opatchauto/opatchauto2024-10-24_08-27-34PM.log
Executing OPatch prereq operations to verify patch applicability on home /u01/app/21.3.0.0/grid
Patch applicability verified successfully on home /u01/app/21.3.0.0/grid
...
Executing patch validation checks on home /u01/app/oracle/product/21.3.0/dbhome_1
Patch validation checks successfully completed on home /u01/app/oracle/product/21.3.0/dbhome_1
Verifying SQL patch applicability on home /u01/app/oracle/product/21.3.0/dbhome_1
-- ==================================================================
-- 13. Run OPatch OPatchAuto Apply
-- ==================================================================
export PATH=$PATH:/u01/app/21.3.0.0/grid/OPatch
opatchauto apply
### See Another terminal ###
tail -f /u01/app/21.3.0.0/grid/cfgtoollogs/opatchautodb/systemconfig2024-10-25_08-46-11PM.log
# If Opatch fails, it stops with error and saves details about the error in a log file.
# If this happens to you, consider performing the following:
# a) Look into the log file reported by the Opatch.
# b) Fix the root cause of the reported issue.
# c) Resume the Opatch using the following command:
opatchauto apply resume
=======================================
### ALTERNATIVE: APPLY one by one ###
=======================================
/u01/app/21.3.0.0/grid/OPatch/opatch apply -oh /u01/app/21.3.0.0/grid -local -silent /softwares/36990664/36991631
/u01/app/21.3.0.0/grid/OPatch/opatch apply -oh /u01/app/21.3.0.0/grid -local -silent /softwares/36990664/36999645
/u01/app/21.3.0.0/grid/OPatch/opatch apply -oh /u01/app/21.3.0.0/grid -local -silent /softwares/36990664/37157122
/u01/app/21.3.0.0/grid/OPatch/opatch apply -oh /u01/app/21.3.0.0/grid -local -silent /softwares/36990664/36772575
/u01/app/21.3.0.0/grid/OPatch/opatch apply -oh /u01/app/21.3.0.0/grid -local -silent /softwares/36990664/36949613
/u01/app/21.3.0.0/grid/OPatch/opatch apply -oh /u01/app/21.3.0.0/grid -local -silent /softwares/36990664/36718064
Oracle Interim Patch Installer version 12.2.0.1.44
Copyright (c) 2024, Oracle Corporation. All rights reserved.
Oracle Home : /u01/app/21.3.0.0/grid
Central Inventory : /u01/app/oraInventory
from : /u01/app/21.3.0.0/grid/oraInst.loc
OPatch version : 12.2.0.1.44
OUI version : 12.2.0.9.0
Log file location : /u01/app/21.3.0.0/grid/cfgtoollogs/opatch/opatch2024-10-25_21-26-32PM_1.log
Verifying environment and performing prerequisite checks...
....
-- ==================================================================
-- 14. Verify that the patches have been applied in srv1.
-- ==================================================================
su - grid
$ORACLE_HOME/OPatch/opatch lsinventory -detail
$ORACLE_HOME/OPatch/opatch lsinventory | grep -i "applied on"
su - oracle
$ORACLE_HOME/OPatch/opatch lsinventory
-- ==================================================================
-- 15. Verify that the database is up and running in its nodes.
-- ==================================================================
srvctl status database -d ORCL -v
-- ==================================================================
-- 12. Check Patching Sanity
-- ==================================================================
$ORACLE_HOME/OPatch/datapatch -sanity_checks
SQL Patching sanity checks version 19.24.0.0.0
Copyright (c) 2021, 2024, Oracle. All rights reserved.
Checks completed. Printing report:
...
Check: Locale - OK
SQL Patching sanity checks completed.
-- ==================================================================
-- 13. Ele carrega dados SQL modificados.
-- ==================================================================
$ORACLE_HOME/OPatch/datapatch -verbose
Copyright (c) 2012, 2024, Oracle. All rights reserved.
...
SQL Patching tool complete
-- ==================================================================
-- 14. Check the patch SQL
-- ==================================================================
sqlplus / as sysdba
SELECT DESCRIPTION FROM DBA_REGISTRY_SQLPATCH ORDER BY ACTION_TIME DESC;
-- ==================================================================
-- 15. Recompilar Objetos Inválidos
-- ==================================================================
@?/rdbms/admin/utlrp.sql
-- ==================================================================
-- 16. Check if the patch has been applied with SQLPLUS (SYSDBA)
-- ==================================================================
SELECT * FROM SYS.REGISTRY$HISTORY;
SELECT DBMS_QOPATCH.GET_OPATCH_LIST FROM DUAL;
##-- SYS.REGISTRY$HISTORY-- ##
COLUMN action_time FORMAT A20
COLUMN action FORMAT A20
COLUMN version FORMAT A10
COLUMN comments FORMAT A30
COLUMN bundle_series FORMAT A10
SELECT
TO_CHAR(ACTION_TIME, 'DD-MON-YYYY HH24:MI:SS') AS ACTION_TIME,
ACTION, VERSION, ID, COMMENTS, BUNDLE_SERIES
FROM SYS.REGISTRY$HISTORY
ORDER BY ACTION_TIME;
##--DBA_REGISTRY_SQLPATCH-- ##
COL ACTION_TIME FOR A28
COL ACTION FOR A8
COL TARGET_VERSION FOR A8
COL COMMENTS FOR A30
COL STATUS FOR A10
SET LINE 999 PAGES 999
SELECT
PATCH_ID, TARGET_VERSION, STATUS, ACTION, ACTION_TIME
FROM DBA_REGISTRY_SQLPATCH
ORDER BY ACTION_TIME;
-- ==================================================================
-- 17. Check if the patch has been applied with DBMS
-- ==================================================================
##--Put patch number which you want to check -- ##
SELECT
XMLTRANSFORM(DBMS_QOPATCH.IS_PATCH_INSTALLED ('XXXX'),
DBMS_QOPATCH.GET_OPATCH_XSLT) "PATCH INSTALLED?"
FROM DUAL;
##-- VERIFIQUE TODOS OS PATCHES APLICADOS DO DBMS --##
SET SERVEROUT ON;
EXEC DBMS_QOPATCH.GET_SQLPATCH_STATUS;
cat .bash_profile
# .bash_profile
# Get the aliases and functions
if [ -f ~/.bashrc ]; then
. ~/.bashrc
fi
#=================================
# ORACLE
#=================================
export ORACLE_HOSTNAME=`hostname`
export ORACLE_SID=orcl1
export ORACLE_UNQNAME=orcl
export ORACLE_BASE=/u01/app/oracle
export ORACLE_HOME=$ORACLE_BASE/product/19.3.0/dbhome_1
export JAVA_HOME=$ORACLE_HOME/jdk:/usr/bin/java
export APEX_BASE=$ORACLE_HOME/apex/
export PATH=.:$PATH:/usr/sbin:$ORACLE_HOME/bin:$ORACLE_HOME/OPatch:$ORACLE_HOME/jdk/bin:$ORACLE_HOME/suptools/oratop
export LD_LIBRARY_PATH=$ORACLE_HOME/lib:/lib:/usr/lib
export CLASSPATH=$ORACLE_HOME/jlib:$ORACLE_HOME/rdbms/jlib:$JAVA_HOME/ojdbc8.jar:$JAVA_HOME/orai18n.jar:$APEX_BASE/utilities
export TNS_ADMIN=$ORACLE_HOME/network/admin
export NLS_LANG="AMERICAN_AMERICA.WE8MSWIN1252"
export NLS_DATE_FORMAT="DD-MON-YYYY HH24:MI:SS"
export TMP=/tmp
export TMPDIR=$TMP
export EDITOR=vi
export TERM=xterm
umask 022
#export DISPLAY=[IP_WINDOWS]:0.0
# -=ALIAS=- #
alias sqlcl="$ORACLE_HOME/sqlcl/bin/sql"
alias ll='ls -latrh'
alias l='ls -latrh'
alias oh='cd $ORACLE_HOME'
alias ob='cd $ORACLE_BASE/diag'
alias ot='cd $ORACLE_BASE/diag/rdbms/orcl/orcl/trace'
alias on='cd $ORACLE_HOME/network/'
alias ct='cd /storage_df1/manutencao/rotina/logs/'
alias oa='cd /u01/app/oracle/admin/orcl/adump'
cat .bash_profile
# .bash_profile
# Get the aliases and functions
if [ -f ~/.bashrc ]; then
. ~/.bashrc
fi
#=================================
# GRID
#=================================
export ORACLE_HOSTNAME=`hostname`
export ORACLE_SID=+ASM1
export ORACLE_BASE=/u01/app/grid/
export ORACLE_HOME=/u01/app/19.3.0.0/grid
export GRID_BASE=/u01/app/grid/
export GRID_HOME=/u01/app/19.3.0.0/grid
export NLS_DATE_FORMAT="YYYY-MM-DD HH24:MI:SS"
export NLS_LANG="AMERICAN_AMERICA.AL32UTF8"
export TNS_ADMIN=$ORACLE_HOME/network/admin
export PATH=.:$PATH:/usr/sbin:$ORACLE_HOME/bin:$ORACLE_HOME/OPatch:$ORACLE_HOME/jdk/bin:$ORACLE_HOME/suptools/oratop
export LD_LIBRARY_PATH=$ORACLE_HOME/lib:/lib:/usr/lib
export CLASSPATH=$ORACLE_HOME/jlib:$ORACLE_HOME/rdbms/jlib:$JAVA_HOME/ojdbc8.jar:$JAVA_HOME/orai18n.jar:$APEX_BASE/utilities
export JAVA_HOME=$ORACLE_HOME/jdk:/usr/bin/java
export NLS_LANG="AMERICAN_AMERICA.WE8MSWIN1252"
export NLS_DATE_FORMAT="DD-MON-YYYY HH24:MI:SS"
export THREADS_FLAG=native
export TERM=xterm
export TMPDIR=/tmp
export TEMP=/tmp
export EDITOR=vi
umask 022
#export DISPLAY=[IP_WINDOWS]:0.0
SELECT
SYS_CONTEXT ( 'USERENV', 'DB_NAME' ) DB_NAME,
SYS_CONTEXT ( 'USERENV', 'SESSION_USER' ) USER_NAME,
SYS_CONTEXT ( 'USERENV', 'SERVER_HOST' ) DB_HOST,
SYS_CONTEXT ( 'USERENV', 'HOST' ) USER_HOST
FROM DUAL;
SELECT
UTL_INADDR.GET_HOST_ADDRESS, -- get local IP addr
UTL_INADDR.GET_HOST_NAME -- get local host name
FROM DUAL;
SELECT PROGRAM FROM V$SESSION WHERE PROGRAM LIKE '%(PMON)%';
SELECT HOST_NAME FROM V$INSTANCE;
-- Como saber se a instância está com login em modo restrito:
SELECT LOGINS FROM V$INSTANCE;
SELECT INSTANCE_NAME,LOGINS FROM V$INSTANCE;
-- Como habilitar sessões restritas:
ALTER SYSTEM ENABLE RESTRICTED SESSION;
-- Como desabilitar sessões restritas:
ALTER SYSTEM DISABLE RESTRICTED SESSION;
export PATH=.:$PATH:/usr/sbin:$ORACLE_HOME/bin:$ORACLE_HOME/OPatch:$ORACLE_HOME/jdk/bin:$ORACLE_HOME/suptools/oratop
fonte: https://support.oracle.com/epmos/faces/DocumentDisplay?_afrLoop=392886160032222&id=1500864.1
oratop [ [Options] [Logon] ]
Logon:
{username[/password][@connect_identifier] | / }
[AS {SYSDBA|SYSOPER}]
Options:
-i : Interval Delay (requires value in seconds, default: 3s)
-f : Long format for header & section 4 (default: 80 column)
-r : IORL mode for Section 2 (default is IOPS)
-d : Real-Time Top 5 Wait Events (default: Cumulative)
-m : MODULE/ACTION mode for Section 4 (default: USER/PROGRAM_NAME)
-b : Batch mode
-n : maximum number of iterations (requires number)
-h : Help
...
oratop -h
oratop -f -r -i 3 / as sysdba
oratop -f / as sysdba
oratop -dsf / as sysdba
oratop -sbn4 / as sysdba
...
oratop -i 10 / as sysdba
oratop -i 10 username/password@tns_alias
oratop -i 10 system/manager@tns_alias
-- QUANTIDADE DE CURSORES ABERTOS / LIMITE
clear columns
COLUMN VALUE FORMAT A20 heading 'LIMITE'
SELECT COUNT(p.VALUE) AS OPEN_CURSORS, p.VALUE
FROM v$sesstat a, v$statname b, v$parameter p, v$session s
WHERE a.statistic# = b.statistic#
AND s.sid=a.sid
AND b.name = 'opened cursors current'
AND p.name = 'open_cursors'
GROUP BY p.VALUE;
-- QUEM ESTA COM CURSORES ABERTOS E A QUANTIDADE
COLUMN username FORMAT A40 heading 'USUARIO'
SELECT s.username, count(*) AS QTD
FROM v$sesstat a, v$statname b, v$session s
WHERE a.statistic# = b.statistic#
AND s.sid=a.sid
AND b.name = 'opened cursors current'
GROUP BY s.username
ORDER BY s.username asc;
Rem
Rem NOME
Rem asm.sql
Rem
Rem DESCRIÇÃO
Rem Este script mostra informações os diskgroups e discos ASM usados pela instância.
Rem
Rem UTILIZAÇÃO
Rem @asm
Rem
Rem ATUALIZAÇÕES (MM/DD/YY)
Rem FERR@RI 01/04/09 - criação do script
Rem
Rem ---------- ---------- ---------- ---------- ---------- ---------- ---------- ----------
set feedback off
set pages 20
PROMPT
PROMPT --> Espaço livre por DG
select NAME, TOTAL_MB, FREE_MB, STATE, TYPE, OFFLINE_DISKS, UNBALANCED
from V$ASM_DISKGROUP
order by 2 desc
/
col NAME for a30
col PATH for a45
PROMPT
PROMPT
PROMPT --> Espaço livre em cada disco de cada DG
select NAME, GROUP_NUMBER, DISK_NUMBER, TOTAL_MB, FREE_MB, MOUNT_STATUS, PATH
from V$ASM_DISK
order by 2, 3
/
PROMPT
set feedback on
SELECT SUM_ARCH.DAY,
SUM_ARCH.GENERATED_MB,
SUM_ARCH_DEL.DELETED_MB,
SUM_ARCH.GENERATED_MB - SUM_ARCH_DEL.DELETED_MB "REMAINING_MB"
FROM ( SELECT TO_CHAR (COMPLETION_TIME, 'DD/MM/YYYY') DAY,
SUM (ROUND ( (blocks * block_size) / (1024 * 1024), 2))
GENERATED_MB
FROM V$ARCHIVED_LOG
WHERE ARCHIVED = 'YES'
GROUP BY TO_CHAR (COMPLETION_TIME, 'DD/MM/YYYY')) SUM_ARCH,
( SELECT TO_CHAR (COMPLETION_TIME, 'DD/MM/YYYY') DAY,
SUM (ROUND ( (blocks * block_size) / (1024 * 1024), 2))
DELETED_MB
FROM V$ARCHIVED_LOG
WHERE ARCHIVED = 'YES' AND DELETED = 'YES'
GROUP BY TO_CHAR (COMPLETION_TIME, 'DD/MM/YYYY')) SUM_ARCH_DEL
WHERE SUM_ARCH.DAY = SUM_ARCH_DEL.DAY(+)
ORDER BY TO_DATE (DAY, 'DD/MM/YYYY');
Rem
Rem NOME
Rem plus.sql
Rem
Rem DESCRIÇÃO
Rem Ajustes do ambiente SQl*Plus e informações da base de dados.
Rem
Rem UTILIZAÇÃO
Rem @plus
Rem
Rem ATUALIZAÇÕES (MM/DD/YY)
Rem FERR@RI 26/01/07 - criação do script
Rem NORONHA 30/10/09 - Logon Automático, FlashBack ON/OFF
Rem
Rem ---------- ---------- ---------- ---------- ---------- ---------- ---------- ----------
set tab off
SET SQLPLUSCOMPATIBILITY 8.1.7
-- Format for administration purpose
col object_name for a15
col grantee for a20
col grantor for a20
col privilege for a25
col sql_text for a75
col file_name for a45
col column_name for A20
col object_name for A30
col spid for A7
col sid for 999999
col serial# for 9999999
col segment_name for a25
col degree for a5
col owner for a20
col table_owner for a20
col table_name for a20
col comments for a90
col partition_name for a4 heading Part
col subpartition_name for a5 heading Spart
col truncated for a5
col username FOR A10
col status for A3 trunc
col osuser for A10
col machine for A20 trunc
col terminal for A15
col program for A25 trunc
col module for A16
col member for A40
col waiting_session heading wait for 9999999
col holding_session heading holding for 9999999
col lock_type for a13
col mode_held for a10
col mode_requested for a15
col db_link for a25
col referenced_owner for a15
col referenced_name for a20
col referenced_link_name for a25
col host for a20
col directory_path for a40
col parameter for a30
col value for a30
col triggering_event for a40
col sid_serial for a15
col last_call_et for a15 heading 'LAST_CALL_ET|HH:MM:SS' justify r
col load for a6 justify right
col executes for 9999999
col sql_text for a100
col name for a15
col file_id for 9999
col mb for 99999
-- Used by Trusted Oracle
col rowlabel format a15
-- used for the show errors command
col line/col for a8
col error for a65 word_wrapped
-- used for the show sga command
col name_col_plus_show_sga for a24
-- defaults for show parameters
col name_col_plus_show_param for a36 heading name
col value_col_plus_show_param for a30 heading value
-- defaults for set autotrace explain report
col id_plus_exp for 990 heading i
col parent_id_plus_exp for 990 heading p
col plan_plus_exp for a60
col object_node_plus_exp for a8
col other_tag_plus_exp for a29
col other_plus_exp for a44
-- info
set heading off time on feedback off
column user new_value usuario
column name new_value instancia
column host_name new_value nome_host
column crlf new_value crlf
column sid_curr new_value sid_da_sessao
set termout off
set linesize 1000
conn system/Soa$Jam3@&&ambiente
HOST TITLE &&ambiente
select USER, HOST_NAME, NAME, chr(10) CRLF from V$INSTANCE, V$DATABASE;
select trim(SID) SID_CURR from V$MYSTAT where rownum = 1;
set termout on
select b.NAME || ' (' || a.VERSION || ') - ' ||
a.HOST_NAME || ' - Uptime: ' || to_char(a.STARTUP_TIME, 'dd/mm/yyyy hh24:mm:ss') || ' - ' ||
b.LOG_MODE || ' - Archiver: ' || a.ARCHIVER
from V$INSTANCE a, V$DATABASE b;
select 'DB Block Size ' || lpad( a.VALUE / 1024 || 'KB ', 17 ) ||
'Database Buffer Cache ' || lpad( round( ( decode( b.VALUE,
0, c.VALUE,
b.VALUE * a.VALUE ) ) / 1024 / 1024 ) || 'MB', 11 ) || chr(10) ||
'Shared Pool ' || lpad( round( d.VALUE / 1024 / 1024 ) || 'MB ', 19 ) ||
'Shared Pool Reserved ' || lpad( round( e.VALUE / 1024 / 1024 ) || 'MB', 12 ) || chr(10) ||
'Sort Area Size ' || lpad( round( f.VALUE / 1024 ) || 'KB ', 16 ) ||
'Sort Area Retained Size ' || lpad( round( g.VALUE / 1024 ) || 'KB', 9 ) || chr(10) ||
'SGA Max Size' || lpad( decode( h.VALUE, null, 'N/A',
round( h.VALUE / 1024 / 1024 ) || 'MB' ), 12 )
from V$PARAMETER a, V$PARAMETER b, ( select 'db_block_buffers' NAME, VALUE from V$PARAMETER
where NAME = 'db_cache_size' ) c, V$PARAMETER d, V$PARAMETER e, V$PARAMETER f,
V$PARAMETER g, ( select 'db_block_buffers' NAME, VALUE
from V$PARAMETER
where NAME = 'sga_max_size' ) h
where a.NAME = 'db_block_size'
and b.NAME = 'db_block_buffers'
and c.NAME (+) = b.NAME
and d.NAME = 'shared_pool_size'
and e.NAME = 'shared_pool_reserved_size'
and f.NAME = 'sort_area_size'
and g.NAME = 'sort_area_retained_size'
and h.NAME (+) = b.NAME;
set serveroutput on
declare
v_version varchar2(10);
v_flashback_on varchar2(3);
begin
select version into v_version from v$instance;
IF substr(v_version,1,2) = '10' THEN
execute immediate 'SELECT flashback_on FROM v$database' INTO v_flashback_on;
dbms_output.put_line('FLASHBACK DATABASE TURNED ON?: ' || v_flashback_on);
END IF;
end;
/
set serveroutput OFF
PROMPT
PROMPT
-- Sets do SQLPlus
clear breaks
clear columns
-- alter session set NLS_DATE_FORMAT = 'DD/MM/YYYY HH24:MI:SS';
-- alter session set NLS_NUMERIC_CHARACTERS = ',.';
set heading on
set long 10000000
set longchunksize 1000
set feedback on
set verify off
-- set buffer 1000
set pagesize 9000
set trimspool on
SET SQLPROMPT 'system on &&_CONNECT_IDENTIFIER> '
SET TERMOUT ON
-- outra forma de prompt
-- set sqlprompt "- &USUARIO. (SID:&SID_DA_SESSAO.) em &INSTANCIA. / &NOME_HOST.&CRLF.SQL> "
Rem
Rem NOME
Rem grantofdba.sql
Rem
Rem DESCRIÇÃO
Rem Este script lista todos os usuários que possuem os privilégios existentes na
Rem role DBA, menos os privilegios existentes nas roles CONNECT e RESOURCE.
Rem
Rem UTILIZAÇÃO
Rem grantofdba.sql
Rem
Rem ATUALIZAÇÕES (MM/DD/YY)
Rem FERR@RI 01/06/08 - criação do script
Rem
Rem ---------- ---------- ---------- ---------- ---------- ---------- ---------- ----------
col PRIVILEGE for a40
col GRANTEE for a15
col SCHEMA.OBJECT for a30
set feedback off
set verify off
PROMPT
PROMPT Este script lista todos os usuários que possuem os privilégios existentes na
PROMPT role DBA, menos os privilegios existentes nas roles CONNECT e RESOURCE.
PROMPT
PROMPT Roles atribuídas ao Usuário:
select GRANTEE,
GRANTED_ROLE,
ADMIN_OPTION,
DEFAULT_ROLE,
'revoke '||GRANTED_ROLE|| ' from ' ||GRANTEE|| ';' AS "GRANTs EM ROLES"
from dba_role_privs
where GRANTEE not in ('SYS','SYSTEM','DBA','EXP_FULL_DATABASE','IMP_FULL_DATABASE')
and GRANTED_ROLE in ('DBA','EXP_FULL_DATABASE','IMP_FULL_DATABASE','DELETE_CATALOG_ROLE','SELECT_CATALOG_ROLE','EXECUTE_CATALOG_ROLE','GATHER_SYSTEM_STATISTICS')
/
PROMPT
PROMPT
PROMPT Privilegio de SYSDBA
col sysdba for a10
col sysoper for a10
select USERNAME,
SYSDBA,
SYSOPER
from V$PWFILE_USERS
/
PROMPT
PROMPT
PROMPT Privilegios de Sistema:
select GRANTEE,
PRIVILEGE,
ADMIN_OPTION,
'revoke ' ||PRIVILEGE|| ' from ' ||GRANTEE|| ';' AS "GRANTs DE SISTEMA"
FROM dba_sys_privs
where GRANTEE not in ('SYS','DBA','EXP_FULL_DATABASE','IMP_FULL_DATABASE','AQ_ADMINISTRATOR_ROLE',
'DBSNMP','OEM_MONITOR','OUTLN','PERFSTAT','QUEST','HS_ADMIN_ROLE','AQ_USER_ROLE')
and PRIVILEGE in (
'AUDIT ANY',
'DROP USER',
'RESUMABLE',
'ALTER USER',
'ANALYZE ANY',
'BECOME USER',
'CREATE ROLE',
'CREATE RULE',
'CREATE USER',
'ALTER SYSTEM',
'AUDIT SYSTEM',
'DROP PROFILE',
'ALTER PROFILE',
'DROP ANY ROLE',
'DROP ANY RULE',
'DROP ANY TYPE',
'DROP ANY VIEW',
'QUERY REWRITE',
'ALTER ANY ROLE',
'ALTER ANY RULE',
'ALTER ANY TYPE',
'ALTER DATABASE',
'CREATE LIBRARY',
'CREATE PROFILE',
'DROP ANY INDEX',
'DROP ANY TABLE',
'GRANT ANY ROLE',
'LOCK ANY TABLE',
'UNDER ANY TYPE',
'UNDER ANY VIEW',
'ALTER ANY INDEX',
'ALTER ANY TABLE',
'CREATE ANY RULE',
'CREATE ANY TYPE',
'CREATE ANY VIEW',
'CREATE RULE SET',
'CREATE SNAPSHOT',
'DROP TABLESPACE',
'UNDER ANY TABLE',
'ALTER TABLESPACE',
'BACKUP ANY TABLE',
'CREATE ANY INDEX',
'CREATE ANY TABLE',
'CREATE DIMENSION',
'DELETE ANY TABLE',
'DROP ANY CLUSTER',
'DROP ANY CONTEXT',
'DROP ANY LIBRARY',
'DROP ANY OUTLINE',
'DROP ANY SYNONYM',
'DROP ANY TRIGGER',
'EXECUTE ANY RULE',
'EXECUTE ANY TYPE',
'INSERT ANY TABLE',
'MANAGE ANY QUEUE',
'SELECT ANY TABLE',
'UPDATE ANY TABLE',
'ALTER ANY CLUSTER',
'ALTER ANY LIBRARY',
'ALTER ANY OUTLINE',
'ALTER ANY TRIGGER',
'COMMENT ANY TABLE',
'CREATE TABLESPACE',
'DEQUEUE ANY QUEUE',
'DROP ANY OPERATOR',
'DROP ANY RULE SET',
'DROP ANY SEQUENCE',
'DROP ANY SNAPSHOT',
'ENQUEUE ANY QUEUE',
'FORCE TRANSACTION',
'MANAGE TABLESPACE',
'ON COMMIT REFRESH',
'ALTER ANY RULE SET',
'ALTER ANY SEQUENCE',
'ALTER ANY SNAPSHOT',
'CREATE ANY CLUSTER',
'CREATE ANY CONTEXT',
'CREATE ANY LIBRARY',
'CREATE ANY OUTLINE',
'CREATE ANY SYNONYM',
'CREATE ANY TRIGGER',
'DROP ANY DIMENSION',
'DROP ANY DIRECTORY',
'DROP ANY INDEXTYPE',
'DROP ANY PROCEDURE',
'RESTRICTED SESSION',
'ALTER ANY DIMENSION',
'ALTER ANY INDEXTYPE',
'ALTER ANY PROCEDURE',
'ALTER RESOURCE COST',
'CREATE ANY OPERATOR',
'CREATE ANY RULE SET',
'CREATE ANY SEQUENCE',
'CREATE ANY SNAPSHOT',
'DEBUG ANY PROCEDURE',
'DROP PUBLIC SYNONYM',
'EXECUTE ANY LIBRARY',
'FLASHBACK ANY TABLE',
'GRANT ANY PRIVILEGE',
'SELECT ANY SEQUENCE',
'CREATE ANY DIMENSION',
'CREATE ANY DIRECTORY',
'CREATE ANY INDEXTYPE',
'CREATE ANY PROCEDURE',
'EXECUTE ANY OPERATOR',
'EXECUTE ANY RULE SET',
'GLOBAL QUERY REWRITE',
'CREATE PUBLIC SYNONYM',
'DEBUG CONNECT SESSION',
'DROP ROLLBACK SEGMENT',
'EXECUTE ANY INDEXTYPE',
'EXECUTE ANY PROCEDURE',
'FORCE ANY TRANSACTION',
'SELECT ANY DICTIONARY',
'ALTER ROLLBACK SEGMENT',
'CREATE ROLLBACK SEGMENT',
'CREATE EVALUATION CONTEXT',
'DROP PUBLIC DATABASE LINK',
'GRANT ANY OBJECT PRIVILEGE',
'ADMINISTER DATABASE TRIGGER',
'ADMINISTER RESOURCE MANAGER',
'CREATE PUBLIC DATABASE LINK',
'DROP ANY EVALUATION CONTEXT',
'ALTER ANY EVALUATION CONTEXT',
'CREATE ANY EVALUATION CONTEXT',
'EXECUTE ANY EVALUATION CONTEXT'
)
order by GRANTEE, PRIVILEGE
/
PROMPT
PROMPT OBS: Para ver privilegios em objetos do SYS -> tecle ENTER!
PAUSE
col GRANTEE for a25
PROMPT
PROMPT Privilegios de Objeto:
select GRANTEE,
PRIVILEGE,
' ON ' as "ON",
OWNER|| '.'||TABLE_NAME AS "SCHEMA.OBJECT",
GRANTABLE,
GRANTOR,
'revoke ' ||PRIVILEGE|| ' on ' ||OWNER|| '.'||TABLE_NAME|| ' from ' ||GRANTEE|| ';' AS "GRANTs DE OBJETO"
from dba_tab_privs
where GRANTEE not in ('SYS','SYSTEM','DBA','PUBLIC','SELECT_CATALOG_ROLE','EXP_FULL_DATABASE','AQ_ADMINISTRATOR_ROLE',
'HP_DBSPI','PERFSTAT','QUEST','EXECUTE_CATALOG_ROLE','IMP_FULL_DATABASE','DELETE_CATALOG_ROLE',
'GATHER_SYSTEM_STATISTICS','HS_ADMIN_ROLE','OEM_MONITOR','OUTLN','AQ_USER_ROLE')
and OWNER = 'SYS'
order by GRANTEE
/
PROMPT
set feedback on
set verify on
Rem
Rem NOME
Rem tab.sql
Rem
Rem DESCRIÇÃO
Rem Este script lista informações da tabela especificada.
Rem
Rem UTILIZAÇÃO
Rem @tab
Rem
Rem ATUALIZAÇÕES (MM/DD/YY)
Rem FERR@RI 23/11/07 - criação do script
Rem
Rem ---------- ---------- ---------- ---------- ---------- ---------- ---------- ----------
@cab
col LAST_ANALYZED for a18
col MB for 9999999
select a.CREATED, a.LAST_DDL_TIME,
to_char(b.LAST_ANALYZED,'DD/MM/YY hh24:mi:ss') LAST_ANALYZED,
b.NUM_ROWS
from DBA_OBJECTS a, DBA_TABLES b
where a.OBJECT_TYPE = 'TABLE'
and a.OWNER = upper( '&&1' )
and a.OBJECT_NAME = upper( '&&2' )
and b.OWNER = a.OWNER
and b.TABLE_NAME = a.OBJECT_NAME;
--
prompt
prompt Armazenamento:
select a.TABLESPACE_NAME, a.BYTES/1024/1024 MB, a.EXTENTS, a.INITIAL_EXTENT / 1024 INITIAL_KB, a.NEXT_EXTENT / 1024 NEXT_KB,
a.FREELISTS, b.INI_TRANS, b.MAX_TRANS, b.PCT_INCREASE, b.PCT_USED, b.PCT_FREE, b.DEGREE, b.MONITORING
from DBA_SEGMENTS a, DBA_TABLES b
where SEGMENT_TYPE = 'TABLE'
and a.OWNER = upper( '&&1' )
and a.SEGMENT_NAME = upper( '&&2' )
and b.OWNER = a.OWNER
and b.TABLE_NAME = a.SEGMENT_NAME;
--
-- Partições
--
prompt
prompt Partições:
column "Critério de Particionamento:" format a32
select COLUMN_NAME "Critério de Particionamento:"
from DBA_PART_KEY_COLUMNS
where OWNER = upper( '&&1' )
and NAME = upper( '&&2' )
and trim( OBJECT_TYPE ) = 'TABLE'
order by COLUMN_POSITION;
--
column HIGH_VALUE format a100
select PARTITION_POSITION POS, PARTITION_NAME, TABLESPACE_NAME, HIGH_VALUE, LAST_ANALYZED,
INI_TRANS, MAX_TRANS, FREELISTS
from DBA_TAB_PARTITIONS
where TABLE_OWNER = upper( '&&1' )
and TABLE_NAME = upper( '&&2' )
order by PARTITION_POSITION;
--
-- Sub-partições
--
prompt
prompt Subpartições:
column "Critério de Sub-Partição:" format a32
select COLUMN_NAME "Critério de Sub-Partição:"
from DBA_SUBPART_KEY_COLUMNS
where OWNER = upper( '&&1' )
and NAME = upper( '&&2' )
and trim( OBJECT_TYPE ) = 'TABLE'
order by COLUMN_POSITION;
--
break on PARTITION_NAME skip 1 nodup
column PARTITION_NAME format a40
column SUBPARTITION_NAME format a40
select a.PARTITION_POSITION || ' - ' || a.PARTITION_NAME PARTITION_NAME,
b.SUBPARTITION_POSITION || ' - ' || b.SUBPARTITION_NAME SUBPARTITION_NAME, b.TABLESPACE_NAME
from DBA_TAB_PARTITIONS a, DBA_TAB_SUBPARTITIONS b
where a.TABLE_OWNER = upper( '&&1' )
and a.TABLE_NAME = upper( '&&2' )
and b.TABLE_OWNER = a.TABLE_OWNER
and b.TABLE_NAME = a.TABLE_NAME
and b.PARTITION_NAME = a.PARTITION_NAME
order by a.PARTITION_POSITION, b.SUBPARTITION_POSITION;
--
-- Primary Key
--
set heading off
select 'Primary Key:'
from dual;
set heading on
--
break on PK_CONSTRAINT skip 1 nodup on STATUS nodup on VALIDATED nodup on LAST_CHANGE nodup
column COLUMN_NAME format a32
select a.CONSTRAINT_NAME PK_CONSTRAINT, b.COLUMN_NAME COLUMN_NAME,
a.STATUS, a.VALIDATED, a.LAST_CHANGE
from DBA_CONSTRAINTS a, DBA_CONS_COLUMNS b
where a.OWNER = upper( '&&1' )
and a.TABLE_NAME = upper( '&&2' )
and a.CONSTRAINT_TYPE = 'P'
and b.OWNER = a.OWNER
and b.TABLE_NAME = a.TABLE_NAME
and b.CONSTRAINT_NAME = a.CONSTRAINT_NAME
order by a.CONSTRAINT_NAME, b.POSITION;
--
-- Índices
--
set heading off
select 'Índices:'
from dual;
set heading on
--
break on INDEX_NAME skip 1 nodup on PARTICIONADO nodup on UNIQUENESS nodup on STATUS nodup
column INDEX_NAME format a40
column COLUMN_NAME format a40
column PARTICIONADO format a12
select a.INDEX_OWNER || '.' || a.INDEX_NAME INDEX_NAME,
a.COLUMN_NAME || decode( a.DESCEND, 'ASC', '', ' (' || a.DESCEND || ')' ) COLUMN_NAME,
nvl( b.LOCALITY, 'NÃO' ) PARTICIONADO, c.UNIQUENESS, c.STATUS
from DBA_IND_COLUMNS a, DBA_PART_INDEXES b, DBA_INDEXES c
where a.TABLE_OWNER = upper( '&&1' )
and a.TABLE_NAME = upper( '&&2' )
and b.OWNER (+) = a.INDEX_OWNER
and b.INDEX_NAME (+) = a.INDEX_NAME
and c.OWNER = a.INDEX_OWNER
and c.INDEX_NAME = a.INDEX_NAME
order by INDEX_OWNER, INDEX_NAME, COLUMN_POSITION;
clear breaks
--
-- Triggers
--
set heading off
select 'Triggers:'
from dual;
set heading on
--
column TRIGGER_NAME format a30
column TRIGGERING_EVENT format a20
select OWNER || '.' || TRIGGER_NAME TRIGGER_NAME,
TRIGGERING_EVENT, TRIGGER_TYPE, STATUS
from DBA_TRIGGERS
where TABLE_OWNER = upper( '&&1' )
and TABLE_NAME = upper( '&&2' )
order by TABLE_OWNER, TABLE_NAME, OWNER, TRIGGER_NAME;
--
-- Foreign Keys
--
set heading off
select 'Foreign Keys:'
from dual;
set heading on
--
break on FK_CONSTRAINT skip 1 nodup on TABELA_PAI nodup on R_CONSTRAINT nodup
column TABELA_PAI format a40
select a.CONSTRAINT_NAME FK_CONSTRAINT, b.COLUMN_NAME COLUMN_NAME,
a.R_OWNER || '.' || c.TABLE_NAME TABELA_PAI,
c.CONSTRAINT_TYPE || ' - ' || a.R_CONSTRAINT_NAME R_CONSTRAINT, d.COLUMN_NAME, a.STATUS, a.VALIDATED, a.DELETE_RULE, a.LAST_CHANGE
from DBA_CONSTRAINTS a, DBA_CONS_COLUMNS b, DBA_CONSTRAINTS c, DBA_CONS_COLUMNS d
where a.OWNER = upper( '&&1' )
and a.TABLE_NAME = upper( '&&2' )
and a.CONSTRAINT_TYPE = 'R'
and b.OWNER = a.OWNER
and b.TABLE_NAME = a.TABLE_NAME
and b.CONSTRAINT_NAME = a.CONSTRAINT_NAME
and c.OWNER = a.R_OWNER
and c.CONSTRAINT_NAME = a.R_CONSTRAINT_NAME
and d.OWNER = c.OWNER
and d.TABLE_NAME = c.TABLE_NAME
and d.CONSTRAINT_NAME = c.CONSTRAINT_NAME
and d.POSITION = b.POSITION
order by a.CONSTRAINT_NAME, b.POSITION;
--
@rod;
--===============================================================================
-- Script que verifica o plano de execucao dos usuarios conectados no banco
--===============================================================================
@cab;
--
set echo off
col TQID format A4
col "SLAVE SQL" format A95 WORD_WRAP
col address format A12
col sql_hash format A15
col exec format 9999
repfooter off;
set timing off veri off space 1 flush on pause off termout on numwidth 10;
alter session set "_complex_view_merging"=false;
break on hash_value skip 1 nodup
select hash_value,
sql_text
from v$sqltext
where hash_value= &1
--and rownum < 2
order by piece;
clear break
select '| Operation | Name |Cost | Starts | E-Rows | Bytes | A-Rows | Buffers | Reads | Writes | E-Time |' as "Plan Table" from dual
union all /* QWEKLOIPYRTJHH7 */
select '-----------------------------------------------------------------------------------------------------------------------------------------------------'
from dual
union all
select rpad('| '||substr(lpad(' ',1*(depth))||operation|| decode(options, null,'',' '||options), 1, 33), 34, ' ')||'|'||
rpad(substr(object_name||' ',1, 30), 31, ' ')||'|'||
lpad(decode(cost, null,' ',
decode(sign(cost-1000), -1, cost||' ',
decode(sign(cost-1000000), -1, round(cost/1000)||'K',
decode(sign(cost-1000000000), -1, round(cost/1000000)||'M',
round(cost/1000000000)||'G')))), 8, ' ') || '|' ||
lpad(decode(starts,null,' ',
decode(sign(starts-1000), -1, starts||' ',
decode(sign(starts-1000000), -1, round(starts/1000)||'K',
decode(sign(starts-1000000000), -1, round(starts/1000000)||'M',
round(starts/1000000000)||'G')))), 8, ' ') || '|' ||
lpad(decode(cardinality,null,' ',
decode(sign(cardinality-1000), -1, cardinality||' ',
decode(sign(cardinality-1000000), -1, round(cardinality/1000)||'K',
decode(sign(cardinality-1000000000), -1, round(cardinality/1000000)||'M',
round(cardinality/1000000000)||'G')))), 8, ' ') || '|' ||
lpad(decode(bytes,null,' ',
decode(sign(bytes-1000), -1, bytes||' ',
decode(sign(bytes-1000000), -1, round(bytes/1000)||'K',
decode(sign(bytes-1000000000), -1, round(bytes/1000000)||'M',
round(bytes/1000000000)||'G')))), 8, ' ') || '|' ||
lpad(decode(outrows,null,' ',
decode(sign(outrows-1000), -1, outrows||' ',
decode(sign(outrows-1000000), -1, round(outrows/1000)||'K',
decode(sign(outrows-1000000000), -1, round(outrows/1000000)||'M',
round(outrows/1000000000)||'G')))), 8, ' ') || '|' ||
lpad(decode(crgets,null,' ',
decode(sign(crgets-10000000), -1, crgets||' ',
decode(sign(crgets-1000000000), -1, round(crgets/1000000)||'M',
round(crgets/1000000000)||'G'))), 9, ' ') || '|' ||
lpad(decode(reads,null,' ',
decode(sign(reads-10000000), -1, reads||' ',
decode(sign(reads-1000000000), -1, round(reads/1000000)||'M',
round(reads/1000000000)||'G'))), 8, ' ') || '|' ||
lpad(decode(writes,null,' ',
decode(sign(writes-10000000), -1, writes||' ',
decode(sign(writes-1000000000), -1, round(writes/1000000)||'M',
round(writes/1000000000)||'G'))), 8, ' ') || '|' ||
lpad(decode(etime,null,' ',
decode(sign(etime-10000000), -1, etime||' ',
decode(sign(etime-1000000000), -1, round(etime/1000000)||'M',
round(etime/1000000000)||'G'))), 8, ' ') || '|' as "Explain plan"
from
(select /*+ no_merge */
p.HASH_VALUE, p.ID, p.DEPTH, p.POSITION, p.OPERATION,
p.OPTIONS, p.COST COST, p.CARDINALITY CARDINALITY,
p.BYTES BYTES, p.OBJECT_NODE, p.OBJECT_OWNER,
p.OBJECT_NAME, p.OTHER_TAG, p.PARTITION_START,
p.PARTITION_STOP, p.DISTRIBUTION, pa.starts,
pa.OUTPUT_ROWS outrows, pa.CR_BUFFER_GETS crgets,
pa.DISK_READS reads, pa.DISK_WRITES writes,
pa.ELAPSED_TIME etime
from v$sql_plan_statistics_all pa,
V$sql_plan p
where p.hash_value = &1
and p.CHILD_NUMBER= 0
and p.hash_value = pa.hash_value(+)
and pa.child_number(+) = 0
order by p.id )
union all
select '-----------------------------------------------------------------------------------------------------------------------------------------------------'
from dual;
REM
REM Print slave sql
REM
select /* QWEKLOIPYRTJHH7 */
decode(object_node,null,'', substr(object_node,length(object_node)-3,1) || ',' ||
substr(object_node,length(object_node)-1,2)) TQID,
other "SLAVE SQL"
from v$sql_plan vp
where other is not NULL
and hash_value = &1
and CHILD_NUMBER= 0
order by vp.id;
--
@rod;
Rem
Rem NOME
Rem undo.sql
Rem
Rem DESCRIÇÃO
Rem Este script informa a situação da Tablespace de UNDO, a taxas de geração de UNDO e sugere valores para UNDO_RETENTION.
Rem
Rem UTILIZAÇÃO
Rem @undo
Rem
Rem ATUALIZAÇÕES (MM/DD/YY)
Rem FERR@RI 03/04/08 - criação do script
Rem
Rem ---------- ---------- ---------- ---------- ---------- ---------- ---------- ----------
set feedback off
PROMPT
PROMPT Situacao atual do UNDO:
col name for a20
col value for a20
select NAME, VALUE from v$parameter where NAME = 'undo_management'
/
PROMPT
-- col "UNDO_RETENTION (Sec)" for 999,999,999
-- col "UNDO_RETENTION (Min)" for 999,999,999
select value/60/60 as "UNDO_RETENTION (Horas)",
value/60 as "UNDO_RETENTION (Min)",
to_number(value) as "UNDO_RETENTION (Sec)"
from v$parameter
where name = 'undo_retention'
/
PROMPT
PROMPT
PROMPT Taxa de Geracao de Undo:
SELECT trunc(((AVG_UNDO_PER_SEC * 60) * DB_BLOCK_SIZE) /1024/1024,0) AS "Media(MB/Min)",
trunc(((MAX_UNDO_PER_SEC * 60) * DB_BLOCK_SIZE) /1024/1024,0) AS "Maximo(MB/Min)"
FROM (SELECT (SUM(undoblks)/SUM(((end_time-begin_time)*86400))) AS AVG_UNDO_PER_SEC
FROM v$undostat),
(SELECT MAX(UNDOBLKS)/600 AS MAX_UNDO_PER_SEC
FROM v$undostat),
(SELECT value AS DB_BLOCK_SIZE
FROM v$parameter
WHERE name = 'db_block_size')
/
PROMPT
PROMPT
PROMPT Undo necessario para atender as transacoes atuais:
-- col Média(MB) for 999,999,999
-- col Máximo(MB) for 999,999,999
SELECT trunc((AVG_UNDO_PER_SEC * DB_BLOCK_SIZE * UNDO_RETENTION) /1024/1024,0) AS "Media(MB)",
trunc((MAX_UNDO_PER_SEC * DB_BLOCK_SIZE * UNDO_RETENTION) /1024/1024,0) AS "Maximo(MB)"
FROM (SELECT (SUM(undoblks)/SUM(((end_time-begin_time)*86400))) AS AVG_UNDO_PER_SEC
FROM v$undostat),
(SELECT MAX(UNDOBLKS)/600 AS MAX_UNDO_PER_SEC
FROM v$undostat),
(SELECT value AS DB_BLOCK_SIZE
FROM v$parameter
WHERE name = 'db_block_size'),
(SELECT value AS UNDO_RETENTION
FROM v$parameter
WHERE name = 'undo_retention')
/
PROMPT
PROMPT
PROMPT O UNDO_RETENTION pode ser configurado para:
col "CONSIDERANDO GERACAO MEDIA" for a26
col "CONSIDERANDO GERACAO MAX" for a25
SELECT 'alter system set undo_retention=' || trunc((UNDO_SIZE_BYTES / (AVG_UNDO_PER_SEC * DB_BLOCK_SIZE)),0) AS "CONSIDERANDO GERACAO MEDIA",
'alter system set undo_retention=' || trunc((UNDO_SIZE_BYTES / (MAX_UNDO_PER_SEC * DB_BLOCK_SIZE)),0) AS "CONSIDERANDO GERACAO MAX"
FROM (select sum(BYTES) AS UNDO_SIZE_BYTES
from DBA_DATA_FILES
where TABLESPACE_NAME = (select value from v$parameter where name = 'undo_tablespace')),
(SELECT (SUM(undoblks)/SUM(((end_time-begin_time)*86400))) AS AVG_UNDO_PER_SEC
FROM v$undostat),
(SELECT MAX(UNDOBLKS)/600 AS MAX_UNDO_PER_SEC
FROM v$undostat),
(SELECT value AS DB_BLOCK_SIZE
FROM v$parameter
WHERE name = 'db_block_size')
/
PROMPT
PROMPT
PROMPT Se o no. de esperas por cabecalho de rollback for superior a 1% do no. total de solicitacoes, crie mais segmentos de rollback.
SELECT round((sum(waits)* 100 /sum(gets)),5) "Hit_Ratio",
sum(waits) "Waits",
sum(gets) "Gets"
FROM v$rollstat
/
PROMPT
column TABLESPACE_NAME format a25
column TAM_MB format a11
column USADO_MB format a11
column LIVRE_MB format a11
column OCUP_% format a7
column " " format a40
select c.TABLESPACE_NAME, to_char( nvl( e.TAM, b.TAM ), '9999990.99' ) TAM_MB,
to_char( nvl( e.TAM, b.TAM ) - nvl( nvl( d.LIVRE, a.LIVRE ), 0 ), '9999990.99' ) USADO_MB,
to_char( nvl( nvl( d.LIVRE, a.LIVRE ), 0 ), '9999990.99' ) LIVRE_MB,
to_char( round( ( ( nvl( e.TAM, b.TAM ) - nvl( nvl( d.LIVRE, a.LIVRE ), 0 ) ) * 100 ) / nvl( e.TAM, b.TAM ), 2 ), '990.99' ) "OCUP_%",
rpad( rpad( chr(1), round( ( ( ( nvl( e.TAM, b.TAM ) - nvl( nvl( d.LIVRE, a.LIVRE ), 0 ) ) * 100 ) / nvl( e.TAM, b.TAM ) ) / 2.5 ), chr(1) ) ||
'_', 40, '_' ) " "
from DBA_TABLESPACES c,
--
( select TABLESPACE_NAME, sum( BYTES ) / 1024 / 1024 LIVRE
from DBA_FREE_SPACE
where TABLESPACE_NAME = (select value from v$parameter where name = 'undo_tablespace')
group by TABLESPACE_NAME ) a,
--
( select TABLESPACE_NAME, ( a.free_BLOCKS * b.VALUE ) / 1024 / 1024 LIVRE
from V$SORT_SEGMENT a, V$PARAMETER b
where b.NAME = 'db_block_size'
and a.TABLESPACE_NAME = (select value from v$parameter where name = 'undo_tablespace') ) d,
--
( select TABLESPACE_NAME, sum( BYTES ) / 1024 / 1024 TAM
from DBA_DATA_FILES
where TABLESPACE_NAME = (select value from v$parameter where name = 'undo_tablespace')
group by TABLESPACE_NAME ) b,
--
( select TABLESPACE_NAME, sum( BYTES ) / 1024 / 1024 TAM
from DBA_TEMP_FILES
where TABLESPACE_NAME = (select value from v$parameter where name = 'undo_tablespace')
group by TABLESPACE_NAME ) e
--
where c.TABLESPACE_NAME = (select value from v$parameter where name = 'undo_tablespace')
and a.TABLESPACE_NAME (+) = c.TABLESPACE_NAME
and d.TABLESPACE_NAME (+) = c.TABLESPACE_NAME
and b.TABLESPACE_NAME (+) = c.TABLESPACE_NAME
and e.TABLESPACE_NAME (+) = c.TABLESPACE_NAME
order by c.TABLESPACE_NAME
/
PROMPT
PROMPT
set feedback on
set feed off
set wrap off
set lines 130
set pages 100
alter session set nls_date_format='dd/mm/yyyy-hh24:mi:ss';
PROMPT =============================================================================================================
col kinstance_name for a12 heading 'Instancia'
col khostname for a20 heading 'Servidor'
col kstatus heading 'Estado'
col ksessions for 9999 heading 'Sessoes'
col start_time for a20 heading 'Start_Time'
col today for a20 heading 'Today'
col days_running for 9999 heading 'Days_Running'
col sql_text for A100 heading Sql word wrap
col child_number for 99999 heading Child#
select decode(i.instance_name, null, ' ', '>> ') ||
c.instance_name kinstance_name,
c.host_name khostname,
c.status kstatus,
l.sessions_current ksessions,
i.startup_time start_time,
sysdate today,
trunc(sysdate - i.startup_time) days_running
from gv$instance c,
gv$license l,
v$instance i
where c.instance_number = i.instance_number (+)
and c.thread# = i.thread# (+)
and l.inst_id = c.inst_id;
PROMPT
PROMPT =============================================================================================================
set feed on
set lines 150
SET SERVEROUTPUT ON
set echo off
DECLARE
csid1 gv$session.sid%type;
cusr1 gv$session.username%type;
cmac1 gv$session.machine%type;
cprg1 gv$session.program%type;
csid2 gv$session.sid%type;
cusr2 gv$session.username%type;
cmac2 gv$session.machine%type;
cprg2 gv$session.program%type;
contador number;
c2sid gv$session.sid%type;
c2serial gv$session.serial#%type;
c2username gv$session.username%type;
c2osuser gv$session.osuser%type;
c2machine gv$session.machine%type;
c2program gv$session.program%type;
c2instance gv$instance.instance_name%type;
c2host gv$instance.host_name%type;
c2spid gv$process.spid%type;
c2hash gv$session.sql_hash_value%type;
c2status gv$session.status%type;
c2logon gv$session.logon_time%type;
c3child v$sql.child_number%type;
c3text v$sqltext.sql_text%type;
CURSOR c1
IS
select /*+ rule */ s1.sid ,s1.username,s1.machine, s1.program, s2.sid,s2.username,s2.machine, s2.program
from gv$lock l1, gv$session s1, gv$lock l2, gv$session s2
where s1.sid=l1.sid
and s2.sid=l2.sid
and l1.BLOCK=1
and l2.request > 0
and l1.id1 = l2.id1
and l2.id2 = l2.id2;
CURSOR c2
IS
select s.sid, s.serial#, s.username, s.osuser, s.machine, s.program, i.instance_name, i.host_name, p.spid, s.sql_hash_value, s.status,s.logon_time
from gv$session s, gv$process p, gv$instance i
where s.sid = csid1
and s.paddr = p.addr
and p.inst_id = i.inst_id;
CURSOR c3
IS
select s.child_number, t.sql_text
from v$sqltext t, v$sql s
where s.hash_value = c2hash
and s.address = t.address
and s.hash_value = t.hash_value
order by s.child_number, t.piece;
BEGIN
open c1;
contador := 0;
LOOP
fetch c1 into csid1,cusr1,cmac1,cprg1,csid2,cusr2,cmac2,cprg2;
if c1%found then
contador := contador + 1;
DBMS_OUTPUT.PUT_LINE('A SESSAO SID='||csid1||' USER='||cusr1||'@'||substr(cprg1,1,7)||'@'||cmac1||' esta bloqueando o SID='||csid2||' USER='||cusr2||'@'||substr(cprg2,1,7)||'@'||cmac2);
end if;
if contador = 0 then
DBMS_OUTPUT.PUT_LINE('NAO HA SESSOES EM LOCK!!!');
end if;
EXIT WHEN c1%NOTFOUND;
END LOOP;
if contador <> 0 then
open c2;
open c3;
fetch c2 into c2sid, c2serial, c2username, c2osuser, c2machine, c2program, c2instance, c2host, c2spid, c2hash, c2status, c2logon;
fetch c3 into c3child, c3text ;
DBMS_OUTPUT.PUT_LINE ('=============================================================================================================');
dbms_output.put_line('Sid..............: ' || c2sid);
dbms_output.put_line('Serial#..........: ' || c2serial);
dbms_output.put_line('Status...........: ' || c2status);
dbms_output.put_line('Username.........: ' || c2username);
dbms_output.put_line('Maquina..........: ' || c2machine);
dbms_output.put_line('Programa.........: ' || c2program);
dbms_output.put_line('OS User..........: ' || c2osuser);
dbms_output.put_line('Host.............: ' || c2host);
dbms_output.put_line('Instance.........: ' || c2instance);
dbms_output.put_line('SQL Hash Value...: ' || c2hash);
dbms_output.put_line('PID..............: ' || c2spid);
dbms_output.put_line('Logon Time ......: ' || c2logon);
dbms_output.put_line('Child Number.....: ' || c3child);
dbms_output.put_line('Query ...........: ' || c3text);
DBMS_OUTPUT.PUT_LINE ('=======================================================');
DBMS_OUTPUT.PUT_LINE ('=DIRECIONAR O CHAMADO AO CLIENTE COM ESTAS INFORMACOES=');
DBMS_OUTPUT.PUT_LINE ('=======================================================');
close c2;
close c3;
end if;
close c1;
END;
/
set pages 200
spool c:\TEMP\tuning.lst
-- Este programa apresenta a situacao de uma terminada instance dentro dos requerimentos
-- que a Oracle Corporation exige para considerar uma base de dados equilibrada(afinada)
prompt " Database Block Buffers Hit Ratio "
prompt O Resultado deve ser maior que 95%
select (1 - (sum(decode(name, 'physical reads', value, 0)) /
(sum(decode(name, 'db block gets', value, 0)) +
sum(decode(name, 'consistent gets', value, 0)))))
* 100 "Hit Ratio"
from v$sysstat
/
prompt " Apresenta a quantidade de memoria disponivel em um determinado momento "
prompt Se a disponibilidade=0, uma solucao seria aumentar o parametro DB_BLOCK_BUFFERS
col name format a50
col value format a20
select name,value from v$parameter where name='db_block_buffers'
/
prompt " Dictionary Cache Hit Ratio "
prompt O Resultado deve ser maior que 95%
select ((1 - (sum(getmisses) / (sum(gets) + sum(getmisses)))) * 100) "Hit Ratio"
from v$rowcache
where ((gets + getmisses) <> 0)
/
prompt " Verifica se o Database Buffers(DB BLOCK BUFFER) tem tamanho suficiente "
prompt Deve ser acima de 95%
column phys format 99,999,999,999 heading 'Physical Reads'
column gets format 99,999,999,999 heading 'DB Block Gets'
column con_gets format 99,999,999,999 heading 'Consistent Gets'
column hitratio format 9,999.999 heading 'Hit Ratio'
select sum(decode(name,'physical reads',value,0)) "phys",
sum(decode(name,'db block gets',value,0)) "gets",
sum(decode(name,'consistent gets',value,0)) "con_gets",
100 * (1 - sum(decode(name,'physical reads',value,0)) /
(sum(decode(name,'db block gets',value,0)) +
sum(decode(name,'consistent gets',value,0)))) "hitratio"
from v$sysstat
/
prompt " This query looks at the row cache in detail and places an * by those values
prompt that have miss ratio greater than 10% "
column parameter format a20 heading 'Data Dictionary Area'
column gets format 99,999,999,999 heading 'Total|Requests'
column getmisses format 99,999,999,999 heading 'Misses'
column modifications format 99,999,999 heading 'DMLs|(I,U,D)'
column flushes format 99,999,999 heading 'Flushes|Disk'
column getmiss_ratio format 9,999.99 heading 'Miss|Ratio'
prompt "Shared Pool Row Cache Usage"
select parameter, gets, getmisses, modifications, flushes,
(getmisses / decode(gets,0,1,gets)) getmiss_ratio,
decode(trunc((getmisses / decode(gets,0,1,gets)),1),.0,' ','*') " "
from v$rowcache
where ( gets + getmisses ) <> 0
order by gets desc
/
prompt " Detecting file I/O balacing problems "
col PHYRDS format 9,999,999,999
col PHYWRTS format 9,999,999,999
prompt "Disk Balancing Report"
col READTIM format 9,999,999,999
col WRITETIM format 9,999,999,999
col name format a50
select name, phyrds, phywrts, readtim, writetim
from v$filestat a, v$dbfile b
where a.file# = b.file#
order by readtim desc
/
prompt -- Shared Pool Detail Break Down
prompt --------------------------------------------------------------------------*
prompt R-free This is SHARED_POOL_RESERVED_SIZE (Default 5% of SP)
prompt R-freea This is probably reserved memory that has been used but free-able
prompt free This is the amount of contiguous free memory available
prompt freeabl This is probably memory that has been used but is freeable
prompt perm This is free memory not yet moved to the free area for use
prompt recr I am not sure what this is. Possibly reserved memory for Oracle
prompt --------------------------------------------------------------------------*
prompt " How much memory is left for SHARED_POOL"
col value for 9,999,999,999,999 heading "Shared Pool Size"
col bytes for 9,999,999,999,999 heading "Free Bytes"
select to_number(v$parameter.value) value, v$sgastat.bytes,
(v$sgastat.bytes/v$parameter.value) * 100 "Percent Free"
from v$sgastat, v$parameter
where v$sgastat.name = 'free memory'
and v$parameter.name = 'shared_pool_size'
/
prompt " This Query identifies the use of Individual Library Cache Parameters to
prompt diagnose Shared Pool use "
prompt Pin Hit Ratio must be close to one(1)
prompt Misses can be reduced by writing identical SQL statements.
set pages 24
prompt "Shared Pool Library Cache Usage"
column namespace format a20 heading 'Entity'
column pins format 99,999,999,999 heading 'Executions'
column pinhits format 99,999,999,999 heading 'Hits'
column pinhitratio format 999.99 heading 'PinHit|Ratio'
column reloads format 99,999,999 heading 'Reloads'
column reloadratio format 9.9999 heading 'Reload|Ratio'
select namespace, pins, pinhits, pinhitratio, reloads,
(reloads / decode(pins,0,1,pins)) reloadratio
from v$librarycache
/
prompt " Shared Pool Library Cache Hit Ratio "
prompt O Resultado deve ser maior que 95%
select sum(pins) "Hits",
sum(reloads) "Misses",
(sum(pins) / (sum(pins) + sum(reloads)) * 100) "Hit Ratio %"
from v$librarycache
/
prompt " If the Reload Ratio is not zero, then there are statements that are being
prompt "aged out" that are later needed and brought back into memory. If the Reload
prompt Ratio is above 1%, you should probably increase the SHARED_POOL_SIZE
select sum(pins) "Hits",
sum(Reloads) "Misses",
((sum(reloads) / sum(pins)) * 100) "Reloads %"
from v$librarycache
/
prompt " Query to know if there is contention of LOG BUFFER "
prompt if Space Request Ratio > 0,02% - Increase the LOG BUFFER
select a.value "Redo Log Space Requests", b.value "Redo Entries",
decode(a.value,0,1,a.value)*100/b.value "Space Request Ratio"
from v$sysstat a, v$sysstat b
where a.name = 'redo log space requests'
and b.name = 'redo entries'
/
prompt " Query to get memory and disk sorts "
select a.value "Disk Sorts", b.value "Memory Sorts",
round((100 * b.value) / decode((a.value + b.value),0,1,
(a.value + b.value)),2) "Pct Memory Sorts"
from v$sysstat a, v$sysstat b
where a.name = 'sorts (disk)'
and b.name = 'sorts (memory)'
/
prompt " Verifica contencao de Rollbacks "
prompt Se XACTS for regularmente maior que 1, aumentar numero de Rollbacks.
prompt Se WAITS for maior que 0, aumentar numero de Rollbacks
prompt Se possivel tentar deixar o numero de user per rollback = 1
select substr(a.name,1,10), b.extents, b.rssize, b.xacts,
b.waits, b.gets, optsize, status
from v$rollname a, v$rollstat b
where a.usn = b.usn
/
prompt " Apresenta a utilizacao dos Rollbacks "
select substr(segment_name,1,10) "Rollback",
substr(tablespace_name,1,10) "Tablespace",
bytes/1024/1024 "Usados MB",
blocks "Blocos",
extents "Extents"
from dba_segments
where segment_type = 'ROLLBACK'
/
spool off
-- Enable Managed recovery mode at STANDBY side and check archive logs.
-- STANDBY:
ALTER DATABASE RECOVER MANAGED STANDBY DATABASE DISCONNECT;
ALTER DATABASE RECOVER MANAGED STANDBY DATABASE DISCONNECT FROM SESSION;
ALTER DATABASE RECOVER MANAGED STANDBY DATABASE CANCEL;
-- CHECK ROLE:
-- PRIMARY:
SELECT name,database_role,controlfile_type,open_mode FROM V$DATABASE;
NAME DATABASE_ROLE CONTROLFILE_TYPE OPEN_MODE
--------------------- ------------------ -------------------- ----------
ORCL PRIMARY CURRENT READ WRITE
-- STANDBY:
SELECT name,database_role,controlfile_type,open_mode FROM V$DATABASE;
NAME DATABASE_ROLE CONTROLFILE_TYPE OPEN_MODE
--------------------- ------------------ -------------------- ----------
ORCL PHYSICAL STANDBY STANDBY MOUNTED
-- Check max archive log sequence
-- PRIMARY:
SELECT max(sequence#) FROM V$thread;
MAX(SEQUENCE#)
--------------
93
-- STANDBY:
SELECT max(sequence#) FROM V$thread;
MAX(SEQUENCE#)
--------------
93
-- Switch logfile in PRIMARY database :
ALTER SYSTEM SWITCH LOGFILE;
-- Check sequence from STANDBY database :
SELECT max(sequence#) FROM V$thread;
MAX(SEQUENCE#)
--------------
94
-- Check archive log files
-- PRIMARY:
ARCHIVE LOG LIST
Database log mode Archive Mode
Automatic archival Enabled
Archive destination /u01/oradata/production/arch
Oldest online log sequence 251
Next log sequence to archive 252
Current log sequence 252
-- PRIMARY:
SELECT sequence#, first_time, next_time, applied FROM V$archived_log ORDER BY next_time;
SEQUENCE# FIRST_TIME NEXT_TIME APPLIED
____________ _____________ ____________ __________
01 06-SEP-23 06-SEP-23 NO
02 06-SEP-23 08-SEP-23 NO
03 08-SEP-23 09-SEP-23 NO
04 09-SEP-23 10-SEP-23 NO
05 10-SEP-23 11-SEP-23 NO
06 11-SEP-23 11-SEP-23 NO
07 11-SEP-23 11-SEP-23 NO
08 11-SEP-23 11-SEP-23 NO
09 11-SEP-23 11-SEP-23 NO
10 11-SEP-23 11-SEP-23 NO
11 11-SEP-23 11-SEP-23 NO
-- STANDBY:
SELECT sequence#, first_time, next_time, applied FROM V$archived_log WHERE applied='YES' ORDER BY next_time;
SEQUENCE# FIRST_TIME NEXT_TIME APPLIED
____________ ______________________ ______________________ __________
8 2023-09-11 15:39:46 2023-09-11 17:17:30 YES
9 2023-09-11 17:17:30 2023-09-11 18:54:40 YES
-- STANDBY:
SELECT name,applied FROM V$archived_log;
NAME APPLIED
---------------------------------------- ---------
/u01/oradata/production/arch/1_250_976404635.dbf YES
/u01/oradata/production/arch/1_249_976404635.dbf YES
/u01/oradata/production/arch/1_251_976404635.dbf YES
-- PRIMARY: verifica ultimo archive destinado ao STANDBY e que foi aplicado
SELECT thread#, max(completion_time), max(sequence#)
FROM v$archived_log
WHERE STANDBY_dest = 'YES' AND applied = 'YES'
GROUP BY thread#;
-- STANDBY:
SELECT thread#,max(sequence#) FROM V$archived_log WHERE applied='YES' GROUP BY thread#;
THREAD# MAX(SEQUENCE#)
---------- --------------
1 9
-- STANDBY:
SELECT registrar, creator, thread#, sequence#, first_change#, next_change# FROM V$archived_log;
REGISTRAR CREATOR THREAD# SEQUENCE# FIRST_CHANGE# NEXT_CHANGE#
____________ __________ __________ ____________ ________________ ________________
RFS ARCH 1 8 1977707952752 1977707977407
RFS LGWR 1 9 1977707977407 1977707996615
-- Check the current log sequence on the PRIMARY database:
-- STANDBY:
SELECT thread#, max(sequence#) "Last PRIMARY Seq Generated" FROM v$archived_log val, v$database vdb WHERE val.resetlogs_change# = vdb.resetlogs_change# GROUP BY thread# ORDER BY 1;
THREAD# Last PRIMARY Seq Generated
__________ _____________________________
1 11
OR
ARCHIVE LOG LIST;
--PRIMARY | STANDBY:
SELECT dest_id,error FROM V$ARCHIVE_DEST;
-- VERIFICAR: Atraso, Transporte, Aplicacao, Tempo estimado em caso de transicao para PRIMARY
-- STANDBY:
SELECT * FROM V$DATAGUARD_STATS;
SELECT name, value, datum_time, time_computed FROM V$DATAGUARD_STATS WHERE name like '%lag';
NAME VALUE DATUM_TIME TIME_COMPUTED
________________ _______________ ______________________ ______________________
transport lag +00 00:00:00 09/12/2023 17:06:53 09/12/2023 17:07:01
apply lag +00 00:00:00 09/12/2023 17:06:53 09/12/2023 17:07:01
-- PRIMARY | STANDBY: Detalhes das operacoes de transporte e aplicacao de redo
SELECT * FROM v$dataguard_status order by timestamp desc;
-- STANDBY:Convert physical STANDBY into active STANDBY database:
-- STANDBY:
ALTER DATABASE RECOVER MANAGED STANDBY DATABASE CANCEL;
ALTER DATABASE OPEN;
SELECT name,database_role,controlfile_type,open_mode FROM V$DATABASE.
NAME DATABASE_ROLE CONTROLFILE_TYPE OPEN_MODE
-------------- ----------------- ----------------- -------------------------------
ORCL PHYSICAL STANDBY STANDBY READ ONLY WITH APPLY
-- TO VERIFY RECOVER PROCESS ON STANDBY:
-- PRIMARY
SELECT thread#, sequence# FROM V$LOG WHERE status='CURRENT';
THREAD# SEQUENCE#
__________ ____________
1 12
-- STANDBY
SELECT PROCESS, STATUS, THREAD#, SEQUENCE#, BLOCK#, BLOCKS FROM V$MANAGED_STANDBY ;
SELECT thread#, sequence#, status FROM V$MANAGED_STANDBY WHERE process='MRP0';
THREAD# SEQUENCE# STATUS
__________ ____________ _______________
1 12 APPLYING_LOG
-- Check applied log on STANDBY
-- STANDBY
SELECT thread#, max(sequence#) "Last STANDBY Seq Applied"
FROM v$archived_log val, v$database vdb
WHERE val.resetlogs_change# = vdb.resetlogs_change# AND val.applied IN ('YES','IN-MEMORY')
GROUP BY thread# ORDER BY 1;
THREAD# Last STANDBY Seq Applied
__________ ___________________________
1 9
-- Identify the missing archive log file - archive gap
-- PRIMARY | STANDBY
SELECT * FROM v$archive_gap;
SELECT THREAD#, LOW_SEQUENCE#, HIGH_SEQUENCE# FROM V$ARCHIVE_GAP;
-- Check redo RECEIVED AND APPLIED ON STANDBY.
-- STANDBY
SELECT ARCH.THREAD# "Thread",
ARCH.SEQUENCE# "Last Sequence Received",
APPL.SEQUENCE# "Last Sequence Applied",
(ARCH.SEQUENCE# - APPL.SEQUENCE#) "Difference"
FROM
(SELECT THREAD# ,SEQUENCE# FROM V$ARCHIVED_LOG WHERE (THREAD#,FIRST_TIME ) IN (SELECT THREAD#,MAX(FIRST_TIME) FROM V$ARCHIVED_LOG GROUP BY THREAD#)) ARCH,
(SELECT THREAD# ,SEQUENCE# FROM V$LOG_HISTORY WHERE (THREAD#,FIRST_TIME ) IN (SELECT THREAD#,MAX(FIRST_TIME) FROM V$LOG_HISTORY GROUP BY THREAD#)) APPL
WHERE ARCH.THREAD# = APPL.THREAD# ORDER BY 1;
Thread Last Sequence Received Last Sequence Applied Difference
_________ _________________________ ________________________ _____________
1 9 11 -2
-- PRIMARY
SELECT THREAD# "Thread",SEQUENCE# "Last Sequence Generated"
FROM V$ARCHIVED_LOG
WHERE (THREAD#,FIRST_TIME ) IN (SELECT THREAD#,MAX(FIRST_TIME) FROM V$ARCHIVED_LOG GROUP BY THREAD#)
ORDER BY 1;
Thread Last Sequence Generated
_________ __________________________
1 11
-- PRIMARY
SELECT distinct SEQUENCE# "Last Sequence Generated", THREAD# "Thread"
FROM V$ARCHIVED_LOG
WHERE (THREAD#,FIRST_TIME ) IN (SELECT THREAD#,MAX(FIRST_TIME) FROM V$ARCHIVED_LOG GROUP BY THREAD#)
ORDER BY 1;
-- PRIMARY
SELECT thread#, max(sequence#) "Last PRIMARY Seq Generated"
FROM v$archived_log val, v$database vdb
WHERE val.resetlogs_change# = vdb.resetlogs_change#
GROUP BY thread# ORDER BY 1;
-- STANDBY
SELECT thread#, max(sequence#) "Last STANDBY Seq Applied"
FROM v$archived_log val, v$database vdb
WHERE val.resetlogs_change# = vdb.resetlogs_change#
AND val.applied IN ('YES','IN-MEMORY')
GROUP BY thread# ORDER BY 1;
THREAD# Last STANDBY Seq Applied
__________ ___________________________
1 9
-- PRIMARY: Ultimo sequence# aplicado para cada thread
SELECT max(sequence#) as last_sequence, thread#
FROM v$archived_log
WHERE resetlogs_change# = (SELECT max(resetlogs_change#) FROM v$archived_log)
GROUP BY thread#;
-- PRIMARY: Verifica se algum archived log esta faltando em um destino especifico (Assumindo que local archive esta em dest_id=1 e STANDBY esta em dest_id=2)
SELECT thread#, sequence#
FROM v$archived_log prim
WHERE
resetlogs_change# = (SELECT resetlogs_change# FROM v$database)
AND dest_id = 1
AND sequence# not IN (SELECT sequence# FROM v$archived_log WHERE dest_id = 2 AND thread# = prim.thread# AND resetlogs_change# = prim.resetlogs_change#)
AND sequence# >= (SELECT max(sequence#) FROM v$archived_log WHERE dest_id = 2 AND thread# = prim.thread# AND resetlogs_change# = prim.resetlogs_change#);
-- PRIMARY: verifica se archives destinados ao STANDBY ja foram aplicados
SELECT thread#, sequence#, completion_time, STANDBY_dest, archived, applied
FROM v$archived_log WHERE STANDBY_dest = 'YES'
ORDER BY completion_time desc;
-- STANDBY
SELECT LOG_ARCHIVED-LOG_APPLIED "LOG_GAP"
FROM (SELECT MAX(SEQUENCE#) LOG_ARCHIVED FROM V$ARCHIVED_LOG WHERE DEST_ID=1 AND ARCHIVED='YES'),(SELECT MAX(SEQUENCE#) LOG_APPLIED FROM V$ARCHIVED_LOG WHERE DEST_ID=2 AND APPLIED='YES');
-- Check received log on STANDBY
-- STANDBY
SELECT thread#, max(sequence#) "Last STANDBY Seq Received" FROM v$archived_log val, v$database vdb WHERE val.resetlogs_change# = vdb.resetlogs_change# GROUP BY thread# ORDER BY 1;
THREAD# Last STANDBY Seq Received
__________ ____________________________
1 9
-- Check for GAP on STANDBY
-- STANDBY
SELECT THREAD# "Thread",SEQUENCE# "Last Sequence Generated"
FROM V$ARCHIVED_LOG
WHERE (THREAD#,FIRST_TIME ) IN (SELECT THREAD#,MAX(FIRST_TIME) FROM V$ARCHIVED_LOG GROUP BY THREAD#)
ORDER BY 1;
Thread Last Sequence Generated
_________ __________________________
1 9
-- Copy missing archive log file
-- PRIMARY
SELECT name FROM v$archived_log WHERE thread# = 1 AND dest_id = 1 AND sequence# BETWEEN XXX AND YYY;
NAME
_______________________________________
/oraarch/ORCL_1_1_1146845631.arc
-- Register archive logfile with STANDBY.
-- STANDBY
ALTER DATABASE REGISTER LOGFILE ‘/oraarch/ORCL_1_1_1146845631.arc’;
-- Restart the managed recovery operations.
-- STANDBY
ALTER DATABASE RECOVER MANAGED STANDBY DATABASE DISCONNECT FROM SESSION;
-- Displays runtime and configuration information for the archived redo log destinations.
-- PRIMARY | STANDBY
SELECT archived_thread#, archived_seq#, applied_thread#, applied_seq# FROM V$archive_dest_status;
-- PRIMARY: verifica e estado do transporte para o STANDBY
SELECT d.dest_id,d.dest_name,d.status,d.transmit_mode,d.affirm,d.reopen_secs,d.delay_mins,d.net_timeout,s.type,s.recovery_mode,s.synchronized,s.protection_mode,s.synchronization_status
FROM v$archive_dest d
inner join v$archive_dest_status s on d.dest_id = s.dest_id
WHERE d.dest_name = 'LOG_ARCHIVE_DEST_2';
-- PRIMARY: Sequence# de archive mais recente em cada destino (Sequence# deve ser o mesmo em todos os destinos, caso contrario um deles possivelmente estara com algum erro)
SELECT destination, status, archived_thread#, archived_seq#
FROM v$archive_dest_status
WHERE status <> 'DEFERRED' AND status <> 'INACTIVE';
-- PRIMARY | STANDBY: configuracoes e Status
SELECT * FROM v$dataguard_config;
-- PRIMARY
SELECT current_scn FROM v$database;
CURRENT_SCN
________________
1977708627918
-- STANDBY
SELECT current_scn FROM v$database;
CURRENT_SCN
________________
1977708627919
-- Displays messages recently written to the alert log
-- STANDBY
SELECT message,timestamp FROM V$DATAGUARD_STATUS WHERE timestamp > sysdate - 1/6;
SELECT message FROM V$DATAGUARD_STATUS WHERE dest_id = 2;
MESSAGE TIMESTAMP
------------------------------------------------------------------------------------------
RFS[48]: No STANDBY redo logfiles created 05-AUG-15
Media Recovery Log /uv1010/arch/MRSX/arch_MRSX_779539386_1_49482.log 05-AUG-15
Media Recovery Waiting for thread 1 sequence 49483 (in transit) 05-AUG-15
-- =======================================================================
-- Find LAG in DATA GUARD with ORACLE RAC :
-- =======================================================================
set echo on feed on term on
set linesize 120
col PRIMARY_TIME format a20
col STANDBY_COMPLETION_TIME format a23
SELECT
prim.thread# thread,
prim.seq PRIMARY_seq,
to_char(prim.tm, 'DD-MON-YYYY HH24:MI:SS') PRIMARY_time,
tgt.thread# STANDBY_thread,
tgt.seq STANDBY_seq,
to_char(tgt.tm, 'DD-MON-YYYY HH24:MI:SS') STANDBY_completion_time,
prim.seq - tgt.seq seq_gap,
( prim.tm - tgt.tm ) * 24 * 60 lag_minutes
FROM
(SELECT thread#, MAX(sequence#) seq, MAX(completion_time) tm FROM v$archived_log GROUP BY thread# ) prim,
(SELECT thread#, MAX(sequence#) seq, MAX(completion_time) tm FROM v$archived_log WHERE dest_id IN (SELECT dest_id FROM v$archive_dest WHERE target = 'STANDBY' )
AND applied = 'YES' GROUP BY thread# ) tgt
WHERE prim.thread# = tgt.thread#;
--=================================
--### DATA GUARD - CHECKLIST E LAG
--=================================
--SCRIPT IDENTIFICACAO
set lines 400 pages 500
alter session set NLS_DATE_FORMAT = 'DD/MM/YYYY HH24:MI:SS';
prompt ### INDENTIFICA (primary ou phisical standby)
SELECT DBID,NAME,DB_UNIQUE_NAME,DATABASE_ROLE FROM gv$DATABASE
/
prompt ### STATUS DATA GUARD (open ou mounted)
col HOST_NAME for a55
col ACTIVE_STATE for a17
SELECT INSTANCE_NAME, HOST_NAME, STATUS, DATABASE_STATUS, ACTIVE_STATE FROM gv$INSTANCE
/
--SCRIPT LAG VALUE (conectado no Physical Standby)
col NAME for a18
col value for a18
SELECT name, value, datum_time, time_computed FROM V$DATAGUARD_STATS WHERE name like 'apply lag' or name like 'transport lag';
set lines 200 pages 50
col name format a30
col value format a18
col unit format a35
col time_computed format a22
SELECT
NAME
, VALUE
, UNIT
, DATUM_TIME
, TIME_COMPUTED
FROM v$dataguard_stats
ORDER BY time_computed;
--SCRIPT ARCHIVE APLICADO - atividade nos blocks (conectado no Physical Standby)
--MRP0 este processo e responsavel por mostra onde esta o gap - aplicando
SELECT PROCESS, SEQUENCE#, THREAD#, BLOCK#, BLOCKS, TO_CHAR(SYSDATE, 'DD-MON-YYYY HH:MI:SS') TIME
FROM gv$MANAGED_STANDBY WHERE PROCESS='MRP0';
--SCRIPT GAP (conectado no PRIMARY ou Physical Standby)
SELECT al.thread# "THREAD",
almax "ULTIMA SEQ RECEBIDA",
lhmax "ULTIMA SEQ APLICADA",
(almax - lhmax) "GAP"
FROM (SELECT thread#, Max(sequence#) almax
FROM v$archived_log
WHERE resetlogs_change# = (SELECT resetlogs_change# FROM v$database)
GROUP BY thread#) al,
(SELECT thread# thrd, Max(sequence#) lhmax
FROM v$log_history
WHERE resetlogs_change# = (SELECT resetlogs_change# FROM v$database)
GROUP BY thread#) lh
WHERE al.thread# = lh.thrd;
--ERROS DE COMUNICACAO ENTRE PRIMARIO E STANDBY - ARCHIVES SENDO ENVIADOS OU RECEBIDOS e ARCHIVES APLICADOS
--Quando executado no PRIMARIO, ele mostra o archive que foi GERADO, e a transferencia para o standby
--Quando executado no STANDBY, ele mostra o archive sendo RECEBIDO, aplicado no banco de dados, e possivel falha de comunicação com o primario.
--Ele tambem mostra se existe erro de comunicação
col MESSAGE for a100
col TIMESTAMP for a20
SELECT message, TO_CHAR(TIMESTAMP, 'DD-MM-RRRR HH24:MI:SS') "TIMESTAMP" FROM v$DATAGUARD_STATUS;
--DATA GUARD - seq gerada (conectado no primary)
SQL>
SELECT thread#, Max(sequence#) "ULT_SEQ_GERADA_PRIMARY"
FROM v$ARCHIVED_LOG alog, v$DATABASE db
WHERE alog.resetlogs_change# = db.resetlogs_change#
GROUP BY thread#
ORDER BY 1;
--DATA GUARD - seq recebida (conectado no Physical Standby)
SELECT thread#, Max(sequence#) "ULT_SEQ_RECEBIDA_STANDBY"
FROM v$ARCHIVED_LOG alog, v$DATABASE db
WHERE alog.resetlogs_change# = db.resetlogs_change#
GROUP BY thread#
ORDER BY 1;
--DATA GUARD - seq aplicada (conectado no Physical Standby)
SELECT thread#, Max(sequence#) "ULT_SEQ_APLICADA_STANDBY"
FROM v$ARCHIVED_LOG alog, v$DATABASE db
WHERE alog.resetlogs_change# = db.resetlogs_change#
AND alog.applied IN ( 'YES', 'IN-MEMORY' )
GROUP BY thread#
ORDER BY 1;
--===============================
--### DATA GUARD - REPLICACAO STOP START
--===============================
--DATA GUARD - PARAR REPLICACAO (conectado no Physical Standby)
SQL> ALTER DATABASE RECOVER MANAGED STANDBY DATABASE CANCEL;
--DATA GUARD - INICIAR REPLICACAO COM PARALLEL (conectado no Physical Standby)
SQL> ALTER DATABASE RECOVER MANAGED STANDBY DATABASE PARALLEL 30 THROUGH ALL SWITCHOVER DISCONNECT USING CURRENT LOGFILE;
SQL>
--DATA GUARD - INICIA REPLICACAO CASO NAO RETORNE VALORES no SCRIPT ARCHIVE APLICADO (conectado no Physical Standby)
--verificar se dataguard esta recebendo os archives ou em modo de recovery
SQL> ALTER DATABASE RECOVER MANAGED STANDBY DATABASE USING CURRENT LOGFILE DISCONNECT FROM SESSION;
--COMANDO FORCA NOVA SEQUENCIA de LOG (conectado no primary)
SQL> ALTER SYSTEM SWITCH LOGFILE;
--========================================================
--### DATA GUARD - PROCEDIMENTO PARA TRANSPORTE DOS ARCHIVES DA ORIGEM PARA DESTINO
--========================================================
O tempo estimado neste momento para finalizar o apply dos redos está em cerca de 1 hora, desta forma não vale a pena criar um backup incremental para o transporte
Como o +ASM irá ficar no ar o tempo todo é possível que mesmo que o archive_dest_3 esteja em disable continuar copiando os archives e aplicando no destino.
Para este procedimento, seguir os passos abaixo, qualquer dúvida favor entrar em contato.
--### query 1 monitora o status se o archive a ser transportado ficar com status de "Wait for GAP"
--==============
por mais de 5 minutos executar a query 3 com os parâmetros (thread# e sequence# ela irá gerar o comando ASM para cópia do archive)
SELECT process, status, thread#, sequence#, block#, blocks, DELAY_MINS FROM v$managed_standby ORDER BY 3,4;
--### monitora o gap do transporte e do apply redo, nas colunas transport lag e apply finish time
--==============
col name format a30
col value format a18
col unit format a35
col time_computed format a22
SELECT
NAME
, VALUE
, UNIT
, DATUM_TIME
, TIME_COMPUTED
FROM v$dataguard_stats
ORDER BY time_computed;
NAME VALUE UNIT DATUM_TIME TIME_COMPUTED
------------------------------ ------------------ ----------------------------------- ------------------------------ ----------------------
transport lag +00 00:00:00 day(2) to second(0) interval 05/28/2016 22:28:23 05/28/2016 23:21:44
estimated startup time 19 second 05/28/2016 23:21:44
apply finish time +00 00:55:42.542 day(2) to second(3) interval 05/28/2016 23:21:44
apply lag +00 20:41:57 day(2) to second(0) interval 05/28/2016 22:28:23 05/28/2016 23:21:44
--### gera um comando de SO que copia os archives faltantes
--==============
Executar o comando abaixo como o usuário grid, com as variáveis exportadas para o GRID, no RDBMS de origem ele irá copiar o archive diretamente para dentro do ASM de destino.
set lines 256
col comando format a256
SELECT 'asmcmd -p cp --port 1530 ' || name || ' sys/welcome1@"10.116.68.36".+ASM1:' || replace(substr(name,1,INSTR(name,'.',-1,1)-1),'siebelp2','siebels2') as comando FROM v$archived_log WHERE sequence# in (&seq) and thread# = &thread and dest_id =1;
--### A query 4 Registra os archives copiados após a cópia ser finalizada
--==============
registra os archives no banco de destino como o usuário oracle e exportado para o RDBMS requisitado.
Os archives que faltam ou aparecem como wait for gap na query 1 ou no alert log do RDBMS d edestino.
set lines 256
col comando format a256
SELECT 'alter database register logfile ' || CHR(39) || replace(substr(name,1,INSTR(name,'.',-1,1)-1),'siebelp2','siebels2') || CHR(39) || ';' as comando FROM v$archived_log WHERE sequence# in (&seq) and thread# = &thread and dest_id =1;
-- NAME: new_dg_psby_diag.sql
--
-- Copyright 2002, Oracle Corporation
--
-- LAST UPDATED: 02-Sep-2015
--
-- Usage: @new_dg_psby_diag
--
-- (Run from sqlplus on PHYSICAL STANDBY, ACTIVE STANDBY as SYS)
--
-- PURPOSE:
--
-- This script is to be used to assist in the collection of information to help
-- troubleshoot Data Guard issues involving a Physical or Active Standby.
--
-- DISCLAIMER:
--
-- This script is provided for educational purposes only. It is NOT
-- supported by Oracle World Wide Technical Support.
-- The script has been tested and appears to work as intended.
-- You should always run new scripts on a test instance initially.
--
--
-- Script output is as follows:
set echo off
set feedback off
column timecol new_value timestamp
column spool_extension new_value suffix
SELECT TO_CHAR(sysdate,'yyyymmdd_hh24mi') timecol, '.html' spool_extension FROM dual;
column output new_value dbname
SELECT value || '_' output FROM v$parameter WHERE name = 'db_unique_name';
spool new_dg_psby_diag_&&dbname&×tamp&&suffix
set linesize 2000
set pagesize 50000
set numformat 999999999999999
set trim on
set trims on
set markup html on
set markup html entmap off
set feedback on
ALTER SESSION SET nls_date_format = 'DD-MON-YYYY HH24:MI:SS';
SELECT TO_CHAR(sysdate) time FROM dual;
set echo on
-- The following select will give us the generic information about how this standby is setup.
-- The DATABASE_ROLE should be STANDBY as that is what this script is intended to be run on.
-- PLATFORM_ID should match the PLATFORM_ID of the primary or conform to the supported options in
-- Note: 413484.1 Data Guard Support for Heterogeneous Primary and Physical Standbys in Same Data Guard Configuration.
-- FLASHBACK can be YES (recommended) or NO.
-- If PROTECTION_LEVEL is different from PROTECTION_MODE then for some reason the mode listed in PROTECTION_MODE experienced a need to downgrade.
-- Once the error condition has been corrected the PROTECTION_LEVEL should match the PROTECTION_MODE after the next log switch.
SELECT database_role role, name,dbid, db_unique_name, platform_id, open_mode, log_mode, flashback_on, protection_mode, protection_level FROM v$database;
-- FORCE_LOGGING is not mandatory but is recommended.
-- REMOTE_ARCHIVE should be ENABLE.
-- SUPPLEMENTAL_LOG_DATA_PK and SUPPLEMENTAL_LOG_DATA_UI must be enabled if this standby is associated with a primary that has a logical standby.
-- During normal operations it is acceptable for SWITCHOVER_STATUS to be NOT ALLOWED.
-- DATAGUARD_BROKER can be ENABLED (recommended) or DISABLED.
column force_logging format a13 tru
column supplemental_log_data_pk format a24 tru
column supplemental_log_data_ui format a24 tru
SELECT force_logging, remote_archive, supplemental_log_data_pk, supplemental_log_data_ui, switchover_status, dataguard_broker FROM v$database;
-- Check how many threads are enabled and started for this database. If the number of instances below does not match then not all instances are up.
SELECT thread#, instance, status FROM v$thread;
-- The number of instances returned below is the number currently running. If it does not match the number returned in Threads above then not all instances are up.
-- VERSION should match the version from the primary database.
-- ARCHIVER can be (STOPPED | STARTED | FAILED). FAILED means that the archiver failed to archive a log last time, but will try again within 5 minutes.
-- LOG_SWITCH_WAIT the ARCHIVE LOG/CLEAR LOG/CHECKPOINT event log switching is waiting for.
-- Note that if ALTER SYSTEM SWITCH LOGFILE is hung, but there is room in the current online redo log, then the value is NULL.
column host_name format a32 wrap
SELECT thread#, instance_name, host_name, version, archiver, log_switch_wait FROM gv$instance ORDER BY thread#;
-- Check the number and size of online redo logs on each thread.
SELECT thread#, group#, sequence#, bytes, archived ,status FROM v$log ORDER BY thread#, group#;
-- The following query is run to see if standby redo logs have been created.
-- The standby redo logs should be the same size as the online redo logs.
-- There should be (( # of online logs per thread + 1) * # of threads) standby redo logs.
-- A value of 0 for the thread# means the log has never been allocated.
SELECT thread#, group#, sequence#, bytes, archived, status FROM v$standby_log order by thread#, group#;
-- This query produces a list of defined archive destinations.
-- It shows if they are enabled, what process is servicing that destination, if the destination is local or remote, and if remote what the current mount ID is.
-- For a physical standby we should have at least one remote destination that points the primary set.
column destination format a35 wrap
column process format a7
column ID format 99
column mid format 99
SELECT thread#, dest_id, destination, gvad.status, target, schedule, process, mountid mid FROM gv$archive_dest gvad, gv$instance gvi WHERE gvad.inst_id = gvi.inst_id AND destination is NOT NULL ORDER BY thread#, dest_id;
-- If the protection mode of the standby is set to anything higher than max performance then we need to make sure the remote destination that points to the primary is set with the correct options else we will have issues during switchover.
set numwidth 8
column archiver format a8
column ID format 99
column error format a55 wrap
SELECT thread#, dest_id, gvad.archiver, transmit_mode, affirm, async_blocks, net_timeout, delay_mins, reopen_secs reopen, register, binding FROM gv$archive_dest gvad, gv$instance gvi WHERE gvad.inst_id = gvi.inst_id AND destination is NOT NULL ORDER BY thread#, dest_id;
-- The following select will show any errors that occured the last time an attempt to archive to the destination was attempted.
-- If ERROR is blank and status is VALID then the archive completed correctly.
SELECT thread#, dest_id, gvad.status, error FROM gv$archive_dest gvad, gv$instance gvi WHERE gvad.inst_id = gvi.inst_id AND destination is NOT NULL ORDER BY thread#, dest_id;
-- The query below will determine if any error conditions have been reached by querying the v$dataguard_status view (view only available in 9.2.0 and above).
column message format a80
SELECT timestamp, gvi.thread#, message FROM gv$dataguard_status gvds, gv$instance gvi WHERE gvds.inst_id = gvi.inst_id AND severity in ('Error','Fatal') ORDER BY timestamp, thread#;
-- Query gv$managed_standby to see the status of processes involved in the shipping redo on this system.
-- Does not include processes needed to apply redo.
SELECT thread#, process, pid, status, client_process, client_pid, sequence#, block#, active_agents, known_agents FROM gv$managed_standby ORDER BY thread#, process;
-- Verify the last sequence# received and the last sequence# applied to standby database.
SELECT al.thrd "Thread", almax "Last Seq Received", lhmax "Last Seq Applied" FROM (select thread# thrd, MAX(sequence#) almax FROM v$archived_log WHERE resetlogs_change#=(SELECT resetlogs_change# FROM v$database) GROUP BY thread#) al, (SELECT thread# thrd, MAX(sequence#) lhmax FROM v$log_history WHERE resetlogs_change#=(SELECT resetlogs_change# FROM v$database) GROUP BY thread#) lh WHERE al.thrd = lh.thrd;
-- Check the transport lag and apply lag from the V$DATAGUARD_STATS view. This is only relevant when LGWR log transport and real time apply are in use.
SELECT * FROM v$dataguard_stats WHERE name LIKE '%lag%';
-- Check how often and how far the apply lags.
SELECT name, time, unit, count, TO_DATE(last_time_updated, 'MM/DD/YYYY HH24:MI:SS') FROM v$standby_event_histogram ORDER BY unit DESC, time;
-- The V$ARCHIVE_GAP fixed view on a physical standby database only returns the next gap that is currently blocking redo apply from continuing.
-- After resolving the identified gap and starting redo apply, query the V$ARCHIVE_GAP fixed view again on the physical standby database to determine the next gap sequence, if there is one.
SELECT * FROM v$archive_gap;
-- Non-default init parameters.
-- For a RAC DB Thread# = * means the value is the same for all threads (SID=*)
-- Threads with different values are shown with their individual thread# and values.
column num noprint
SELECT num, '*' "THREAD#", name, value FROM v$PARAMETER WHERE NUM IN (SELECT num FROM v$parameter WHERE (isdefault = 'FALSE' OR ismodified <> 'FALSE') AND name NOT LIKE 'nls%'
MINUS
SELECT num FROM gv$parameter gvp, gv$instance gvi WHERE num IN (SELECT DISTINCT gvpa.num FROM gv$parameter gvpa, gv$parameter gvpb WHERE gvpa.num = gvpb.num AND gvpa.value <> gvpb.value AND (gvpa.isdefault = 'FALSE' OR gvpa.ismodified <> 'FALSE') AND gvpa.name NOT LIKE 'nls%') AND gvi.inst_id = gvp.inst_id AND (gvp.isdefault = 'FALSE' OR gvp.ismodified <> 'FALSE') AND gvp.name NOT LIKE 'nls%')
UNION
SELECT num, TO_CHAR(thread#) "THREAD#", name, value FROM gv$parameter gvp, gv$instance gvi WHERE num IN (SELECT DISTINCT gvpa.num FROM gv$parameter gvpa, gv$parameter gvpb WHERE gvpa.num = gvpb.num AND gvpa.value <> gvpb.value AND (gvpa.isdefault = 'FALSE' OR gvpa.ismodified <> 'FALSE') AND gvp.name NOT LIKE 'nls%') AND gvi.inst_id = gvp.inst_id AND (gvp.isdefault = 'FALSE' OR gvp.ismodified <> 'FALSE') AND gvp.name NOT LIKE 'nls%' ORDER BY 1, 2;
spool off
set markup html off entmap on
set echo on
//CONCEDER PRIVILEGIOS:
SELECT TABLE_NAME FROM DBA_TABLES WHERE OWNER='SEI';
SELECT 'GRANT SELECT ON '||OWNER||'.'||TABLE_NAME||' TO XXXXXX;' FROM DBA_TABLES P WHERE P.OWNER = 'SEI' ORDER BY 1;
SELECT 'GRANT ' ||PRIVILEGE||' ON '||OWNER||'.'||TABLE_NAME||' TO '||GRANTEE||';' FROM DBA_TAB_PRIVS P WHERE P.OWNER = 'SEI' ORDER BY GRANTEE ASC;
//Acesso de leitura em todos os objetos (tabelas, views, packages, procedures e functions) do schema SRH2 para o usuário userRecebedor no ambiente de produção
SELECT 'GRANT select on '||owner||'.'||object_name||' to userRecebedor;' FROM dba_objects p where p.owner = 'SRH2' ORDER BY 1;
SELECT 'GRANT EXECUTE ON '||owner||'.'||object_name||' to userRecebedor;' FROM dba_objects p where p.owner = 'SRH2' AND object_TYPE IN ('PACKAGE','PACKAGE BODY') ;
set lines 120
set pages 999
clear col
set termout off
set trimout on
set trimspool on
col "Setting" format 999,999,999,999
col "MBytes" format 999,999
col inst_id format 999 head "Instance #"
spool parameters.out
break on inst_id skip 2
select inst_id, 'Shared Pool Size'||': '||decode(value,null,-1,value) "Setting"
,(value/1024/1024) "MBytes"
from gv$parameter where name='shared_pool_size'
union
select inst_id, 'Shared Pool Reserved Area'||': '||decode(value,null,-1,value) "Setting"
,(value/1024/1024) "MBytes"
from gv$parameter where name='shared_pool_reserved_size'
union
select inst_id, 'Log Buffer'||': '||decode(value,null,-1,value) "Setting"
,(value/1024/1024) "MBytes"
from gv$parameter where name='log_buffer'
union
select inst_id, 'Streams Pool Size'||': '||decode(value,null,-1,value) "Setting"
,(value/1024/1024) "MBytes"
from gv$parameter where name='streams_pool_size'
union
select inst_id, 'Buffer Cache'||': '||decode(value,null,-1,value) "Setting"
,(value/1024/1024) "MBytes"
from gv$parameter where name='db_cache_size'
union
select inst_id, 'Recycle Cache'||': '|| decode(value, null,-1,value) "Setting"
,(value/1024/1024) "MBytes"
from gv$parameter where name='db_recycle_cache_size'
union
select inst_id, 'Keep Cache'||': '|| decode(value, null,-1,value) "Setting"
,(value/1024/1024) "MBytes"
from gv$parameter where name='db_keep_cache_size'
union
select inst_id, '2K Cache'||': '|| decode(value, null,-1,value) "Setting"
,(value/1024/1024) "MBytes"
from gv$parameter where name='db_2k_cache_size'
union
select inst_id, '4K Cache'||': '|| decode(value, null,-1,value) "Setting"
,(value/1024/1024) "MBytes"
from gv$parameter where name='db_4k_cache_size'
union
select inst_id, '8K Cache'||': '|| decode(value, null,-1,value) "Setting"
,(value/1024/1024) "MBytes"
from gv$parameter where name='db_8k_cache_size'
union
select inst_id, '16K Cache'||': '|| decode(value, null,-1,value) "Setting"
,(value/1024/1024) "MBytes"
from gv$parameter where name='db_16k_cache_size'
union
select inst_id, '32K Cache'||': '|| decode(value, null,-1,value) "Setting"
,(value/1024/1024) "MBytes"
from gv$parameter where name='db_32k_cache_size'
union
select inst_id, 'Large Pool Size'||': '||decode(value,null,-1,value) "Setting"
,(value/1024/1024) "MBytes"
from gv$parameter where name='large_pool_size'
union
select inst_id, 'Java Pool Size'||': '||decode(value,null,-1,value) "Setting"
,(value/1024/1024) "MBytes"
from gv$parameter where name='java_pool_size'
union
select inst_id, 'SGA Max'||': '|| decode(value, null,-1,value) "Setting"
,(value/1024/1024) "MBytes"
from gv$parameter where name='sga_max_size'
union
select inst_id, 'SGA Target'||': '|| decode(value, null,-1,value) "Setting"
,(value/1024/1024) "MBytes"
from gv$parameter where name='sga_target'
order by 1, 2
/
col Setting format 999,999,99
select inst_id, 'Session Cached Cursors'||': '|| decode(value, null,-1,value) "Setting"
from gv$parameter where name='session_cached_cursors'
union
select inst_id, 'Open Cursors'||': '||decode(value,null,-1,value) "Setting"
from gv$parameter where name='open_cursors'
union
select inst_id, 'Processes'||': '||decode(value,null,-1,value) "Setting"
from gv$parameter where name='processes'
union
select inst_id, 'Sessions'||': '||decode(value,null,-1,value) "Setting"
from gv$parameter where name='sessions'
union
select inst_id, 'DB Files'||': '||decode(value,null,-1,value) "Setting"
from gv$parameter where name='db_files'
union
select inst_id, 'Shared Server (MTS)'||': '||decode(value,null,-1,value) "Setting"
from gv$parameter where name='shared_server'
order by 1, 2
/
col Setting format a30
select inst_id, 'Cursor Sharing'||': '|| value "Setting"
from gv$parameter where name='cursor_sharing'
union
select inst_id, 'Query Rewrite'||': '||value "Setting"
from gv$parameter where name='query_rewrite_enabled'
union
select inst_id, 'Statistics Level'||': '||value "Setting"
from gv$parameter where name='statistics_level'
union
select inst_id, 'Cache Advice'||': '||value "Setting"
from gv$parameter where name='db_cache_advice'
union
select inst_id, 'Use Large Pages'||': '||value "Setting"
from gv$parameter where name='use_large_pages'
union
select inst_id, 'Compatible'||': '||value "Setting"
from gv$parameter where name='compatible'
order by 1, 2
/
col resource_name format a25 head "Resource"
col current_utilization format 999,999,999,999 head "Current"
col max_utilization format 999,999,999,999 head "HWM"
col intl format a15 head "Setting"
select inst_id, resource_name, current_utilization, max_utilization, initial_allocation intl
from gv$resource_limit
where resource_name in ('processes', 'sessions','enqueue_locks','enqueue_resources',
'ges_procs','ges_ress','ges_locks','ges_cache_ress','ges_reg_msgs',
'ges_big_msgs','ges_rsv_msgs','gcs_resources','dml_locks','max_shared_servers')
order by resource_name, inst_id
/
spool off
clear col
set termout on
set trimout off
set trimspool off
clear breaks
col Name for a20;
select substr(a.segment_name,1,20) as "Name", a.initial_extent,a.next_extent,b.OPTSIZE,a.status,b.shrinks
from dba_rollback_segs a,v$rollstat b
where a.SEGMENT_ID = b.USN;
set serveroutput on;
declare
v_log number;
v_days number;
v_logsz number;
v_adsw number;
V_advol number;
v_ahsw number;
v_ahvol number;
begin
select count(first_time) into v_log from v$log_history;
select count(distinct(to_char(first_time,'dd-mon-rrrr'))) into v_days from v$log_history;
select max(bytes)/1024/1024 into v_logsz from v$log;
v_adsw := round(v_log / v_days);
v_advol := round(v_adsw * v_logsz);
v_ahsw := round(v_adsw / 24);
v_ahvol := round((v_adsw / 24 )) * v_logsz;
dbms_output.put ('Total Switches' || ' '||v_log||' ==> ');
dbms_output.put ('Total Days' || ' '|| v_days||' ==> ');
dbms_output.put_line ('Redo Size' || ' ' || v_logsz);
dbms_output.put ('Avg Daily Switches' || ' ' || v_adsw||' ==> ');
dbms_output.put_line ('Avg Daily Volume in Meg' || ' ' || v_advol);
dbms_output.put ('Avg Hourly Switches' || ' ' || v_ahsw||' ==> ');
dbms_output.put_line ('Avg Hourly Volume in Meg' || ' ' || v_ahvol);
end;
/
set heading on;
col Total for a5;
col h00 for a3;
col h01 for a3;
col h02 for a3;
col h03 for a3;
col h04 for a3;
col h05 for a3;
col h06 for a3;
col h07 for a3;
col h08 for a3;
col h09 for a3;
col h10 for a3;
col h11 for a3;
col h12 for a3;
col h13 for a3;
col h14 for a3;
col h15 for a3;
col h16 for a3;
col h17 for a3;
col h18 for a3;
col h19 for a3;
col h20 for a3;
col h21 for a3;
col h22 for a3;
col h23 for a3;
col h24 for a3;
break on report
compute max of "Total" on report
compute max of "h00" on report
compute max of "h01" on report
compute max of "h02" on report
compute max of "h03" on report
compute max of "h04" on report
compute max of "h05" on report
compute max of "h06" on report
compute max of "h07" on report
compute max of "h08" on report
compute max of "h09" on report
compute max of "h10" on report
compute max of "h11" on report
compute max of "h12" on report
compute max of "h13" on report
compute max of "h14" on report
compute max of "h15" on report
compute max of "h16" on report
compute max of "h17" on report
compute max of "h18" on report
compute max of "h19" on report
compute max of "h20" on report
compute max of "h21" on report
compute max of "h22" on report
compute max of "h23" on report
SELECT trunc(first_time) "Date",
to_char(first_time, 'Dy') "Day",
substr(count(1),1,5) as "Total",
substr(SUM(decode(to_char(first_time, 'hh24'),'00',1,0)),1,3) as "h00",
substr(SUM(decode(to_char(first_time, 'hh24'),'01',1,0)),1,3) as "h01",
substr(SUM(decode(to_char(first_time, 'hh24'),'02',1,0)),1,3) as "h02",
substr(SUM(decode(to_char(first_time, 'hh24'),'03',1,0)),1,3) as "h03",
substr(SUM(decode(to_char(first_time, 'hh24'),'04',1,0)),1,3) as "h04",
substr(SUM(decode(to_char(first_time, 'hh24'),'05',1,0)),1,3) as "h05",
substr(SUM(decode(to_char(first_time, 'hh24'),'06',1,0)),1,3) as "h06",
substr(SUM(decode(to_char(first_time, 'hh24'),'07',1,0)),1,3) as "h07",
substr(SUM(decode(to_char(first_time, 'hh24'),'08',1,0)),1,3) as "h08",
substr(SUM(decode(to_char(first_time, 'hh24'),'09',1,0)),1,3) as "h09",
substr(SUM(decode(to_char(first_time, 'hh24'),'10',1,0)),1,3) as "h10",
substr(SUM(decode(to_char(first_time, 'hh24'),'11',1,0)),1,3) as "h11",
substr(SUM(decode(to_char(first_time, 'hh24'),'12',1,0)),1,3) as "h12",
substr(SUM(decode(to_char(first_time, 'hh24'),'13',1,0)),1,3) as "h13",
substr(SUM(decode(to_char(first_time, 'hh24'),'14',1,0)),1,3) as "h14",
substr(SUM(decode(to_char(first_time, 'hh24'),'15',1,0)),1,3) as "h15",
substr(SUM(decode(to_char(first_time, 'hh24'),'16',1,0)),1,3) as "h16",
substr(SUM(decode(to_char(first_time, 'hh24'),'17',1,0)),1,3) as "h17",
substr(SUM(decode(to_char(first_time, 'hh24'),'18',1,0)),1,3) as "h18",
substr(SUM(decode(to_char(first_time, 'hh24'),'19',1,0)),1,3) as "h19",
substr(SUM(decode(to_char(first_time, 'hh24'),'20',1,0)),1,3) as "h20",
substr(SUM(decode(to_char(first_time, 'hh24'),'21',1,0)),1,3) as "h21",
substr(SUM(decode(to_char(first_time, 'hh24'),'22',1,0)),1,3) as "h22",
substr(SUM(decode(to_char(first_time, 'hh24'),'23',1,0)),1,3) as "h23"
FROM V$log_history
group by trunc(first_time), to_char(first_time, 'Dy')
Order by 1;
clear breaks
col username for a20
select USERNAME,
substr(count(decode(o.TYPE#, 2,o.OBJ#,'')),1,5) as Tabs,
substr(count(decode(o.TYPE#, 1,o.OBJ#,'')),1,5) as Indx,
substr(count(decode(o.TYPE#, 5,o.OBJ#,'')),1,5) as Syns,
substr(count(decode(o.TYPE#, 4,o.OBJ#,'')),1,5) as Views,
substr(count(decode(o.TYPE#, 6,o.OBJ#,'')),1,5) as Seqs,
substr(count(decode(o.TYPE#, 7,o.OBJ#,'')),1,5) as Procs,
substr(count(decode(o.TYPE#, 8,o.OBJ#,'')),1,5) as Funcs,
substr(count(decode(o.TYPE#, 9,o.OBJ#,'')),1,5) as Pkgs,
substr(count(decode(o.TYPE#,12,o.OBJ#,'')),1,5) as Trigs,
substr(count(decode(o.TYPE#,10,o.OBJ#,'')),1,5) as Deps
from sys.obj$ o, dba_users u
where u.USER_ID = o.OWNER# (+)
and o.TYPE# is NOT NULL
and u.username not in ('SYS','SYSTEM','OUTLN','XDB','WMSYS')
group by USERNAME
order by USERNAME;
set heading on;
break on report
compute sum of "total MB" on report
col "total MB" format 999,999,999,999,990
compute sum of "Free MB" on report
col "Free MB" format 999,999,999,999,990
compute sum of "Used MB" on report
col "Used MB" format 999,999,999,999,990
select
d.tablespace_name,
SUBSTR(d.file_name,1,50) "Datafile name",
ROUND(MAX(d.bytes)/1024/1024,2) as "total MB",
DECODE(SUM(f.bytes), null, 0, ROUND(SUM(f.Bytes)/1024/1024,2)) as "Free MB" ,
DECODE( SUM(f.Bytes), null, 0, ROUND((MAX(d.bytes)/1024/1024) - (SUM(f.bytes)/1024/1024),2)) as "Used MB"
from
DBA_FREE_SPACE f , DBA_DATA_FILES d
where
f.tablespace_name(+) = d.tablespace_name
and f.file_id(+) = d.file_id
group by
d.tablespace_name,d.file_name;
clear breaks
set wrap off
set lines 130
set pages 100
col owner format a12 heading ‘Owner’
col session_id format 9999 heading ‘Sid’
col object_type format a20 heading ‘Type’
col object_name format a30 heading ‘Objeto’
col oracle_username format a15 heading ‘Username’
col os_user_name format a15 heading ‘OS user’
select l.SESSION_ID,
o.owner,
o.object_type,
o.object_name,
l.oracle_username,
l.os_user_name
FROM gv$locked_object l,
dba_objects o
WHERE l.object_id = o.object_id
ORDER by l.SESSION_ID,o.object_name;
set lines 1000 pages 100
col username form a10
col osuser form a15
col program form a50
col logon_time form a20
alter session set nls_date_format='dd/mm/yyyy hh24:mi:ss';
ttitle left skip 1 "SESSÕES" skip 2
select sid, serial#, username, osuser, status, program, logon_time
from v$session
order by logon_time;
ttitle off;
col "Table_Nm" for a30;
select owner, substr(object_name,1,30) as "Table_Nm",created
from dba_objects
where object_type = 'TABLE' and created > sysdate-60
and owner not in ('SYS','SYSTEM','OUTLN','XDB','WMSYS');
select 'datafile : '|| name AS FILES from v$datafile
union
select 'tempfile : '|| name from v$tempfile
union
select 'controlfile: '|| name from v$controlfile
union
select 'logfile : '|| member from v$logfile;
alter database backup controlfile to trace;
set pagesize 0
set lines 300
!rm drop_objectos.sql
spo drop_objectos.sql
select 'DROP ' || object_type || ' ' || owner || '.' || object_name || ' cascade constraints;' AS COMANDO
from dba_objects
where owner = 'CCA'
and object_type = 'TABLE'
order by object_type, object_name;
select 'DROP ' || object_type || ' ' || owner || '.' || object_name || ';' AS COMANDO
from dba_objects
where owner = 'CCA'
and object_type in ('FUNCTION','INDEX','LIBRARY','PACKAGE','PROCEDURE','SEQUENCE','TRIGGER','TYPE','VIEW')
order by object_type, object_name;
spo off
!ls -ltr drop_objectos.sql
-- Step 01: Check the orphaned datapump jobs.
SET LINES 140
COL OWNER_NAME FORMAT A10;
COL JOB_NAME FORMAT A20;
COL STATE FORMAT A12 ;
COL OPERATION LIKE OWNER_NAME;
COL JOB_MODE LIKE OWNER_NAME;
SELECT OWNER_NAME, JOB_NAME, OPERATION, JOB_MODE,STATE, ATTACHED_SESSIONS
FROM DBA_DATAPUMP_JOBS
ORDER BY 1;
OWNER_NAME JOB_NAME OPERATION JOB_MODE STATE ATTACHED_SESSIONS
---------- -------------------- -------------- ----------- ------------ -----------------
BACKUP SYS_EXPORT_FULL_01 EXPORT FULL NOT RUNNING 0
C##SANTOS SYS_IMPORT_SCHEMA_01 IMPORT SCHEMA NOT RUNNING 0
-- Step 02: Check the state field. For orphaned jobs the state will be NOT RUNNING.
-- Step 03: Drop the master table.
DROP TABLE USER.SYS_EXPORT_SCHEMA_01;
DROP TABLE USER.SYS_EXPORT_SCHEMA_02;
-- Step 04: Check for existing data pump jobs by query issued in step 01. If objects are in recyclebin bin then purge the objects from the recyclebin.
SQL> PURGE TABLE USER.SYS_EXPORT_SCHEMA_01;
Table purged.
SQL> PURGE TABLE USER.SYS_EXPORT_SCHEMA_02;
Table purged.
-- Step 05: In this stage you did not get any orphaned jobs if the jobs have a master table. If there are still jobs listed in dba_datapump_jobs do cleanup process like below.
SET serveroutput on
SET lines 100
DECLARE
job1 NUMBER;
BEGIN
job1 := DBMS_DATAPUMP.ATTACH('SYS_EXPORT_SCHEMA_01','USER');
DBMS_DATAPUMP.STOP_JOB (job1);
END;
/
DECLARE
job2 NUMBER;
BEGIN
job2 := DBMS_DATAPUMP.ATTACH('SYS_EXPORT_SCHEMA_02','USER');
DBMS_DATAPUMP.STOP_JOB (job2);
END;
/
ORACLE_HOME/bin/sqlplus
sqlplus /nolog
connect sys as sysdba
connect sys/pass@host:1521/pdb1 as sysdba
sqlplus / as SYSDBA | SYSOPER | SYSASM | SYSBACKUP | SYSDG | SYSKM | SYSRAC
sqlplus username/password
sqlplus username/password@connect_identifier
sqlplus username/password@database:port/container
sqlplus username/password@host:port/container
sqlplus username/password@ip:port/container
sqlplus username/password@service
sqlplus username/password@(DESCRIPTION=(ADDRESS=(PROTOCOL=TCP)(HOST=HOSTNAME.NETWORK)(PORT=1521))(CONNECT_DATA=(SID=REMOTE_SID)))
sqlplus "username/password@(DESCRIPTION=(ADDRESS=(PROTOCOL=TCP)(HOST=HOSTNAME.NETWORK)(PORT=1521))(CONNECT_DATA=(SID=REMOTE_SID)))"
sqlplus 'username/password@(DESCRIPTION=(ADDRESS=(PROTOCOL=TCP)(HOST=HOSTNAME.NETWORK)(PORT=1521))(CONNECT_DATA=(SID=REMOTE_SID)))'
sqlplus username/password@hostname.network/remote_service_name
sqlplus username/password@host[:port]/service_name
SELECT name,pdb from V$SERVICES;
--=================================
-- List Available PDBs
--=================================
SHOW PDBS
CON_ID CON_NAME OPEN MODE RESTRICTED
---------- ------------ ---------- ----------
2 PDB$SEED READ ONLY NO
3 PDBX READ WRITE NO
SELECT con_id, name, open_mode FROM V$PDBS;
CON_ID NAME OPEN_MODE
------- ------------ ----------
2 PDB$SEED READ ONLY
3 PDBX READ WRITE
SHOW con_id SHOW con_name
CON_ID CON_NAME
--------- -------------
1 CDB$ROOT
SELECT
SYS_CONTEXT('USERENV','CON_ID') CON_ID,
SYS_CONTEXT('USERENV','CON_NAME') CON_NAME
FROM DUAL;
CON_ID CON_NAME
-------- --------------
3 PDBX
SELECT pdb_id, pdb_name, dbid, con_id FROM CDB_PDBS;
PDB_ID PDB_NAME DBID CON_ID
------ -------- ---------- ------
3 PDBX 1234567890 3
2 PDB$SEED 123456789 2
--=================================
-- Open the PDB.
--=================================
ALTER PLUGGABLE DATABASE ALL OPEN;
ALTER PLUGGABLE DATABASE PDBX OPEN;
ALTER PLUGGABLE DATABASE ALL EXCEPT PDBX OPEN;
ALTER PLUGGABLE DATABASE PDBX OPEN READ ONLY;
ALTER PLUGGABLE DATABASE PDBX OPEN READ ONLY [RESTRICTED] [FORCE];
ALTER PLUGGABLE DATABASE PDBX OPEN READ WRITE;
ALTER PLUGGABLE DATABASE PDBX OPEN READ WRITE [RESTRICTED] [FORCE];
ALTER PLUGGABLE DATABASE PDBX OPEN UPGRADE [RESTRICTED];
--- Connected in PDB ---
ALTER SESSION SET CONTAINER = PDBX;
ALTER PLUGGABLE DATABASE OPEN READ WRITE [RESTRICTED] [FORCE];
ALTER PLUGGABLE DATABASE OPEN READ ONLY [RESTRICTED] [FORCE];
ALTER PLUGGABLE DATABASE OPEN UPGRADE [RESTRICTED];
--=================================
-- Save State:
--=================================
SELECT name, open_mode FROM v$pdbs;
NAME OPEN_MODE
------------------------------ ----------
PDB$SEED READ ONLY
PDBX MOUNTED
ALTER PLUGGABLE DATABASE PDBX OPEN;
ALTER PLUGGABLE DATABASE PDBX SAVE STATE;
ALTER PLUGGABLE DATABASE ALL SAVE STATE;
SELECT con_name, instance_name, state FROM CDB_PDB_SAVED_STATES;
CON_NAME INSTANCE_NAME STATE
-------------------- -------------------- --------------
PDBX CDBX OPEN
--=================================
-- Close the PDB.
--=================================
ALTER PLUGGABLE DATABASE ALL CLOSE;
ALTER PLUGGABLE DATABASE PDBX CLOSE;
ALTER PLUGGABLE DATABASE ALL EXCEPT PDBX CLOSE IMMEDIATE;
ALTER PLUGGABLE DATABASE PDBX CLOSE [IMMEDIATE];
-- connected to the PDB
ALTER SESSION SET CONTAINER = PDBX;
ALTER PLUGGABLE DATABASE CLOSE IMMEDIATE;
--=================================
-- Automatic Startup:
--=================================
CREATE OR REPLACE TRIGGER open_pdbs
AFTER STARTUP ON DATABASE
BEGIN
EXECUTE IMMEDIATE 'ALTER PLUGGABLE DATABASE ALL OPEN';
END open_pdbs;
/
--=================================
-- Unplug the PDB:
--=================================
ALTER PLUGGABLE DATABASE PDBX CLOSE;
ALTER PLUGGABLE DATABASE PDBX UNPLUG INTO '/tmp/pdbx.pdb';
SELECT pdb_id, pdb_name, status FROM cdb_pdbs;
PDB_ID PDB_NAME STATUS
------ -------- ----------
2 PDB$SEED NORMAL
3 PDB18 NORMAL
--=================================
-- Rename:
--=================================
SHOW PDBS
CONNECT sys@PDBX AS SYSDBA
ALTER PLUGGABLE DATABASE CLOSE IMMEDIATE;
ALTER PLUGGABLE DATABASE OPEN RESTRICTED;
SELECT con_id, name, open_mode, restricted FROM V$PDBS;
ALTER PLUGGABLE DATABASE RENAME GLOBAL_NAME TO PDB_ORCL;
SELECT con_id, name, open_mode, restricted FROM V$PDBS;
ALTER PLUGGABLE DATABASE CLOSE IMMEDIATE;
ALTER PLUGGABLE DATABASE OPEN;
SELECT con_id, name, open_mode, restricted FROM V$PDBS;
--=================================
-- Remove:
--=================================
DROP PLUGGABLE DATABASE PDBX INCLUDING DATAFILES;
DROP PLUGGABLE DATABASE PDBX KEEP DATAFILES;
--=================================
-- Check applications
--=================================
SELECT
name, con_id, application_root "APP_ROOT",
application_seed "APP_Seed",application_pdb "APP_PDB",
application_root_con_id "APP_ROOT_CONID"
FROM v$containers;
--=================================
-- CDB / PDB
--=================================
ALTER SESSION SET CONTAINER = CDB$ROOT;
ALTER SESSION SET CONTAINER = PDBX;
-- Ele fornece estatísticas sobre instruções SQL que estão na memória, analisadas e prontas para execução.
SELECT PARSING_SCHEMA_NAME,SQL_TEXT,ELAPSED_TIME,DISK_READS, BUFFER_GETS
FROM V$SQLAREA
WHERE USERS_EXECUTING>0 AND PARSING_SCHEMA_NAME='SCHEMA'
/
SELECT
PRIVILEGE,
OBJ_OWNER,
OBJ_NAME,
USERNAME,
LISTAGG(GRANT_TARGET, ',') WITHIN GROUP (ORDER BY GRANT_TARGET) AS GRANT_SOURCES, -- Lists the sources of the permission
MAX(ADMIN_OR_GRANT_OPT) AS ADMIN_OR_GRANT_OPT, -- MAX acts as a Boolean OR by picking 'YES' over 'NO'
MAX(HIERARCHY_OPT) AS HIERARCHY_OPT -- MAX acts as a Boolean OR by picking 'YES' over 'NO'
FROM (
-- Gets all roles a user has, even inherited ones
WITH ALL_ROLES_FOR_USER AS (
SELECT DISTINCT CONNECT_BY_ROOT GRANTEE AS GRANTED_USER, GRANTED_ROLE
FROM DBA_ROLE_PRIVS
CONNECT BY GRANTEE = PRIOR GRANTED_ROLE
)
SELECT
PRIVILEGE,
OBJ_OWNER,
OBJ_NAME,
USERNAME,
REPLACE(GRANT_TARGET, USERNAME, 'Direct to user') AS GRANT_TARGET,
ADMIN_OR_GRANT_OPT,
HIERARCHY_OPT
FROM (
-- System privileges granted directly to users
SELECT PRIVILEGE, NULL AS OBJ_OWNER, NULL AS OBJ_NAME, GRANTEE AS USERNAME, GRANTEE AS GRANT_TARGET, ADMIN_OPTION AS ADMIN_OR_GRANT_OPT, NULL AS HIERARCHY_OPT
FROM DBA_SYS_PRIVS
WHERE GRANTEE IN (SELECT USERNAME FROM DBA_USERS)
UNION ALL
-- System privileges granted users through roles
SELECT PRIVILEGE, NULL AS OBJ_OWNER, NULL AS OBJ_NAME, ALL_ROLES_FOR_USER.GRANTED_USER AS USERNAME, GRANTEE AS GRANT_TARGET, ADMIN_OPTION AS ADMIN_OR_GRANT_OPT, NULL AS HIERARCHY_OPT
FROM DBA_SYS_PRIVS
JOIN ALL_ROLES_FOR_USER ON ALL_ROLES_FOR_USER.GRANTED_ROLE = DBA_SYS_PRIVS.GRANTEE
UNION ALL
-- Object privileges granted directly to users
SELECT PRIVILEGE, OWNER AS OBJ_OWNER, TABLE_NAME AS OBJ_NAME, GRANTEE AS USERNAME, GRANTEE AS GRANT_TARGET, GRANTABLE, HIERARCHY
FROM DBA_TAB_PRIVS
WHERE GRANTEE IN (SELECT USERNAME FROM DBA_USERS)
UNION ALL
-- Object privileges granted users through roles
SELECT PRIVILEGE, OWNER AS OBJ_OWNER, TABLE_NAME AS OBJ_NAME, GRANTEE AS USERNAME, ALL_ROLES_FOR_USER.GRANTED_ROLE AS GRANT_TARGET, GRANTABLE, HIERARCHY
FROM DBA_TAB_PRIVS
JOIN ALL_ROLES_FOR_USER ON ALL_ROLES_FOR_USER.GRANTED_ROLE = DBA_TAB_PRIVS.GRANTEE
) ALL_USER_PRIVS
-- Adjust your filter here
WHERE USERNAME = 'ALTERE_INFORME_USER_NAME'
) DISTINCT_USER_PRIVS
GROUP BY
PRIVILEGE,
OBJ_OWNER,
OBJ_NAME,
USERNAME
;
-- -----------------------------------------------------------------------------
-- CONCEDER X REVOGAR
-- -----------------------------------------------------------------------------
BEGIN
FOR R IN (
SELECT OWNER, TABLE_NAME FROM ALL_TABLES WHERE OWNER = 'SCHEMA'
)
LOOP
EXECUTE IMMEDIATE
'GRANT SELECT, INSERT, UPDATE, DELETE ON '||R.OWNER||'.'||R.TABLE_NAME||' TO ' || GRANTEE;
--'REVOKE SELECT, INSERT, UPDATE, DELETE ON '||R.OWNER||'.'||R.TABLE_NAME||' FROM ' || GRANTEE;
END LOOP;
END;
PL/SQL procedure successfully completed.
CREATE OR REPLACE PROCEDURE Drop_DbLink( schemaName varchar2, dbLink varchar2 ) is
plsql varchar2(1000);
cur number;
uid number;
rc number;
begin
select
u.user_id into uid
from dba_users u
where u.username = schemaName;
plsql := 'drop database link "'||dbLink||'"';
cur := SYS.DBMS_SYS_SQL.open_cursor;
SYS.DBMS_SYS_SQL.parse_as_user(
c => cur,
statement => plsql,
language_flag => DBMS_SQL.native,
userID => uid
);
rc := SYS.DBMS_SYS_SQL.execute(cur);
SYS.DBMS_SYS_SQL.close_cursor(cur);
end;
/
-- EXECUCAO DA PROCEDURE
exec Drop_DbLink( 'USUARIO', 'DBLINK_ALVO' );
SELECT * FROM DBA_DB_LINKS WHERE DB_LINK='DBLINK_ALVO';
no rows selected
SELECT owner_name, job_name, operation, job_mode, state FROM dba_datapump_jobs;
OWNER_NAME JOB_NAME OPERATION JOB_MODE STATE
---------- -------------------- ---------- ---------- ------------
SYSTEM SYS_EXPORT_FULL_01 EXPORT FULL EXECUTING
Processing object type DATABASE_EXPORT/SCHEMA/TABLE/TABLE_DATA
????INTERACTIVE COMMAND MODE [CTRL+C]
?CONTINUE_CLIENT : Switch back to the normal client, with the log output echoed to the screen again.
?EXIT_CLIENT : The client is closed, but the database job continues, so the operation completes as normal.
?KILL_JOB : Detaches all clients and kills the database job.
?STOP_JOB : By default, the current actions are completed, then the job is stopped. It can be resumed later. If you use the ?STOP_JOB=IMMEDIATE option, all actions are stopped immediately. When the job resumed, some of those actions will need to be rerun to make the action consistent.
?START_JOB : Restarts a stopped job.
?STATUS : Displays basic information about the job, including the status of the workers.
Example:
Export> KILL_JOB
..or..
Export> STOP_JOB=IMMEDIATE
Are you sure you wish to stop this job ([yes]/no): yes
Example-02:
Export> status
Job: SYS_EXPORT_FULL_01
Operation: EXPORT
Mode: FULL
State: EXECUTING
Bytes Processed: 0
Current Parallelism: 1
Job Error Count: 0
Dump File: /u01/app/oracle/dpump/admin.dmp
bytes written: 4,096
Worker 1 Status:
Process Name: DW00
State: EXECUTING
Object Schema: ADMIN
Object Name: TEST_01
Object Type: DATABASE_EXPORT/SCHEMA/PACKAGE_BODIES/PACKAGE/PACKAGE_BODY
Completed Objects: 78
Worker Parallelism: 1
-- Querying DBA_DATAPUMP_JOBS view
SET LINESIZE 150
COLUMN owner_name FORMAT A20
COLUMN job_name FORMAT A30
COLUMN operation FORMAT A10
COLUMN job_mode FORMAT A10
COLUMN state FORMAT A12
SELECT owner_name,
job_name,
TRIM(operation) AS operation,
TRIM(job_mode) AS job_mode,
state,
degree,
attached_sessions,
datapump_sessions
FROM dba_datapump_jobs
ORDER BY 1, 2;
OWNER_NAME JOB_NAME OPERATION JOB_MODE STATE DEGREE ATTACHED_SESSIONS DATAPUMP_SESSIONS
-------------------- ------------------------------ ---------- ---------- ------------ ---------- ----------------- -----------------
DUMMY_DBA SYS_EXPORT_SCHEMA_01 EXPORT SCHEMA EXECUTING 4 1 6
1 row selected.
-- Querying V$SESSION_LONGOPS & V$SESSION views
SELECT b.username,
a.sid,
b.opname,
b.target,
round(b.SOFAR*100/b.TOTALWORK,0) || '%' as "%DONE", b.TIME_REMAINING,
to_char(b.start_time,'YYYY/MM/DD HH24:MI:SS') start_time
FROM v$session_longops b, v$session a
WHERE a.sid = b.sid
ORDER BY 6;
-- Querying V$SESSION_LONGOPS & V$DATAPUMP_JOB views:
SELECT sl.sid,
sl.serial#,
sl.sofar,
sl.totalwork,
dp.owner_name,
dp.state,
dp.job_mode
FROM v$session_longops sl, v$datapump_job dp
WHERE sl.opname = dp.job_name
AND sl.sofar != sl.totalwork;
-- Querying all the related views with a single query:-
select x.job_name,
b.state,
b.job_mode,
b.degree,
x.owner_name,
z.sql_text,
p.message,
p.totalwork,
p.sofar,
round((p.sofar/p.totalwork)*100,2) done,
p.time_remaining
from dba_datapump_jobs b
left join dba_datapump_sessions x on (x.job_name = b.job_name)
left join v$session y on (y.saddr = x.saddr)
left join v$sql z on (y.sql_id = z.sql_id)
left join v$session_longops p ON (p.sql_id = y.sql_id)
WHERE y.module='Data Pump Worker'
AND p.time_remaining > 0;
-- Also for any errors you can check the alert log and query the DBA_RESUMABLE view.
select name, sql_text, error_msg from dba_resumable;
???? Once you know the job name, you can attach the client to the job using the ATTACH={JOB_NAME} parameter as follows.
expdp user/password@service attach=SYS_EXPORT_SCHEMA_01
impdp user/password@service attach=SYS_IMPORT_SCHEMA_01
SELECT TO_CHAR (COMPLETION_TIME, 'DD/MM/YYYY') DAY,
SUM (DECODE (TO_CHAR (COMPLETION_TIME, 'HH24'), '00', 1, NULL)) "00-01",
SUM (DECODE (TO_CHAR (COMPLETION_TIME, 'HH24'), '01', 1, NULL)) "01-02",
SUM (DECODE (TO_CHAR (COMPLETION_TIME, 'HH24'), '02', 1, NULL)) "02-03",
SUM (DECODE (TO_CHAR (COMPLETION_TIME, 'HH24'), '03', 1, NULL)) "03-04",
SUM (DECODE (TO_CHAR (COMPLETION_TIME, 'HH24'), '04', 1, NULL)) "04-05",
SUM (DECODE (TO_CHAR (COMPLETION_TIME, 'HH24'), '05', 1, NULL)) "05-06",
SUM (DECODE (TO_CHAR (COMPLETION_TIME, 'HH24'), '06', 1, NULL)) "06-07",
SUM (DECODE (TO_CHAR (COMPLETION_TIME, 'HH24'), '07', 1, NULL)) "07-08",
SUM (DECODE (TO_CHAR (COMPLETION_TIME, 'HH24'), '08', 1, NULL)) "08-09",
SUM (DECODE (TO_CHAR (COMPLETION_TIME, 'HH24'), '09', 1, NULL)) "09-10",
SUM (DECODE (TO_CHAR (COMPLETION_TIME, 'HH24'), '10', 1, NULL)) "10-11",
SUM (DECODE (TO_CHAR (COMPLETION_TIME, 'HH24'), '11', 1, NULL)) "11-12",
SUM (DECODE (TO_CHAR (COMPLETION_TIME, 'HH24'), '12', 1, NULL)) "12-13",
SUM (DECODE (TO_CHAR (COMPLETION_TIME, 'HH24'), '13', 1, NULL)) "13-14",
SUM (DECODE (TO_CHAR (COMPLETION_TIME, 'HH24'), '14', 1, NULL)) "14-15",
SUM (DECODE (TO_CHAR (COMPLETION_TIME, 'HH24'), '15', 1, NULL)) "15-16",
SUM (DECODE (TO_CHAR (COMPLETION_TIME, 'HH24'), '16', 1, NULL)) "16-17",
SUM (DECODE (TO_CHAR (COMPLETION_TIME, 'HH24'), '17', 1, NULL)) "17-18",
SUM (DECODE (TO_CHAR (COMPLETION_TIME, 'HH24'), '18', 1, NULL)) "18-19",
SUM (DECODE (TO_CHAR (COMPLETION_TIME, 'HH24'), '19', 1, NULL)) "19-20",
SUM (DECODE (TO_CHAR (COMPLETION_TIME, 'HH24'), '20', 1, NULL)) "20-21",
SUM (DECODE (TO_CHAR (COMPLETION_TIME, 'HH24'), '21', 1, NULL)) "21-22",
SUM (DECODE (TO_CHAR (COMPLETION_TIME, 'HH24'), '22', 1, NULL)) "22-23",
SUM (DECODE (TO_CHAR (COMPLETION_TIME, 'HH24'), '23', 1, NULL)) "23-00",
COUNT (*) TOTAL
FROM V$ARCHIVED_LOG
WHERE ARCHIVED='YES'
GROUP BY TO_CHAR (COMPLETION_TIME, 'DD/MM/YYYY')
ORDER BY TO_DATE (DAY, 'DD/MM/YYYY');
SELECT
HOST_NAME,
INSTANCE_NAME,
TO_CHAR(STARTUP_TIME,'DD/MM/YYYY HH24:MI:SS') AS STARTUP_TIME ,
FLOOR(SYSDATE - STARTUP_TIME) || ' DIAS',
TO_CHAR(SYSDATE,'DD/MM/YYYY HH24:MI:SS') AS COLETA
FROM V$INSTANCE;
COLUMN PDB_ID FORMAT 999
COLUMN PDB_NAME FORMAT A8
COLUMN FILE_ID FORMAT 9999
COLUMN TABLESPACE_NAME FORMAT A10
COLUMN FILE_NAME FORMAT A45
SELECT p.PDB_ID, p.PDB_NAME, d.FILE_ID, d.TABLESPACE_NAME, d.FILE_NAME
FROM DBA_PDBS p, CDB_DATA_FILES d
WHERE p.PDB_ID = d.CON_ID
ORDER BY p.PDB_ID;
Sample output:
PDB_ID PDB_NAME FILE_ID TABLESPACE FILE_NAME
------ -------- ------- ---------- ---------------------------------------------
2 PDB$SEED 6 SYSAUX /disk1/oracle/dbs/pdbseed/cdb1_ax.f
2 PDB$SEED 5 SYSTEM /disk1/oracle/dbs/pdbseed/cdb1_db.f
3 HRPDB 9 SYSAUX /disk1/oracle/dbs/hrpdb/hrpdb_ax.f
3 HRPDB 8 SYSTEM /disk1/oracle/dbs/hrpdb/hrpdb_db.f
3 HRPDB 13 USER /disk1/oracle/dbs/hrpdb/hrpdb_usr.dbf
4 SALESPDB 15 SYSTEM /disk1/oracle/dbs/salespdb/salespdb_db.f
4 SALESPDB 16 SYSAUX /disk1/oracle/dbs/salespdb/salespdb_ax.f
4 SALESPDB 18 USER /disk1/oracle/dbs/salespdb/salespdb_usr.dbf
https://docs.oracle.com/database/121/ADMIN/cdb_mon.htm#ADMIN13939
-- This example queries the DBA_PDBS view and the CDB_USERS view from the root to show the users in each PDB.
-- The query uses p.PDB_ID > 2 to avoid showing the users in the root and the seed.
COLUMN PDB_NAME FORMAT A15
COLUMN USERNAME FORMAT A30
SELECT p.PDB_ID, p.PDB_NAME, u.USERNAME
FROM DBA_PDBS p, CDB_USERS u
WHERE p.PDB_ID > 2 AND
p.PDB_ID = u.CON_ID
ORDER BY p.PDB_ID;
font:
https://docs.oracle.com/database/121/ADMIN/cdb_mon.htm#ADMIN13939
//Tamanho do banco
select sum(bytes) / 1024 / 1024 / 1024 tamanho_GB from dba_segments;
//TAMANHO DO SCHEMA
SELECT
SEGMENT_TYPE, SUM(BYTES) SIZE_IN_BYTES
FROM DBA_SEGMENTS
WHERE OWNER = 'NOME_DA_SCHEMA'
GROUP BY
SEGMENT_TYPE
//TAMANHO DA TABELA
SELECT * FROM
(SELECT OWNER, SEGMENT_NAME, TRUNC(SUM(BYTES)/1024/1024/1024,2) "SIZE GB"
FROM DBA_SEGMENTS
WHERE SEGMENT_TYPE = 'TABLE' AND OWNER = 'XXX'
GROUP BY SEGMENT_NAME, OWNER
ORDER BY 3 DESC)
WHERE ROWNUM <= 100;
SELECT * FROM
(SELECT OWNER, SEGMENT_NAME, TRUNC(SUM(BYTES)/1024/1024/1024,2) "SIZE GB"
FROM DBA_SEGMENTS
WHERE SEGMENT_TYPE = 'TABLE' AND
OWNER = 'SYS' AND
SEGMENT_NAME IN ('AUD_POLICY$','AUD_OBJECT_OPT$','AUDIT_NG$','AUDIT_ACTIONS','AUDIT$','AUD_CONTEXT$','AUD$')
GROUP BY SEGMENT_NAME, OWNER
ORDER BY 2 DESC)
WHERE ROWNUM <= 10;
ORA-39001: valor de argumento invalido
ORA-39000: especificac?o de arquivo de dump incorreto
ORA-31619: arquivo de dump invalido "/nas/oracle/dumps/ARQUIVO.dmp"
ORA-17500: Erro ODM:Invalid argument
-rw-r----- 1 543215 54325 16700481536 Aug 10 12:34 ARQUIVO.dmp
ONDE FOI GERADO:
chmod +r /nas/oracle/dumps/ARQUIVO.dmp
SELECT USERNAME
FROM DBA_USERS U
WHERE EXISTS ( SELECT 1 FROM DBA_OBJECTS O WHERE O.OWNER = U.USERNAME )
AND USERNAME NOT IN ('SYSTEM','SYS')
ORDER BY USERNAME;
--217 ROWS SELECTED.
SELECT OWNER, OBJECT_TYPE,COUNT(OBJECT_TYPE)
FROM DBA_OBJECTS
WHERE OBJECT_TYPE = 'TABLE'
GROUP BY OBJECT_TYPE ,OWNER
ORDER BY 1 ASC;
--190 ROWS SELECTED.
SELECT OWNER USUARIO
,OBJECT_TYPE OBJETO
,COUNT(OBJECT_TYPE) TOTAL
FROM DBA_OBJECTS
GROUP BY OBJECT_TYPE,OWNER
ORDER BY 1 ASC;
SQL> break on report
SQL> compute sum of data_mb on report
SQL> compute sum of indx_mb on report
SQL> compute sum of lob_mb on report
SQL> compute sum of total_mb on report
SQL> select table_name,
decode(partitioned,'/','NO',partitioned) partitioned,
num_rows,
data_mb,
indx_mb,
lob_mb,
total_mb
from (select data.table_name,
partitioning_type
|| decode (subpartitioning_type,
'none', null,
'/' || subpartitioning_type)
partitioned,
num_rows,
nvl(data_mb,0) data_mb,
nvl(indx_mb,0) indx_mb,
nvl(lob_mb,0) lob_mb,
nvl(data_mb,0) + nvl(indx_mb,0) + nvl(lob_mb,0) total_mb
from ( select table_name,
nvl(min(num_rows),0) num_rows,
round(sum(data_mb),2) data_mb
from (select table_name, num_rows, data_mb
from (select a.table_name,
a.num_rows,
b.bytes/1024/1024 as data_mb
from user_tables a, user_segments b
where a.table_name = b.segment_name))
group by table_name) data,
( select a.table_name,
round(sum(b.bytes/1024/1024),2) as indx_mb
from user_indexes a, user_segments b
where a.index_name = b.segment_name
group by a.table_name) indx,
( select a.table_name,
round(sum(b.bytes/1024/1024),2) as lob_mb
from user_lobs a, user_segments b
where a.segment_name = b.segment_name
group by a.table_name) lob,
user_part_tables part
where data.table_name = indx.table_name(+)
and data.table_name = lob.table_name(+)
and data.table_name = part.table_name(+))
order by table_name;
TABLE_NAME PARTITIONED NUM_ROWS DATA_MB INDX_MB LOB_MB TOTAL_MB
----------- ----------- --------- --------- --------- --------- ---------
T1 NO 5912285 576 1160 0 1736
T2 RANGE 1597647 75,81 70,94 0 146,75
T3 NO 700890 80 0 0 80
T4 NO 24008 4 ,5 287 291,5
T5 RANGE/HASH 60000 66,5 11,25 1,5 79,25
T6 RANGE/LIST 1572864 236,44 154,31 96,69 487,44
T7 LIST 1527191 23 95 0 118
T8 NO 19441 3 1,25 271 275,25
T9 NO 10565 2 0 0 2
--------- --------- --------- ---------
sum 1066,75 1493,25 656,19 3216,19
9 linhas selecionadas.
-- Para gerar arquivo com a lista de diretórios
find . -type d > dirs.txt
-- Para criar esse diretórios em qualquer ambiente
xargs mkdir -p < dirs.txt
SELECT *FROM V$DATABASE;
SELECT *FROM v$THREAD;
SELECT *FROM GLOBAL_NAME;
SELECT *FROM v$INSTANCE;
sqlplus C#DBA/S3nha@orcl:1521/ALFA
sqlplus C#DBA/S3nha@localhost:1521/ALFA
sqlplus C#DBA/S3nha@10.20.30.40:1521/ALFA
================================================================
$> sqlplus / as sysdba
SQL> SHOW CON_NAME;
CON_NAME
------------------------------
CDB$ROOT
SQL> show pdbs;
CON_ID CON_NAME OPEN MODE RESTRICTED
---------- ------------------------------ -------------------- ----------
1 PDB$SEED READ ONLY NO
2 ALFA READ WRITE NO
3 BETA READ WRITE NO
SELECT CON_ID, NAME, OPEN_MODE FROM V$PDBS;
CON_ID NAME OPEN_MODE
--------------------------------------------------------------------------------
1 PDB$SEED READ ONLY
2 ALFA READ WRITE
SQL> ALTER SESSION SET CONTAINER = ALFA;
SQL> ALTER SESSION SET CONTAINER = BETA;
SQL> ALTER SESSION SET CONTAINER = CDB$ROOT;
Session altered.
ALTER USER DeQuem GRANT CONNECT THROUGH Usuario;
create table tabletemp as select * from owner.table;
//APENAS ESTRUTURA - SEM DADOS
create table tabletemp as select * from table where rowid is null;
-- Em caso de erro ao instalar o oracle 12c no Oracle linux 8:
[INS-13001] Oracle Database não é suportado neste sistema operacional.
O instalador não executará verificações de pré-requisitos no sistema.
Executar:
[oracle@linux-8 19]$ export CV_ASSUME_DISTID=OL7
./runInstaller -debug -logLevel finest
//Instalar o repositório de acordo com seu sistema operacional.
[root@localhost]# yum install https://dl.fedoraproject.org/pub/epel/epel-release-latest-6.noarch.rpm
[root@localhost]# yum install https://dl.fedoraproject.org/pub/epel/epel-release-latest-7.noarch.rpm
[root@localhost]# yum install https://dl.fedoraproject.org/pub/epel/epel-release-latest-8.noarch.rpm -y
[root@localhost]# yum install rlwrap -y
//->Criar um alias para chamar o SQL*Plus através do rlwrap alterar o arquivo ~/.bashrc do usuário oracle:
[root@localhost~]# su - oracle
[oracle@localhost~]$ vim ~/.bashrc
============Arquivo.bashrc===========
| |
| #.bashrc |
| alias sqlplus='rlwrap sqlplus' |
| alias rman='rlwrap rman' |
| alias adrci='rlwrap adrci' |
| alias expdp='rlwrap expdp' |
| alias impdp='rlwrap impdp' |
| |
| # Source global definitions |
| if [ -f /etc/bashrc ]; then |
| . /etc/bashrc |
| fi |
| ... |
=====================================
[oracle@localhost ~]$ . .bashrc
[oracle@localhost ~]$ sqlplus
[oracle@localhost ~]$ rman
[oracle@localhost ~]$ adrci
/*-------------------SEGUNDA--FORMA-------------------------------------------*/
# wget https://dl.fedoraproject.org/pub/epel/epel-release-latest-7.noarch.rpm
# yum -y install epel-release-latest-7.noarch.rpm
# yum -y install rlwrap
$ rlwrap sqlplus / AS SYSDBA
$ rlwrap rman TARGET /
$ rlwrap lsnrctl
$ rlwrap dgmgrl SYS/pass@ORCL
/*-------------------TERCEIRA--FORMA-------------------------------------------*/
# yum search epel-release
# yum info epel-release
# yum install epel-release
/*--update the software packages and verify the installation of the EPEL repository --*/
# yum update
# rpm -qa | grep epel
sudo usermod -G vboxsf -a [yourusername]
sudo usermod -G vboxsf -a $USER
/*
1.Install Guest Additions
2.Add Shared Folder to VM configuration
3.Add user to the vboxsf group with command ‘sudo usermod -G vboxsf -a [yourusername]’
4.Reboot (or log out and back in) to have access.*/
rpm -qa | less
/*--Another way is to use the below command.--*/
yum list installed
Ao instalar a partir de um ISO que teve correções pontuais feitas nele, os cabeçalhos kernel-devel provavelmente serão uma versão mais recente do que o kernel que veio com o ISO.
Você precisa se certificar de que tudo está atualizado e em sincronia:
1.sudo yum update
2.sudo yum install binutils gcc make patch libgomp glibc-headers glibc-devel elfutils-libelf-devel kernel-headers kernel-devel
3.sudo reboot
4.Insert VBox Guest Additions again
fonte: https://superuser.com/questions/412527/modprobe-vboxguest-failed
/* All in one */
set lines 1000 pages 9999
COL instance_number FOR 9999 HEA 'Inst';
COL end_time HEA 'End Time';
COL plan_hash_value HEA 'Plan|Hash Value';
COL executions_total FOR 999,999 HEA 'Execs|Total';
COL rows_per_exec HEA 'Rows Per Exec';
COL et_secs_per_exec HEA 'Elap Secs|Per Exec';
COL cpu_secs_per_exec HEA 'CPU Secs|Per Exec';
COL io_secs_per_exec HEA 'IO Secs|Per Exec';
COL cl_secs_per_exec HEA 'Clus Secs|Per Exec';
COL ap_secs_per_exec HEA 'App Secs|Per Exec';
COL cc_secs_per_exec HEA 'Conc Secs|Per Exec';
COL pl_secs_per_exec HEA 'PLSQL Secs|Per Exec';
COL ja_secs_per_exec HEA 'Java Secs|Per Exec';
SELECT 'gv$dba_hist_sqlstat' source,h.instance_number,
TO_CHAR(CAST(s.begin_interval_time AS DATE), 'DD-MM-YYYY HH24:MI') snap_time,
TO_CHAR(CAST(s.end_interval_time AS DATE), 'DD-MM-YYYY HH24:MI') end_time,
h.sql_id,
h.plan_hash_value,
h.executions_total,
TO_CHAR(ROUND(h.rows_processed_total / h.executions_total), '999,999,999,999') rows_per_exec,
TO_CHAR(ROUND(h.elapsed_time_total / h.executions_total / 1e6, 3), '999,990.000') et_secs_per_exec,
TO_CHAR(ROUND(h.cpu_time_total / h.executions_total / 1e6, 3), '999,990.000') cpu_secs_per_exec,
TO_CHAR(ROUND(h.iowait_total / h.executions_total / 1e6, 3), '999,990.000') io_secs_per_exec,
TO_CHAR(ROUND(h.clwait_total / h.executions_total / 1e6, 3), '999,990.000') cl_secs_per_exec,
TO_CHAR(ROUND(h.apwait_total / h.executions_total / 1e6, 3), '999,990.000') ap_secs_per_exec,
TO_CHAR(ROUND(h.ccwait_total / h.executions_total / 1e6, 3), '999,990.000') cc_secs_per_exec,
TO_CHAR(ROUND(h.plsexec_time_total / h.executions_total / 1e6, 3), '999,990.000') pl_secs_per_exec,
TO_CHAR(ROUND(h.javexec_time_total / h.executions_total / 1e6, 3), '999,990.000') ja_secs_per_exec
FROM dba_hist_sqlstat h,
dba_hist_snapshot s
WHERE h.sql_id = '&sql_id'
AND h.executions_total > 0
AND s.snap_id = h.snap_id
AND s.dbid = h.dbid
AND s.instance_number = h.instance_number
UNION ALL
SELECT 'gv$sqlarea_plan_hash' source,h.inst_id,
TO_CHAR(sysdate, 'DD-MM-YYYY HH24:MI') snap_time,
TO_CHAR(sysdate, 'DD-MM-YYYY HH24:MI') end_time,
h.sql_id,
h.plan_hash_value,
h.executions,
TO_CHAR(ROUND(h.rows_processed / h.executions), '999,999,999,999') rows_per_exec,
TO_CHAR(ROUND(h.elapsed_time / h.executions / 1e6, 3), '999,990.000') et_secs_per_exec,
TO_CHAR(ROUND(h.cpu_time / h.executions / 1e6, 3), '999,990.000') cpu_secs_per_exec,
TO_CHAR(ROUND(h.USER_IO_WAIT_TIME / h.executions / 1e6, 3), '999,990.000') io_secs_per_exec,
TO_CHAR(ROUND(h.CLUSTER_WAIT_TIME / h.executions / 1e6, 3), '999,990.000') cl_secs_per_exec,
TO_CHAR(ROUND(h.APPLICATION_WAIT_TIME / h.executions / 1e6, 3), '999,990.000') ap_secs_per_exec,
TO_CHAR(ROUND(h.CLUSTER_WAIT_TIME / h.executions / 1e6, 3), '999,990.000') cc_secs_per_exec,
TO_CHAR(ROUND(h.PLSQL_EXEC_TIME / h.executions / 1e6, 3), '999,990.000') pl_secs_per_exec,
TO_CHAR(ROUND(h.JAVA_EXEC_TIME / h.executions / 1e6, 3), '999,990.000') ja_secs_per_exec
FROM gv$sqlarea_plan_hash h
WHERE h.sql_id = '&&sql_id'
AND h.executions > 0
order by source ;
/* AWR data */
set lines 1000 pages 9999
COL instance_number FOR 9999 HEA 'Inst';
COL end_time HEA 'End Time';
COL plan_hash_value HEA 'Plan|Hash Value';
COL executions_total FOR 999,999 HEA 'Execs|Total';
COL rows_per_exec HEA 'Rows Per Exec';
COL et_secs_per_exec HEA 'Elap Secs|Per Exec';
COL cpu_secs_per_exec HEA 'CPU Secs|Per Exec';
COL io_secs_per_exec HEA 'IO Secs|Per Exec';
COL cl_secs_per_exec HEA 'Clus Secs|Per Exec';
COL ap_secs_per_exec HEA 'App Secs|Per Exec';
COL cc_secs_per_exec HEA 'Conc Secs|Per Exec';
COL pl_secs_per_exec HEA 'PLSQL Secs|Per Exec';
COL ja_secs_per_exec HEA 'Java Secs|Per Exec';
SELECT h.instance_number,
TO_CHAR(CAST(s.begin_interval_time AS DATE), 'DD-MM-YYYY HH24:MI') snap_time,
TO_CHAR(CAST(s.end_interval_time AS DATE), 'DD-MM-YYYY HH24:MI') end_time,
h.sql_id,
h.plan_hash_value,
h.executions_total,
TO_CHAR(ROUND(h.rows_processed_total / h.executions_total), '999,999,999,999') rows_per_exec,
TO_CHAR(ROUND(h.elapsed_time_total / h.executions_total / 1e6, 3), '999,990.000') et_secs_per_exec,
TO_CHAR(ROUND(h.cpu_time_total / h.executions_total / 1e6, 3), '999,990.000') cpu_secs_per_exec,
TO_CHAR(ROUND(h.iowait_total / h.executions_total / 1e6, 3), '999,990.000') io_secs_per_exec,
TO_CHAR(ROUND(h.clwait_total / h.executions_total / 1e6, 3), '999,990.000') cl_secs_per_exec,
TO_CHAR(ROUND(h.apwait_total / h.executions_total / 1e6, 3), '999,990.000') ap_secs_per_exec,
TO_CHAR(ROUND(h.ccwait_total / h.executions_total / 1e6, 3), '999,990.000') cc_secs_per_exec,
TO_CHAR(ROUND(h.plsexec_time_total / h.executions_total / 1e6, 3), '999,990.000') pl_secs_per_exec,
TO_CHAR(ROUND(h.javexec_time_total / h.executions_total / 1e6, 3), '999,990.000') ja_secs_per_exec
FROM dba_hist_sqlstat h,
dba_hist_snapshot s
WHERE h.sql_id = '&sql_id'
AND h.executions_total > 0
AND s.snap_id = h.snap_id
AND s.dbid = h.dbid
AND s.instance_number = h.instance_number
ORDER BY
s.begin_interval_time,
s.end_interval_time;
/* AWR-LIO */
col execs for 999,999,999
col avg_etime for 999,999
col avg_lio for 999,999,999
col avg_pio for 999,999,999
col begin_interval_time for a30
col node for 99999
break on plan_hash_value on startup_time skip 1
select ss.snap_id, ss.instance_number node, begin_interval_time, sql_id, plan_hash_value,
nvl(executions_delta,0) execs,
(elapsed_time_delta/decode(nvl(executions_delta,0),0,1,executions_delta))/1000000 avg_etime,
(buffer_gets_delta/decode(nvl(buffer_gets_delta,0),0,1,executions_delta)) avg_lio,
ROUND(disk_reads_delta/DECODE(executions_delta,0,1, executions_delta),1) avg_pio,
ROUND(rows_processed_delta/DECODE(executions_delta,0, 1, executions_delta), 1) avg_rows,
round(px_servers_execs_delta/decode(executions_delta,0,1, executions_delta), 1) avg_px
from DBA_HIST_SQLSTAT S, DBA_HIST_SNAPSHOT SS
where sql_id = nvl('&sql_id','4dqs2k5tynk61')
and ss.snap_id = S.snap_id
and ss.instance_number = S.instance_number
and executions_delta > 0
order by 1, 2, 3;
/* Current Memory */
set linesize 999
col avg_et_secs justify right format 9999999.99
col cost justify right format 9999999999
col timestamp justify center format a25
col parsing_schema_name justify center format a30
col inst_id format 999999999
alter session set nls_date_format='dd-mm-yyyy hh24:mi:ss';
select 'gv$sqlarea_plan_hash' source, INST_ID, SQL_ID, PLAN_HASH_VALUE,
round(elapsed_time/decode(nvl(executions,0),0,1,executions)/1e6/
decode(px_servers_executions,0,1,px_servers_executions)/decode(nvl(executions,0),0,1,executions),2) avg_et_secs,
px_servers_executions/decode(nvl(executions,0),0,1,executions) avg_px,
optimizer_cost cost, LAST_LOAD_TIME timestamp, parsing_schema_name --FIRST_LOAD_TIME, LAST_LOAD_TIME, LAST_ACTIVE_TIME, SQL_PROFILE
from gv$sqlarea_plan_hash
where sql_id = nvl(trim('&sql_id'),sql_id)
UNION
SELECT 'dba_hist_sql_plan' source, null INST_ID, t1.sql_id sql_id, t1.plan_hash_value plan_hash_value, t2.avg_et_secs avg_et_secs, t2.avg_px, t1.cost cost, t1.timestamp timestamp, NULL parsing_schema_name
FROM dba_hist_sql_plan t1,
(
SELECT sql_id, plan_hash_value, --round(SUM(elapsed_time_total)/decode(SUM(executions_total),0,1,SUM(executions_total))/1e6,2) avg_et_secs
round(SUM(elapsed_time_total)/decode(SUM(executions_total),0,1,SUM(executions_total))/1e6/
decode(SUM(px_servers_execs_total),0,1,SUM(px_servers_execs_total))/decode(SUM(executions_total),0,1,SUM(executions_total)),2) avg_et_secs,
SUM(px_servers_execs_total)/decode(SUM(executions_total),0,1,SUM(executions_total)) avg_px
FROM dba_hist_sqlstat
WHERE
executions_total > 0
GROUP BY sql_id, plan_hash_value
) t2
WHERE
t1.sql_id = nvl(TRIM('&sql_id'), t1.sql_id)
AND t1.depth = 0
AND t1.sql_id = t2.sql_id(+)
AND t1.plan_hash_value = t2.plan_hash_value(+)
order by avg_et_secs, cost;
/* Sql_monitor report */
set pagesize 0 echo off timing off linesize 1000 trimspool on trim on long 2000000 longchunksize 2000000
select
DBMS_SQLTUNE.REPORT_SQL_MONITOR(
sql_id=>'&sql_id',
report_level=>'ALL',
type=>'TEXT')
from dual;
/* Elapsed/CPU/Read/Write MB */
SELECT *
FROM
(SELECT status,
--username,
sql_id,
sql_exec_id,
TO_CHAR(sql_exec_start,'dd-mon-yyyy hh24:mi:ss') AS sql_exec_start,
ROUND(elapsed_time/1000000) AS ""Elapsed (s)"",
ROUND(cpu_time /1000000) AS ""CPU (s)"",
buffer_gets,
ROUND(physical_read_bytes /(1024*1024)) AS ""Phys reads (MB)"",
ROUND(physical_write_bytes/(1024*1024)) AS ""Phys writes (MB)""
FROM gv$sql_monitor where sql_id='&sql_id' and inst_id=&inst_id
ORDER BY elapsed_time DESC
)
WHERE rownum<=20;
/* Each Layer time spend */
SELECT ROUND(elapsed_time /1000000) AS ""Elapsed (s)"",
ROUND(cpu_time /1000000,3) AS ""CPU (s)"",
ROUND(queuing_time /1000000,3) AS ""Queuing (s)"",
ROUND(application_wait_time/1000000,3) AS ""Appli wait (s)"",
ROUND(concurrency_wait_time/1000000,3) AS ""Concurrency wait (s)"",
ROUND(cluster_wait_time /1000000,3) AS ""Cluster wait (s)"",
ROUND(user_io_wait_time /1000000,3) AS ""User io wait (s)"",
ROUND(physical_read_bytes /(1024*1024)) AS ""Phys reads (MB)"",
ROUND(physical_write_bytes /(1024*1024)) AS ""Phys writes (MB)"",
buffer_gets AS ""Buffer gets"",
ROUND(plsql_exec_time/1000000,3) AS ""Plsql exec (s)"",
ROUND(java_exec_time /1000000,3) AS ""Java exec (s)""
FROM gv$sql_monitor
WHERE sql_id='&sql_id' and inst_id=&inst_id;
/* Explain Plan waiting steps */
col PLAN FOR a150
SELECT
RPAD('(' || p.plan_line_ID || ' ' || NVL(p.plan_parent_id,'0') || ')',8) || '|' ||
RPAD(LPAD (' ', 2*p.plan_DEPTH) || p.plan_operation || ' ' || p.plan_options,60,'.') ||
NVL2(p.plan_object_owner||p.plan_object_name, '(' || p.plan_object_owner|| '.' || p.plan_object_name || ') ', '') ||
NVL2(p.plan_COST,'Cost:' || p.plan_COST,'') || ' ' ||
NVL2(p.plan_bytes||p.plan_CARDINALITY,'(' || p.plan_bytes || ' bytes, ' || p.plan_CARDINALITY || ' rows)','') || ' ' ||
NVL2(p.plan_partition_start || p.plan_partition_stop,' PStart:' || p.plan_partition_start || ' PStop:' || p.plan_partition_stop,'') ||
NVL2(p.plan_time, p.plan_time || '(s)','') AS PLAN
FROM gv$sql_plan_monitor p
WHERE sql_id='&sql_id'
ORDER BY p.plan_line_id, p.plan_parent_id;
/* v$sqlarea/v$sql */
set lines 1500 pages 9999
column sid format 9999
column username format a15
column PARSING_SCHEMA_NAME format a15
column SQL_EXEC_START for a21
column sql_text format a50
column module format a35
select a.inst_id,a.sid,a.username,b.PARSING_SCHEMA_NAME,a.module,a.sql_id,a.sql_child_number child,b.plan_hash_value,to_char (a.sql_exec_start, 'dd-Mon-yyyy hh24:mi:ss') sql_exec_start,(sysdate-sql_exec_start)*24*60*60 SECS,b.rows_processed,a.status,substr(b.sql_text,1,50) sql_text
from gv$session a,gv$sqlarea b
where a.sql_hash_value = b.hash_value
and a.sql_address = b.address
and a.module not like '%emagent%'
and a.module not like '%oraagent.bin%'
and sql_text not like '%b.PARSING_SCHEMA_NAME%'
and a.username is not null
order by a.status;
/* ASH */
column my_sid format 999
column my_ser format 99999
column my_state format a30
column my_blkr format 999
select to_char(a.sample_time, 'HH24:MI:SS') MY_TIME,a.session_id MY_SID,a.session_serial# MY_SER,
DECODE(a.session_state, 'WAITING' ,a.event, a.session_state) MY_STATE,a.xid, a.sql_id,
a.blocking_session MY_BLKR
from gv$active_session_history a, dba_users u
where u.user_id = a.user_id
and a.sql_id = '&sql_id'
and a.sample_time > SYSTIMESTAMP-(2/1440);
/* AWR */
set lines 1000 pages 9999
SELECT s.snap_id,TO_CHAR(s.begin_interval_time, 'DD-MON HH24:MI') snap_time,ss.sql_id,ss.plan_hash_value,
ss.ROWS_PROCESSED_TOTAL,
ss.executions_delta execs,
(ss.elapsed_time_delta/1000000)/DECODE(ss.executions_delta,0,1,ss.executions_delta) ela_per_exec,
(ss.cpu_time_delta /1000000)/DECODE(ss.executions_delta,0,1,ss.executions_delta) cpu_per_exec,
ss.buffer_gets_delta /DECODE(ss.executions_delta,0,1,ss.executions_delta) lio_per_exec,
ss.disk_reads_delta /DECODE(ss.executions_delta,0,1,ss.executions_delta) pio_per_exec
FROM dba_hist_snapshot s,
dba_hist_sqlstat ss
WHERE ss.dbid = s.dbid
AND ss.instance_number = s.instance_number
AND ss.snap_id = s.snap_id
AND ss.sql_id = nvl('&sql_id','4dqs2k5tynk61')
/* and ss.executions_delta > 0 */
/* check executions_delta for 1 , if it is 0 just consider only rows proceesed and calculate total execution time = sum ( executions_delta 1 + executions_delta 0 ) */
ORDER BY s.snap_id;
select
s.sql_id,
sum(case
when begin_interval_time = to_date('14-nov-2017 1100','dd-mon-yyyy hh24mi') then s.executions_total
else 0
end) sum_after,
(sum(case
when begin_interval_time >= to_date('14-nov-2017 1100','dd-mon-yyyy hh24mi') then s.executions_total
else 0
end) -
sum(case
when begin_interval_time < to_date('14-nov-2017 1100','dd-mon-yyyy hh24mi') then s.executions_total
else 0
end)) difference
from
dba_hist_sqlstat s,
dba_hist_snapshot sn
where
sn.begin_interval_time between to_date('05-nov-2017 0001','dd-mon-yyyy hh24mi')
and
to_date('05-nov-2017 2359','dd-mon-yyyy hh24mi')
and
sn.snap_id=s.snap_id
group by
s.sql_id
order by
difference desc;
/* Time based */
select * from
(
select
sql_id,
sql_plan_hash_value,
event,sql_exec_id,
sql_exec_start,current_obj#,
sql_plan_line_id,
sql_plan_operation,
sql_plan_options,
SUM (delta_read_io_requests) lio_read ,
SUM (delta_read_io_bytes) pio_read ,
count(*) count_1
from
dba_hist_active_sess_history
where
sql_id='&sql_id'
group by
sql_id,
sql_plan_hash_value,
event,sql_exec_id,
sql_exec_start,
current_obj#,
sql_plan_line_id,
sql_plan_operation,
sql_plan_options
)
order by count_1 desc;
SELECT *
FROM
(SELECT status,
username,
sql_id,
sql_exec_id,
TO_CHAR(sql_exec_start,'dd-mon-yyyy hh24:mi:ss') AS sql_exec_start,
ROUND(elapsed_time/1000000) AS "Elapsed (s)",
ROUND(cpu_time /1000000) AS "CPU (s)",
buffer_gets,
ROUND(physical_read_bytes /(1024*1024)) AS "Phys reads (MB)",
ROUND(physical_write_bytes/(1024*1024)) AS "Phys writes (MB)"
FROM v$sql_monitor
ORDER BY elapsed_time DESC
)
WHERE rownum<=20;
SQL> select count(*) from hr.employees;
SQL> select namespace,pins,reloads,invalidations from v$librarycache;
SQL> ANALYZE TABLE hr.employees COMPUTE STATISTICS;
SQL> select count(*) from hr.employees;
SQL> select namespace,pins,reloads,invalidations from v$librarycache;
// When Invalidations Occur ?
when a table, sequence, synonym, or view is re-created or altered or dropped, or a procedure or package specification is recompiled, all dependent shared SQL areas are invalidated.
Additional V$SQL_PLAN columns not found in PLAN_TABLE:
• ADDRESS: Cursor parent handle address
• HASH_VALUE: Parent statement hash value in library cache
• CHILD_NUMBER: Number using this execution plan
• DEPTH: Level of the operation in the tree
• CPU_COST: CPU cost of the operation as estimated by the cost-based optimizer. If using the rule-based optimizer, this column is null.
• IO_COST: Cost of the operation as estimated by the cost-based optimizer. If using the rule-based optimizer, this column is Null.
• TEMP_SPACE: Space usage of sort or hash-join estimated by cost-based optimizer
SET LINESIZE 100
COLUMN trace_file FORMAT A60
SELECT s.sid,
s.serial#,
pa.value || '/' || LOWER(SYS_CONTEXT('userenv','instance_name')) ||
'_ora_' || p.spid || '.trc' AS trace_file
FROM v$session s,
v$process p,
v$parameter pa
WHERE pa.name = 'user_dump_dest'
AND s.paddr = p.addr
AND s.audsid = SYS_CONTEXT('USERENV', 'SESSIONID');
select metric_name, round(value,2) from v$sysmetric
where metric_name in ('Database CPU Time Ratio', 'Database Wait Time Ratio')
and intsize_csec = (select max(INTSIZE_CSEC) FROM V$SYSMETRIC);
SELECT
STAT_NAME,
DECODE(STAT_NAME,'PHYSICAL_MEMORY_BYTES',(ROUND(VALUE/1024/1024/1024,2))
|| ' GB','FREE_MEMORY_BYTES',(ROUND(VALUE /1024/1024/1024,2))
|| ' GB',VALUE ) VALUE
FROM
v$osstat
WHERE
stat_name IN ( 'FREE_MEMORY_BYTES', 'LOAD', 'NUM_CPUS', 'NUM_CPU_CORES', 'NUM_CPU_SOCKETS', 'PHYSICAL_MEMORY_BYTES' );
SET TERMOUT ON FEEDBACK OFF VERIFY OFF NUMWIDTH 20 PAGES 500 LINES 200
VAR SQLTX VARCHAR2(4000)
DEFINE P_HASH=&1.
DEFINE P_SQL_ID=&1.
COL PARSING_SCHEMA_NAME FORMAT A20 HEAD "Usuário"
COL VERSION_COUNT FORMAT 999G999 HEAD "Versões"
COL EXECUTIONS FORMAT 99G999G999 HEAD "Execuções"
COL ROWS_PROCESSED FORMAT 999G999G999 HEAD "Linhas|Processadas"
COL DISK_READS FORMAT 999G999G999 HEAD "Leituras|Físicas"
COL BUFFER_GETS FORMAT 99G999G999G999 HEAD "Leituras|Lógicas"
COL DR_EXEC FORMAT 99G999G999 HEAD "Leit. Fís.|/Execuções"
COL BG_EXEC FORMAT 99G999G999 HEAD "Leit. Lógica|/Execuções"
COL SHARABLE_MEM FORMAT 99G999G999 HEAD "Memória|Compartilhada"
COL SQLX FORMAT A121 HEAD "Comando de SQL" WORD_WRAP NEW_VALUE P_SQL
COL PLAN_HASH_VALUE FORMAT 99999999999999
COL dw_exec FORMAT 99G999G999 HEAD "Direct|Writes/Exec"
COL ADDRESS NEW_VALUE P_ADDR NOPRINT
COL HASH_VALUE NEW_VALUE P_HASH2 NOPRINT FORMAT 99999999999999
SET HEAD OFF
SELECT LPAD( '~', 121, '~' ) FROM DUAL;
SET HEAD ON
SELECT
ADDRESS, HASH_VALUE/*, PLAN_HASH_VALUE*/, VERSION_COUNT, EXECUTIONS, ROWS_PROCESSED,
DISK_READS, ROUND(DISK_READS/DECODE(EXECUTIONS,0,1,EXECUTIONS),2) DR_EXEC,
BUFFER_GETS, ROUND(BUFFER_GETS/DECODE(EXECUTIONS,0,1,EXECUTIONS),2) BG_EXEC,
--ROUND( SHARABLE_MEM/1048576 ) SHARABLE_MEM,
ROUND(DIRECT_WRITES/DECODE(EXECUTIONS,0,1,EXECUTIONS),2) DW_exec , SQL_ID
FROM V$SQLAREA
WHERE ( SQL_ID= '&P_SQL_ID.' )
ORDER BY ADDRESS
/
DECLARE
V_AUX VARCHAR2(100);
BEGIN
:SQLTX := '' ;
FOR C IN ( SELECT SQL_TEXT FROM V$SQLTEXT_WITH_NEWLINES
WHERE HASH_VALUE = &P_HASH2. AND ADDRESS = '&P_ADDR'
ORDER BY PIECE ) LOOP
V_AUX := C.SQL_TEXT;
EXIT WHEN ( LENGTH( V_AUX ) + LENGTH( :SQLTX ) ) > 3000;
:SQLTX := :SQLTX || V_AUX;
END LOOP;
IF :SQLTX IS NULL THEN
:SQLTX := 'Comando Não Encontrado';
END IF;
END;
/
SELECT TRIM(:SQLTX) || ';' SQLX FROM DUAL
/
SET HEAD OFF
SELECT LPAD( '~', 121, '~' ) FROM DUAL;
SET HEAD ON
PROMPT
SET PAGES 100 FEEDBACK 6 VERIFY ON
UNDEFINE P_SQL
UNDEFINE P_SQL_ID
UNDEFINE P_HASH
UNDEFINE P_HASH2
UNDEFINE P_ADDR
SELECT *
FROM
(SELECT status,
username,
sql_id,
sql_exec_id,
TO_CHAR(sql_exec_start,'dd-mon-yyyy hh24:mi:ss') AS sql_exec_start,
ROUND(elapsed_time/1000000) AS "Elapsed (s)",
ROUND(cpu_time /1000000) AS "CPU (s)",
buffer_gets,
ROUND(physical_read_bytes /(1024*1024)) AS "Phys reads (MB)",
ROUND(physical_write_bytes/(1024*1024)) AS "Phys writes (MB)"
FROM gv$sql_monitor
--WHERE sid=&sid and inst_id=&inst_id
ORDER BY elapsed_time DESC
)
WHERE rownum<=20;
-- ---------------------------------------------------------------------------------------------------
SELECT ROUND(elapsed_time /1000000) AS "Elapsed (s)",
ROUND(cpu_time /1000000,3) AS "CPU (s)",
ROUND(queuing_time /1000000,3) AS "Queuing (s)",
ROUND(user_io_wait_time /1000000,3) AS "I/O wait (s)",
ROUND(application_wait_time/1000000,3) AS "Appli wait (s)",
ROUND(concurrency_wait_time/1000000,3) AS "Concurrency wait (s)",
ROUND(cluster_wait_time /1000000,3) AS "Cluster wait (s)",
ROUND(physical_read_bytes /(1024*1024)) AS "Phys reads (MB)",
ROUND(physical_write_bytes /(1024*1024)) AS "Phys writes (MB)",
buffer_gets AS "Buffer gets",
ROUND(plsql_exec_time/1000000,3) AS "Plsql exec (s)",
ROUND(java_exec_time /1000000,3) AS "Java exec (s)"
FROM gv$sql_monitor
WHERE sid=&sid and inst_id=&inst_id;
-- ---------------------------------------------------------------------------------------------------
col PLAN FOR a150
SELECT
RPAD('(' || p.plan_line_ID || ' ' || NVL(p.plan_parent_id,'0') || ')',8) || '|' ||
RPAD(LPAD (' ', 2*p.plan_DEPTH) || p.plan_operation || ' ' || p.plan_options,60,'.') ||
NVL2(p.plan_object_owner||p.plan_object_name, '(' || p.plan_object_owner|| '.' || p.plan_object_name || ') ', '') ||
NVL2(p.plan_COST,'Cost:' || p.plan_COST,'') || ' ' ||
NVL2(p.plan_bytes||p.plan_CARDINALITY,'(' || p.plan_bytes || ' bytes, ' || p.plan_CARDINALITY || ' rows)','') || ' ' ||
NVL2(p.plan_partition_start || p.plan_partition_stop,' PStart:' || p.plan_partition_start || ' PStop:' || p.plan_partition_stop,'') ||
NVL2(p.plan_time, p.plan_time || '(s)','') AS PLAN
FROM gv$sql_plan_monitor p
WHERE sid=&sid
ORDER BY p.plan_line_id, p.plan_parent_id;
col WAIT_CLASS for a10
SELECT sw.inst_id,NVL(s.username, '(oracle)') AS username,
s.sid,
s.serial#,
sw.event,
sw.wait_class,
sw.wait_time,
sw.seconds_in_wait,
sw.state
FROM gv$session_wait sw,
gv$session s
WHERE s.sid = sw.sid and s.inst_id=sw.inst_id and s.sid=&sid
ORDER BY sw.seconds_in_wait DESC;
-- ---------------------------------------------------------------------------------------------------
COLUMN username FORMAT A20
COLUMN sid FORMAT 9999
COLUMN serial# FORMAT 9999
COLUMN event FORMAT A40;
SELECT NVL(s.username, '(oracle)') AS username,
s.sid,
s.serial#,
se.event,
se.total_waits,
se.total_timeouts,
se.time_waited,
se.average_wait,
se.max_wait,
se.time_waited_micro
FROM v$session_event se,
v$session s
WHERE s.sid = se.sid
AND s.sid = &Session_ID
ORDER BY se.time_waited DESC;
-- ---------------------------------------------------------------------------------------------------
select stat_name, value
from V$SESS_TIME_MODEL
where sid = &sid
order by value desc;
-- ---------------------------------------------------------------------------------------------------
select vsn.name, vst.value
from v$sesstat vst, v$statname vsn
where vsn.statistic# = vst.statistic#
and vst.value != 0
and vst.sid = &sid
order by vst.value;
SELECT a.sid,RPAD(a.opname,30),a.sofar,a.totalwork,a.ELAPSED_SECONDS,ROUND(((a.sofar)*100)/a.totalwork,3) "%_COMPLETED",
RPAD(a.username,10) username,a.SQL_HASH_VALUE,B.STATUS
FROM gV$SESSION_LONGOPS a, gv$session b
WHERE a.sid=b.sid
--AND a.sid=&sid
--AND b.status='ACTIVE'
AND a.sofar<> a.totalwork;
-- ---------------------------------------------------------------------------------------------------
set pages 50000 lines 32767
col OPNAME for a10
col SID form 9999
col SERIAL form 9999999
col PROGRAM for a10
col USERNAME for a10
col SQL_TEXT for a40
col START_TIME for a10
col LAST_UPDATE_TIME for a10
col TARGET for a25
col MESSAGE for a25
alter session set nls_date_format = 'DD-MM-YYYY HH24:MI:SS';
SELECT inst_id,sid, serial#, sql_id, opname, username, target, sofar, totalwork, start_time,last_update_time,round(time_remaining/60,2) "REMAIN MINS", round(elapsed_seconds/60,2) "ELAPSED MINS", round((time_remaining+elapsed_seconds)/60,2) "TOTAL MINS", ROUND(SOFAR/TOTALWORK*100,2) "%_COMPLETE", message
FROM gv$session_longops
WHERE OPNAME NOT LIKE 'RMAN%'
AND OPNAME NOT LIKE '%aggregate%'
AND TOTALWORK != 0
AND sofar<>totalwork
AND time_remaining > 0;
-- ---------------------------------------------------------------------------------------------------
COLUMN sid FORMAT 99999
COLUMN serial# FORMAT 9999999
COLUMN machine FORMAT A30
COLUMN progress_pct FORMAT 99999999.00
COLUMN elapsed FORMAT A10
COLUMN remaining FORMAT A10
SELECT s.sid,
s.serial#,
s.machine,
ROUND(sl.elapsed_seconds/60) || ':' || MOD(sl.elapsed_seconds,60) elapsed,
ROUND(sl.time_remaining/60) || ':' || MOD(sl.time_remaining,60) remaining,
ROUND(sl.sofar/sl.totalwork*100, 2) progress_pct
FROM gv$session s,
gv$session_longops sl
WHERE s.sid = sl.sid
AND s.serial# = sl.serial#;
-- ---------------------------------------------------------------------------------------------------
SELECT SID, SERIAL#, OPNAME, TARGET, SOFAR, TOTALWORK, UNITS,
TO_CHAR(START_TIME,'DD/MON/YYYY HH24:MI:SS') START_TIME,
TO_CHAR(LAST_UPDATE_TIME,'DD/MON/YYYY HH24:MI:SS') LAST_UPDATE_TIME,
TIME_REMAINING, ELAPSED_SECONDS, MESSAGE, USERNAME
FROM V$SESSION_LONGOPS
WHERE TIME_REMAINING != 0;
set lines 1000 pages 9999
column sid format 9999
column serial for 999999
column status format a15
column username format a20
column sql_text format a80
col program for a33
col SQL_EXEC_START for a20
SELECT * FROM
(SELECT status,inst_id,sid,SESSION_SERIAL# as Serial,username,sql_id,SQL_PLAN_HASH_VALUE,program,
TO_CHAR(sql_exec_start,'dd-mon-yyyy hh24:mi:ss') AS sql_exec_start,
ROUND(elapsed_time/1000000) AS "Elapsed (s)",
ROUND(cpu_time /1000000) AS "CPU (s)",
substr(sql_text,1,30) sql_text
FROM gv$sql_monitor where module not like '%emagent%'
-- and sid=&sid
ORDER BY sql_exec_start desc
);
set linesize 750 pages 9999
column box format a30
column spid format a10
column username format a20
column program format a30
column os_user format a20
col LOGON_TIME for a20
select b.inst_id,b.sid,b.serial#,a.spid, substr(b.machine,1,30) box,to_char (b.logon_time, 'dd-mon-yyyy hh24:mi:ss') logon_time,
substr(b.username,1,20) username,
substr(b.osuser,1,20) os_user,
substr(b.program,1,30) program,status,b.last_call_et AS last_call_et_secs,b.sql_id
from gv$session b,gv$process a
where b.paddr = a.addr
and a.inst_id = b.inst_id
and type='USER'
and b.sid=&sid
order by logon_time;
SELECT report_id, key1 sql_id, key2 sql_exec_id, key3 sql_exec_start
FROM dba_hist_reports
WHERE component_name = 'sqlmonitor';
column text_line format a254
set lines 750 pages 9999
set long 20000 longchunksize 20000
select dbms_sqltune.report_sql_monitor_list() text_line from dual;
select dbms_sqltune.report_sql_monitor() text_line from dual;
set lines 1000 pages 9999
column sid format 9999
column serial for 999999
column status format a15
column username format a10
column sql_text format a80
column module format a30
col program for a30
col SQL_EXEC_START for a20
SELECT * FROM
(SELECT status,inst_id,sid,SESSION_SERIAL# as Serial,username,sql_id,SQL_PLAN_HASH_VALUE,
MODULE,program,
TO_CHAR(sql_exec_start,'dd-mon-yyyy hh24:mi:ss') AS sql_exec_start,
ROUND(elapsed_time/1000000) AS "Elapsed (s)",
ROUND(cpu_time /1000000) AS "CPU (s)",
substr(sql_text,1,30) sql_text
FROM gv$sql_monitor where module not like '%emagent%'
ORDER BY sql_exec_start desc
)
WHERE rownum<=20;
set lines 1000 pages 9999
column sid format 9999
column serial for 999999
column status format a15
column username format a10
column sql_text format a80
column module format a30
col program for a30
col SQL_EXEC_START for a20
SELECT * FROM
(SELECT status,inst_id,sid,SESSION_SERIAL# as Serial,username,sql_id,SQL_PLAN_HASH_VALUE,
MODULE,program,
TO_CHAR(sql_exec_start,'dd-mon-yyyy hh24:mi:ss') AS sql_exec_start,
ROUND(elapsed_time/1000000) AS "Elapsed (s)",
ROUND(cpu_time /1000000) AS "CPU (s)",
substr(sql_text,1,30) sql_text
FROM gv$sql_monitor where status='EXECUTING' and module not like '%emagent%'
ORDER BY sql_exec_start desc
);
set pages 500
set linesize 750
column box format a30
column spid format a10
column username format a30
column program format a30
column os_user format a20
select b.sid,b.serial#,a.spid, substr(b.machine,1,30) box,b.logon_time logon_date , to_char (b.logon_time, 'hh24:mi:ss') logon_time,
substr(b.username,1,30) username, substr(b.osuser,1,20) os_user, substr(b.program,1,30) program,status,b.last_call_et AS last_call_et_secs,b.sql_id
from v$session b,v$process a
where b.paddr = a.addr
and type='USER'
order by b.sid;
set linesize 750 pages 9999
column box format a30
column spid format a10
column username format a30
column program format a30
column os_user format a20
col LOGON_TIME for a20
select b.inst_id,b.sid,b.serial#,a.spid, substr(b.machine,1,30) box,to_char (b.logon_time, 'dd-mon-yyyy hh24:mi:ss') logon_time,
substr(b.username,1,30) username,
substr(b.osuser,1,20) os_user,
substr(b.program,1,30) program,status,b.last_call_et AS last_call_et_secs,b.sql_id
from gv$session b,gv$process a
where b.paddr = a.addr
and a.inst_id = b.inst_id
and type='USER'
order by logon_time;
set lines 750 pages 9999
break on report
compute SUM of tot on report
compute SUM of active on report
compute SUM of inactive on report
col username for a50
select DECODE(username,NULL,'INTERNAL',USERNAME) Username,
count(*) TOT,
COUNT(DECODE(status,'ACTIVE',STATUS)) ACTIVE,
COUNT(DECODE(status,'INACTIVE',STATUS)) INACTIVE
from gv$session
where status in ('ACTIVE','INACTIVE')
group by username;
set lines 200
set pages 200
col file_name for a50
col tablespace_name for a30
col status for a21
compute sum of "Total(Mb)" on report
compute sum of "Free(Mb)" on report
break on report
SELECT t.tablespace_name,
ts.contents,
ts.status,
round(nvl(t.bytes,0)/1024/1024,1) "Total(Mb)",
round((nvl(nvl(f.free,ft.free),0)/1024/1024),1) "Free(Mb)",
round((nvl(nvl(f.free,ft.free),0)*100/t.bytes),1) "% Free",
decode((case when round((nvl(nvl(f.free,ft.free),0)/1024/1024/1024))>=5 then 'OK' else 'NOK' end),'OK','OK',decode(contents,'UNDO','OK - UNDO TABLESPACE',decode(contents,'TEMPORARY','OK - TEMP TABLESPACE',decode(round((nvl(nvl(f.free,ft.free),0)*100)/t.bytes) ,'0','CRITICAL','1','CRITICAL','2','CRITICAL','3','CRITICAL','4','CRITICAL','5','WARNING','6','WARNING','7','WARNING','8','WARNING','9','WARNING','OK'))))
STATUS
FROM (SELECT d.tablespace_name,
sum(d.bytes) bytes
FROM dba_data_files d
GROUP BY tablespace_name
UNION
SELECT d.tablespace_name,
sum(d.bytes) bytes
FROM dba_TEMP_files d
GROUP BY tablespace_name) t,
(SELECT tablespace_name,
sum(bytes) free
FROM dba_free_space
GROUP BY tablespace_name) f,
(select TABLESPACE_NAME,
sum(bytes_free) free
from V$TEMP_SPACE_HEADER
group by tablespace_name) ft,
dba_tablespaces ts
WHERE t.tablespace_name = f.tablespace_name(+)
AND t.tablespace_name = ft.tablespace_name(+)
AND t.tablespace_name = ts.tablespace_name
ORDER BY 5;
select owner
, job_name
, job_action
, state, failure_count
, max_failures --qtd de falhas que deve ter para ficar broken
, TO_CHAR(last_start_date, 'dd/mm/yyyy hh24:mi:ss') last_start_date
, TO_CHAR(next_run_date, 'dd/mm/yyyy hh24:mi:ss') next_run_date
, last_run_duration
from dba_scheduler_jobs
where job_name='SYNC';
set linesize 2000;
set pagesize 1000;
set long 9999999;
set ECHO off;
set FEED off;
set HEAD off;
set time off;
COLUMN DDL FORMAT a9999;
spool PAGAMENTO_CONTA_CORRENTE.bkp
exec dbms_metadata.set_transform_param(dbms_metadata.session_transform,'SQLTERMINATOR',true);
select dbms_metadata.get_ddl('TABLE','PAGAMENTO_CONTA_CORRENTE','TS') "DDL" from dual;
spool off
set FEED on;
set HEAD on;
set time on;
select count(*) from gv$session where lockwait is not null;
alter system enable restricted session;
alter system disable restricted session;
select logins, active_state from v$instance;
select
decode(BACKUP_TYPE, 'L', 'ARCH', 'D', 'DB', 'I', 'INC','Unknown type='||BACKUP_TYPE) TYPE,
to_char(a.start_time, 'DDMON HH24:MI') start_time,
to_char(a.elapsed_seconds/60, '99.9')||' Min' DURATION,
substr(handle, -35) handle,
nvl(d.file#, l.sequence#) file#, nvl(d.blocks, l.blocks) blocks
from
SYS.V_$BACKUP_SET a, SYS.V_$BACKUP_PIECE b,
SYS.V_$BACKUP_DATAFILE d, SYS.V_$BACKUP_REDOLOG l
where
a.start_time between sysdate-1 and sysdate
and a.SET_STAMP = b.SET_STAMP
and a.SET_STAMP = d.SET_STAMP(+)
and a.SET_STAMP = l.SET_STAMP(+)
order
by start_time, file#
;
SELECT
ctime "Date",
Decode(
backup_type, 'L', 'Archive Log', 'D',
'Full', 'Incremental'
) backup_type,
bsize "Size GB"
FROM
(
SELECT
Trunc(bp.completion_time) ctime,
backup_type,
Round( SUM(bp.bytes / 1024 / 1024 /1024 ), 2 ) bsize
FROM
v$backup_set bs,
v$backup_piece bp
WHERE
bs.set_stamp = bp.set_stamp
AND bs.set_count = bp.set_count
AND bp.status = 'A'
GROUP BY
Trunc(bp.completion_time),
backup_type
)
ORDER BY 1, 2;
Date BACKUP_TYPE Size GB
-------- ----------- ----------
13/04/21 Full 103,16
14/04/21 Full 103,19
15/04/21 Full 103,4
17/04/21 Archive Log 1,5
17/04/21 Full 124,78
18/04/21 Archive Log 1,49
18/04/21 Full 124,85
19/04/21 Archive Log 6,84
19/04/21 Full 125,07
-- Localização do TNS NAMES
$ORACLE_HOME/network/admin
/u01/app/oracle/product/version/dbname/network/admin/tnsnames.ora
CREATE DATABASE LINK nome_do_dblink CONNECT TO usuário_banco_remoto IDENTIFIED BY senha USING ‘connect_string’;
connect_string =
(DESCRIPTION =
(ADDRESS = (PROTOCOL = TCP)(HOST = NOME_SERVIDOR_DE_BANCO)(PORT = 1521))
(CONNECT_DATA =
(SERVER = DEDICATED)
(SERVICE_NAME = SERVICO)
)
)
-- Criando o Database Link não tendo uma string de conexão:
CREATE DATABASE LINK "usuário_banco_remoto.WORLD"
CONNECT TO "usuário_banco_remoto" IDENTIFIED BY senha
USING '(DESCRIPTION=
(ADDRESS=(PROTOCOL=TCP)(HOST=NOME_SERVIDOR_DE_BANCO)(PORT=1521))
(CONNECT_DATA=
(SERVER = DEDICATED)
(SERVICE_NAME=SERVICO)
)
)';
begin
dbms_output.put_line('GRANTS: started...');
for x in (select 'GRANT SELECT ON '||owner||'.'||table_name||' to USUARIO_RECEBEDOR' sql_stmt
from all_tables
where owner='USUARIO_DOADOR' )
loop
dbms_output.put_line( x.sql_stmt );
execute immediate x.sql_stmt;
dbms_output.put_line( 'success: ' || x.sql_stmt );
end loop;
dbms_output.put_line('GRANTS: completed.');
end;
SET VERIFY OFF
COL OBJETO FORMAT A8
--COL OWNER FORMAT A15
SELECT 'TABELA' OBJETO, LAST_ANALYZED, TABLE_NAME OBJET_NAME, NUM_ROWS, NULL BLEVEL, NULL DISTINCT_KEYS, CHAIN_CNT, INI_TRANS
FROM DBA_TABLES WHERE OWNER= UPPER( '&&1.' ) AND TABLE_NAME LIKE UPPER( '&&2.')
UNION ALL
SELECT 'INDICE', LAST_ANALYZED, INDEX_NAME, NUM_ROWS, BLEVEL, DISTINCT_KEYS, NULL, INI_tRANS
FROM DBA_INDEXES
WHERE TABLE_OWNER= UPPER( '&1.' ) AND TABLE_NAME LIKE UPPER( '&2.')
AND INDEX_NAME NOT LIKE 'SYS_IL%'
ORDER BY 1 DESC, 2 DESC
/
SET VERIFY ON
COL OBJETO CLEAR
--COL OWNER CLEAR
UNDEFINE 1 2
SELECT username FROM dba_users;
SELECT username
FROM dba_users u
WHERE EXISTS (
SELECT 1
FROM dba_objects o
WHERE o.owner = u.username );
SELECT username
FROM dba_users
WHERE default_tablespace not in ('SYSTEM','SYSAUX');
-- Excluindo da consulta os usuários nativos do SGBD Oracle --
SELECT username
FROM dba_users
WHERE username NOT IN('QS_CB','PERFSTAT','QS_ADM','PM','SH','HR','OE','ODM_MTR','WKPROXY','ANONYMOUS','OWNER',
'SYS','SYSTEM','SCOTT','SYSMAN','XDB','DBSNMP','EXFSYS','OLAPSYS','MDSYS','WMSYS','WKSYS','DMSYS','ODM','EXFSYS',
'CTXSYS','LBACSYS','ORDPLUGINS','SQLTXPLAIN','OUTLN','TSMSYS','XS$NULL','TOAD','STREAM','SPATIAL_CSW_ADMIN',
'SPATIAL_WFS_ADMIN','SI_INFORMTN_SCHEMA','QS','QS_CBADM','QS_CS','QS_ES','QS_OS','QS_WS','PA_AWR_USER',
'OWBSYS_AUDIT','OWBSYS','ORDSYS','ORDDATA','ORACLE_OCM','MGMT_VIEW','MDDATA','FLOWS_FILES','FLASHBACK',
'AWRUSER','APPQOSSYS','APEX_PUBLIC_USER','APEX_030200','FLOWS_020100');
SELECT username
FROM dba_users u
WHERE EXISTS (
SELECT 1
FROM dba_objects o
WHERE o.owner = u.username )
AND default_tablespace not in ('SYSTEM','SYSAUX');
SELECT distinct owner
FROM dba_segments
WHERE owner in (SELECT username FROM dba_users WHERE default_tablespace not in ('SYSTEM','SYSAUX'));
COL NAME FORMAT A20 HEAD "Parâmetro"
COL VALUE FORMAT A30 HEAD "Valor"
COL PLAN_TABLE_OUTPUT FORMAT A165 HEAD "Plano de Execução"
SELECT NAME, UPPER(VALUE) VALUE
FROM V$PARAMETER
WHERE NAME IN ( 'cursor_sharing', 'optimizer_mode', 'hash_join_enabled' )
UNION ALL
SELECT 'arquivo', upper('explain.&1..sql') FROM DUAL
/
SELECT PLAN_TABLE_OUTPUT
FROM TABLE(DBMS_XPLAN.DISPLAY('SYS.PLAN_TABLE$', '&1.', 'TYPICAL' ))
--FROM TABLE(DBMS_XPLAN.DISPLAY('SYS.PLAN_TABLE$', '&1.', 'ALL' )) -- ALL -PROJECTION -ALIAS
/
COL NAME CLEAR
COL VALUE CLEAR
COL PLAN_TABLE_OUTPUT CLEAR
SELECT OWNER, OBJECT_TYPE, OBJECT_NAME
FROM DBA_OBJECTS
WHERE OBJECT_NAME LIKE '%PLAN_TABLE%'
/
//-- --------- 2.---------------------------------------------------------------------------------------------
COL NAME FORMAT A20 HEAD "Parâmetro"
COL VALUE FORMAT A15 HEAD "Valor"
COL V1 FORMAT A7 HEAD "Ordem" JUSTIFY L
COL V2 FORMAT A83 HEAD "Plano de Execução" JUSTIFY L
COL V3 FORMAT A7 HEAD "Card" JUSTIFY R
COL V4 FORMAT A7 HEAD "Bytes" JUSTIFY R
COL V5 FORMAT A9 HEAD "Custo" JUSTIFY R
COL V6 FORMAT A17 HEAD "Partições" JUSTIFY L
COL OTHER_TAG FORMAT A30
COL DISTRIBUTE FORMAT A30
SELECT NAME, UPPER(VALUE) VALUE
FROM V$PARAMETER
WHERE NAME IN ( 'cursor_sharing', 'optimizer_mode', 'hash_join_enabled' )
/
SELECT
LPAD( ID, 3 ) || ' ' || LPAD( PARENT_ID, 3 ) V1,
LPAD(' ', 1*(LEVEL-1), ' ') || OPERATION ||
DECODE( OPTIONS, NULL, '', ' ('||OPTIONS|| ') ' || DECODE( OBJECT_NAME, NULL, NULL, 'OF '''|| OBJECT_NAME || '''' ) ) ||
DECODE(OBJECT_TYPE, NULL, '', '('||OBJECT_TYPE||')' ) V2,
--||DECODE( COST, NULL, NULL, ' (COST='||COST||' CARD='||CARDINALITY||')' ) V2,
LPAD( DECODE(CARDINALITY, NULL, NULL,
DECODE(SIGN(CARDINALITY-1000), -1, CARDINALITY||'',
DECODE(SIGN(CARDINALITY-1000000), -1, TRUNC(CARDINALITY/1000)||'K',
DECODE(SIGN(CARDINALITY-1000000000), -1, TRUNC(CARDINALITY/1000000)||'M',TRUNC(CARDINALITY/1000000000)||'G')))), 7 ) V3,
LPAD( DECODE(BYTES, NULL, ' ',
DECODE(SIGN(BYTES-1024), -1, BYTES||'',
DECODE(SIGN(BYTES-1048576), -1, TRUNC(BYTES/1024)||'K',
DECODE(SIGN(BYTES-1073741824), -1, TRUNC(BYTES/1048576)||'M', TRUNC(BYTES/1073741824)||'G')))), 7 ) V4,
LPAD( DECODE(COST, NULL, ' ',
DECODE(SIGN(COST-10000000), -1, COST||'',
DECODE(SIGN(COST-1000000000), -1, TRUNC(COST/1000000)||'M',TRUNC(COST/1000000000)||'G'))), 9 ) V5,
DECODE( PARTITION_START, NULL, '', '[' ||
DECODE(PARTITION_START, 'ROW LOCATION', 'ROWID', 'KEY', 'KEY', 'KEY(INLIST)', 'KEY(I)',
DECODE(SUBSTR(PARTITION_START, 1, 6), 'NUMBER', SUBSTR(PARTITION_START,8,10), 1,LENGTH(PARTITION_START),PARTITION_START)) || '...' ||
DECODE(PARTITION_STOP, NULL, '', 'ROW LOCATION', 'ROWID', 'KEY', 'KEY', 'KEY(INLIST)', 'KEY(I)',
DECODE(SUBSTR(PARTITION_STOP, 1, 6), 'NUMBER', SUBSTR(PARTITION_STOP,8,10), 1,LENGTH(PARTITION_STOP),PARTITION_STOP)) || ']' ) V6
-- ,distribution, other_tag
FROM PLAN_TABLE
WHERE STATEMENT_ID = '&1.'
CONNECT BY PRIOR ID = PARENT_ID AND STATEMENT_ID = '&1.'
START WITH ID = 0 AND STATEMENT_ID = '&1.'
/
COL NAME CLEAR
COL VALUE CLEAR
COL V1 CLEAR
COL V2 CLEAR
COL V3 CLEAR
COL V4 CLEAR
COL V5 CLEAR
COL V6 CLEAR
COL OTHER_TAG CLEAR
COL DISTRIBUTE CLEAR
//-- --------- 3.---------------------------------------------------------------------------------------------
SET FEEDBACK OFF VERIFY OFF TERMOUT OFF
COL STMT_ID NEW_VALUE STMT_ID NOPRINT
SELECT osuser STMT_ID
FROM V$SESSION
WHERE SID = ( SELECT SID FROM V$MYSTAT WHERE ROWNUM < 2 )
/
DELETE PLAN_TABLE WHERE STATEMENT_ID = '&STMT_ID.'
/
COMMIT
/
SET TERMOUT ON
COL STMT_ID CLEAR
SET FEEDBACK ON VERIFY ON
SET SERVEROUTPUT ON
DECLARE
ESQUEMA VARCHAR2(30) := upper('ESQUEMA_A_SER_IMPORTADO');
SENHA_CRIPT VARCHAR2(30);
TESTE VARCHAR2(100);
NROLES INT;
NSYSPRIVS INT;
NTQUOTAS INT;
NOBJPRIVS INT;
NPROXY INT;
BEGIN
DBMS_OUTPUT.ENABLE(1000000);
FOR X IN ( SELECT USERNAME, DEFAULT_TABLESPACE, TEMPORARY_TABLESPACE, PROFILE, ACCOUNT_STATUS
FROM DBA_USERS
WHERE USERNAME=ESQUEMA) LOOP
SELECT PASSWORD INTO SENHA_CRIPT FROM SYS.USER$ WHERE NAME = ESQUEMA;
BEGIN
DBMS_OUTPUT.PUT_LINE('DROP USER ' || X.USERNAME || ' CASCADE;');
DBMS_OUTPUT.PUT_LINE(' ');
DBMS_OUTPUT.PUT_LINE('CREATE USER ' || X.USERNAME);
DBMS_OUTPUT.PUT_LINE(' IDENTIFIED BY VALUES ''' || SENHA_CRIPT || '''');
DBMS_OUTPUT.PUT_LINE(' DEFAULT TABLESPACE ' || X.DEFAULT_TABLESPACE);
DBMS_OUTPUT.PUT_LINE(' TEMPORARY TABLESPACE ' || X.TEMPORARY_TABLESPACE);
DBMS_OUTPUT.PUT_LINE(' PROFILE ' || X.PROFILE);
CASE
WHEN X.ACCOUNT_STATUS='OPEN' THEN
DBMS_OUTPUT.PUT_LINE(' ACCOUNT UNLOCK;');
WHEN X.ACCOUNT_STATUS='EXPIRED' THEN
DBMS_OUTPUT.PUT_LINE(' PASSWORD EXPIRE');
DBMS_OUTPUT.PUT_LINE(' ACCOUNT UNLOCK;');
WHEN X.ACCOUNT_STATUS='EXPIRED(GRACE)' THEN
DBMS_OUTPUT.PUT_LINE(' PASSWORD EXPIRE');
DBMS_OUTPUT.PUT_LINE(' ACCOUNT UNLOCK;');
WHEN X.ACCOUNT_STATUS='LOCKED(TIMED)' THEN
DBMS_OUTPUT.PUT_LINE(' ACCOUNT LOCK;');
WHEN X.ACCOUNT_STATUS='LOCKED' THEN
DBMS_OUTPUT.PUT_LINE(' ACCOUNT LOCK;');
ELSE
DBMS_OUTPUT.PUT_LINE(' PASSWORD EXPIRE');
DBMS_OUTPUT.PUT_LINE(' ACCOUNT LOCK;');
END CASE;
SELECT COUNT(*) INTO NROLES FROM DBA_ROLE_PRIVS WHERE GRANTEE=ESQUEMA;
IF NROLES >= 1 THEN
DBMS_OUTPUT.PUT_LINE(' -- ' || NROLES || ' Role(s) for ' || ESQUEMA);
END IF;
FOR R IN (SELECT GRANTED_ROLE,ADMIN_OPTION FROM DBA_ROLE_PRIVS WHERE GRANTEE=ESQUEMA) LOOP
BEGIN
IF R.ADMIN_OPTION ='YES' THEN
DBMS_OUTPUT.PUT_LINE(' GRANT ' || R.GRANTED_ROLE || ' TO ' || ESQUEMA || ' WITH ADMIN OPTION;');
ELSE
DBMS_OUTPUT.PUT_LINE(' GRANT ' || R.GRANTED_ROLE || ' TO ' || ESQUEMA || ';');
END IF;
END;
END LOOP;
SELECT COUNT(*) INTO NROLES FROM DBA_ROLE_PRIVS WHERE GRANTEE=ESQUEMA AND DEFAULT_ROLE<>'YES';
IF NROLES < 1 THEN
DBMS_OUTPUT.PUT_LINE(' ALTER USER ' || ESQUEMA || ' DEFAULT ROLE ALL;');
ELSE
FOR DR IN (SELECT GRANTED_ROLE FROM DBA_ROLE_PRIVS WHERE GRANTEE=ESQUEMA AND DEFAULT_ROLE='YES') LOOP
BEGIN
DBMS_OUTPUT.PUT_LINE(' ALTER USER ' || ESQUEMA || ' DEFAULT ROLE ' || DR.GRANTED_ROLE || ';');
END;
END LOOP;
END IF;
SELECT COUNT(*) INTO NSYSPRIVS FROM DBA_SYS_PRIVS WHERE GRANTEE=ESQUEMA;
IF NSYSPRIVS >= 1 THEN
DBMS_OUTPUT.PUT_LINE(' -- ' || NSYSPRIVS || ' System Privilege(s) for ' || ESQUEMA);
END IF;
FOR SP IN (SELECT PRIVILEGE FROM DBA_SYS_PRIVS WHERE GRANTEE=ESQUEMA) LOOP
BEGIN
DBMS_OUTPUT.PUT_LINE(' GRANT ' || SP.PRIVILEGE || ' TO ' || ESQUEMA || ';');
END;
END LOOP;
SELECT COUNT(*) INTO NTQUOTAS FROM DBA_TS_QUOTAS WHERE USERNAME=ESQUEMA;
IF NTQUOTAS >= 1 THEN
DBMS_OUTPUT.PUT_LINE(' -- ' || NTQUOTAS || ' Tablespace Quota(s) for ' || ESQUEMA);
END IF;
FOR TQ IN (SELECT TABLESPACE_NAME FROM DBA_TS_QUOTAS WHERE USERNAME=ESQUEMA) LOOP
BEGIN
DBMS_OUTPUT.PUT_LINE(' ALTER USER ' || ESQUEMA || ' QUOTA UNLIMITED ON ' || TQ.TABLESPACE_NAME || ';');
END;
END LOOP;
SELECT COUNT(DISTINCT(TABLE_NAME)) INTO NOBJPRIVS FROM DBA_TAB_PRIVS WHERE GRANTEE=ESQUEMA;
IF NOBJPRIVS >= 1 THEN
DBMS_OUTPUT.PUT_LINE(' -- ' || NOBJPRIVS || ' Object Privilege(s) for ' || ESQUEMA);
END IF;
FOR TP IN (SELECT OWNER,TABLE_NAME,PRIVILEGE FROM DBA_TAB_PRIVS WHERE GRANTEE=ESQUEMA) LOOP
BEGIN
DBMS_OUTPUT.PUT_LINE(' GRANT ' || TP.PRIVILEGE || ' ON ' || TP.OWNER || '.' || TP.TABLE_NAME || ' TO ' || ESQUEMA || ';');
END;
END LOOP;
SELECT COUNT(PROXY) INTO NPROXY FROM DBA_PROXIES WHERE CLIENT=ESQUEMA;
IF NPROXY >= 1 THEN
DBMS_OUTPUT.PUT_LINE(' -- ' || NPROXY || ' Proxy(ies) for ' || ESQUEMA);
END IF;
FOR P IN (SELECT PROXY,CLIENT FROM DBA_PROXIES WHERE CLIENT=ESQUEMA) LOOP
BEGIN
DBMS_OUTPUT.PUT_LINE(' ALTER USER ' || ESQUEMA || ' GRANT CONNECT THROUGH ' || P.PROXY || ';');
END;
END LOOP;
END;
END LOOP;
END;
/* Para gerar arquivo com a lista de diretórios */
find . -type d > dirs.txt
/* Para criar esse diretórios em qualquer ambiente */
xargs mkdir -p < dirs.txt
# Invoca o ADRCI: Automatic Diagnostic Repository Command Interpreter
[oracle@oracle]$ adrci
#comando descreve o uso.
adrci> help purge
# Listar todos os diretórios de rastreamento de banco de dados disponíveis
adrci> SHOW HOMES | HOME | HOMEPATH
Este comando será usado para definir um valor inicial específico (diretório de rastreamento)
adrci> set home diag/rdbms/orcl/orcl
# As políticas podem ser ajustadas de acordo com a necessidade usando os seguintes comandos:
adrci> SHOW CONTROL
ADR Home = /u01/oracle/diag/rdbms/proddb01/proddb01:
*************************************************************************
ADRID SHORTP_POLICY LONGP_POLICY
-------------------- -------------------- --------------------
597879840 720 8760
# Por default, os arquivos de trace serão mantidos no ADR por 30 dias (720 horas),
# os arquivos de INCIDENTE por um ano (8760 horas).
# Porém, é possível limpar manualmente, utilizando o comando PURGE:
/*------------ PURGES -----------------------------------------------------------------*/
# Inicie manualmente a eliminação de tudo com base nos padrões.
adrci> purge
# Eliminar tudo com mais de 1 dia.
adrci> purge -age 24 -type trace
# Eliminar tudo com mais de 1 mês.
adrci> purge -age 43200
# Eliminar INCIDENTes com mais de 1 mês
adrci> purge -age 43200 -type INCIDENT
# Eliminar todos os arquivos de rastreamento com mais de 48 horas
adrci> purge -age 48 -type trace
# Outros exemplos (2160 horas = 90 dias):
PURGE -AGE 2160 -TYPE ALERT
PURGE -AGE 2160 -TYPE INCIDENT
PURGE -AGE 2160 -TYPE cdump
PURGE -AGE 2160 -TYPE stage
PURGE -AGE 2160 -TYPE sweep
PURGE -AGE 2160 -TYPE hm
/*--------Problems and INCIDENTs---------------------------------------------------------*/
adrci> SHOW ALERT
adrci> SHOW ALERT -p "message_text like '%INCIDENT%'"
adrci> SHOW ALERT -tail –f
adrci> SHOW ALERT -tail 20
adrci> SHOW BASE
adrci> SHOW HM_RUN
adrci> SHOW LOG
adrci> SHOW PROBLEM
adrci> SHOW REPORT
adrci> SHOW INCIDENT
adrci> SHOW INCIDENT -MODE BRIEF
adrci> SHOW INCIDENT -MODE DETAIL
adrci> SHOW INCIDENT -MODE BASIC
adrci> SHOW INCIDENT -MODE DETAIL -p INCIDENT_id=XxXxx
procurar por: start error stack dump with barriers
adrci> SHOW trace /u01/app/oracle/diag/rdbms/orcl/orcl/INCIDENT/incdir_33921/orcl_ora_25872_i33921.trc
adrci> SHOW TRACEFILE
adrci> SHOW TRACEFILE %mmon%
#Este exemplo mostra todos os arquivos de rastreamento para todos os INCIDENTes
adrci> SHOW INCDIR
/*---------IPS (INCIDENT Packaging Service )-----------------------------------------------------------------------*/
# Utilizando o IPS para gerar um pacote a ser enviado para o suporte da Oracle com todos detalhes do problema ocorrido:
adrci> ips create package problem 1 correlate all
Created package 1 based on problem id 1, correlation level all
adrci> ips generate package 1 in "/tmp/oracle"
Generated package 1 in file /tmp/oracle/IPSPKG_20141223161727_COM_1.zip, MODE complete
# Visualizando os arquivos gerados dentro do pacote:
adrci> IPS SHOW FILES PACKAGE 1
adrci
show home
set home diag/rdbms/xxx/xxx
show alert -tail -f
-- TAMANHO DO BANCO DE DADOS
-- ----------------------------------------------------------------------------------------------
SELECT sum(bytes) / 1024 / 1024 / 1024 tamanho_GB FROM dba_segments;
SELECT sum(bytes) /1073741824 TAMANHO_GB FROM dba_segments;
-- Tamanho por Tablespace
SELECT tablespace_name, sum(bytes) / 1024 / 1024 / 1024 tamanho_GB FROM dba_segments GROUP BY tablespace_name;
-- Segments Tamanho
SELECT count(*) segments ,round(sum(bytes)/1024/1024/1024,2) size_GB FROM dba_segments;
-- ----------------------------------------------------------------------------------------------
SELECT
'Database Tamanho' "*****",
ROUND(SUM(ROUND(SUM(NVL(fs.bytes / 1024 / 1024, 0)))) /
SUM(ROUND(SUM(NVL(fs.bytes / 1024 / 1024, 0))) +
ROUND(df.bytes / 1024 / 1024 - SUM(NVL(fs.bytes / 1024 / 1024, 0)))) * 100, 0) " % Livre",
ROUND(SUM(ROUND(df.bytes / 1024 / 1024 - SUM(NVL(fs.bytes / 1024 / 1024, 0)))) /
SUM(ROUND(SUM(NVL(fs.bytes / 1024 / 1024, 0))) +
ROUND(df.bytes / 1024 / 1024 - SUM(NVL(fs.bytes / 1024 / 1024, 0)))) * 100, 0) " % Usado",
SUM(ROUND(SUM(NVL(fs.bytes / 1024 / 1024 / 1024, 0)))) "GB Livre",
SUM(ROUND(df.bytes / 1024 / 1024 / 1024 - SUM(NVL(fs.bytes / 1024 / 1024 / 1024, 0)))) "GB Usado",
SUM(ROUND(SUM(NVL(fs.bytes / 1024 / 1024 / 1024, 0))) +
ROUND(df.bytes / 1024 / 1024 / 1024 - SUM(NVL(fs.bytes / 1024 / 1024 / 1024, 0)))) "Tamanho em GB"
FROM
dba_free_space fs,
dba_data_files df
WHERE
fs.file_id( + ) = df.file_id
GROUP BY
df.tablespace_name,
df.file_id,
df.bytes,
df.autoextensible
ORDER BY
df.file_id ;
SET TERMOUT OFF
COL PRINT_DETALHE NEW_VALUE PRINT_DETALHE
COL BREAK_DETALHE NEW_VALUE BREAK_DETALHE
SELECT
DECODE( UPPER('&DETALHAR.'), 'SIM', 'PRINT', 'NOPRINT' ) PRINT_DETALHE
,DECODE( UPPER('&DETALHAR.'), 'SIM', 'ON TABLESPACE_NAME SKIP PAGE', 'ON REPORT SKIP PAGE' ) BREAK_DETALHE
FROM DUAL
/
SET TERMOUT ON
BREAK &BREAK_DETALHE.
COMPUTE SUM LABEL "TOTAIS" OF MAX_MB SIZE_MB FREE_MB ON REPORT
SET VERIFY OFF DEFINE ON LINES 189 NUMWIDTH 7 FEED OFF PAGES 200
COL TABLESPACE_NAME FORMAT A30
COL FILE_NAME FORMAT A60
COL DETALHE FORMAT A21 &PRINT_DETALHE.
COL TIPO FORMAT A34
COL STATUS FORMAT A9
COL FILE_ID FORMAT 9999 HEAD "F#"
COL PCT_USED_MAX FORMAT A12
COL PCT_USED FORMAT A8
SELECT
V.TABLESPACE_NAME
,V.STATUS
,V.TIPO
,V.MAX_MB
,V.SIZE_MB
,NVL( V.FREE_MB, 0 ) FREE_MB
,TO_CHAR( ROUND((V.SIZE_MB-NVL(V.FREE_MB,0))/NULLIF(V.MAX_MB,0)*100, 2 ), '99999990D00' ) PCT_USED_MAX
,TO_CHAR(ROUND((V.SIZE_MB-NVL(V.FREE_MB,0))/NULLIF(V.SIZE_MB,0)*100, 2 ), '9990D00' ) PCT_USED
/*
,TRUNC(FREE_MB/1&zero.)*1&zero. "1&zero._MB"
,TRUNC(FREE_MB/2&zero.)*2&zero. "2&zero._MB"
,TRUNC(FREE_MB/3&zero.)*3&zero. "3&zero._MB"
,TRUNC(FREE_MB/4&zero.)*4&zero. "4&zero._MB"
,TRUNC(FREE_MB/5&zero.)*5&zero. "5&zero._MB"
,TRUNC(FREE_MB/10&zero.)*10&zero. "10&zero._MB"
,TRUNC(FREE_MB/20&zero.)*20&zero. "20&zero._MB"
*/
,CURSOR ( SELECT FILE_ID, FILE_NAME, MEGAS, USERMEGAS, ROUND( INCREMENTO * V.BLOCK_SIZE / 1048576, 2 ) NEXTMEGAS, MAXMEGAS
FROM (
SELECT TABLESPACE_NAME, FILE_NAME, file_id,
SUBSTR( FILE_NAME, INSTR(FILE_NAME, '/', -1 ) +1 ),
ROUND(BYTES/1048576, 2 ) MEGAS,
ROUND(MAXBYTES/1048576, 2 ) MAXMEGAS,
INCREMENT_BY INCREMENTO,
ROUND(USER_BYTES/1048576, 2 ) USERMEGAS
FROM DBA_DATA_FILES
UNION ALL
SELECT TABLESPACE_NAME, FILE_NAME, file_id,
SUBSTR( FILE_NAME, INSTR(FILE_NAME, '/', -1 ) +1 ),
ROUND(BYTES/1048576, 2 ) MEGAS,
ROUND(MAXBYTES/1048576, 2 ) MAXMEGAS,
INCREMENT_BY INCREMENTO,
ROUND(USER_BYTES/1048576, 2 ) USERMEGAS
FROM DBA_TEMP_FILES
ORDER BY 3 DESC
) C
WHERE C.TABLESPACE_NAME = V.TABLESPACE_NAME AND ROWNUM <= 45 ) DETALHE
FROM
(
SELECT TBS.TABLESPACE_NAME,
DECODE( EXTENT_MANAGEMENT, 'DICTIONARY', EXTENT_MANAGEMENT,
EXTENT_MANAGEMENT || ' ' || DECODE( ALLOCATION_TYPE, 'SYSTEM', 'AUTOALLOCATE', 'UNIFORM' ) ) || ' ' ||
SUBSTR( CONTENTS, 1, 4 ) || DECODE( LOGGING, 'LOGGING', ' LOGG', ' NOLOG' ) || ' ' ||
DECODE( SEGMENT_SPACE_MANAGEMENT, 'AUTO', 'ASSM' ) TIPO
, STATUS
, BLOCK_SIZE
, ( SELECT SUM(TRUNC(DECODE(I.INCREMENT_BY, 0, I.BYTES, I.MAXBYTES)/1048576))
FROM ( SELECT tablespace_name, increment_by, bytes, maxbytes FROM DBA_DATA_FILES F
UNION ALL
SELECT tablespace_name, increment_by, bytes, maxbytes FROM DBA_TEMP_FILES T ) I
WHERE I.TABLESPACE_NAME = TBS.TABLESPACE_NAME )
"MAX_MB"
, ( SELECT SUM(TRUNC(I.BYTES/1048576))
FROM ( SELECT tablespace_name, increment_by, bytes, maxbytes FROM DBA_DATA_FILES F
UNION ALL
SELECT tablespace_name, increment_by, bytes, maxbytes FROM DBA_TEMP_FILES T ) I
WHERE I.TABLESPACE_NAME = TBS.TABLESPACE_NAME )
"SIZE_MB"
, CASE TBS.CONTENTS
WHEN 'TEMPORARY' THEN
( SELECT
TRUNC(
((SELECT SUM(T.BYTES) FROM DBA_TEMP_FILES T WHERE T.TABLESPACE_NAME = TBS.TABLESPACE_NAME) -
(SELECT SUM(I.BLOCKS*TBS.BLOCK_SIZE) FROM V$SORT_USAGE I WHERE I.TABLESPACE = TBS.TABLESPACE_NAME))/1048576
)
FROM DUAL
)
ELSE
( SELECT SUM(TRUNC(I.BYTES/1048576))
FROM DBA_FREE_SPACE I
WHERE I.TABLESPACE_NAME = TBS.TABLESPACE_NAME
)
END "FREE_MB"
FROM DBA_TABLESPACES TBS
WHERE TBS.TABLESPACE_NAME LIKE UPPER('&tbs.')
) V
--ORDER BY /*PCT_USED DESC */ FREE_MB
ORDER BY TO_NUMBER(PCT_USED_MAX) DESC
/
PROMPT
UNDEFINE 1 2 3 PRINT_DETALHE BREAK_DETALHE
SET VERIFY ON NUMWIDTH 10 FEED 6 PAGES 66
CLEAR COMPUTE
CLEAR BREAK
COL TABLESPACE_NAME CLEAR
COL DETALHE CLEAR
COL TIPO CLEAR
COL STATUS CLEAR
--OBS: A documentaç?o da oracle se encontra no site abaixo:
--SITE: http://download-west.oracle.com/docs/cd/A97630_01/server.920/a96521/logminer.htm#18501
/* Otitiza o ítem 4.
select 'EXECUTE DBMS_LOGMNR.ADD_LOGFILE('''||'/u01/utl/'||substr(name,14,27)||''', DBMS_LOGMNR.ADDFILE);'
from V$ARCHIVED_LOG where dest_id = 1
and sequence# between 94540 and 94611
*/
--1. setar a variável UTL_FILE_DIR para um cominho exiteste
--2. executar o comando a procedure DBMS_LOGMNR_D.BUILD para a construç?o do dicionário (FLAT FILE)
EXECUTE DBMS_LOGMNR_D.BUILD('dictionary.ora', '/u01/utl', DBMS_LOGMNR_D.STORE_IN_FLAT_FILE);
--3. Iniciar uma nova lista de archives com o comando abaixo:
EXECUTE DBMS_LOGMNR.ADD_LOGFILE('/u01/utl/vs01_1_66700_623237409.dbf', DBMS_LOGMNR.NEW);
--4. Adicionar novos archives com os comandos abaixo:
EXECUTE DBMS_LOGMNR.ADD_LOGFILE('/u01/utl/vs01_1_66701_623237409.dbf', DBMS_LOGMNR.ADDFILE);
EXECUTE DBMS_LOGMNR.ADD_LOGFILE('/u01/utl/vs01_1_66702_623237409.dbf', DBMS_LOGMNR.ADDFILE);
--5. Executar a procudure DBMS_LOGMNR.START_LOGMNR para iniciar a consulta na V$LOGMNR_CONTENTS
EXECUTE DBMS_LOGMNR.START_LOGMNR( DICTFILENAME =>'/u01/utl/dictionary.ora');
--6 Exemplo de uma consulta na tabela V$LOGMNR_CONTENTS
--SELECT /* + FIRST_ROWS */ A.USERNAME, A.session_info, A.ROW_ID, a.operation, a.timestamp,SQL_REDO, SQL_UNDO
--CREATE TABLE admin.tb_auditoria_15102008 AS
insert /*+ APPEND */ into admin.tb_auditoria_15102008
SELECT /*+ FIRST_ROWS */ *
FROM V$LOGMNR_CONTENTS A
WHERE UPPER(A.SQL_REDO) LIKE '%TB_PROFISSAO%'
SELECT /* + FIRST_ROWS */ B.USERNAME, B.session_info, B.operation, B.timestamp, B.SQL_REDO
from admin.tb_auditoria_15102008 B
select * from V$LOGMNR_CONTENTS
--7. Executar a procudure DBMS_LOGMNR.END_LOGMNR para finalizar a consulta na V$LOGMNR_CONTENTS
EXECUTE DBMS_LOGMNR.END_LOGMNR;
SELECT NAME FROM V$ARCHIVED_LOG WHERE DICTIONARY_BEGIN='YES';
SELECT NAME FROM V$ARCHIVED_LOG WHERE DICTIONARY_END='YES';
create table tbl_00001 (id number(1))
create synonym tbl_teste for marco.tbl_00001
drop synonym tbl_teste
drop table marco.tbl_00001
select * from dba_synonyms
-- =======================================================================
-- Flash Back - Query
-- =======================================================================
--SELECT ORA_ROWSCN FROM owner.table --> It is a pseudocolumn that represents the SCN of the most recent change to a given row;
SELECT * FROM dbseguranca.tb_perfil_detalhe
AS OF TIMESTAMP (SYSTIMESTAMP - INTERVAL '30' MINUTE)
where co_porte is null and id_pessoa_juridica_principal is null
--create table dbsvs.tb_tramitacao_documento_TESTE as
SELECT * FROM dbsvs.tb_tramitacao_documento
AS OF TIMESTAMP TO_TIMESTAMP('10-AGO-09 08:00','DD-MON-YY HH24:MI')
WHERE CO_INTERNO_UORG_DESTINO = 46 AND NU_CPF_DESTINO = '00000000045' AND ST_ENCAMINHAMENTO = 'N'
-- Exemplo
SELECT * FROM EMPLOYEE AS OF TIMESTAMP TO_TIMESTAMP('06-NOV-07 15:40','DD-MON-YY HH24:MI')
WHERE name = 'YASH';
-- Exemplo
INSERT INTO emp
(SELECT * FROM emp AS OF TIMESTAMP TO_TIMESTAMP('06-NOV-07 15:40','DD-MON-YY HH24:MI') WHERE name = 'YASH');
-- =======================================================================
-- Flash Back - Drop Table
-- =======================================================================
/* Consulta para localizar as tabelas que foram recentemente apagadas*/
--show recyclebin / select * from recyclebin
select distinct 'purge tablespace '||ts_name||' user '||owner||';' from DBA_recyclebin
select DISTINCT 'purge tablespace '|| TS_NAME||';' from DBA_recyclebin
select * from DBA_recyclebin order by droptime desc
/*restaurando uma tabela do recyclebin*/
flashback table to before drop rename to ;
flashback table to before drop;
/* Removendo um objeto definitivamente do banco de dados e liberando espaço no tablespace.*/
--Nome atribuído pelo oracle
purge table BIN$ljJa/YYg3yLgQGcKkQIbhg==$0;
-- ou com o nome orignal da tabela
purge table
/*Removendo todos os objetos existentes no RECYCLE BIN que foram excluídos anteriormente do tablespace dados.*/
purge tablespace
/*removendo todos os objetos existentes no RECYCLE BIN que foram excluídos anteriormente do tablespace dados e
que pertenciam a um determinado usuário.*/
purge tablespace user
/*removendo todos os objetos existentes no RECYCLE BIN */
purge recyclebin;
-- =======================================================================
-- compile any object view
-- =======================================================================
select object_name, object_type, status, owner,
'ALTER '||OBJECT_TYPE||' '||OWNER||'.'||OBJECT_NAME||' COMPILE;'
from dba_objects
where status <> 'VALID'
and owner NOT IN ('SYS', 'SYSTEM', 'PUBLIC','OUTLN','DBSNMP','WMSYS','SYSMAN')
and owner not like '%SYS%' and owner like 'DBSVS%'
and object_type IN ('SEQUENCE','TRIGGER','PROCEDURE','FUNCTION','PACKAGE','PACKAGE BODY','VIEW','MATERIALIZED VIEW')
--and object_name like '%037%'
and object_type = 'MATERIALIZED VIEW'
-- =======================================================================
-- compile materialized view
-- =======================================================================
SELECT 'ALTER MATERIALIZED VIEW '||A.OWNER||'.'||TABLE_NAME||' COMPILE;'
FROM DBA_SNAPSHOTS a --WHERE a.OWNER = ''
-- =======================================================================
-- Mostra o andamento dos canais do RMAN
-- =======================================================================--
SELECT SID, SERIAL#, CONTEXT, SOFAR, TOTALWORK, ROUND(SOFAR/TOTALWORK*100,2) "%_COMPLETE"
FROM V$SESSION_LONGOPS
WHERE OPNAME LIKE 'RMAN%'
AND OPNAME NOT LIKE '%aggregate%'
AND TOTALWORK != 0
AND SOFAR <> TOTALWORK;
-- =======================================================================
-- Mostra informações dos jobs do RMAN
-- =======================================================================
SELECT a.command_id, a.start_time, a.end_time, a.output_device_type, a.status, a.input_type,
round(a.compression_ratio,2) as compression_ratio, a.input_bytes_display, a.output_bytes_display, a.time_taken_display
FROM V$RMAN_BACKUP_JOB_DETAILS a
where rownum < 4
order by start_time desc
-- =======================================================================
-- Mostra informações detalhadas dos jobs do RMAN
-- =======================================================================
SELECT * FROM V$RMAN_STATUS order by start_time desc
SELECT * FROM V$RMAN_OUTPUT
SELECT * FROM V$RMAN_CONFIGURATION
SELECT * FROM V$RMAN_COMPRESSION_ALGORITHM
SELECT * FROM V$RMAN_BACKUP_TYPE
-- =======================================================================
-- Consulta backupset RMAN
-- =======================================================================
SELECT * FROM V$BACKUP_SET order by start_time;
--Backup RMAN vs01 - agendamento: domingo(full) - quarta(increm) - sexta(dif) (iniício: 18h)
SELECT 'vs01',a.command_id, a.start_time, a.end_time, a.output_device_type, a.status, a.input_type,
round(a.compression_ratio,2) as compression_ratio, a.input_bytes_display, a.output_bytes_display, a.time_taken_display
FROM V$RMAN_BACKUP_JOB_DETAILS a order by start_time desc;
--Backup RMAN vs03 - agendamento: sábado(full) - terça(increm) (inicío: 19h)
SELECT 'vs03',a.command_id, a.start_time, a.end_time, a.output_device_type, a.status, a.input_type,
round(a.compression_ratio,2) as compression_ratio, a.input_bytes_display, a.output_bytes_display, a.time_taken_display
FROM V$RMAN_BACKUP_JOB_DETAILS@admin_vs03 a order by start_time desc;
--Backup RMAN vs05 - agendamento: sábado(full) - terça(increm) (inicío: 22h)
SELECT 'vs05',a.command_id, a.start_time, a.end_time, a.output_device_type, a.status, a.input_type,
round(a.compression_ratio,2) as compression_ratio, a.input_bytes_display, a.output_bytes_display, a.time_taken_display
FROM V$RMAN_BACKUP_JOB_DETAILS@admin_vs05 a order by start_time desc;
--Backup RMAN vs07 - agendamento: sábado(full) - terça(increm) (inicío: 22h)
--SELECT 'vs11',a.command_id, a.start_time, a.end_time, a.output_device_type, a.status, a.input_type,
-- round(a.compression_ratio,2) as compression_ratio, a.input_bytes_display, a.output_bytes_display, a.time_taken_display
--FROM V$RMAN_BACKUP_JOB_DETAILS@admin_vs07 a order by start_time desc;
--Backup RMAN vs11 - agendamento: sábado(full) - terça(increm) (inicío: 22h)
SELECT 'vs11',a.command_id, a.start_time, a.end_time, a.output_device_type, a.status, a.input_type,
round(a.compression_ratio,2) as compression_ratio, a.input_bytes_display, a.output_bytes_display, a.time_taken_display
FROM V$RMAN_BACKUP_JOB_DETAILS@admin_vs11 a order by start_time desc;
--Backup RMAN vs15 - agendamento: sábado(full) - terça(increm) (inicío: 18h)
SELECT 'vs15',a.command_id, a.start_time, a.end_time, a.output_device_type, a.status, a.input_type,
round(a.compression_ratio,2) as compression_ratio, a.input_bytes_display, a.output_bytes_display, a.time_taken_display
FROM V$RMAN_BACKUP_JOB_DETAILS@admin_vs15 a order by start_time desc;
--Archived and unarchived redo logs
SELECT * FROM RC_ARCHIVED_LOG
--Details about archived redo log backups for Enterprise Manager
SELECT * FROM RC_BACKUP_ARCHIVELOG_DETAILS
--Summary of information about archived redo log backups for Enterprise Manager
SELECT * FROM RC_BACKUP_ARCHIVELOG_SUMMARY
--Control files backed up in backup sets
SELECT * FROM RC_BACKUP_CONTROLFILE
--Details about control file backups for Enterprise Manager
SELECT * FROM RC_BACKUP_CONTROLFILE_DETAILS
--Summary of information about control file backups for Enterprise Manager
SELECT * FROM RC_BACKUP_CONTROLFILE_SUMMARY
--Details about datafile image copy backups for Enterprise Manager
SELECT * FROM RC_BACKUP_COPY_DETAILS
--Summary of information about datafile image copy backups for Enterprise Manager
SELECT * FROM RC_BACKUP_COPY_SUMMARY
--Corrupt block ranges in datafile backups
SELECT * FROM RC_BACKUP_CORRUPTION
--Datafiles in backup sets
SELECT * FROM RC_BACKUP_DATAFILE
--Details about datafile backups for Enterprise Manager
SELECT * FROM RC_BACKUP_DATAFILE_DETAILS
--Summary of information about datafile backups for Enterprise Manager
SELECT * FROM RC_BACKUP_DATAFILE_SUMMARY
--RMAN backups and copies known to the repository.
SELECT * FROM RC_BACKUP_FILES
--Backup pieces
SELECT * FROM RC_BACKUP_PIECE
--Details about backup pieces for Enterprise Manager
SELECT * FROM RC_BACKUP_PIECE_DETAILS
--Archived redo logs in backup sets
SELECT * FROM RC_BACKUP_REDOLOG
--Backup sets for all incarnations of databases registered in the catalog
SELECT * FROM RC_BACKUP_SET
--Details about backup sets for Enterprise Manager
SELECT * FROM RC_BACKUP_SET_DETAILS
--Summary of information about backup sets for Enterprise Manager
SELECT * FROM RC_BACKUP_SET_SUMMARY
--Server parameter files in backups
SELECT * FROM RC_BACKUP_SPFILE
--Details about SPFILE backups for Enterprise Manager
SELECT * FROM RC_BACKUP_SPFILE_DETAILS
--Summary of information about SPFILE backups for Enterprise Manager
SELECT * FROM RC_BACKUP_SPFILE_SUMMARY
--Deprecated in favor of RC_RESYNC
SELECT * FROM RC_CHECKPOINT
--Control file copies on disk
SELECT * FROM RC_CONTROLFILE_COPY
--Corrupt block ranges in datafile copies
SELECT * FROM RC_COPY_CORRUPTION
--Databases registered in the recovery catalog
SELECT * FROM RC_DATABASE
--Database blocks marked as corrupted in the most recent RMAN backup or copy
SELECT * FROM RC_DATABASE_BLOCK_CORRUPTION
--Database incarnations registered in the recovery catalog
SELECT * FROM RC_DATABASE_INCARNATION
--Datafiles registered in the recovery catalog
SELECT * FROM RC_DATAFILE
--Datafile copies on disk
SELECT * FROM RC_DATAFILE_COPY
--Online redo log history indicating when log switches occurred
SELECT * FROM RC_LOG_HISTORY
--Offline ranges for datafiles
SELECT * FROM RC_OFFLINE_RANGE
--Output FROM RMAN commands for use in Enterprise Manager
SELECT * FROM RC_RMAN_OUTPUT
--Output FROM RMAN commands for use in Enterprise Manager
SELECT * FROM RC_REDO_LOG
--All redo threads for all incarnations of the database since the last catalog resynchronization
SELECT * FROM RC_REDO_THREAD
--Recovery catalog resynchronizations
SELECT * FROM RC_RESYNC
--Details about backup jobs for Enterprise Manager
SELECT * FROM RC_RMAN_BACKUP_JOB_DETAILS
--Details about backup subjobs for Enterprise Manager
SELECT * FROM RC_RMAN_BACKUP_SUBJOB_DETAILS
--Used internally by Enterprise Manager
SELECT * FROM RC_RMAN_BACKUP_TYPE
--RMAN configuration settings
SELECT * FROM RC_RMAN_CONFIGURATION
--Historical status information about RMAN operations
SELECT * FROM RC_RMAN_STATUS
--Names of scripts stored in the recovery catalog
SELECT * FROM RC_STORED_SCRIPT
--Contents of the scripts stored in the recovery catalog
SELECT * FROM RC_STORED_SCRIPT_LINE
--All tablespaces registered in the recovery catalog, all dropped tablespaces, and tablespaces that belong to old incarnations
SELECT * FROM RC_TABLESPACE
--All tempfiles registered in the recovery catalog
SELECT * FROM RC_TEMPFILE
--Unusable backup files registered in the recovery catalog
SELECT * FROM RC_UNUSABLE_BACKUPFILE_DETAILS
-- =======================================================================
-- Muda a tablespace da tabela - sql
-- =======================================================================
select 'ALTER TABLE '||a.OWNER||'.'||a.TABLE_NAME||' move tablespace SITE_DADOS;'
from dba_tables a
where a.owner = 'DBSVS'
select b.owner, b.segment_name, b.segment_type, b.tablespace_name, b.header_block, b.header_file, b.segment_type
-- ,'ALTER TABLE '||b.OWNER||'.'||b.segment_name||' move tablespace TD_DBGERALENTIDADE;'
,'ALTER INDEX '||b.OWNER||'.'||b.segment_name||' rebuild ONLINE tablespace TI_DBGERALENTIDADE;'
from dba_segments b
where b.tablespace_name = 'TH_DBSVS'
--and b.segment_type = 'INDEX'
--and b.header_block > 90000
order by 3
-- =======================================================================
-- Muda Lob de Tablespace - sql
-- =======================================================================
ALTER TABLE dbsngpc.tb_recebimento_arquivo MOVE LOB(ds_arquivo_recebido2) STORE AS (TABLESPACE TD_DBSNGPC_LOBS);
ALTER TABLE dbsngpc.tb_recebimento_arquivo MOVE LOB(ds_validacao2) STORE AS (TABLESPACE TD_DBSNGPC_LOBS);
--View que mostra se o índice é usado
SELECT index_name, table_name, monitoring, used, start_monitoring, end_monitoring
FROM v$object_usage
WHERE lower(index_name) = 'in_tramitacao_codocnucpfstenc'
ORDER BY index_name;
--Comando para monitorar se o índice é usado
alter index dbsvs.in_tramitacao_codocnucpfstenc MONITORING USAGE
select *
from dba_constraints t
where t.constraint_type = 'R'
and t.owner = 'CORPORATIVO'
and t.r_constraint_name = (select t2.constraint_name
from dba_constraints t2
where t2.constraint_type = 'P'
and t2.table_name = 'UM_PERMISSAO_WEB'
and t2.owner = 'CORPORATIVO')
select aa.owner, aa.table_name, aa.num_rows as "Número de linha", round((bb.bytes / (1024*1024))) as MB
from (select a.owner, a.table_name, a.num_rows from dba_tables a) aa,
(select b.owner, b.segment_name, b.bytes from dba_segments b where b.segment_type = 'TABLE') bb
where aa.owner = bb.owner
and aa.table_name = bb.segment_name
and aa.owner like 'DB%'
and aa.num_rows is not null
order by MB desc
SELECT OWNER, TABLE_NAME, COLUMN_NAME, CONSTRAINT_NAME
FROM DBA_CONS_COLUMNS c
WHERE position=1 AND
(OWNER, TABLE_NAME, COLUMN_NAME) IN
(
SELECT c.OWNER, c.TABLE_NAME,cc.COLUMN_NAME
FROM DBA_CONSTRAINTS c, DBA_CONS_COLUMNS cc
WHERE c.CONSTRAINT_NAME = cc.CONSTRAINT_NAME
AND c.TABLE_NAME = cc.TABLE_NAME
AND c.OWNER = cc.OWNER
AND c.CONSTRAINT_TYPE = 'R'
AND cc.POSITION = 1
AND c.OWNER = UPPER('DBSVS')
AND c.TABLE_NAME = UPPER('TB_DOCUMENTO')
MINUS
SELECT table_owner, table_name, column_name
FROM DBA_IND_COLUMNS
WHERE COLUMN_POSITION = 1
AND TABLE_OWNER = UPPER('DBSVS')
AND TABLE_NAME = UPPER('TB_DOCUMENTO')
)
ORDER BY OWNER, TABLE_NAME, CONSTRAINT_NAME;
-- =======================================================================
-- Lista de Lobs - sql
-- =======================================================================
select distinct a.owner, a.table_name, a.column_name, c.data_type, a.segment_name,
round(b.bytes / (1024*1024)) as "MB", a.securefile, a.compression
from dba_lobs a, dba_segments b, dba_tab_columns c
where a.segment_name = b.segment_name
and a.column_name = c.column_name
and a.owner = b.owner
and b.owner = c.owner
--and b.tablespace_name = 'TD_DBSVS_LOB'
order by "MB" desc
select a.owner, a.table_name, round(b.bytes / (1024*1024)) as "MB"
from dba_tables a, dba_segments b
where a.table_name = b.segment_name
and a.owner = b.owner
-- =======================================================================
-- Relatórios dos privilégios dos usuários - sql
-- =======================================================================
SELECT DECODE(SA1.GRANTEE#, 1, 'PUBLIC', U1.NAME), SUBSTR(U2.NAME,1,20),
SUBSTR(SPM.NAME,1,27)
FROM SYS.SYSAUTH$ SA1, SYS.SYSAUTH$ SA2, SYS.USER$ U1,
SYS.USER$ U2, SYS.SYSTEM_PRIVILEGE_MAP SPM
WHERE SA1.GRANTEE# = U1.USER#
AND SA1.PRIVILEGE# = U2.USER#
AND U2.USER# = SA2.GRANTEE#
AND SA2.PRIVILEGE# = SPM.PRIVILEGE
--AND U1.NAME = 'CORPORATIVO'
UNION
SELECT U.NAME, NULL, SUBSTR(SPM.NAME,1,27)
FROM SYS.SYSTEM_PRIVILEGE_MAP SPM, SYS.SYSAUTH$ SA, SYS.USER$ U
WHERE SA.GRANTEE#=U.USER#
AND SA.PRIVILEGE#=SPM.PRIVILEGE
--AND U.NAME = 'CORPORATIVO'
SELECT t.privilege,t.grantee,t.grantor, d.directory_name, d.directory_path
FROM user_tab_privs t, all_directories d
WHERE t.table_name(+)=d.directory_name
--AND d.directory_name in ('DTPUMP') ORDER BY 2,1;
select * from dba_directories
/*
select * from dba_datapump_jobs
select * from dba_datapump_sessions
select * from dba_tables where table_name like '%VS0%'
-- para elimar uma sess?o de expdp, que foi cancelada de forma n?o convencional é necessário elinar a tabela que consta no campo Job_name da dba_datapump_jobs
-- drop table sys.vs01
drop directory DT_VS01;
create directory dt_vs01 as '/u02/backup';
grant write, read on directory dt_vs01 to EXP_FULL_DATABASE;
grant write, read on directory dt_vs01 to IMP_FULL_DATABASE;
*/
/* DUMPS
-- =======================================================================
expdp dumpfile=Arquivo.dmp logfile=Arquivo_exp.log schemas=SCHEMA directory=DUMP_DIR compression=all consistent=y
impdp dumpfile=Arquivo.dmp logfile=Arquivo_imp.log schemas=SCHEMA directory=DUMP_DIR
======================================================================= */
--ALTER SYSTEM SET GLOBAL_NAMES = FALSE
ALTER DATABASE RENAME GLOBAL_NAME TO VS01.ANVISA.GOV.BR
--select * from V$INSTANCE@ANVSSDF45N --select * from USER_TABLES@ANVSSDF45N
drop DATABASE LINK VS05
--CREATE PUBLIC DATABASE LINK DBSIGAVS06
CREATE DATABASE LINK ADMIN_VS05
--CONNECT TO CTXSYS IDENTIFIED BY
CONNECT TO admin IDENTIFIED BY
--USING '(DESCRIPTION = (ADDRESS_LIST = (ADDRESS = (PROTOCOL = TCP)(HOST = 10.103.2.97)(PORT = 1521))) (CONNECT_DATA = (SERVICE_NAME = vs01)))'
USING 'VS05'
/*
SELECT * FROM DBA_DB_LINKS order by created desc
SELECT * from GLOBAL_NAME
*/
--select * from DBSIGA.TB_CONTAGEM@DBSIGAVS06
--grant create database link to dbsiga
--revoke create database link from dbsiga
-- =======================================================================
-- Para matar a sessão de um determiando usuário primeiro você deve saber o seu SID e SERIAL,
-- Executar o sql logado como SYS
-- =======================================================================
SELECT SID, SERIAL#, USERNAME, MACHINE FROM V$SESSION
/* ---- Após descobrir o SID e SERIAL execute: ---- */
ALTER SYSTEM KILL SESSION 'SID_DESEJADO, SERIAL#_DESEJADO' IMMEDIATE;
-- USUARIO ALTERACAO --
ALTER USER username account LOCK/UNLOCK password expire;
ALTER USER username IDENTIFIED by new_password;
ALTER USER username account LOCK/UNLOCK;
ALTER USER username IDENTIFIED BY password ACCOUNT UNLOCK;
-- Start of DDL Script for Trigger SYS.AFTER_LOGON_BD
-- Generated 25-nov-2010 15:07:59 from SYS@vs08
DROP TRIGGER after_logon_bd;
CREATE OR REPLACE TRIGGER after_logon_bd
AFTER
LOGON
ON DATABASE
DECLARE
v_session sys.GV$SESSION%rowtype;
--instance sys.v$instance.instance_name%type;
BEGIN
-- select sys_context('USERENV','IP_ADDRESS') into ip from dual;
--
--instance := userenv('instance');
--
select * into v_session from gv$session where sid = userenv('sid') and inst_id = userenv('instance');
--select * into v_session from gv$session where audsid = userenv('SESSIONID') and OSUSER= SYS_CONTEXT('USERENV','OS_USER');
--
--raise_application_error('-20000',v_session.username||' '||v_session.inst_id);
-- Verifica se o usuário de banco tem acesso
IF (UPPER(v_session.username) NOT IN ('SYSTEM','SYS','ADMIN','DWADMIN','DBSNMP','SYSMAN')) then
-- Verifica se o usuário de Sistema Operacional tem acesso - Funcionário com perfil de DBA/AD/DW
If UPPER(v_session.osuser) NOT IN ('MARCO.LIMA','GABRIELA.MARQUES','YURI.ADAME', -- DBA
'ANDERSON.RIBEIRO','DEIVISON.MUNIZ','JAQUELINE.GISMONTI','GUSTAVO.SILVA','ALINE.MAGALHAES','CHRISTIANO.MATOS','NATANAEL.LEITE') then
-- Trava de usuário com problema
if UPPER(v_session.username) in ('CONSULTA_DBSVS_WEB') then
null;
--Verifica se as conexões são provenientes dos servidores ANVSSDFxx
elsif (upper(v_session.machine) like '%ANVSSDF%') then
null;
elsif (upper(v_session.terminal) like '%ANVSSDF%') then
null;
--Verifica se as conexões são provenientes dos servidores WWW1.ANVISA.GOV.BR
elsif (upper(v_session.machine) like '%WWW1.ANVISA.GOV.BR%') then
null;
elsif (upper(v_session.terminal) like '%WWW1.ANVISA.GOV.BR%') then
null;
--Libera o acesso temporário de migração
elsif (upper(v_session.machine) like '%WWW1N%') then
null;
-- --Libera o acesso da máquina an041387 da usuaria Carolina.Pigret e da maquina AN042791 do Ricardo.Borges
-- elsif (upper(v_session.terminal) in ('AN041387','AN042791','AN057032','AN041386')) and UPPER(v_session.osuser) IN ('CAROLINA.PINGRET','RICARDO.BORGES','MARCELO.ANGELO','FABIO.ALMEIDA') and upper(v_session.username) = 'CONSULTA_DBSVS' then
-- null;
--Libera o acesso para os usuários MARCELO_ANGELO,NADIR_OGLIARI com conexão dedicada
elsif UPPER(v_session.osuser) in ('MARCELO_ANGELO','NADIR_OGLIARI') and (upper(v_session.server) = 'DEDICATED') then
null;
elsif (upper(v_session.program) in ('JDBC THIN CLIENT')) and UPPER(v_session.username) IN ('ETIQUETA_WEB') then
null;
--###############################################################
--Libera o acesso da máquina gbt-02 Alessandro Mirante temporario
--elsif v_session.machine in ('gbt-02.local') and UPPER(v_session.username) IN ('CONS_EXTERNA') then
-- null;
--################################################################
-- Acesso para o setor de Arrecadação do sistema SAT
elsif UPPER(v_session.osuser) in ('FREDERICO.FERNANDES','JULIANA.QUARTIN','JORGE.NASCIMENTO') and (upper(v_session.username) = 'CADEMPRESA_WEB') then
null;
-- Libera o acesso para o usuário de banco CONS_PPS_DATAVISA
elsif UPPER(v_session.osuser) in ('STELA.MELCHIOR','MARIA.VICENTE','CARLA.CRUZ','GUILHERME.BUSS','CARLOS.FORNAZIER','MARIO.CHAVES')
and (upper(v_session.username) = 'CONS_PPS_DATAVISA') then
null;
--Acesso para Sammed
elsif (upper(v_session.username) = 'SAMMED_WEB') then
null;
-- Acesso para a GGREM
elsif UPPER(v_session.osuser) in ('ALESANDRE.SANTOS') and (upper(v_session.username) = 'MON_WEB') then
null;
--Libera o acesso da máquina AN0431 para o acesso do CSS com ousuário CSS_DATAVISA
elsif upper(v_session.terminal) = 'AN0431' and UPPER(v_session.username) = 'CSS_DATAVISA' then
null;
--Verifica se as conexões são proveniente de um APLICATIVO autorizado
elsif upper(v_session.program) in ('AGENDATEL.EXE','BAIXABBARRECADACAO.EXE','CODIVA_VS01.EXE','DIVA_VS01.EXE','FINANCEIROSIPAD.EXE',
'INETINFO.EXE','ESTATPAFSEG.EXE','MONITORAMENTO.EXE','PRJ_INTERFACE_DBMON.EXE',
'PDARF.EXE','UNICA.EXE','SNGPC.EXE','SIPAT.EXE') then
null;
--Elimina as conexões de usuários de SO desconhecidos
elsif v_session.osuser is null then
begin
execute immediate 'ALTER SYSTEM KILL SESSION '||''''||v_session.sid||','||v_session.serial#||',@'||v_session.inst_id||''';';
EXCEPTION
when others then
insert into admin.tb_after_logon values (v_session.OSUSER, v_session.PROGRAM, v_session.username, v_session.machine, v_session.terminal, v_session.logon_time,'Login-Anvisa-1.0');
commit;
raise_application_error('-20000','Acesso negado - 1.0!');
end;
--Elimina as conexões dos usuário DB*
elsif (UPPER(v_session.username) like 'DB%') or (UPPER(v_session.username) in ('AD')) then
begin
execute immediate 'ALTER SYSTEM KILL SESSION '||''''||v_session.sid||','||v_session.serial#||',@'||v_session.inst_id||''';';
EXCEPTION
when others then
insert into admin.tb_after_logon values (v_session.OSUSER, v_session.PROGRAM, v_session.username, v_session.machine, v_session.terminal, v_session.logon_time,'Login-Anvisa-1.1');
commit;
raise_application_error('-20000','Acesso negado - 1.1!');
end;
--Elimina as conexões não autorizadas
else
If (UPPER(v_session.osuser) NOT IN (
/* ANALISTA DE SISTEMAS - ANVISA */
'CARLOS.GONCALVES','DANIELLE.MACIEL','EWERTON.MARTINS','HONORIO.MARQUES','PEDRO.ALMEIDA',
'PAULO.CESAR','NELCI.SANTOS','ORACLE','VERANGGE.LOPES','JORGE.CARVALHO',
--/*ANALISTAS DA UNIMIX*/
/* ANALISTA DE SISTEMAS - MIRANTE */
'ADEMIR.JUNIOR','ALEXANDRE.MAXIMO','BRUNO.AMORIM','DIONE.OLIVEIRA','ROGERIO.MIARI','GLADSON.LIMA','MARCELO.RODRIGUES','WESLEY.MARINHO', 'ROBERTO.LUIZ','DARLAN.LISBOA','ERIC.SILVA','HELCIO.GONCALVES','RUZBEH.SHOKRANIAN','VICTOR.LUIZ','BRUNO.SANTOS','DIOGO.CORAZOLLA','PEDRO.ALMEIDA',
'RENATO.VALE','DIVINO.JUNIOR','ULISSES.SOARES','LEO.MARRA','LEONARDO.OSOUZA','JOAO.CHAGAS','BRUNO.BEHMOIRAS','WALLACE.SANTOS','DAYSE.MAGALHAES','LAZARO.FREITAS','CLAUDIO.DASILVA','ALESSANDRO.LEITE','WILSON.BRITO','DAVID.PEREIRA','RAIMUNDA.CIRILO','HOSANA.MACHADO','FRANCISCO.ADEMILSON'
/* DIVERSOS */)) then
begin
execute immediate 'ALTER SYSTEM KILL SESSION '||''''||v_session.sid||','||v_session.serial#||',@'||v_session.inst_id||''';';
EXCEPTION
when others then
insert into admin.tb_after_logon values (v_session.OSUSER, v_session.PROGRAM, v_session.username, v_session.machine, v_session.terminal, v_session.logon_time,'Login-Anvisa-1.2');
commit;
--admin.send_mail('ORACLE','dba@anvisa.gov.br',instance||' - '||to_char(sysdate,'dd/mm/yyyy hh24:mi:ss')||' Login-Anvisa-1.1','Login: '||v_session.OSUSER||chr(13)||'Program: '||v_session.PROGRAM||chr(13)||'User DB: '||v_session.username||chr(13)||'Máquina: '||v_session.machine||chr(13)||'Máquina: '||v_session.terminal);
raise_application_error('-20000','Acesso negado! Favor entrar em contato com a GESIS para maiores informações. Ramal: 1133.');
end;
end if;
end if;
End if;
END IF;
END;
/
-- End of DDL Script for Trigger SYS.AFTER_LOGON_BD
-- Start of DDL Script for Trigger SYS.AFTER_LOGON_BD
-- Generated 29/10/2007 10:45:47 from SYS@VS01
CREATE OR REPLACE TRIGGER sys.after_logon_bd
AFTER
LOGON
ON DATABASE
DECLARE
v_program SYS.V$SESSION.PROGRAM%TYPE;
v_osuser SYS.V$SESSION.OSUSER%TYPE;
v_sid sys.V$SESSION.sid%type;
v_serial sys.V$SESSION.serial#%type;
v_machine sys.V$SESSION.machine%type;
v_username sys.V$SESSION.username%type;
instance varchar2(20);
ip varchar2(30);
BEGIN
begin
select instance_name into instance from v$instance;
--
select sys_context('USERENV','IP_ADDRESS') into ip from dual;
--
select program, osuser, sid, serial#, machine, username into v_program, v_osuser, v_sid, v_serial, v_machine, v_username
from v$session where audsid = userenv('sessionid') and OSUSER= SYS_CONTEXT('USERENV','OS_USER');
exception
when others then
null;
end;
--Verifica se a máquina é da rede da Politec ANVS\BSBxxxx
if upper(v_machine) like '%BSB%' then
-- Elimina as conexões do css que estão usando o sqlnav ou o sqlplus
if (UPPER(V_PROGRAM) in ('SQLNAV4.EXE','SQLPLUSW.EXE','SQLPLUS.EXE','TOAD.EXE','MSACCESS.EXE')) and v_username not in ('CSS_DATAVISA' ) then
begin
execute immediate 'ALTER SYSTEM KILL SESSION '||''''||v_sid||','||v_serial||''';';
EXCEPTION
when others then
admin.send_mail('ORACLE','dba@anvisa.gov.br',instance||' Login: '||V_OSUSER||' - Program: '||V_PROGRAM||' User DB: '||v_username||' Máquina: '||v_machine||' Data: '||to_char(sysdate,'dd/mm/yyyy hh24:mi:ss')||' Login-Politec-1.1',null);
raise_application_error('-20000','Ferramenta permitida apenas para o usuário CSS_DATAVISA!');
end;
-- Verifica se as conexões dos CSS são feitas pelos usários permitidos
elsif (lower(V_OSUSER) not in (
/* CSS - Sistemas diversos */ 'alexandre.maximo','luciana.nunes','bruna.ferreira','wilton.Souza','vando.ferreira','marcelo.pinto','herliton.silva','allan.moreira',
'rodolfo.mota','cleyton.cruz','alexander.marinho','valter.Gomes','gleidson.lima','wesley.assis','marcos.teixeira',
/* CSS - Sistema Datavisa */ 'alysson.muniz','cleidson.carritilha','ademir.gouveia','livia.mota','christiany.melo','ricardo.almeida','joana.hattingh',
'marcelo.rodrigues','ademir.junior','bruno.saturnino','flavio.penna','marlene.marques','gladson.lima','carlenisio.oliveira')) then
begin
execute immediate 'ALTER SYSTEM KILL SESSION '||''''||v_sid||','||v_serial||''';';
EXCEPTION
when others then
admin.send_mail('ORACLE','dba@anvisa.gov.br',instance||' Login: '||V_OSUSER||' - Program: '||V_PROGRAM||' User DB: '||v_username||' Máquina: '||v_machine||' Data: '||to_char(sysdate,'dd/mm/yyyy hh24:mi:ss')||' Login-Politec-1.2',null);
raise_application_error('-20000','Acesso negado!');
end;
end if;
--Máquinas da rede da Anvisa ANVS\ANxxxx
else
IF UPPER(V_OSUSER) NOT IN
/* Usuários DBAs */ ('SYSTEM','SYS','ANVS\ADMINISTRATOR','MARCO.LIMA','ROGERIO.COSTA','ROGERIO.ADMIN','GABRIELA.MARQUES','NATANAEL.LEITE','ORACLE','ANDERSON.RIBEIRO',
/* Func. Politec */ 'ANDERSON.ALDI','BETAN.GUIMARAES','GUSTAVO.SILVA','LEONARDO.SANTOS','CONCEICAO.MARTINS','LUIZ.REIS','ANDRE.BOARO','HAI.CUI',
/* Func. Anvisa */ 'REINALDO.NELLI','NELCI.SANTOS','SHEILA.ABDALA','PAULO.CESAR','CAMILO.MUSSI','JAQUELINE.GISMONTI') then
IF UPPER(V_PROGRAM) NOT IN ('DLLHOST.EXE','JDBC THIN CLIENT','ORACLE@ANVSSDF40.ANVISA.GOV.BR (TNS V1-V3)','EXP.EXE','PHP-CGI.EXE','DELPHI32.EXE',
'DIVA_OLD.EXE','CODIVA_VS01.EXE','DIVA.EXE','VIGI.EXE','PRJ_INTERFACE_DBMON.EXE','ASPNET_WP.EXE','SINEPSINTRA.EXE','SINEPS.EXE','SAMMED.EXE',
'DIVA_VS01.EXE','BAIXABBARRECADACAO.EXE','DATAVISASEG.EXE','MONITORAMENTO.EXE','MONITORAMENTOMERCADOSERVNT.EXE',
'SQLPLUS@ANVSSDF45.ANVISA.GOV.BR (TNS V1-V3)','ORACLE@ANVSSDF22N.ANVISA.GOV.BR (TNS V1-V3)','RMAN.EXE','ORACLEDBCOLLECT@LW-APPLIANCE (TNS V1-V3)',
'ORACLEVS05@ANVSSDF22.ANVISA.GOV.BR (TNS V1-V3)','ORACLEVS09@ANVSSDF40.ANVISA.GOV.BR (TNS V1-V3)') THEN
IF UPPER(V_PROGRAM) NOT LIKE ('SQLPLUS@ANVSSDF45N%') THEN
admin.send_mail('ORACLE','dba@anvisa.gov.br',instance||' Login: '||V_OSUSER||' - Program: '||V_PROGRAM||' User DB: '||v_username||' Máquina: '||v_machine||' Data: '||to_char(sysdate,'dd/mm/yyyy hh24:mi:ss'),null);
END IF;
END IF;
END IF;
end if;
END;
/
-- End of DDL Script for Trigger SYS.AFTER_LOGON_BD
-- Start of DDL Script for Trigger SYS.AFTER_LOGON_BD
-- Generated 25-nov-2010 10:41:14 from SYS@vs01
CREATE OR REPLACE TRIGGER after_logon_bd
AFTER
LOGON
ON DATABASE
DECLARE
v_session sys.V$SESSION%rowtype;
instance sys.v$instance.instance_name%type;
BEGIN
-- select sys_context('USERENV','IP_ADDRESS') into ip from dual;
--
select instance_name into instance from v$instance;
--
select * into v_session from v$session where sid = userenv('sid');
--select * into v_session from v$session where audsid = userenv('SESSIONID') and OSUSER= SYS_CONTEXT('USERENV','OS_USER');
--
--Verifica se a máquina é da rede da Politec ANVS\BSBxxxx
if (upper(v_session.machine) like '%BSBXXXX%') OR (upper(v_session.terminal) like '%BSBXXXX%')then
-- Elimina as conexões do css que estão usando o sqlnav ou o sqlplus
if (UPPER(v_session.PROGRAM) in ('SQLNAV4.EXE','SQLNAV5.EXE','SQLPLUSW.EXE','SQLPLUS.EXE','TOAD.EXE','MSACCESS.EXE','SQL DEVELOPER')) and v_session.username not in ('CSS_DATAVISA' ) then
begin
execute immediate 'ALTER SYSTEM KILL SESSION '||''''||v_session.sid||','||v_session.serial#||''';';
EXCEPTION
when others then
insert into admin.tb_after_logon values (v_session.OSUSER, v_session.PROGRAM, v_session.username, v_session.machine, v_session.terminal, v_session.logon_time,'Login-Politec-1.1');
commit;
-- admin.send_mail('ORACLE','dba@anvisa.gov.br',instance||' Login: '||v_session.osuser||' - Program: '||v_session.PROGRAM||' User DB: '||v_session.username||' Máquina: '||v_session.machine||' Data: '||to_char(sysdate,'dd/mm/yyyy hh24:mi:ss')||' Login-Politec-1.1',null);
raise_application_error('-20000','Ferramenta permitida apenas para o usuário CSS_DATAVISA!');
end;
-- Verifica se as conexões dos CSS são feitas pelos usários permitidos
elsif (lower(v_session.OSUSER) not in (
/* Fábrica Mirante - Sistemas diversos */
'nilton.andrade')) then
begin
execute immediate 'ALTER SYSTEM KILL SESSION '||''''||v_session.sid||','||v_session.serial#||''';';
EXCEPTION
when others then
insert into admin.tb_after_logon values (v_session.OSUSER, v_session.PROGRAM, v_session.username, v_session.machine, v_session.terminal, v_session.logon_time,'Login-Politec-1.2');
commit;
-- admin.send_mail('ORACLE','dba@anvisa.gov.br',instance||' Login: '||v_session.OSUSER||' - Program: '||v_session.PROGRAM||' User DB: '||v_session.username||' Máquina: '||v_session.machine||' Data: '||to_char(sysdate,'dd/mm/yyyy hh24:mi:ss')||' Login-Politec-1.2',null);
raise_application_error('-20000','Acesso negado!');
end;
end if;
--Máquinas da rede da Anvisa ANVS\ANxxxx
else -- Verifica se o usuário de banco tem acesso
IF (UPPER(v_session.username) NOT IN ('SYSTEM','SYS','ADMIN','DWADMIN','DBSNMP','SYSMAN','MARCELO_ANGELO','NADIR_OGLIARI')) then
-- Verifica se o usuário de Sistema Operacional tem acesso - Funcionário com perfil de DBA/AD/DW
If UPPER(v_session.osuser) NOT IN ('MARCO.LIMA','GABRIELA.MARQUES','ANDERSON.RIBEIRO','DEIVISON.MUNIZ','JAQUELINE.GISMONTI','GUSTAVO.SILVA','YURI.ADAME') then
-- Trava de usuário com problema
if UPPER(v_session.username) in ('CONSULTA_DBSVS_WEB') then
--raise_application_error('-20000','Acesso negado!');
null;
--Verifica se as conexões são provenientes dos servidores ANVSSDFxx
elsif (upper(v_session.machine) like '%ANVSSDF%') then
null;
elsif (upper(v_session.terminal) like '%ANVSSDF%') then
null;
--Verifica se as conexões são provenientes dos servidores WWW1.ANVISA.GOV.BR
elsif (upper(v_session.machine) like '%WWW1.ANVISA.GOV.BR%') then
null;
elsif (upper(v_session.terminal) like '%WWW1.ANVISA.GOV.BR%') then
null;
--Libera o acesso temporário de migração
elsif (upper(v_session.machine) like '%WWW1N%') then
null;
--Libera o acesso da máquina an041387 da usuaria Carolina.Pigret e da maquina AN042791 do Ricardo.Borges
-- elsif (upper(v_session.terminal) in ('AN041387','AN042791','AN057032','AN041386')) and UPPER(v_session.osuser) IN ('CAROLINA.PINGRET','RICARDO.BORGES','MARCELO.ANGELO','FABIO.ALMEIDA') and upper(v_session.username) = 'CONSULTA_DBSVS' then
-- null;
elsif (upper(v_session.program) in ('JDBC THIN CLIENT')) and UPPER(v_session.username) IN ('ETIQUETA_WEB') then
null;
--Libera o acesso da máquina an050717 da analista aline
elsif (upper(v_session.terminal) in ('AN050717')) and UPPER(v_session.osuser) IN ('ALINE.MAGALHAES') then
null;
--###############################################################
--Libera o acesso da máquina gbt-02 Alessandro Mirante temporario
elsif v_session.machine in ('gbt-02.local') and UPPER(v_session.username) IN ('CONS_EXTERNA') then
null;
--################################################################
-- Acesso para o setor de Arrecadação do sistema SAT
elsif UPPER(v_session.osuser) in ('FREDERICO.FERNANDES','JULIANA.QUARTIN','JORGE.NASCIMENTO') and (upper(v_session.username) = 'CADEMPRESA_WEB') then
null;
-- Libera o acesso para o usuário de banco CONS_PPS_DATAVISA
elsif UPPER(v_session.osuser) in ('STELA.MELCHIOR','MARIA.VICENTE','CARLA.CRUZ','GUILHERME.BUSS','CARLOS.FORNAZIER','MARIO.CHAVES')
and (upper(v_session.username) = 'CONS_PPS_DATAVISA') then
null;
--Acesso para Sammed
elsif (upper(v_session.username) = 'SAMMED_WEB') then
null;
--desenvolvedor
-- Acesso para a GGREM
elsif UPPER(v_session.osuser) in ('ALESANDRE.SANTOS') and (upper(v_session.username) = 'MON_WEB') then
null;
--Libera o acesso da máquina AN0431 para o acesso do CSS com ousuário CSS_DATAVISA
elsif upper(v_session.terminal) = 'AN0431' and UPPER(v_session.username) = 'CSS_DATAVISA' then
null;
--Verifica se as conexões são proveniente de um APLICATIVO autorizado
elsif upper(v_session.program) in ('AGENDATEL.EXE','BAIXABBARRECADACAO.EXE','CODIVA_VS01.EXE','DIVA_VS01.EXE','FINANCEIROSIPAD.EXE',
'INETINFO.EXE','ESTATPAFSEG.EXE','MONITORAMENTO.EXE','PRJ_INTERFACE_DBMON.EXE',
'PDARF.EXE','UNICA.EXE','SNGPC.EXE','SIPAT.EXE') then
null;
--Elimina as conexões de usuários de SO desconhecidos
elsif v_session.osuser is null then
begin
insert into admin.tb_after_logon values (v_session.OSUSER, v_session.PROGRAM, v_session.username, v_session.machine, v_session.terminal, v_session.logon_time,'Login-Anvisa-1.0');
commit;
--execute immediate 'ALTER SYSTEM KILL SESSION '||''''||v_session.sid||','||v_session.serial#||''';';
EXCEPTION
when others then
null;
--insert into admin.tb_after_logon values (v_session.OSUSER, v_session.PROGRAM, v_session.username, v_session.machine, v_session.terminal, v_session.logon_time,'Login-Anvisa-1.0');
--commit;
--admin.send_mail('ORACLE','dba@anvisa.gov.br',instance||' Login: '||v_session.OSUSER||' - Program: '||v_session.PROGRAM||' User DB: '||v_session.username||' Máquina: '||v_session.machine||' Data: '||to_char(sysdate,'dd/mm/yyyy hh24:mi:ss')||' Login-Anvisa-1.0',null);
--raise_application_error('-20000','Acesso negado!');
end;
--Elimina as conexões dos usuário DB*
elsif (UPPER(v_session.username) like 'DB%') or (UPPER(v_session.username) in ('AD')) then
begin
execute immediate 'ALTER SYSTEM KILL SESSION '||''''||v_session.sid||','||v_session.serial#||''';';
EXCEPTION
when others then
insert into admin.tb_after_logon values (v_session.OSUSER, v_session.PROGRAM, v_session.username, v_session.machine, v_session.terminal, v_session.logon_time,'Login-Anvisa-1.1');
commit;
--admin.send_mail('ORACLE','dba@anvisa.gov.br',instance||' Login: '||v_session.OSUSER||' - Program: '||v_session.PROGRAM||' User DB: '||v_session.username||' Máquina: '||v_session.machine||' Data: '||to_char(sysdate,'dd/mm/yyyy hh24:mi:ss')||' Login-Anvisa-1.0',null);
raise_application_error('-20000','Acesso negado!');
end;
--Elimina as conexões não autorizadas
else
If (UPPER(v_session.osuser) NOT IN (
/* ANALISTA DE SISTEMAS - ANVISA */
'CARLOS.GONCALVES','DANIELLE.MACIEL','EWERTON.MARTINS','HONORIO.MARQUES','PEDRO.ALMEIDA',
'PAULO.CESAR','NELCI.SANTOS','ORACLE','VERANGGE.LOPES','JORGE.CARVALHO',
--/*ANALISTAS DA UNIMIX*/ 'ALEX.VIEIRA',
/* ANALISTA DE SISTEMAS - MIRANTE */
--/*Suporte Oracle*/ 'ARISTOTELLES.SERRA',
'ADEMIR.JUNIOR','ALEXANDRE.MAXIMO','BRUNO.AMORIM','DIONE.OLIVEIRA','ROGERIO.MIARI','GLADSON.LIMA','MARCELO.RODRIGUES','WESLEY.MARINHO', 'ROBERTO.LUIZ','DARLAN.LISBOA','ERIC.SILVA','HELCIO.GONCALVES','RUZBEH.SHOKRANIAN','VICTOR.LUIZ','BRUNO.SANTOS','DIOGO.CORAZOLLA','PEDRO.ALMEIDA',
'RENATO.VALE','DIVINO.JUNIOR','ULISSES.SOARES','LEO.MARRA','LEONARDO.OSOUZA','JOAO.CHAGAS','BRUNO.BEHMOIRAS','WALLACE.SANTOS','DAYSE.MAGALHAES','LAZARO.FREITAS','CLAUDIO.DASILVA','ALESSANDRO.LEITE','WILSON.BRITO','DAVID.PEREIRA','RAIMUNDA.CIRILO','HOSANA.MACHADO','FRANCISCO.ADEMILSON'
/* DIVERSOS */)) then
begin
execute immediate 'ALTER SYSTEM KILL SESSION '||''''||v_session.sid||','||v_session.serial#||''';';
EXCEPTION
when others then
insert into admin.tb_after_logon values (v_session.OSUSER, v_session.PROGRAM, v_session.username, v_session.machine, v_session.terminal, v_session.logon_time,'Login-Anvisa-1.2');
commit;
--admin.send_mail('ORACLE','dba@anvisa.gov.br',instance||' - '||to_char(sysdate,'dd/mm/yyyy hh24:mi:ss')||' Login-Anvisa-1.1','Login: '||v_session.OSUSER||chr(13)||'Program: '||v_session.PROGRAM||chr(13)||'User DB: '||v_session.username||chr(13)||'Máquina: '||v_session.machine||chr(13)||'Máquina: '||v_session.terminal);
raise_application_error('-20000','Acesso negado! Favor entrar em contato com a GESIS para maiores informações. Ramal: 1133.');
end;
end if;
end if;
End if;
END IF;
end if;
END;
/
-- End of DDL Script for Trigger SYS.AFTER_LOGON_BD
DECLARE
v_session sys.GV$SESSION%rowtype;
--instance sys.v$instance.instance_name%type;
BEGIN
-- select sys_context('USERENV','IP_ADDRESS') into ip from dual;
--
--instance := userenv('instance');
--
select * into v_session from gv$session where sid = userenv('sid') and inst_id = userenv('instance');
--select * into v_session from gv$session where audsid = userenv('SESSIONID') and OSUSER= SYS_CONTEXT('USERENV','OS_USER');
--
--raise_application_error('-20000',v_session.username||' '||v_session.inst_id);
-- Verifica se o usuário de banco tem acesso
IF (UPPER(v_session.username) NOT IN ('SYS','ADMIN','DBSNMP','SYSMAN')) then
-- Verifica se o usuário de Sistema Operacional tem acesso - Funcionário com perfil de DBA/AD/DW
If UPPER(v_session.osuser) NOT IN ('MARCO.LIMA','GABRIELA.MARQUES','YURI.ADAME', -- DBA
'ANDERSON.MOTA','DEIVISON.MUNIZ','JAQUELINE.GISMONTI','GUSTAVO.SILVA','ALINE.MAGALHAES','CHRISTIANO.MATOS','NATANAEL.SLEITE') then
-- Trava de usuário com problema
--if UPPER(v_session.username) in ('CONSULTA_DBSVS_WEB') then
--raise_application_error('-20000','Usuário bloqueado!');
--end if;
--Verifica se as conexões são provenientes dos servidores ANVSSDFxx
if (upper(v_session.machine) like '%ANVSSDF%') then
null;
elsif (upper(v_session.terminal) like '%ANVSSDF%') then
null;
--Verifica se as conexões são provenientes dos servidores WWW1.ANVISA.GOV.BR
elsif (upper(v_session.machine) like '%WWW1.ANVISA.GOV.BR%') then
null;
elsif (upper(v_session.terminal) like '%WWW1.ANVISA.GOV.BR%') then
null;
--Libera o acesso temporário de migração
elsif (upper(v_session.machine) like '%WWW1N%') then
null;
--###############################################################
--Libera o acesso da máquina MarcelloAndrade do analista MARCELLO.ANDRADE do projeto PRIMOR
elsif v_session.machine in ('nbk-0050','GESTAO\NBK-0050') and UPPER(v_session.username) IN ('CONS_PRIMOR') then
null;
--###############################################################
--Libera o acesso da máquina FSOARES-BR - Consultar Oracle Felipe temporario
--elsif v_session.machine in ('FSOARES-BR') and UPPER(v_session.username) IN ('CONS_BAM') then
--null;
--Libera o acesso do usuário Luiz.Vassoler - Consultar Oracle Felipe temporario
elsif upper(v_session.osuser) in ('LUIZ.VASSOLER') and UPPER(v_session.username) IN ('DWUNIMIX') then
null;
--Libera o acesso da máquina an041387 da usuaria Carolina.Pigret e da maquina AN042791 do Ricardo.Borges
elsif (upper(v_session.terminal) in ('AN064166','AN064809','AN064183','AN064170'))
and (upper(v_session.osuser) in ('CAROLINA.PINGRET','RICARDO.BORGES','MARCELO.ANGELO','FABIO.ALMEIDA'))
and (upper(v_session.username) = 'CONS_ESTAT_GGMED') and ((upper(v_session.server) = 'DEDICATED')) then
null;
elsif (upper(v_session.program) in ('JDBC THIN CLIENT')) and UPPER(v_session.username) IN ('ETIQUETA_WEB') then
null;
-- Acesso para o setor de Arrecadação do sistema SAT
elsif UPPER(v_session.osuser) in ('FREDERICO.FERNANDES','JULIANA.QUARTIN','JORGE.NASCIMENTO') and (upper(v_session.username) = 'CADEMPRESA_WEB') then
null;
-- Libera o acesso para o usuário de banco CONS_PPS_DATAVISA
elsif upper(v_session.osuser) in ('STELA.MELCHIOR','MARIA.VICENTE','CARLA.CRUZ','GUILHERME.BUSS','CARLOS.FORNAZIER','MARIO.CHAVES')
and upper(v_session.username) = 'CONS_PPS_DATAVISA' then
null;
--Acesso para Sammed
--elsif (upper(v_session.username) = 'SAMMED_WEB') then
--null;
-- Acesso para a GGREM
elsif UPPER(v_session.osuser) in ('ALESANDRE.SANTOS') and (upper(v_session.username) = 'MON_WEB') then
null;
--Verifica se as conexões são proveniente de um APLICATIVO autorizado
elsif upper(v_session.program) in ('AGENDATEL.EXE','BAIXABBARRECADACAO.EXE','CODIVA_VS01.EXE','DIVA_VS01.EXE','FINANCEIROSIPAD.EXE',
'INETINFO.EXE','ESTATPAFSEG.EXE','MONITORAMENTO.EXE','PRJ_INTERFACE_DBMON.EXE',
'PDARF.EXE','UNICA.EXE','SNGPC.EXE','SIPAT.EXE','FINANCEIROSIPAD.EXE') then
null;
--Elimina as conexões de usuários de SO desconhecidos
elsif v_session.osuser is null then
begin
execute immediate 'ALTER SYSTEM KILL SESSION '||''''||v_session.sid||','||v_session.serial#||',@'||v_session.inst_id||''';';
EXCEPTION
when others then
insert into admin.tb_after_logon values (v_session.OSUSER, v_session.PROGRAM, v_session.username, v_session.machine, v_session.terminal, v_session.logon_time,'Login-Anvisa-1.0');
commit;
raise_application_error('-20000','Acesso negado - 1.0!');
end;
--Elimina as conexões dos usuário DB*
elsif (UPPER(v_session.username) like 'DB%') or (UPPER(v_session.username) in ('AD')) then
begin
execute immediate 'ALTER SYSTEM KILL SESSION '||''''||v_session.sid||','||v_session.serial#||',@'||v_session.inst_id||''';';
EXCEPTION
when others then
insert into admin.tb_after_logon values (v_session.OSUSER, v_session.PROGRAM, v_session.username, v_session.machine, v_session.terminal, v_session.logon_time,'Login-Anvisa-1.1');
commit;
raise_application_error('-20000','Acesso negado - 1.1!');
end;
--Elimina as conexões não autorizadas
else
If (UPPER(v_session.osuser) NOT IN (
/* ANALISTA DE SISTEMAS - ANVISA */
/*'CARLOS.GONCALVES','DANIELLE.MACIEL','EWERTON.MARTINS',*/'HONORIO.MARQUES','PEDRO.ALMEIDA','BRUNO.BEHMOIRAS','VICTOR.LUIZ',
/*'PAULO.CESAR',*/'NELCI.SANTOS','ORACLE',--'VERANGGE.LOPES','JORGE.CARVALHO',
/* ANALISTA DE SISTEMAS - MIRANTE */
'ADEMIR.JUNIOR','ALEXANDRE.MAXIMO','ROGERIO.MIARI','MARCELO.RODRIGUES',
'BRUNO.SANTOS','DIOGO.CORAZOLLA','LEO.MARRA','JOAO.CHAGAS','CLAUDIO.DASILVA',
'WILSON.BRITO','DAVID.PEREIRA','RAIMUNDA.CIRILO','HOSANA.MACHADO','RODRIGO.AIRES','FRANCISCO.ADEMILSON','JONAS.GONCALVES'
/* DIVERSOS */)) then
begin
execute immediate 'ALTER SYSTEM KILL SESSION '||''''||v_session.sid||','||v_session.serial#||',@'||v_session.inst_id||''';';
EXCEPTION
when others then
insert into admin.tb_after_logon values (v_session.OSUSER, v_session.PROGRAM, v_session.username, v_session.machine, v_session.terminal, v_session.logon_time,'Login-Anvisa-1.2');
commit;
--admin.send_mail('ORACLE','dba@anvisa.gov.br',instance||' - '||to_char(sysdate,'dd/mm/yyyy hh24:mi:ss')||' Login-Anvisa-1.1','Login: '||v_session.OSUSER||chr(13)||'Program: '||v_session.PROGRAM||chr(13)||'User DB: '||v_session.username||chr(13)||'Máquina: '||v_session.machine||chr(13)||'Máquina: '||v_session.terminal);
raise_application_error('-20000','Acesso negado! Favor entrar em contato com a GESIS para maiores informações. Ramal: 1133.');
end;
end if;
end if;
End if;
END IF;
END;
SELECT OWNER, JOB_NAME, ENABLED FROM DBA_SCHEDULER_JOBS;
SELECT 'EXEC dbms_scheduler.disable (''' || owner || '.' || job_name || ''');'
FROM dba_scheduler_jobs
WHERE enabled = 'TRUE'
ORDER BY owner, job_name;
-- Start of DDL Script for Trigger SYS.TA_ERRORS
-- Generated 11/11/2010 09:24:08 from SYS@vs01
CREATE OR REPLACE TRIGGER ta_errors
AFTER
SERVERERROR
ON DATABASE
declare
instance varchar2(20);
captured_sql varchar2(1000);
terminal gv$session.terminal%type;
machine gv$session.machine%type;
program gv$session.program%type;
osuser gv$session.osuser%type;
begin
if ora_server_error(1) not in (1,31,54,604,900,902,903,904,905,906,907,908,909,911,913,917,918,919,920,921,922,923,924,926,927,928,932,933,936,937,938,942,947,955,957,959,964,971,972,979,984,990,997,1002,1008,1013,1017,1031,1400,1401,1407,1408,1418,1427,1430,1438,1440,1445,1446,1453,1458,1468,1476,1490,1704,1719,1720,1722,1735,1747,1756,1785,1789,1791,1795,1821,1830,1835,1839,1840,1841,1843,1847,1849,1850,1858,1861,1917,1927,2000,2019,2051,2248,2158,2261,2264,2267,2270,2289,2290,2291,2292,2298,2299,2402,2404,2429,2430,2443,2449,3217,4043,4070,4071,6502,6550,6564,8108,12154,12899,20000,20034,22920,24372,24761,25228,30021,29902,20620,20601,25254,20501,20101,03001,31050,15000,20206,00028) then --,00028 --> kill session
--eliminagco de erros para TODAS as instances
select instance_name into instance from v$instance;
if instance = 'vs03' and ( --eliminagco de erros para instances especmficas
(ora_login_user='LINKDATA' and ora_server_error(1) in (936)) or
(ora_login_user='NEWSLETTER_WEB' and ora_server_error(1) in (1002)) ) then
null;
else
begin
SELECT q.sql_text, s.terminal, s.machine, s.program, s.osuser INTO captured_sql, terminal, machine, program, osuser
FROM gv$sql q, gv$sql_cursor c, gv$session s
WHERE s.audsid = audsid
AND s.prev_sql_addr = q.address
AND q.address = c.parent_handle;
exception
when no_data_found then
null;
end;
admin.send_mail('ORACLE','dba@anvisa.gov.br',instance||' User: '||ora_login_user||' - Erro: '
||ora_server_error(1)||' Msg: '||ora_server_error_msg(1)||' Data: '||to_char(sysdate,'dd/mm/yyyy hh24:mi:ss'),
'Terminal: '||terminal||chr(13)||'Machine: '||machine||chr(13)||'Program: '||program||chr(13)||'Osuser: '||osuser||chr(13)
||captured_sql);
end if;
end if;
end;
/
-- End of DDL Script for Trigger SYS.TA_ERRORS
-- =======================================================================
-- COMMANDS
-- =======================================================================
[root@srv1 ~]# ssh-keygen -t rsa
[root@srv2 ~]# ssh-keygen -t rsa
[root@srv3 ~]# ssh-keygen -t rsa
[root@srv1 ~]# cat ~/.ssh/id_rsa.pub >> ~/.ssh/authorized_keys
[root@srv1 ~]# ssh srv2 cat ~/.ssh/id_rsa.pub >> ~/.ssh/authorized_keys
[root@srv1 ~]# ssh srv3 cat ~/.ssh/id_rsa.pub >> ~/.ssh/authorized_keys
[root@srv1 ~]# cat .ssh/authorized_keys
[root@srv1 ~]# scp .ssh/authorized_keys srv2:/root/.ssh/authorized_keys
[root@srv1 ~]# scp .ssh/authorized_keys srv3:/root/.ssh/authorized_keys
[root@srv1 ~]# chmod 644 ~/.ssh/authorized_keys
[root@srv2 ~]# chmod 644 ~/.ssh/authorized_keys
[root@srv3 ~]# chmod 644 ~/.ssh/authorized_keys
[root@srv1 ~]# ssh srv2 date
[root@srv1 ~]# ssh srv3 date
[root@srv1 ~]# date ; ssh srv2 date; ssh srv3 date;
-- =======================================================================
-- EXECUTION
-- =======================================================================
====================================================================================
[root@srv1 ~]# ssh-keygen -t rsa |
Generating public/private rsa key pair. |
Enter file in which to save the key (/root/.ssh/id_rsa): |
Created directory '/root/.ssh'. |
Enter passphrase (empty for no passphrase): |
Enter same passphrase again: |
Your identification has been saved in /root/.ssh/id_rsa. |
Your public key has been saved in /root/.ssh/id_rsa.pub. |
The key fingerprint is: |
6a:b6:d2:90:b4:d7:33:22:3e:08:4a:3d:65:12:8d:47 root@srv1.localdomain |
The key randomart image is: |
+--[ RSA 2048]----+ |
| | |
| ___ | |
| (._.) | |
| <||> | |
| _/\_ | |
+-----------------+ |
-----------------------------------------------------------------------------------|
[root@srv2 ~]# ssh-keygen -t rsa |
Generating public/private rsa key pair. |
Enter file in which to save the key (/root/.ssh/id_rsa): |
Created directory '/root/.ssh'. |
Enter passphrase (empty for no passphrase): |
Enter same passphrase again: |
Your identification has been saved in /root/.ssh/id_rsa. |
Your public key has been saved in /root/.ssh/id_rsa.pub. |
The key fingerprint is: |
55:59:cb:fe:28:21:93:49:01:4b:f1:6e:83:7d:62:6b root@srv2.localdomain |
The key randomart image is: |
+--[ RSA 2048]----+ |
| | |
| /\_/\ ( | |
| ( ^.^ ) _) | |
| \"/ ( | |
| ( | | ) | |
| (__d b__) | |
+-----------------+ |
-----------------------------------------------------------------------------------|
[root@srv3 ~]# ssh-keygen -t rsa |
Generating public/private rsa key pair. |
Enter file in which to save the key (/root/.ssh/id_rsa): |
Created directory '/root/.ssh'. |
Enter passphrase (empty for no passphrase): |
Enter same passphrase again: |
Your identification has been saved in /root/.ssh/id_rsa. |
Your public key has been saved in /root/.ssh/id_rsa.pub. |
The key fingerprint is: |
55:59:cb:fe:28:21:93:49:01:4b:f1:6e:83:7d:62:6b root@srv2.localdomain |
The key randomart image is: |
+--[ RSA 2048]----+ |
| __ | |
| _/ \_ | |
| ( `_´) | |
| <,=====> --- - - |
| _/ \_ | |
+-----------------+ |
===================================================================================|
[root@srv1 ~]# cat ~/.ssh/id_rsa.pub >> ~/.ssh/authorized_keys
[root@srv1 ~]# ssh srv2 cat ~/.ssh/id_rsa.pub >> ~/.ssh/authorized_keys
The authenticity of host srv2 (192.168.56.72) can not be established.
RSA key fingerprint is 45:ca:cd:61:d5:d2:38:04:1c:10:1e:40:3d:8f:a9:68.
Are you sure you want to continue connecting (yes/no)? YES
Warning: Permanently added srv2,192.168.56.72 (RSA) to the list of known hosts.
root@srv2's password: *********
[root@srv1 ~]# cat .ssh/authorized_keys
ssh-rsa AAAAB3NzaC1yc2EAAAABIwAAAQEAtU4ml7DBNPqCE+OtaASEspVdMoB8A/ALmhH7Fv9/xZaRJa+cHNZuL1ArL0M7XQ== root@srv1.localdomain
ssh-rsa AAAAB3NzaC1yc2EAAAABIwAAAQEAr0R0Ijxh9vYBfvsmH1tFpn5tV14MbwiwixOwPnT7sLVfrYZJj5AKehQn1N99UQ== root@srv2.localdomain
ssh-rsa AAAAB3NzaC1yc2EAAAABIwAAAQEA90R0Ijxh9vYBfvsmH1tFpn5tV14MbwiwixOwPnT7sLVfrYZJj5AKehQn1N99UQ== root@srv3.localdomain
[root@srv1 ~]# scp .ssh/authorized_keys srv2:/root/.ssh/authorized_keys
root@srv2 password: *********
authorized_keys 100% 806 0.8KB/s 00:00
[root@srv1 ~]# scp .ssh/authorized_keys srv3:/root/.ssh/authorized_keys
root@srv2 password: *********
authorized_keys 100% 806 0.8KB/s 00:00
[root@srv1 ~]# chmod 644 ~/.ssh/authorized_keys
[root@srv2 ~]# chmod 644 ~/.ssh/authorized_keys
[root@srv3 ~]# chmod 644 ~/.ssh/authorized_keys
-- =======================================================================
-- TEST
-- =======================================================================
[root@srv1 ~]# ssh srv2 date
Tue May 14 18:44:06 +04 2024
[root@srv1 ~]# date ; ssh srv2 date; ssh srv3 date;
Tue May 14 18:44:52 +04 2024
Tue May 14 18:44:52 +04 2024
Tue May 14 18:44:52 +04 2024
select owner, table_name, stattype_locked
from dba_tab_statistics
where stattype_locked is not null;
exec dbms_stats.unlock_schema_stats('dbtabaco');
exec dbms_stats.unlock_table_stats('dbsvs','MVW_LISTA_PUBLICACAO_MED');
SELECT TRUNC(A.first_time), COUNT(1), round(sum(blocks*block_size) / (1024*1024)) "MB"
FROM V$ARCHIVED_LOG A
WHERE A.dest_id = 1
AND A.first_time > '01-AGO-08'
GROUP BY ROLLUP(TRUNC(A.first_time))
ORDER BY 1 DESC;
select distinct a.osuser, a.username, b.no_usuario, c.sg_unidade_org, a.program
from admin.tb_after_logon a, dbseguranca.tb_usuario b, dbsistru.tb_unidade_org c
where upper(a.osuser) = b.co_username (+)
and b.co_interno_uorg = c.co_seq_interno_uorg (+)
and a.logon_time > '15-MAR-08' order by 1
/* select * from admin.tb_after_logon WHERE logon_time > '15-MAR-08' ORDER BY LOGON_TIME DESC */
-- Total de espaço utilizados apenas pelos datafiles - Espaço alocado e desalocado
select round((sum(bytes) / (1024*1024))) from dba_data_files
-- Total de segmentos do banco de dados - Espaço alocado pelos objetos
select round((sum(bytes) / (1024*1024))) from Dba_Segments
-- Total de datafile e tempfiles
select a.datafile + b.tempfile from
(select round((sum(bytes) / (1024*1024*1024))) as datafile from dba_data_files ) a,
(select round((sum(user_bytes) / (1024*1024*1024))) as tempfile from dba_temp_files) b
select a.owner, a.segment_name, a.segment_type, a.bytes / (1024*1024), b.last_analyzed
from dba_segments a, dba_indexes b
where a.owner = b.owner and a.segment_name = b.index_name and b.table_name = 'TB_ESTOQUE_INVENTARIO'
and a.owner = 'DBSNGPC' and a.segment_type = 'INDEX';
select b.tablespace_name, sum(b.bytes)/(1024*1024)
from dba_data_files b
where b.bytes < 2097152
and b.tablespace_name not in (select distinct c.default_tablespace from dba_users c)
and b.tablespace_name not in (select distinct d.tablespace_name from dba_segments d)
group by b.tablespace_name order by 2;
-- objetos em geral
SELECT DBMS_METADATA.get_ddl(OBJECT_TYPE,OBJECT_NAME,OWNER)--, OWNER
FROM dba_objects
WHERE OBJECT_TYPE = 'INDEX'
AND OBJECT_NAME = 'CTX_DS_CATEGORIA_PRODUTO'
-- índices do ctx
select *--DBMS_METADATA.get_ddl('INDEX',index_NAME,OWNER)
from dba_indexes where index_name like 'CTX_%'
--ddl tablespaces
SELECT DBMS_METADATA.get_ddl('TABLESPACE',TABLESPACE_NAME)||'/' FROM dba_tablespaces
SELECT OBJECT_TYPE,OBJECT_NAME,OWNER, METADATA
FROM (SELECT OBJECT_TYPE,OBJECT_NAME,OWNER,DBMS_METADATA.get_ddl(OBJECT_TYPE,OBJECT_NAME,OWNER) AS METADATA
FROM dba_objects
WHERE OBJECT_TYPE in ('PROCEDURE','FUNCTION') AND
OWNER LIKE 'DB%') A
WHERE A.METADATA LIKE '%TRANSACAO%'
SELECT sequence#, name FROM v$archived_log a ORDER BY sequence#;
CREATE DIRECTORY archdir AS '+fra_asm_dg/vs01/archivelog/2010_10_13';
CREATE DIRECTORY tempdir AS '/u02/tmp';
-- All of the the currently supported procedures have some common usage notes listed below:
-- The user must have read privilege on the source directory object and write privilege on the destination directory object.
-- The procedure converts directory object names to uppercase unless they are surrounded by double quotes.
-- Files to be copied must be multiples of 512 bytes in size.
-- Files to be copied must be equal to or less than 2 terabytes in size.
-- File transfers are not transactional.
-- Files are copied as binary, so no character conversions are performed.
-- File copies can be monitored using the V$SESSION_LONGOPS view.
-- COPY_FILE
-- The COPY_FILE procedure allows you to copy binary files from one location to another on the same server.
-- Create the source and destination directory objects.
CREATE OR REPLACE DIRECTORY db_files_dir1 AS '/u01/oradata/DB10G/';
CREATE OR REPLACE DIRECTORY db_files_dir2 AS '/u02/oradata/DB10G/';
-- Switch a tablespace into read only mode so we can
-- use it for a test file transfer.
ALTER TABLESPACE users READ ONLY;
-- Copy the file.
BEGIN
DBMS_FILE_TRANSFER.COPY_FILE(
source_directory_object => 'DB_FILES_DIR1',
source_file_name => 'USERS01.DBF',
destination_directory_object => 'DB_FILES_DIR2',
destination_file_name => 'USERS01.DBF');
END;
/
-- Switch the tablespace back to read write mode.
ALTER TABLESPACE users READ WRITE;
-- GET_FILE
-- The GET_FILE procedure allows you to copy binary files from a remote server to the local server.
-- Login to the remote server.
CONN system/password@remote
-- Create the source directory object and switch mode of a tablespace.
CREATE OR REPLACE DIRECTORY db_files_dir1 AS '/u01/oradata/DB10G/';
ALTER TABLESPACE users READ ONLY;
-- Login to the local server.
CONN system/password@local
-- Create the destination directory object and a database link.
CREATE OR REPLACE DIRECTORY db_files_dir2 AS '/u02/oradata/DB10G/';
CREATE DATABASE LINK remote CONNECT TO system IDENTIFIED BY password USING 'REMOTE';
-- Get the file.
BEGIN
DBMS_FILE_TRANSFER.GET_FILE(
source_directory_object => 'DB_FILES_DIR1',
source_file_name => 'USERS01.DBF',
source_database => 'REMOTE',
destination_directory_object => 'DB_FILES_DIR2',
destination_file_name => 'USERS01.DBF');
END;
/
-- Login to the remote server.
CONN system/password@remote
-- Switch the tablespace back to read write mode.
ALTER TABLESPACE users READ WRITE;
-- PUT_FILE
-- The PUT_FILE procedure allows you to copy binary files from the local server to a remote server.
-- Login to the remote server.
CONN system/password@remote
-- Create the destination directory object.
CREATE OR REPLACE DIRECTORY db_files_dir2 AS '/u02/oradata/DB10G/';
-- Login to the local server.
CONN system/password@local
-- Create the source directory object, database link and switch mode of a tablespace.
CREATE OR REPLACE DIRECTORY db_files_dir1 AS '/u01/oradata/DB10G/';
CREATE DATABASE LINK remote CONNECT TO system IDENTIFIED BY password USING 'REMOTE';
ALTER TABLESPACE users READ ONLY;
-- Put the file.
BEGIN
DBMS_FILE_TRANSFER.PUT_FILE(
source_directory_object => 'DB_FILES_DIR1',
source_file_name => 'USERS01.DBF',
destination_directory_object => 'DB_FILES_DIR2',
destination_file_name => 'USERS01.DBF',
destination_database => 'REMOTE');
END;
/
-- Switch the tablespace back to read write mode.
ALTER TABLESPACE users READ WRITE;
column comp_id format A10
column version like comp_id
column comp_name format A30
select comp_id, status, version, comp_name from dba_registry order by 1;
-----------
--SELECT * FROM nls_database_parameters WHERE parameter LIKE '%SET' ORDER BY 1;
select a.name, a.status , b.status "status bkp", a.bytes from v$datafile a, v$backup b
where a.file# = b.file# order by b.status;
SELECT * FROM GV$STANDBY_LOG order by 2
select * from GV$LOGSTDBY
--select * from V$ARCHIVED_LOG where dest_id = 1 order by 2 desc
select * from GV$LOGFILE order by group#
select * from GV$LOG order by 1,2
--select * from V$ARCHIVE_DEST
--SELECT TIMESTAMP, MESSAGE FROM V$DATAGUARD_STATUS;
--SELECT PROCESS, STATUS, THREAD#, SEQUENCE#, BLOCK#, BLOCKS FROM V$MANAGED_STANDBY;
--ALTER SYSTEM SWITCH LOGFILE
--ALTER SYSTEM CHECKPOINT
ALTER DATABASE ADD LOGFILE THREAD 3 ('+DATA_ASM_DG') SIZE 300M;
ALTER DATABASE DROP LOGFILE GROUP 26;
ALTER DATABASE ADD LOGFILE GROUP 1 ('/u02/vs01/redo/RedoLog01B.log', '/u01/vs01/redo/RedoLog01A.log') SIZE 250M reuse;
ALTER DATABASE ADD LOGFILE GROUP 2 ('/u02/vs01/redo/RedoLog02B.log', '/u01/vs01/redo/RedoLog02A.log') SIZE 250M reuse;
ALTER DATABASE ADD LOGFILE GROUP 3 ('/u02/vs01/redo/RedoLog03B.log', '/u01/vs01/redo/RedoLog03A.log') SIZE 250M reuse;
ALTER DATABASE ADD LOGFILE GROUP 4 ('/u02/vs01/redo/RedoLog04B.log', '/u01/vs01/redo/RedoLog04A.log') SIZE 250M reuse;
ALTER DATABASE ADD LOGFILE GROUP 5 ('/u02/vs01/redo/RedoLog05B.log', '/u01/vs01/redo/RedoLog05A.log') SIZE 250M reuse;
ALTER DATABASE ADD LOGFILE GROUP 6 ('/u02/vs01/redo/RedoLog06B.log', '/u01/vs01/redo/RedoLog06A.log') SIZE 250M reuse;
ALTER DATABASE DROP LOGFILE GROUP 1;
ALTER DATABASE DROP LOGFILE GROUP 2;
ALTER DATABASE DROP LOGFILE GROUP 3;
ALTER DATABASE DROP LOGFILE GROUP 4;
ALTER DATABASE DROP LOGFILE GROUP 5;
ALTER DATABASE DROP LOGFILE GROUP 6;
--CRIA MAIS MEMBROS PARA OS GRUPOS DE REDO - CRIAR APÓS MIGRAÇÃO
/*
ALTER DATABASE ADD LOGFILE MEMBER '/u01/vs01/redo/RedoLog01B.log' TO GROUP 1;
ALTER DATABASE ADD LOGFILE MEMBER '/u01/vs01/redo/RedoLog02B.log' TO GROUP 2;
ALTER DATABASE ADD LOGFILE MEMBER '/u01/vs01/redo/RedoLog03B.log' TO GROUP 3;
ALTER DATABASE ADD LOGFILE MEMBER '/u01/vs01/redo/RedoLog04B.log' TO GROUP 4;
ALTER DATABASE ADD LOGFILE MEMBER '/u01/vs01/redo/RedoLog05B.log' TO GROUP 5;
*/
-- drop os standby redo logs
ALTER DATABASE DROP STANDBY LOGFILE GROUP 7;
ALTER DATABASE DROP STANDBY LOGFILE GROUP 8;
ALTER DATABASE DROP STANDBY LOGFILE GROUP 9;
ALTER DATABASE DROP STANDBY LOGFILE GROUP 10;
ALTER DATABASE DROP STANDBY LOGFILE GROUP 11;
-- Cria no dia da migração para fazer o standby
ALTER DATABASE ADD STANDBY LOGFILE GROUP 7 ('/u02/vs01/redo/stby_RedoLog07A.log') SIZE 250M reuse;
ALTER DATABASE ADD STANDBY LOGFILE GROUP 8 ('/u02/vs01/redo/stby_RedoLog08A.log') SIZE 250M reuse;
ALTER DATABASE ADD STANDBY LOGFILE GROUP 9 ('/u02/vs01/redo/stby_RedoLog09A.log') SIZE 250M reuse;
ALTER DATABASE ADD STANDBY LOGFILE GROUP 10 ('/u02/vs01/redo/stby_RedoLog10A.log') SIZE 250M reuse;
ALTER DATABASE ADD STANDBY LOGFILE GROUP 11 ('/u02/vs01/redo/stby_RedoLog11A.log') SIZE 250M reuse;
-- Criar logfle stby
ALTER DATABASE ADD STANDBY LOGFILE ('+DATA_ASM_DG') SIZE 300M;
ALTER DATABASE ADD STANDBY LOGFILE ('+DATA_ASM_DG') SIZE 300M;
ALTER DATABASE ADD STANDBY LOGFILE ('+DATA_ASM_DG') SIZE 300M;
ALTER DATABASE ADD STANDBY LOGFILE ('+DATA_ASM_DG') SIZE 300M;
ALTER DATABASE ADD STANDBY LOGFILE ('+DATA_ASM_DG') SIZE 300M;
ALTER DATABASE ADD STANDBY LOGFILE ('+DATA_ASM_DG') SIZE 300M;
ALTER DATABASE ADD STANDBY LOGFILE THREAD 3 ('+DATA_ASM_DG') SIZE 300M;
-- Para evitar Deadlock é necessário que as FKs estejam indexadas. Veja as coluna for_index_name
-- Uma outra opção é aumentar o paramentro ini_trans das tabelas e dos índíces.
select a.owner for_owner, a.table_name for_table, a.constraint_name for_constr, a.index_name for_index_name,
b.owner pri_owner, b.table_name pri_table, b.constraint_name pri_constr, b.index_name pri_index_name
from user_constraints a, user_constraints b
where a.r_constraint_name = b.constraint_name
and a.constraint_type = 'R'
and b.constraint_type = 'P';
select * from dba_source
where owner = 'DBSNGPC' and TYPE in ('FUNCTION','PROCEDURE','PACKAGE BODY')
and upper(text) like '%NÃO PODE SER VALIDADO%'
select b.name, a.status, a.time, round(b.bytes/(1024*1024),2)
from v$backup a , v$datafile b
where a.file# = b.file#
and a.status != 'NOT ACTIVE'
--select name from v$datafile
/*
http://download.oracle.com/docs/cd/B19306_01/network.102/b14266/cfgaudit.htm#i1011851
*/
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'DBHEMOCAD',
object_name => 'TB_HEMOTERAPICA',
policy_name => 'TB_HEMOTERAPICA_AUDIT' );
END;
------------- AUDITORIA NO VS01 29/01/2010 retirada em 18/10/2010---------------
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'DBHEMOCAD',
object_name => 'TB_HEMOTERAPICA',
policy_name => 'TB_HEMOTERAPICA_AUDIT',
audit_condition => NULL,
audit_column => NULL,
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'SELECT',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED,
--,
audit_column_opts => DBMS_FGA.ALL_COLUMNS
);
end;
---------------------------------------
--delete from sys.fga_log$ where POLICYNAME in ('DBCORP_USU_REP','DBGERAL_ENDERECOEMPRESA');
--COMMIT
truncate table sys.fga_log$;
select distinct * from dba_fga_audit_trail
where policy_name = 'TB_HEMOTERAPICA_AUDIT';
order by policy_name;
---------------------------------------
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'DBRH',
object_name => 'TB_SITUACAO',
policy_name => 'TB_SITUACAO_AUDIT' );
END;
------------- AUDITORIA NO VS06 11/11/2009 já retirada---------------
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'DBRH',
object_name => 'TB_SITUACAO',
policy_name => 'TB_SITUACAO_AUDIT',
audit_condition => NULL,
audit_column => 'CO_SITUACAO',
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'SELECT',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED
--,
--audit_column_opts => DBMS_FGA.ALL_COLUMNS
);
end;
/*
desc sys.fga_log$
delete from sys.fga_log$ where POLICYNAME ='TB_PESSOA_AUDIT' and trunc(NTIMESTAMP#) = to_date('16-abr-2008');
desc dba_fga_audit_trail
select distinct policy_name, OBJECT_NAME, OBJECT_SCHEMA from dba_fga_audit_trail ;
select distinct TIMESTAMP, db_user, os_user, userhost, object_schema, object_name, sql_text
from dba_fga_audit_trail
where trunc(TIMESTAMP) <= to_date('16-abr-2008') and policy_name in ('TB_PESSOA_AUDIT')
order by TIMESTAMP, db_user;
select distinct * from dba_fga_audit_trail
where policy_name in ('TB_EMPRESA_AUDIT', 'TB_PESSOA_JURIDICA_AUDIT');
--in('IDBSVSAPREMARCA','IDBGERALMARCA','SCLASSEEMBARCACAO', 'SGERALCLASSEEMBARCACAO','SDBSISTRUBANCO', 'SDBSCINH');
desc dba_fga_audit_trail;
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'DBCORPORATIVO',
object_name => 'TB_PESSOA_FISICA',
policy_name => 'TB_PESSOA_FISICA_AUDIT' );
END;
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'DBCORPORATIVO',
object_name => 'TB_PESSOA_FISICA',
policy_name => 'TB_PESSOA_FISICA_AUDIT',
audit_condition => NULL,
audit_column => 'NU_CPF',
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'UPDATE',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED
--,
--audit_column_opts => DBMS_FGA.ALL_COLUMNS
);
end;
--
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'DBCORPORATIVO',
object_name => 'TB_PESSOA',
policy_name => 'TB_PESSOA_AUDIT' );
END;
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'DBCORPORATIVO',
object_name => 'TB_PESSOA',
policy_name => 'TB_PESSOA_AUDIT',
audit_condition => NULL,
audit_column => 'CO_BANCO,CO_AGENCIA,NU_CONTA_CORRENTE',
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'UPDATE',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED
--,
--audit_column_opts => DBMS_FGA.ALL_COLUMNS
);
end;
--A MESMA PARA DBSAT - TB_PORTE_SAT
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'DBSAT',
object_name => 'TB_PORTE',
policy_name => 'TB_PORTE_SAT' );
END;
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'DBCORPORATIVO',
object_name => 'TB_PORTE',
policy_name => 'TB_PORTE_CORPORATIVO',
audit_condition => NULL,
audit_column => NULL,
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'SELECT, INSERT, UPDATE, DELETE',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED,
audit_column_opts => DBMS_FGA.ALL_COLUMNS);
end;
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'DBCORPORATIVO',
object_name => 'RL_APRESENTACAO_MARCA',
policy_name => 'DBSVSAPREMARCA' );
END;
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'DBCORPORATIVO',
object_name => 'TB_UNIDADE_MEDIDA_PRODUTO',
policy_name => 'SUNIDPRODUTODBCORPORATIVO' );
END;
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'DBCORPORATIVO',
object_name => 'TB_UNIDADE_MEDIDA_PRODUTO',
policy_name => 'SUNIDPRODUTODBCORPORATIVO',
audit_condition => NULL,
audit_column => NULL,
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'SELECT',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED,
audit_column_opts => DBMS_FGA.ALL_COLUMNS);
end;
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'DBGERAL',
object_name => 'TB_GRUPO_PAIS',
policy_name => 'SGRUPOPAISDBGERAL' );
END;
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'DBGERAL',
object_name => 'TB_GRUPO_PAIS',
policy_name => 'SGRUPOPAISDBGERAL',
audit_condition => NULL,
audit_column => NULL,
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'SELECT',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED,
audit_column_opts => DBMS_FGA.ALL_COLUMNS);
end;
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'DBSVS',
object_name => 'RL_EMPRESA_SIVS',
policy_name => 'SRLDBSVS' );
END;
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'DBSVS',
object_name => 'RL_EMPRESA_SIVS',
policy_name => 'SRLDBSVS',
audit_condition => NULL,
audit_column => NULL,
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'SELECT',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED,
audit_column_opts => DBMS_FGA.ALL_COLUMNS);
end;
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'DBSVS',
object_name => 'TB_PROCESSO',
policy_name => 'SDBSVS' );
END;
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'DBSVS',
object_name => 'TB_PROCESSO',
policy_name => 'SDBSVS',
audit_condition => NULL,
audit_column => NULL,
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'SELECT',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED,
audit_column_opts => DBMS_FGA.ALL_COLUMNS);
end;
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'DBSCINH',
object_name => 'TB_UNIDADE_MEDIDA',
policy_name => 'SDBSCINH' );
END;
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'DBSCINH',
object_name => 'TB_UNIDADE_MEDIDA',
policy_name => 'SDBSCINH',
audit_condition => NULL,
audit_column => NULL,
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'SELECT',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED,
audit_column_opts => DBMS_FGA.ALL_COLUMNS);
end;
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'DBSISTRU',
object_name => 'TB_BANCO',
policy_name => 'SDBSISTRUBANCO' );
END;
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'DBSISTRU',
object_name => 'TB_BANCO',
policy_name => 'SDBSISTRUBANCO',
audit_condition => NULL,
audit_column => NULL,
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'SELECT',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED,
audit_column_opts => DBMS_FGA.ALL_COLUMNS);
end;
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'DBSVS',
object_name => 'RL_APRESENTACAO_MARCA',
policy_name => 'idbsvsapremarca' );
END;
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'DBSVS',
object_name => 'RL_APRESENTACAO_MARCA',
policy_name => 'idbsvsapremarca',
audit_condition => NULL,
audit_column => NULL,
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'INSERT',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED,
audit_column_opts => DBMS_FGA.ALL_COLUMNS);
end;
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'DBGERAL',
object_name => 'TB_MARCA',
policy_name => 'idbgeralmarca' );
END;
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'DBGERAL',
object_name => 'TB_MARCA',
policy_name => 'idbgeralmarca',
audit_condition => NULL,
audit_column => NULL,
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'INSERT',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED,
audit_column_opts => DBMS_FGA.ALL_COLUMNS);
end;
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'dbcorporativo',
object_name => 'tb_classe_embarcacao',
policy_name => 'sclasseembarcacao' );
END;
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'dbcorporativo',
object_name => 'tb_classe_embarcacao',
policy_name => 'sclasseembarcacao',
audit_condition => NULL,
audit_column => NULL,
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'SELECT',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED,
audit_column_opts => DBMS_FGA.ALL_COLUMNS);
end;
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'dbgeral',
object_name => 'tb_classe_embarcacao',
policy_name => 'sgeralclasseembarcacao' );
END;
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'dbgeral',
object_name => 'tb_classe_embarcacao',
policy_name => 'sgeralclasseembarcacao',
audit_condition => NULL,
audit_column => NULL,
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'SELECT',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED,
audit_column_opts => DBMS_FGA.ALL_COLUMNS);
end;
*/
/*
http://download.oracle.com/docs/cd/B19306_01/network.102/b14266/cfgaudit.htm#i1011851
*/
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'DBHEMOCAD',
object_name => 'TB_HEMOTERAPICA',
policy_name => 'TB_HEMOTERAPICA_AUDIT' );
END;
------------- AUDITORIA NO VS01 29/01/2010 retirada em 18/10/2010---------------
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'DBHEMOCAD',
object_name => 'TB_HEMOTERAPICA',
policy_name => 'TB_HEMOTERAPICA_AUDIT',
audit_condition => NULL,
audit_column => NULL,
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'SELECT',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED,
--,
audit_column_opts => DBMS_FGA.ALL_COLUMNS
);
end;
---------------------------------------
--delete from sys.fga_log$ where POLICYNAME in ('DBCORP_USU_REP','DBGERAL_ENDERECOEMPRESA');
--COMMIT
truncate table sys.fga_log$;
select distinct * from dba_fga_audit_trail
where policy_name = 'TB_HEMOTERAPICA_AUDIT';
order by policy_name;
---------------------------------------
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'DBRH',
object_name => 'TB_SITUACAO',
policy_name => 'TB_SITUACAO_AUDIT' );
END;
------------- AUDITORIA NO VS06 11/11/2009 já retirada---------------
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'DBRH',
object_name => 'TB_SITUACAO',
policy_name => 'TB_SITUACAO_AUDIT',
audit_condition => NULL,
audit_column => 'CO_SITUACAO',
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'SELECT',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED
--,
--audit_column_opts => DBMS_FGA.ALL_COLUMNS
);
end;
/*
desc sys.fga_log$
delete from sys.fga_log$ where POLICYNAME ='TB_PESSOA_AUDIT' and trunc(NTIMESTAMP#) = to_date('16-abr-2008');
desc dba_fga_audit_trail
select distinct policy_name, OBJECT_NAME, OBJECT_SCHEMA from dba_fga_audit_trail ;
select distinct TIMESTAMP, db_user, os_user, userhost, object_schema, object_name, sql_text
from dba_fga_audit_trail
where trunc(TIMESTAMP) <= to_date('16-abr-2008') and policy_name in ('TB_PESSOA_AUDIT')
order by TIMESTAMP, db_user;
select distinct * from dba_fga_audit_trail
where policy_name in ('TB_EMPRESA_AUDIT', 'TB_PESSOA_JURIDICA_AUDIT');
--in('IDBSVSAPREMARCA','IDBGERALMARCA','SCLASSEEMBARCACAO', 'SGERALCLASSEEMBARCACAO','SDBSISTRUBANCO', 'SDBSCINH');
desc dba_fga_audit_trail;
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'DBCORPORATIVO',
object_name => 'TB_PESSOA_FISICA',
policy_name => 'TB_PESSOA_FISICA_AUDIT' );
END;
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'DBCORPORATIVO',
object_name => 'TB_PESSOA_FISICA',
policy_name => 'TB_PESSOA_FISICA_AUDIT',
audit_condition => NULL,
audit_column => 'NU_CPF',
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'UPDATE',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED
--,
--audit_column_opts => DBMS_FGA.ALL_COLUMNS
);
end;
--
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'DBCORPORATIVO',
object_name => 'TB_PESSOA',
policy_name => 'TB_PESSOA_AUDIT' );
END;
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'DBCORPORATIVO',
object_name => 'TB_PESSOA',
policy_name => 'TB_PESSOA_AUDIT',
audit_condition => NULL,
audit_column => 'CO_BANCO,CO_AGENCIA,NU_CONTA_CORRENTE',
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'UPDATE',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED
--,
--audit_column_opts => DBMS_FGA.ALL_COLUMNS
);
end;
--A MESMA PARA DBSAT - TB_PORTE_SAT
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'DBSAT',
object_name => 'TB_PORTE',
policy_name => 'TB_PORTE_SAT' );
END;
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'DBCORPORATIVO',
object_name => 'TB_PORTE',
policy_name => 'TB_PORTE_CORPORATIVO',
audit_condition => NULL,
audit_column => NULL,
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'SELECT, INSERT, UPDATE, DELETE',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED,
audit_column_opts => DBMS_FGA.ALL_COLUMNS);
end;
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'DBCORPORATIVO',
object_name => 'RL_APRESENTACAO_MARCA',
policy_name => 'DBSVSAPREMARCA' );
END;
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'DBCORPORATIVO',
object_name => 'TB_UNIDADE_MEDIDA_PRODUTO',
policy_name => 'SUNIDPRODUTODBCORPORATIVO' );
END;
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'DBCORPORATIVO',
object_name => 'TB_UNIDADE_MEDIDA_PRODUTO',
policy_name => 'SUNIDPRODUTODBCORPORATIVO',
audit_condition => NULL,
audit_column => NULL,
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'SELECT',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED,
audit_column_opts => DBMS_FGA.ALL_COLUMNS);
end;
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'DBGERAL',
object_name => 'TB_GRUPO_PAIS',
policy_name => 'SGRUPOPAISDBGERAL' );
END;
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'DBGERAL',
object_name => 'TB_GRUPO_PAIS',
policy_name => 'SGRUPOPAISDBGERAL',
audit_condition => NULL,
audit_column => NULL,
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'SELECT',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED,
audit_column_opts => DBMS_FGA.ALL_COLUMNS);
end;
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'DBSVS',
object_name => 'RL_EMPRESA_SIVS',
policy_name => 'SRLDBSVS' );
END;
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'DBSVS',
object_name => 'RL_EMPRESA_SIVS',
policy_name => 'SRLDBSVS',
audit_condition => NULL,
audit_column => NULL,
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'SELECT',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED,
audit_column_opts => DBMS_FGA.ALL_COLUMNS);
end;
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'DBSVS',
object_name => 'TB_PROCESSO',
policy_name => 'SDBSVS' );
END;
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'DBSVS',
object_name => 'TB_PROCESSO',
policy_name => 'SDBSVS',
audit_condition => NULL,
audit_column => NULL,
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'SELECT',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED,
audit_column_opts => DBMS_FGA.ALL_COLUMNS);
end;
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'DBSCINH',
object_name => 'TB_UNIDADE_MEDIDA',
policy_name => 'SDBSCINH' );
END;
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'DBSCINH',
object_name => 'TB_UNIDADE_MEDIDA',
policy_name => 'SDBSCINH',
audit_condition => NULL,
audit_column => NULL,
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'SELECT',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED,
audit_column_opts => DBMS_FGA.ALL_COLUMNS);
end;
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'DBSISTRU',
object_name => 'TB_BANCO',
policy_name => 'SDBSISTRUBANCO' );
END;
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'DBSISTRU',
object_name => 'TB_BANCO',
policy_name => 'SDBSISTRUBANCO',
audit_condition => NULL,
audit_column => NULL,
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'SELECT',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED,
audit_column_opts => DBMS_FGA.ALL_COLUMNS);
end;
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'DBSVS',
object_name => 'RL_APRESENTACAO_MARCA',
policy_name => 'idbsvsapremarca' );
END;
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'DBSVS',
object_name => 'RL_APRESENTACAO_MARCA',
policy_name => 'idbsvsapremarca',
audit_condition => NULL,
audit_column => NULL,
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'INSERT',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED,
audit_column_opts => DBMS_FGA.ALL_COLUMNS);
end;
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'DBGERAL',
object_name => 'TB_MARCA',
policy_name => 'idbgeralmarca' );
END;
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'DBGERAL',
object_name => 'TB_MARCA',
policy_name => 'idbgeralmarca',
audit_condition => NULL,
audit_column => NULL,
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'INSERT',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED,
audit_column_opts => DBMS_FGA.ALL_COLUMNS);
end;
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'dbcorporativo',
object_name => 'tb_classe_embarcacao',
policy_name => 'sclasseembarcacao' );
END;
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'dbcorporativo',
object_name => 'tb_classe_embarcacao',
policy_name => 'sclasseembarcacao',
audit_condition => NULL,
audit_column => NULL,
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'SELECT',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED,
audit_column_opts => DBMS_FGA.ALL_COLUMNS);
end;
BEGIN
sys.DBMS_FGA.DROP_POLICY(
object_schema => 'dbgeral',
object_name => 'tb_classe_embarcacao',
policy_name => 'sgeralclasseembarcacao' );
END;
begin
sys.DBMS_FGA.ADD_POLICY(object_schema => 'dbgeral',
object_name => 'tb_classe_embarcacao',
policy_name => 'sgeralclasseembarcacao',
audit_condition => NULL,
audit_column => NULL,
handler_schema => NULL,
handler_module => NULL,
enable => TRUE,
statement_types=> 'SELECT',
audit_trail => DBMS_FGA.DB+DBMS_FGA.EXTENDED,
audit_column_opts => DBMS_FGA.ALL_COLUMNS);
end;
*/
-- Relatório de objetos auditados
select distinct os_username,username,terminal,trunc(timestamp),action_name,obj_name from dba_audit_trail order by 4 desc
--
SELECT * FROM DBA_AUDIT_TRAIL A ORDER BY A.timestamp desc
SELECT * FROM DBA_AUDIT_OBJECT
SELECT * FROM DBA_COMMON_AUDIT_TRAIL
SELECT * FROM DBA_AUDIT_EXISTS
SELECT * FROM DBA_AUDIT_POLICIES
SELECT * FROM DBA_AUDIT_POLICY_COLUMNS
SELECT * FROM DBA_AUDIT_SESSION
SELECT * FROM DBA_AUDIT_STATEMENT
-- Políticas de autitoria em vigor
SELECT * FROM DBA_OBJ_AUDIT_OPTS
SELECT * FROM DBA_PRIV_AUDIT_OPTS
SELECT * FROM DBA_STMT_AUDIT_OPTS
-- Comando para audidar tabelas e objetos
AUDIT [SELECT | UPDATE | INSERT | ALL] on CORPORATIVO.TB_GRUPO_TIPO_DOCUMENTO BY ACCESS WHENEVER SUCCESSFUL
AUDIT ALTER USER
AUDIT SELECT TABLE, UPDATE TABLE;
AUDIT SELECT TABLE, UPDATE TABLE BY hr, oe;
-- Comando para remover a auditoria
NOAUDIT [SELECT | UPDATE | INSERT | ALL] on DBCORPORATIVO.TB_PAIS [WHENEVER SUCCESSFUL]NOAUDIT session;
NOAUDIT session BY preston, sebastian;
NOAUDIT select ANY TABLE;
NOAUDIT SELECT TABLE, INSERT TABLE, DELETE TABLE, EXECUTE PROCEDURE;
NOAUDIT select, update, delete, insert on OWNER.TABLE;
NOAUDIT ALL STATEMENTS;
--Purging a Subset of Records from the Database Audit Trail
SELECT * FROM SYS.AUD$;
--1.
DELETE FROM SYS.AUD$;
--1.1
ALTER TABLE SYS.AUD$ SHRINK SPACE;
-- or
--2.
TRUNCATE TABLE SYS.AUD$;
--documentation:
--http://download.oracle.com/docs/cd/E11882_01/server.112/e17118/statements_9017.htm#i2088908
--http://download.oracle.com/docs/cd/E11882_01/network.112/e16543/auditing.htm#DBSEG006
--http://download.oracle.com/docs/cd/E11882_01/server.112/e10575/tdpsg_auditing.htm#CEGIDHAG
--VIEWS DE INFORMAÇÕES BÁSICAS DO ASM
--Contains one row for every alias present in every disk group mounted by the Oracle ASM instance.
select * from V$ASM_ALIAS
--In an Oracle ASM instance, identifies databases using disk groups managed by the Oracle ASM instance.
--In a DB instance, contains information about the Oracle ASM instance if the database has any open Oracle ASM files.
select * from V$ASM_CLIENT
--Displays one row for each attribute defined. In addition to attributes specified by CREATE DISKGROUP and ALTER DISKGROUP statements,
--the view may show other attributes that are created automatically. Attributes are only displayed for disk groups where COMPATIBLE.ASM is set to 11.1 or higher.
select * from V$ASM_ATTRIBUTE
--VIEWS DE MONITORAMENTO DOS DISCOS DO ASM
--Contains one row for every disk discovered by the Oracle ASM instance, including disks that are not part of any disk group.
select * from V$ASM_DISK
--Displays information about disk I/O statistics for each Oracle ASM client.
select * from V$ASM_DISK_IOSTAT
--Contains the same columns as V$ASM_DISK, but to reduce overhead, does not perform a discovery when it is queried.
--It only returns information about any disks that are part of mounted disk groups in the storage system. To see all disks, use V$ASM_DISK instead.
select * from V$ASM_DISK_STAT
--Describes a disk group (number, name, size related info, state, and redundancy type).
select * from V$ASM_DISKGROUP
--Contains one row for every Oracle ASM file in every disk group mounted by the Oracle ASM instance.
select * from V$ASM_FILE
--The following query in the ASM instance gives the amount of bytes_read and bytes_written per database client and diskgroup, failgroup, path:
select i.dbname, g.name diskgroup, i.failgroup, d.path, d.total_mb, i.bytes_read, i.bytes_written from v$asm_disk_iostat i, v$asm_diskgroup g, v$asm_disk d
where i.group_number=g.group_number and i.disk_number=d.disk_number and i.failgroup=d.failgroup order by i.dbname, g.name, i.failgroup, d.path;
-- VIEWS DIVERSAS
--In an Oracle ASM instance, contains one row for every active Oracle ASM long running operation executing in the Oracle ASM instance.
select * from V$ASM_OPERATION
--Contains one row for every template present in every disk group mounted by the Oracle ASM instance.
select * from V$ASM_TEMPLATE
--Contains the effective operating system user names of connected database instances and names of file owners.
select * from V$ASM_USER
--Contains the creator for each Oracle ASM File Access Control group.
select * from V$ASM_USERGROUP
--Contains the members for each Oracle ASM File Access Control group.
select * from V$ASM_USERGROUP_MEMBER
-- VIEWS DE MONITORAMENTO DO ACFS
select * from V$ASM_ACFSVOLUMES
select * from V$ASM_FILESYSTEM
select * from V$ASM_VOLUME
select * from V$ASM_VOLUME_STAT
select * from V$ASM_ACFSSNAPSHOTS
--1. Find the name of the datafile that you're going to migrate:
SQL> SELECT FILE_NAME, a.status FROM DBA_DATA_FILES a WHERE tablespace_name = 'TI_DBPETICAO';
--2. Take the tablespace offline:
SQL> alter tablespace TI_DBPETICAO offline;
--3. Copy the file using RMAN:
RMAN> COPY datafile '+DATA_ASM_DG/vs01/datafile/ti_dbpeticao.650.830703213' to '+DATA_ASM_DG/vs01/datafile/tidbpeticao01';
--4. Change datafile's name to the name displayed as output of the command above:
SQL> ALTER DATABASE RENAME FILE '+DATA_ASM_DG/vs01/datafile/ti_dbpeticao.650.830703213' to '+DATA_ASM_DG/vs01/datafile/tidbpeticao01';
--5. Bring back the tablespace online:
SQL> alter tablespace TI_DBPETICAO online; -- 364
-- este bloco anomimo dropa e recria os índices para corrgir o erro da oracle
-- ORA-08106, que faz referência a essa ação para sanar o problema do índice
-- select * FROM TOOLS.TB_REBUILD_ANALYZE_LOG WHERE substr(ds_comando_ddl, 1, 1) <> '*'
declare
CURSOR C_ATUALIZA IS
SELECT DS_OWNER, DS_OBJECT_NAME, CL_DDL,
'DROP INDEX '||DS_OWNER||'.'||DS_OBJECT_NAME COMANDO_DDL_DROP,
DBMS_METADATA.GET_DDL('INDEX', DS_OBJECT_NAME, DS_OWNER) COMANDO_DDL_CREATE
FROM TOOLS.TB_REBUILD_ANALYZE_LOG
WHERE substr(ds_comando_ddl, 1, 1) <> '*'
AND cl_log like '%ORA-08106%';
V_ATUALIZA C_ATUALIZA%ROWTYPE;
begin
FOR V_ATUALIZA IN C_ATUALIZA LOOP
EXECUTE IMMEDIATE V_ATUALIZA.COMANDO_DDL_DROP;
EXECUTE IMMEDIATE TO_CHAR(V_ATUALIZA.CL_DDL);
EXECUTE IMMEDIATE 'ANALYZE INDEX '||V_ATUALIZA.DS_OWNER||'.'||V_ATUALIZA.DS_OBJECT_NAME
||' ESTIMATE STATISTICS SAMPLE 45 PERCENT ';
END LOOP;
end;
SET PAGESIZE 0
SPOOL SAIDA.TXT
SELECT 'ANALYZE TABLE '||OWNER||'.'||TABLE_NAME||' DELETE STATISTICS;'
FROM DBA_TABLES
WHERE BLOCKS IS NOT NULL
AND OWNER='USER'
ORDER BY TABLE_NAME
/
SPOOL OF
select distinct
'ALTER INDEX '||t1.OWNER||'.'||t1.INDEX_NAME||' REBUILD ' COMAND0_REBUILD_DDL,
t1.OWNER, t1.INDEX_NAME, t1.index_type, t3.last_ddl_time
from sys.dba_indexes t1, dba_objects t3
where t1.owner like 'DB%'
and t1.index_type in ('FUNCTION-BASED NORMAL','NORMAL')
and t1.index_name = t3.object_name
and t1.owner = t3.owner
and t3.last_ddl_time < to_date('01/02/2012', 'DD/MM/YYYY')
order by trunc(t3.last_ddl_time) desc
exec dbms_stats.gather_schema_stats(ownname => 'COMMUNITYUSR',estimate_percent => dbms_stats.auto_sample_size, cascade => true);
exec dbms_stats.gather_schema_stats(ownname => 'CUSTOMIZATIONUSR',estimate_percent => dbms_stats.auto_sample_size, cascade => true);
exec dbms_stats.gather_schema_stats(ownname => 'FEEDBACK',estimate_percent => dbms_stats.auto_sample_size, cascade => true);
exec dbms_stats.gather_schema_stats(ownname => 'JCR',estimate_percent => dbms_stats.auto_sample_size, cascade => true);
exec dbms_stats.gather_schema_stats(ownname => 'LMDBUSR',estimate_percent => dbms_stats.auto_sample_size, cascade => true);
exec dbms_stats.gather_schema_stats(ownname => 'RELEASEUSR',estimate_percent => dbms_stats.auto_sample_size, cascade => true);
select 'ALTER INDEX '||t1.OWNER||'.'||t1.INDEX_NAME||' REBUILD ONLINE; ' COMAND0_REBUILD_DDL,
--'ALTER INDEX '||t1.OWNER||'.'||t1.INDEX_NAME||' REBUILD ONLINE TABLESPACE TI_DBSNGPC NOLOGGING; ' COMAND0_REBUILD_DDL,
--'ALTER INDEX '||t1.OWNER||'.'||t1.INDEX_NAME||' REBUILD ONLINE INITRANS 50 TABLESPACE TI_DBSVS NOLOGGING; ' COMAND0_REBUILD_DDL,
--'ALTER INDEX '||t1.OWNER||'.'||t1.INDEX_NAME||' REBUILD ONLINE NOLOGGING; ' COMAND0_REBUILD_DDL,
--'ALTER INDEX '||t1.OWNER||'.'||t1.INDEX_NAME||' LOGGING; ' COMAND0_REBUILD_DDL,
t1.OWNER, t1.table_name, t1.INDEX_NAME, t1.tablespace_name, t1.index_type, t1.last_analyzed
--(,SELECT a.last_ddl_time from dba_objects a where a.object_name = t1.index_name and a.owner = t1.owner) last_ddl_time
from dba_indexes t1
where t1.owner = 'DBSVS'
and t1.table_name in ('TB_SITUACAO_PRODUTO')
and t1.index_type <> 'LOB'
--and t1.tablespace_name <> 'TI_DBSVS'
--order by last_ddl_time
--Indices particionados
select * from dba_part_indexes b where b.owner = 'DBSVS' and b.table_name in ('TB_TRAMITACAO_DOCUMENTO')
select * from dba_part_tables c where c.owner = 'DBSVS' and c.table_name in ('TB_TRAMITACAO_DOCUMENTO')
SELECT 'ALTER INDEX DBSVS.IN_DOCUMENTO_COTIPODOCUMENTO REBUILD PARTITION '||d.partition_name||' ONLINE; '
FROM DBA_TAB_PARTITIONS D WHERE d.table_owner = 'DBSVS' and d.table_name in ('TB_DOCUMENTO')
REM =============================================================
REM
REM rebuild_indx.sql
REM
REM Copyright (c) Oracle Software, 1998 - 2000
REM
REM Author : Jurgen Schelfhout
REM
REM The sample program in this article is provided for educational
REM purposes only and is NOT supported by Oracle Support Services.
REM It has been tested internally, however, and works as documented.
REM We do not guarantee that it will work for you, so be sure to test
REM it in your environment before relying on it.
REM
REM This script will analyze all the indexes for a given schema
REM or for a subset of schema's. After this the dynamic view
REM index_stats is consulted to see if an index is a good
REM candidate for a rebuild or for a bitmap index.
REM
REM Database Version : 7.3.X and above.
REM
REM =============================================================
prompt
ACCEPT spoolfile CHAR prompt 'Output-file : ';
ACCEPT schema CHAR prompt 'Schema name (% allowed) : ';
prompt
prompt
prompt Rebuild the index when :
prompt - deleted entries represent 20% or more of the current entries
prompt - the index depth is more then 4 levels.
prompt Possible candidate for bitmap index :
prompt - when distinctiveness is more than 99%
prompt
spool &spoolfile
set serveroutput on
set verify off
declare
c_name INTEGER;
ignore INTEGER;
height index_stats.height%TYPE := 0;
lf_rows index_stats.lf_rows%TYPE := 0;
del_lf_rows index_stats.del_lf_rows%TYPE := 0;
distinct_keys index_stats.distinct_keys%TYPE := 0;
cursor c_indx is
select t.owner, t.table_name, t.index_name
from dba_indexes t
where t.owner like upper('&schema')
and t.num_rows > 0
and t.owner not in ('SYS','SYSTEM');
begin
dbms_output.enable (1000000);
dbms_output.put_line ('Owner Index Name % Deleted Entries Blevel Distinctiveness');
dbms_output.put_line ('--------------- --------------------------------------- ----------------- ------ ---------------');
c_name := DBMS_SQL.OPEN_CURSOR;
for r_indx in c_indx loop
DBMS_SQL.PARSE(c_name,'analyze index ' || r_indx.owner || '.' ||
r_indx.index_name || ' validate structure',DBMS_SQL.NATIVE);
ignore := DBMS_SQL.EXECUTE(c_name);
select HEIGHT, decode (LF_ROWS,0,1,LF_ROWS), DEL_LF_ROWS,
decode (DISTINCT_KEYS,0,1,DISTINCT_KEYS)
into height, lf_rows, del_lf_rows, distinct_keys
from index_stats;
--
-- Index is considered as candidate for rebuild when :
-- - when deleted entries represent 20% or more of the current entries
-- - when the index depth is more then 4 levels.(height starts counting from 1 so > 5)
-- Index is (possible) candidate for a bitmap index when :
-- - distinctiveness is more than 99%
--
if ( height > 5 ) OR ( (del_lf_rows/lf_rows) > 0.2 ) then
dbms_output.put_line (rpad(r_indx.owner,16,' ') || rpad(r_indx.index_name,40,' ') ||
lpad(round((del_lf_rows/lf_rows)*100,3),17,' ') ||
lpad(height-1,7,' ') || lpad(round((lf_rows-distinct_keys)*100/lf_rows,3),16,' '));
end if;
end loop;
DBMS_SQL.CLOSE_CURSOR(c_name);
end;
/
spool off
set verify on
-----------------------------------------------------------------------------------
--------------------- Scrip para Rebuild de índices -------------------------------
-----------------------------------------------------------------------------------
-- Cria script para o rebuild online dos indices "FUNCTION-BASED NORMAL, NORMAL" --
select distinct
'ALTER INDEX '||t1.OWNER||'.'||t1.INDEX_NAME||' REBUILD ONLINE; ' COMAND0_REBUILD_DDL,
--'ALTER INDEX '||t1.OWNER||'.'||t1.INDEX_NAME||' REBUILD ONLINE TABLESPACE CORP_INDICES NOLOGGING ' COMAND0_REBUILD_DDL,
t1.OWNER, t1.INDEX_NAME
from dba_indexes t1,
dba_tables t2
where t1.table_name = t2.table_name
--and t1.owner in ('RHORA8UNESCO', 'DSLICIT', 'SAO', 'SITE', 'UNESCO', 'CORPORATIVO', 'CEP', 'INTRANET', 'UNESCONET', 'SEGURANCA', 'INTEGRATOR', 'TARIFADOR')
--and t1.owner = 'CORP_INDICES'
and t1.index_type in ('FUNCTION-BASED NORMAL','NORMAL')
--and t1.owner = 'CORPORATIVO'
and t1.index_name <> 'AX_1214_410'
and t2.table_name in ('UN_SOL_PGTO','UN_LOG_CERTIFICACAO','UN_SOL_PGTO_DOC_ANEXOS')
--and trunc(t1.last_analyzed) < trunc(sysdate)
and t2.num_rows > 0
-- cria script para o rebuild dos indices "BITMAP", DOMAIN --
select distinct
'ALTER INDEX '||t1.OWNER||'.'||t1.INDEX_NAME||' REBUILD; ' COMAND0_REBUILD_DDL,
t1.OWNER, t1.INDEX_NAME
from dba_indexes t1,
dba_tables t2
where t1.table_name = t2.table_name
and t1.owner in ('RHORA8UNESCO', 'DSLICIT', 'SAO', 'SITE', 'UNESCO', 'CORPORATIVO', 'CEP','INTRANET', 'UNESCONET', 'SEGURANCA', 'INTEGRATOR', 'TARIFADOR')
and t1.index_type in ('BITMAP','DOMAIN')
and t2.num_rows > 0
-------------------------------------------------------------------------------------------
--------------------- Scrip para Analyze de índices e tabelas -----------------------------
-------------------------------------------------------------------------------------------
-- Cria script para o analyze dos indices "FUNCTION-BASED NORMAL, NORMAL, BITMAP,DOMAIN" --
select distinct 'ANALYZE INDEX '||t1.OWNER||'.'||t1.INDEX_NAME||' ESTIMATE STATISTICS SAMPLE 45 PERCENT; ' COMAND0_ANALYZE_DDL,
t1.OWNER, t1.INDEX_NAME, t1.last_analyzed
from dba_indexes t1, dba_tables t2
where t1.table_name = t2.table_name
and t1.owner in ('RHORA8UNESCO', 'DSLICIT', 'SAO', 'SITE', 'UNESCO', 'CORPORATIVO', 'CEP','INTRANET', 'UNESCONET', 'SEGURANCA', 'INTEGRATOR', 'TARIFADOR')
--where t1.owner = 'CORPORATIVO'
--and trunc(t1.last_analyzed) = trunc(sysdate)
--and t1.index_type in ('FUNCTION-BASED NORMAL','NORMAL','BITMAP','DOMAIN')
--and trunc(t1.last_analyzed) < trunc(sysdate)
and t1.table_name in ('UN_SOL_PGTO','UN_SOL_PGTO_DOC_ANEXOS','UN_LOG_CERTIFICACAO')
and t2.num_rows > 0
-- Cria script para o analyze das tabelas --
select 'ANALYZE TABLE '||OWNER||'.'||TABLE_NAME||' ESTIMATE STATISTICS SAMPLE 45 PERCENT; ' COMAND0_ANALYZE_DDL,
OWNER, TABLE_NAME, LAST_ANALYZED
from dba_tables
where owner in ('RHORA8UNESCO', 'DSLICIT', 'SAO', 'SITE', 'UNESCO', 'CORPORATIVO', 'CEP', 'INTRANET', 'UNESCONET', 'SEGURANCA', 'INTEGRATOR', 'TARIFADOR')
and table_name in ('UN_SOL_PGTO','UN_SOL_PGTO_DOC_ANEXOS','UN_LOG_CERTIFICACAO')
--and trunc(last_analyzed) < trunc(sysdate)
--and trunc(last_analyzed) is not null
--and num_rows > 0
su - oracle
export ORACLE_SID=cdb1
export ORACLE_HOME=/oracle/app/12.1.0/db1
export PATH=$ORACLE_HOME/bin:$PATH
sqlplus / as sysdba
shutdown immediate ou shutdown abort;
exit;
export ORACLE_SID=oradb1
export ORACLE_HOME=/oracle/app/11.2.0.4/db1
export PATH=$ORACLE_HOME/bin:$PATH
sqlplus / as sysdba
startup;
#/usr/bin/ksh
# Environment Settings
export ORACLE_BASE=/u01/app/oracle
export ORACLE_HOME=$ORACLE_BASE/product/12.1.0
export ORACLE_SID=dev12c
export BAK_DATE=`date ‘+%d%b%Y_%H_%M’`
export PATH=$ORACLE_HOME/bin:$PATH
# Run Backup
rman target / cmdfile=full_hot_backup.rmn
log=full_hot_backup_${ORACLE_SID}_${BAK_DATE}.log
# Check Error Code
Export ECODE=$?
if [ $ECODE -gt 0 ]; then
mailx –s “RMAN BACKUP FAILED!” dba@yourcompany.com
else echo “RMAN BACKUP SUCCESSFUL”
fi
-- =======================================================================
-- Finding stale sessions
-- =======================================================================
select sid, serial#, username, last_call_et
from v$session
where username is not null;
SID SERIAL# USERNAME LAST_CALL_ET
--- ------- -------- ------------
14 655 HR 0
98 875 CRM 1
32 455 CRM 3
45 165 HR 36
112 592 SYSTEM 160
119 981 CULPADO 36522
65 234 CULPADO 743160
ALTER SYSTEM KILL SESSION ‘65,234’;
System altered.
-- =======================================================================
-- Policing for login abuse and unauthorized logins
-- um usuario passou a senha para outro logar USERNAME / OSUSER
-- =======================================================================
select sid, serial#, username, osuser, program
from v$session
where username is not null;
SID SERIAL# USERNAME OSUSER PROGRAM
------- ---------- -------- ------- -----------------
112 3741 CULPADO CULPADO sqlplusw.exe
122 3763 CULPADO RKHAN sqlplusw.exe
115 9853 SYSMAN oracle OMS
122 35878 HR HRAPP sqlplus@classroom
124 4 DBSNMP oracle emagent@classroom
CREATE USER
IDENTIFIED BY “”
TEMPORARY TABLESPACE
DEFAULT TABLESPACE ;
SQL> SELECT USERNAME, USERHOST, TIMESTAMP, ACTION_NAME, RETURNCODE
2 FROM dba_audit_trail
3 WHERE username = ‘HR’
4 ORDER BY timestamp;
USERNAME USERHOST TIMESTAMP ACTION_NAME RETURNCODE
-------- ---------- --------- ------------ ----------
HR orasvr01 06-JUN-13 LOGON 0
HR orasvr01 08-JUN-13 LOGON 1017
HR orasvr01 09-JUN-13 LOGOFF 0
HR orasvr01 16-JUN-13 LOGON 0
HR orasvr01 17-JUN-13 LOGON 0
HR orasvr01 17-JUN-13 LOGOFF 0
HR orasvr01 18-JUN-13 LOGOFF 0
HR orasvr01 28-JUN-13 LOGON 0
HR orasvr01 28-JUN-13 LOGON 1017
HR orasvr01 28-JUN-13 LOGOFF 0
10 rows selected.
SQL> SELECT object_name, created
2 FROM dba_objects
3 WHERE created > sysdate - 100
4 AND object_type = ‘TABLE’
5 AND owner = ‘HR’;
OBJECT_NAME CREATED
--------------- ---------
REGIONS 09-MAY-13
LOCATIONS 09-MAY-13
JOB_HISTORY 09-MAY-13
JOBS 09-MAY-13
EMPLOYEES 09-MAY-13
DEPARTMENTS 09-MAY-13
COUNTRIES 09-MAY-13
7 rows selected.
-- =======================================================================
-- Using the V$SESSION and V$SESSION_WAIT_HISTORY Views
-- to Troubleshoot RMAN Problems.
-- =======================================================================
Select
sid, serial#, event, seconds_in_wait
From v$session
Where sid in (select sid from v$session Where program like '%rman%');
SID SERIAL# EVENT SECONDS_IN_WAIT
------- ------- ------------------------------ ---------------
121 269 RMAN backup & recovery I/O 2
129 415 SQL*Net message from client 63
130 270 SQL*Net message from client 8
Select
sid, event, wait_time
From v$session_wait_history
Where sid in (select sid from v$session Where program like '%rman%')
And wait_time>0;
SID EVENT WAIT_TIME
--- --------------------------- ----------
121 RMAN backup & recovery I/O 11
129 SQL*Net message from client 1
129 SQL*Net message from client 2
129 SQL*Net message from client 2
130 SQL*Net message from client 400
130 SQL*Net message from client 200
130 SQL*Net message from client 100
130 SQL*Net message from client 766
-- =======================================================================
-- verificar os schemas de usuários que foram criados no oracle, e
-- excluindo da consulta os usuários nativos do Oracle database.
-- =======================================================================
SELECT
username
FROM
dba_users
WHERE
username NOT IN
(
'QS_CB',
'PERFSTAT',
'QS_ADM',
'PM',
'SH',
'HR',
'OE',
'ODM_MTR',
'WKPROXY',
'ANONYMOUS',
'OWNER',
'SYS',
'SYSTEM',
'SCOTT',
'SYSMAN',
'XDB',
'DBSNMP',
'EXFSYS',
'OLAPSYS',
'MDSYS',
'WMSYS',
'WKSYS',
'DMSYS',
'ODM',
'EXFSYS',
'CTXSYS',
'LBACSYS',
'ORDPLUGINS',
'SQLTXPLAIN',
'OUTLN',
'TSMSYS',
'XS$NULL',
'TOAD',
'STREAM',
'SPATIAL_CSW_ADMIN',
'SPATIAL_WFS_ADMIN',
'SI_INFORMTN_SCHEMA',
'QS',
'QS_CBADM',
'QS_CS',
'QS_ES',
'QS_OS',
'QS_WS',
'PA_AWR_USER',
'OWBSYS_AUDIT',
'OWBSYS',
'ORDSYS',
'ORDDATA',
'ORACLE_OCM',
'MGMT_VIEW',
'MDDATA',
'FLOWS_FILES',
'FLASHBACK',
'AWRUSER',
'APPQOSSYS',
'APEX_PUBLIC_USER',
'APEX_030200',
'FLOWS_020100'
);
SELECT
name,
space_limit,
space_used,
space_reclaimable
FROM
v$recovery_file_dest;
-- ===========================>
SELECT
name,
floor(space_limit / 1024 / 1024) "Size MB",
ceil(space_used / 1024 / 1024) "Used MB"
FROM
v$recovery_file_dest
order by
name asc;
-- ===========================>
SELECT
name,
ceil( space_limit / 1024 / 1024) size_mb,
ceil( space_used / 1024 / 1024) used_mb,
decode( nvl( space_used, 0),0, 0, ceil ( ( space_used / space_limit) * 100) ) pct_used
FROM
v$recovery_file_dest
order by
name desc;
-- =====================================================================================================>
NAME SIZE_MB USED_MB PCT_USED
-------------------------------------------------------------- ---------- ------------- ------------
/flashback 2048000 18503 1
-- =======================================================================
-- Use the V$RECOVER_FILE, V$DATAFILE, and V$TABLESPACE views
-- which data files are missing and which tablespaces they are associated
-- =======================================================================
SELECT
b.name ts_name,
a.error,
c.name datafile
FROM
v$recover_file a,
v$tablespace b,
v$datafile c
WHERE
a.file#=c.file#
AND b.ts#=c.ts#
TS_NAME ERROR DATAFILE
--------- ------------------- ------------------------------------
USERS FILE NOT FOUND C:\ORACLE\ORADATA\ORCL\USERS01.DBF
ORA-01157: cannot identify/lock data file 4- see DBWR trace file
ORA-01110: data file 4: 'C:\ORACLE\ORADATA\ORCL\USERS01.DBF'
SELECT
a.file#,
a.change#,
b.first_change#,
b.next_change#,
b.sequence#
FROM
v$recover_file a,
v$log_history b
WHERE
a.change#<= b.next_change#;
FILE# CHANGE# FIRST_CHANGE# NEXT_CHANGE# SEQUENCE#
------- ------- ------------- ------------ ---------
4 1418889 1417349 1438925 20
/* --- 2. V$ARCHIVED_LOG ---*/
SELECT
a.file#,
a.change#,
b.first_change#,
b.next_change#,
b.sequence#
FROM
v$recover_file a,
v$archived_log b
WHERE
a.change#<= b.next_change#;
FILE# CHANGE# FIRST_CHANGE# NEXT_CHANGE# SEQUENCE#
------- ------- ------------- ------------ ---------
4 1418889 1417349 1438925 20
C:\ORACLE\ARCH\ORCL\ARC00020_0662757171.001
SELECT
filename,
status,
bytes
FROM v$block_change_tracking;
SELECT
file#,
avg(datafile_blocks),
avg(blocks_read),
avg(blocks_read/datafile_blocks) * 100 AS PCT_READ_FOR_BACKUP,
avg(blocks)
FROM
v$backup_datafile
WHERE
used_change_tracking = 'YES'
AND incremental_level > 0
GROUP BY file#;
lsb_release -a
cat /etc/oracle-release
ls -l /etc/*-release
uname -r
-- =======================================================================
-- Using The Spool Command
-- =======================================================================
RMAN> spool log to '/tmp/backup.log';
RMAN> LIST BACKUP;
RMAN> spool log off;
/* --- O comando append adicionará o novo conteúdo ao final do arquivo de log chamado backup.log ---*/
RMAN> spool log to '/tmp/rman/backup.log' append
-- =======================================================================
-- Este script fornece informações sobre a PGA.
-- =======================================================================
set feedback off
col name for a25
col value_bytes for a20
select NAME,
VALUE VALUE_BYTES
from v$parameter
where NAME in ('pga_aggregate_target',
'workarea_size_policy',
'sort_area_size',
'sort_area_retained_size'
)
order by 1
/
SELECT * FROM v$pgastat WHERE name = 'cache hit percentage'
/
SELECT ROUND(pga_target_for_estimate/1024/1024) AS target_mb,
estd_pga_cache_hit_percentage AS cache_hit_percent,
estd_overalloc_count
FROM v$pga_target_advice
ORDER BY target_mb
/
SELECT low_optimal_size/1024 AS low_kb,
(high_optimal_size+1)/1024 AS high_kb,
ROUND(100*optimal_executions/total_executions) AS optimal,
ROUND(100*onepass_executions/total_executions) AS onepass,
ROUND(100*multipasses_executions/total_executions) AS multipass
FROM v$sql_workarea_histogram
WHERE total_executions != 0
ORDER BY low_kb
/
-- Aumente o valor de PGA_AGGREGATE_TARGET ou SORT_AREA_SIZE se a relação for maior que 5%. --
SELECT d.value "Disk", m.value "Mem",
round (((d.value/m.value)*100),2) "Sort_Hit_Ratio"
FROM v$sysstat m, v$sysstat d
WHERE m.name = 'sorts (memory)'
AND d.name = 'sorts (disk)'
/
set feedback on
-- =======================================================================
-- This script substantiates how partition drop can be used instead of massive deletes
-- =======================================================================
set serveroutput on size 1000000
prompt Test case : partition drop vs delete : Compare redo size
set feedback off
drop table ilp_activity_np;
create table ilp_activity_np
(
activity_date date not null,
item number not null,
period number not null,
location number not null,
item_type number not null,
sales_units number (*,8),
sales_price number(*,8),
ap_units number (*,8),
ap_price number(*,8),
fc_units number(*,8),
fc_price number (*,8)
)
nologging
storage (initial 10M next 10M pctincrease 0)
;
drop table ilp_activity_part;
create table ilp_activity_part
(
activity_date date not null,
item number not null,
period number not null,
location number not null,
item_type number not null,
sales_units number (*,8),
sales_price number(*,8),
ap_units number (*,8),
ap_price number(*,8),
fc_units number(*,8),
fc_price number (*,8)
)
nologging
storage (initial 10M next 10M pctincrease 0)
partition by range (activity_date)
(
partition part_jan values less than ( to_date ( '02-01-2005 00:00:00','MM-DD-YYYY HH24:MI:SS')),
partition part_feb values less than ( to_date ( '03-01-2005 00:00:00','MM-DD-YYYY HH24:MI:SS')),
partition part_mar values less than ( to_date ( '04-01-2005 00:00:00','MM-DD-YYYY HH24:MI:SS')),
partition part_apr values less than ( to_date ( '05-01-2005 00:00:00','MM-DD-YYYY HH24:MI:SS')),
partition part_may values less than ( to_date ( '06-01-2005 00:00:00','MM-DD-YYYY HH24:MI:SS')),
partition part_jun values less than ( to_date ( '07-01-2005 00:00:00','MM-DD-YYYY HH24:MI:SS')),
partition part_jul values less than ( to_date ( '08-01-2005 00:00:00','MM-DD-YYYY HH24:MI:SS')),
partition part_aug values less than ( to_date ( '09-01-2005 00:00:00','MM-DD-YYYY HH24:MI:SS')),
partition part_sep values less than ( to_date ( '10-01-2005 00:00:00','MM-DD-YYYY HH24:MI:SS')),
partition part_oct values less than ( to_date ( '11-01-2005 00:00:00','MM-DD-YYYY HH24:MI:SS')),
partition part_nov values less than ( to_date ( '12-01-2005 00:00:00','MM-DD-YYYY HH24:MI:SS')),
partition part_max values less than (maxvalue)
)
;
set feedback on
declare
i number;
l_begin_redo_size number;
l_end_redo_size number;
l_generated_redo number;
l_begin_time number;
l_end_time number;
l_elapsed_time number;
begin
for i in 1 .. 12 loop -- 10 items
insert into ilp_activity_np
select
add_months('01-DEC-2004',i) activity_date,
i*1000000 item,
mod(rownum, 52) period, -- 52 weeks
rownum location, -- 8000 locations
mod(rownum, 5) item_type, -- 5 types
trunc(dbms_random.value (1,100),8) sales_units,
trunc(dbms_random.value (1,100),8) sales_price,
trunc(dbms_random.value (1,100),8) ap_units,
trunc(dbms_random.value (1,100),8) ap_price,
trunc(dbms_random.value (1,100),8) fc_units,
trunc(dbms_random.value (1,100),8) fc_price
from dba_objects where rownum <8001
;
insert into ilp_activity_part
select
add_months('01-DEC-2004',i) activity_date,
i*1000000 item,
mod(rownum, 52) period, -- 52 weeks
rownum location, -- 8000 locations
mod(rownum, 5) item_type, -- 5 types
trunc(dbms_random.value (1,100),8) sales_units,
trunc(dbms_random.value (1,100),8) sales_price,
trunc(dbms_random.value (1,100),8) ap_units,
trunc(dbms_random.value (1,100),8) ap_price,
trunc(dbms_random.value (1,100),8) fc_units,
trunc(dbms_random.value (1,100),8) fc_price
from dba_objects where rownum <8001
;
commit;
end loop;
select get_my_statistics('redo size') into l_begin_redo_size from dual;
l_begin_time := dbms_utility.get_time;
delete from ilp_activity_np
where activity_date < to_date ('01-FEB-2005','DD-MON-YYYY')
;
commit;
select get_my_statistics('redo size') into l_end_redo_size from dual;
l_end_time := dbms_utility.get_time;
dbms_output.put_line ('Total redo generated for delete ==>'||to_char( l_end_redo_size - l_begin_redo_size));
dbms_output.put_line ('Elapsed time in seconds ==>'||to_char(trunc(( l_end_time-l_begin_time)/100, 2 )));
select get_my_statistics('redo size') into l_begin_redo_size from dual;
l_begin_time := dbms_utility.get_time;
EXECUTE IMMEDIATE 'alter table ilp_activity_part drop partition part_jan';
commit;
select get_my_statistics('redo size') into l_end_redo_size from dual;
l_end_time := dbms_utility.get_time;
dbms_output.put_line ('Total redo generated for partition drop ==>'||to_char( l_end_redo_size - l_begin_redo_size));
dbms_output.put_line ('Elapsed time in seconds ==>'||to_char(trunc(( l_end_time-l_begin_time)/100, 2 )));
end;
/
-- =======================================================================
-- Lista execuções de processos paralelos.
-- =======================================================================
col username for a12
col "QC SID" for A6
col "SID" for A6
col "QC/Slave" for A8
col "Req. DOP" for 9999
col "Actual DOP" for 9999
col "Slaveset" for A8
col "Slave INST" for A9
col "QC INST" for A6
set pages 300 lines 300
col wait_event format a30
select
decode(px.qcinst_id,NULL,username,
' - '||lower(substr(pp.SERVER_NAME,
length(pp.SERVER_NAME)-4,4) ) )"Username",
decode(px.qcinst_id,NULL, 'QC', '(Slave)') "QC/Slave" ,
to_char( px.server_set) "SlaveSet",
to_char(s.sid) "SID",
to_char(px.inst_id) "Slave INST",
decode(sw.state,'WAITING', 'WAIT', 'NOT WAIT' ) as STATE,
case sw.state WHEN 'WAITING' THEN substr(sw.event,1,30) ELSE NULL end as wait_event ,
decode(px.qcinst_id, NULL ,to_char(s.sid) ,px.qcsid) "QC SID",
to_char(px.qcinst_id) "QC INST",
px.req_degree "Req. DOP",
px.degree "Actual DOP"
from gv$px_session px,
gv$session s ,
gv$px_process pp,
gv$session_wait sw
where px.sid=s.sid (+)
and px.serial#=s.serial#(+)
and px.inst_id = s.inst_id(+)
and px.sid = pp.sid (+)
and px.serial#=pp.serial#(+)
and sw.sid = s.sid
and sw.inst_id = s.inst_id
order by
decode(px.QCINST_ID, NULL, px.INST_ID, px.QCINST_ID),
px.QCSID,
decode(px.SERVER_GROUP, NULL, 0, px.SERVER_GROUP),
px.SERVER_SET,
px.INST_ID
/
set pages 300 lines 300
col wait_event format a30
select
sw.SID as RCVSID,
decode(pp.server_name,
NULL, 'A QC',
pp.server_name) as RCVR,
sw.inst_id as RCVRINST,
case sw.state WHEN 'WAITING' THEN substr(sw.event,1,30) ELSE NULL end as wait_event ,
decode(bitand(p1, 65535),
65535, 'QC',
'P'||to_char(bitand(p1, 65535),'fm000')) as SNDR,
bitand(p1, 16711680) - 65535 as SNDRINST,
decode(bitand(p1, 65535),
65535, ps.qcsid,
(select
sid
from
gv$px_process
where
server_name = 'P'||to_char(bitand(sw.p1, 65535),'fm000') and
inst_id = bitand(sw.p1, 16711680) - 65535)
) as SNDRSID,
decode(sw.state,'WAITING', 'WAIT', 'NOT WAIT' ) as STATE
from
gv$session_wait sw,
gv$px_process pp,
gv$px_session ps
where
sw.sid = pp.sid (+) and
sw.inst_id = pp.inst_id (+) and
sw.sid = ps.sid (+) and
sw.inst_id = ps.inst_id (+) and
p1text = 'sleeptime/senderid' and
bitand(p1, 268435456) = 268435456
order by
decode(ps.QCINST_ID, NULL, ps.INST_ID, ps.QCINST_ID),
ps.QCSID,
decode(ps.SERVER_GROUP, NULL, 0, ps.SERVER_GROUP),
ps.SERVER_SET,
ps.INST_ID
/
set pages 300 lines 300
col "Username" for a12
col "QC/Slave" for A8
col "Slaveset" for A8
col "Slave INST" for A9
col "QC SID" for A6
col "QC INST" for A6
col "operation_name" for A30
col "target" for A30
select
decode(px.qcinst_id,NULL,username,
' - '||lower(substr(pp.SERVER_NAME,
length(pp.SERVER_NAME)-4,4) ) )"Username",
decode(px.qcinst_id,NULL, 'QC', '(Slave)') "QC/Slave" ,
to_char( px.server_set) "SlaveSet",
to_char(px.inst_id) "Slave INST",
substr(opname,1,30) operation_name,
substr(target,1,30) target,
sofar,
totalwork,
units,
start_time,
decode(px.qcinst_id, NULL ,to_char(s.sid) ,px.qcsid) "QC SID",
to_char(px.qcinst_id) "QC INST"
from gv$px_session px,
gv$px_process pp,
gv$session_longops s
where px.sid=s.sid
and px.serial#=s.serial#
and px.inst_id = s.inst_id
and px.sid = pp.sid (+)
and px.serial#=pp.serial#(+)
order by
decode(px.QCINST_ID, NULL, px.INST_ID, px.QCINST_ID),
px.QCSID,
decode(px.SERVER_GROUP, NULL, 0, px.SERVER_GROUP),
px.SERVER_SET,
px.INST_ID
/
-- =======================================================================
-- Lista informações sobre a utilização de espaço de um indice
-- =======================================================================
select MODULE,
COUNT(*)
from gv$session
group by MODULE
order by 2
/
select INST_ID,
SID,
STATUS,
MODULE
from gv$session
where MODULE like 'cnPayrunsMain.jsp'
order by STATUS
/
SELECT a.inst_id,
a.sid,
a.serial#,
b.pid as PID_ORACLE,
b.spid as SPID_SO_SERVER,
a.process as PROCESS_CLIENT,
a.sql_address,
a.sql_hash_value,
a.username,
a.status,
to_char(a.logon_time,'yyyy/mm/dd hh24:mi:ss') dtr,
round((a.last_call_et/60),0) LAST_CALL_ET__MIN,
a.program,
a.prev_hash_value,
a.module,
a.machine,
a.osuser,
'alter system kill session '''||a.sid||','||a.serial#||''' immediate;' as Kill_session,
'ALTER SYSTEM KILL SESSION '''||a.sid||','||a.serial#||',@'||a.inst_id||'''immediate;' as Kill_session_RAC,
'kill -9 '||b.spid||'' as Kill_UNIX
FROM gv$session a, gv$process b
WHERE a.paddr = b.addr
AND a.username = 'APPS'
AND a.status = 'ACTIVE'
ORDER BY dtr ASC
/
select
a.sid, a.serial#,c.spid,a.inst_id,a.username, a.machine, a.osuser, a.status,b.address,b.sql_text
from gv$session a, gv$sql b, gv$process c
where
a.SQL_ADDRESS=b.ADDRESS(+) and
a.inst_id=b.inst_id(+) and
a.paddr=c.addr and
a.inst_id=c.inst_id and
c.spid=&spid
order by 1,2;
select * from table(dbms_xplan.display_cursor('&sql',0));
@cab;
--
set pagesize 600
set tab off
set linesize 140
set echo off
set long 4000
col TQID format A4
col "SLAVE SQL" format A95 WORD_WRAP
col address format A12
col sql_hash format A15
col exec format 9999
col sql_text format A100 WORD_WRAP
repfooter off;
set timing off veri off space 1 flush on pause off termout on numwidth 10;
alter session set "_complex_view_merging"=false;
select hash_value||decode(child_number, 0, '', '/'||child_number) sql_hash,
sql_text
from v$sql
where child_number= 0 and hash_value= &hashvalue;
select '| Operation | Name | Starts | E-Rows | A-Rows | Buffers | Reads | Writes | E-Time |' as "Plan Table" from dual
union all /* QWEKLOIPYRTJHH7 */
select '------------------------------------------------------------------------------------------------------------------------'
from dual
union all
select rpad('| '||substr(lpad(' ',1*(depth))||operation|| decode(options, null,'',' '||options), 1, 33), 34, ' ')||'|'||
rpad(substr(object_name||' ',1, 19), 20, ' ')||'|'||
lpad(decode(starts,null,' ',
decode(sign(starts-1000), -1, starts||' ',
decode(sign(starts-1000000), -1, round(starts/1000)||'K',
decode(sign(starts-1000000000), -1, round(starts/1000000)||'M',
round(starts/1000000000)||'G')))), 8, ' ') || '|' ||
lpad(decode(cardinality,null,' ',
decode(sign(cardinality-1000), -1, cardinality||' ',
decode(sign(cardinality-1000000), -1, round(cardinality/1000)||'K',
decode(sign(cardinality-1000000000), -1, round(cardinality/1000000)||'M',
round(cardinality/1000000000)||'G')))), 8, ' ') || '|' ||
lpad(decode(outrows,null,' ',
decode(sign(outrows-1000), -1, outrows||' ',
decode(sign(outrows-1000000), -1, round(outrows/1000)||'K',
decode(sign(outrows-1000000000), -1, round(outrows/1000000)||'M',
round(outrows/1000000000)||'G')))), 8, ' ') || '|' ||
lpad(decode(crgets,null,' ',
decode(sign(crgets-10000000), -1, crgets||' ',
decode(sign(crgets-1000000000), -1, round(crgets/1000000)||'M',
round(crgets/1000000000)||'G'))), 9, ' ') || '|' ||
lpad(decode(reads,null,' ',
decode(sign(reads-10000000), -1, reads||' ',
decode(sign(reads-1000000000), -1, round(reads/1000000)||'M',
round(reads/1000000000)||'G'))), 8, ' ') || '|' ||
lpad(decode(writes,null,' ',
decode(sign(writes-10000000), -1, writes||' ',
decode(sign(writes-1000000000), -1, round(writes/1000000)||'M',
round(writes/1000000000)||'G'))), 8, ' ') || '|' ||
lpad(decode(etime,null,' ',
decode(sign(etime-10000000), -1, etime||' ',
decode(sign(etime-1000000000), -1, round(etime/1000000)||'M',
round(etime/1000000000)||'G'))), 8, ' ') || '|' as "Explain plan"
from
(select /*+ no_merge */
p.HASH_VALUE, p.ID, p.DEPTH, p.POSITION, p.OPERATION,
p.OPTIONS, p.COST COST, p.CARDINALITY CARDINALITY,
p.BYTES BYTES, p.OBJECT_NODE, p.OBJECT_OWNER,
p.OBJECT_NAME, p.OTHER_TAG, p.PARTITION_START,
p.PARTITION_STOP, p.DISTRIBUTION, pa.starts,
pa.OUTPUT_ROWS outrows, pa.CR_BUFFER_GETS crgets,
pa.DISK_READS reads, pa.DISK_WRITES writes,
pa.ELAPSED_TIME etime
from v$sql_plan_statistics_all pa,
V$sql_plan p
where p.hash_value = &hashvalue
and p.CHILD_NUMBER= 0
and p.hash_value = pa.hash_value(+)
and pa.child_number(+) = 0 )
union all
select '------------------------------------------------------------------------------------------------------------------------' from dual;
REM
REM Print slave sql
REM
select /* QWEKLOIPYRTJHH7 */
decode(object_node,null,'', substr(object_node,length(object_node)-3,1) || ',' ||
substr(object_node,length(object_node)-1,2)) TQID,
other "SLAVE SQL"
from v$sql_plan vp
where other is not NULL
and hash_value = &hash_value
and CHILD_NUMBER= 0
order by vp.id;
--
@rod;
-- =======================================================================
-- Ajustes do ambiente SQl*Plus e informações da base de dados.
-- =======================================================================
set tab off
SET SQLPLUSCOMPATIBILITY 8.1.7
-- Format for administration purpose
col object_name for a15
col grantee for a20
col grantor for a20
col privilege for a25
col sql_text for a75
col file_name for a45
col column_name for A20
col object_name for A30
col spid for A7
col sid for 999999
col serial# for 9999999
col segment_name for a25
col degree for a5
col owner for a20
col table_owner for a20
col table_name for a20
col comments for a90
col partition_name for a4 heading Part
col subpartition_name for a5 heading Spart
col truncated for a5
col username FOR A10
col status for A3 trunc
col osuser for A10
col machine for A20 trunc
col terminal for A15
col program for A25 trunc
col module for A16
col member for A40
col waiting_session heading wait for 9999999
col holding_session heading holding for 9999999
col lock_type for a13
col mode_held for a10
col mode_requested for a15
col db_link for a25
col referenced_owner for a15
col referenced_name for a20
col referenced_link_name for a25
col host for a20
col directory_path for a40
col parameter for a30
col value for a30
col triggering_event for a40
col sid_serial for a15
col last_call_et for a15 heading 'LAST_CALL_ET|HH:MM:SS' justify r
col load for a6 justify right
col executes for 9999999
col sql_text for a100
col name for a15
col file_id for 9999
col mb for 99999
-- Used by Trusted Oracle
col rowlabel format a15
-- used for the show errors command
col line/col for a8
col error for a65 word_wrapped
-- used for the show sga command
col name_col_plus_show_sga for a24
-- defaults for show parameters
col name_col_plus_show_param for a36 heading name
col value_col_plus_show_param for a30 heading value
-- defaults for set autotrace explain report
col id_plus_exp for 990 heading i
col parent_id_plus_exp for 990 heading p
col plan_plus_exp for a60
col object_node_plus_exp for a8
col other_tag_plus_exp for a29
col other_plus_exp for a44
-- info
set heading off time on feedback off
column user new_value usuario
column name new_value instancia
column host_name new_value nome_host
column crlf new_value crlf
column sid_curr new_value sid_da_sessao
set termout off
set linesize 1000
-----------------------------------------------------------------------
select USER, HOST_NAME, NAME, chr(10) CRLF from V$INSTANCE, V$DATABASE;
select trim(SID) SID_CURR from V$MYSTAT where rownum = 1;
set termout on
select b.NAME || ' (' || a.VERSION || ') - ' ||
a.HOST_NAME || ' - Uptime: ' || to_char(a.STARTUP_TIME, 'dd/mm/yyyy hh24:mm:ss') || ' - ' ||
b.LOG_MODE || ' - Archiver: ' || a.ARCHIVER
from V$INSTANCE a, V$DATABASE b;
select 'DB Block Size ' || lpad( a.VALUE / 1024 || 'KB ', 17 ) ||
'Database Buffer Cache ' || lpad( round( ( decode( b.VALUE,
0, c.VALUE,
b.VALUE * a.VALUE ) ) / 1024 / 1024 ) || 'MB', 11 ) || chr(10) ||
'Shared Pool ' || lpad( round( d.VALUE / 1024 / 1024 ) || 'MB ', 19 ) ||
'Shared Pool Reserved ' || lpad( round( e.VALUE / 1024 / 1024 ) || 'MB', 12 ) || chr(10) ||
'Sort Area Size ' || lpad( round( f.VALUE / 1024 ) || 'KB ', 16 ) ||
'Sort Area Retained Size ' || lpad( round( g.VALUE / 1024 ) || 'KB', 9 ) || chr(10) ||
'SGA Max Size' || lpad( decode( h.VALUE, null, 'N/A',
round( h.VALUE / 1024 / 1024 ) || 'MB' ), 12 )
from V$PARAMETER a, V$PARAMETER b, ( select 'db_block_buffers' NAME, VALUE from V$PARAMETER
where NAME = 'db_cache_size' ) c, V$PARAMETER d, V$PARAMETER e, V$PARAMETER f,
V$PARAMETER g, ( select 'db_block_buffers' NAME, VALUE
from V$PARAMETER
where NAME = 'sga_max_size' ) h
where a.NAME = 'db_block_size'
and b.NAME = 'db_block_buffers'
and c.NAME (+) = b.NAME
and d.NAME = 'shared_pool_size'
and e.NAME = 'shared_pool_reserved_size'
and f.NAME = 'sort_area_size'
and g.NAME = 'sort_area_retained_size'
and h.NAME (+) = b.NAME;
set serveroutput on
declare
v_version varchar2(10);
v_flashback_on varchar2(3);
begin
select version into v_version from v$instance;
IF substr(v_version,1,2) = '10' THEN
execute immediate 'SELECT flashback_on FROM v$database' INTO v_flashback_on;
dbms_output.put_line('FLASHBACK DATABASE TURNED ON?: ' || v_flashback_on);
END IF;
end;
/
set serveroutput OFF
PROMPT
PROMPT
-- Sets do SQLPlus
clear breaks
clear columns
-- alter session set NLS_DATE_FORMAT = 'DD/MM/YYYY HH24:MI:SS';
-- alter session set NLS_NUMERIC_CHARACTERS = ',.';
set heading on
set long 10000000
set longchunksize 1000
set feedback on
set verify off
-- set buffer 1000
set pagesize 9000
set trimspool on
SET SQLPROMPT 'system on &&_CONNECT_IDENTIFIER> '
SET TERMOUT ON
-- outra forma de prompt
-- set sqlprompt "- &USUARIO. (SID:&SID_DA_SESSAO.) em &INSTANCIA. / &NOME_HOST.&CRLF.SQL> "
-- =======================================================================
-- To lists users running a parallel query and their associated slaves.
-- =======================================================================
col username for a12
col "QC SID" for A6
col SID for A6
col "QC/Slave" for A10
col "Requested DOP" for 9999
col "Actual DOP" for 9999
col "slave set" for A10
set pages 100
col event form a30
col p1text form a20
col p2text form a10
col p3text form a10
col p3 form 999999999999999999999
select
decode(px.qcinst_id,NULL,username,
' - '||lower(substr(s.program,length(s.program)-4,4) ) ) "Username",
decode(px.qcinst_id,NULL, 'QC', '(Slave)') "QC/Slave" ,
to_char( px.server_set) "Slave Set",
to_char(s.sid) "SID",
decode(px.qcinst_id, NULL ,to_char(s.sid) ,px.qcsid) "QC SID",
px.req_degree "Requested DOP",
px.degree "Actual DOP",
s.event,
sw.p3text,
sw.p3,
sw.p1text,
sw.p1,
sw.p2text,
sw.p2
from
v$px_session px,
v$session s,
v$session_wait sw
where
px.sid=s.sid (+)
and
px.serial#=s.serial#
and s.sid=sw.sid
order by 5 , 1 desc
/
-- =======================================================================
-- Mostra os maiores eventos de espera do banco no momento.
-- =======================================================================
col inst_id for 999
col event for a60
select event,
-- p1,
-- p2,
-- p3,
count(event) as qtd
from gv$session_wait
where WAIT_CLASS <> 'Idle'
group by event
-- p1,
-- p2,
-- p3
order by 2 desc
/
-- =======================================================================
col inst_id for 999
col event for a60
select event,
-- p1,
-- p2,
-- p3,
count(event) as qtd
from v$session_wait
where sid = &1
group by event
-- p1,
-- p2,
-- p3
order by 2 desc
/
-- =======================================================================
col event format a60;
select decode(event,'db file scattered read',event || ' - **** FULL TABLE SCAN ****',EVENT) Event, count(1) as Qtde
from gv$session_wait
group by event
order by 2 desc;
-- =======================================================================
select
SID,
event,
p1,
p2,
p3,
SECONDS_IN_WAIT
from v$session_wait
order by 6 desc
/
-- =======================================================================
-- WAITING SESSIONS:
-- The entries that are shown at the top are the sessions that have
-- waited the longest amount of time that are waiting for non-idle wait
-- events (event column). You can research and find out what the wait
-- event indicates (along with its parameters) by checking the Oracle
-- Server Reference Manual or look for any known issues or documentation
-- by searching Metalink for the event name in the search bar. Example
-- (include single quotes): [ 'buffer busy due to global cache' ].
-- Metalink and/or the Server Reference Manual should return some useful
-- information on each type of wait event. The inst_id column shows the
-- instance where the session resides and the SID is the unique identifier
-- for the session (gv$session). The p1, p2, and p3 columns will show
-- event specific information that may be important to debug the problem.
-- To find out what the p1, p2, and p3 indicates see the next section.
-- Items with wait_time of anything other than 0 indicate we do not know
-- how long these sessions have been waiting.
--
set numwidth 10
column state format a7 tru
column event format a25 tru
column last_sql format a40 tru
select sw.inst_id, sw.sid, sw.state, sw.event, sw.seconds_in_wait seconds,
sw.p1, sw.p2, sw.p3, sa.sql_text last_sql
from gv$session_wait sw, gv$session s, gv$sqlarea sa
where sw.event not in
('rdbms ipc message','smon timer','pmon timer',
'SQL*Net message from client','lock manager wait for remote message',
'ges remote message', 'gcs remote message', 'gcs for action', 'client message',
'pipe get', 'null event', 'PX Idle Wait', 'single-task message',
'PX Deq: Execution Msg', 'KXFQ: kxfqdeq - normal deqeue',
'listen endpoint status','slave wait','wakeup time manager')
and sw.seconds_in_wait > 0
and (sw.inst_id = s.inst_id and sw.sid = s.sid)
and (s.inst_id = sa.inst_id and s.sql_address = sa.address)
order by seconds desc;
-- =======================================================================
-- EVENT PARAMETER LOOKUP:
-- This section will give a description of the parameter names of the
-- events seen in the last section. p1test is the parameter value for
-- p1 in the WAITING SESSIONS section while p2text is the parameter
-- value for p3 and p3 text is the parameter value for p3. The
-- parameter values in the first section can be helpful for debugging
-- the wait event.
--
column event format a30 tru
column p1text format a25 tru
column p2text format a25 tru
column p3text format a25 tru
select distinct event, p1text, p2text, p3text
from gv$session_wait sw
where sw.event not in ('rdbms ipc message','smon timer','pmon timer',
'SQL*Net message from client','lock manager wait for remote message',
'ges remote message', 'gcs remote message', 'gcs for action', 'client message',
'pipe get', 'null event', 'PX Idle Wait', 'single-task message',
'PX Deq: Execution Msg', 'KXFQ: kxfqdeq - normal deqeue',
'listen endpoint status','slave wait','wakeup time manager')
and seconds_in_wait > 0
order by event;
-- =======================================================================
-- LOCAL ENQUEUES:
-- This section will show us if there are any local enqueues. The inst_id will
-- show us the instance that the session resides on while the sid will be a
-- unique identifier for. The addr column will show the lock address. The type
-- will show the lock type. The id1 and id2 columns will show specific parameters
-- for the lock type.
--
set numwidth 12
column event format a12 tru
select l.inst_id, l.sid, l.addr, l.type, l.id1, l.id2,
decode(l.block,0,'blocked',1,'blocking',2,'global') block,
sw.event, sw.seconds_in_wait sec
from gv$lock l, gv$session_wait sw
where (l.sid = sw.sid and l.inst_id = sw.inst_id)
and l.block in (0,1)
order by l.type, l.inst_id, l.sid;
-- =======================================================================
-- LATCH HOLDERS:
-- If there is latch contention or 'latch free' wait events in the WAITING
-- SESSIONS section we will need to find out which proceseses are holding
-- latches. The inst_id will show us the instance that the session resides
-- on while the sid will be a unique identifier for. The username column
-- will show the session's username. The os_user column will show the os
-- user that the user logged in as. The name column will show us the type
-- of latch being waited on. You can search Metalink for the latch name in
-- the search bar. Example (include single quotes):
-- [ 'library cache' latch ]. Metalink should return some useful information
-- on the type of latch.
--
set numwidth 5
select distinct lh.inst_id, s.sid, s.username, p.username os_user, lh.name
from gv$latchholder lh, gv$session s, gv$process p
where (lh.sid = s.sid and lh.inst_id = s.inst_id)
and (s.inst_id = p.inst_id and s.paddr = p.addr)
order by lh.inst_id, s.sid;
-- =======================================================================
-- LATCH STATS:
-- This view will show us latches with less than optimal hit ratios
-- The inst_id will show us the instance for the particular latch. The
-- latch_name column will show us the type of latch. You can search Metalink
-- for the latch name in the search bar. Example (include single quotes):
-- [ 'library cache' latch ]. Metalink should return some useful information
-- on the type of latch. The hit_ratio shows the percentage of time we
-- successfully acquired the latch.
--
column latch_name format a30 tru
select inst_id, name latch_name,
round((gets-misses)/decode(gets,0,1,gets),3) hit_ratio,
round(sleeps/decode(misses,0,1,misses),3) "SLEEPS/MISS"
from gv$latch
where round((gets-misses)/decode(gets,0,1,gets),3) < .99
and gets != 0
order by round((gets-misses)/decode(gets,0,1,gets),3);
-- =======================================================================
-- No Wait Latches:
--
select inst_id, name latch_name,
round((immediate_gets/(immediate_gets+immediate_misses)), 3) hit_ratio,
round(sleeps/decode(immediate_misses,0,1,immediate_misses),3) "SLEEPS/MISS"
from gv$latch
where round((immediate_gets/(immediate_gets+immediate_misses)), 3) < .99
and immediate_gets + immediate_misses > 0
order by round((immediate_gets/(immediate_gets+immediate_misses)), 3);
-- =======================================================================
-- GLOBAL CACHE CR PERFORMANCE
-- This shows the average latency of a consistent block request.
-- AVG CR BLOCK RECEIVE TIME should typically be about 15 milliseconds depending
-- on your system configuration and volume, is the average latency of a
-- consistent-read request round-trip from the requesting instance to the holding
-- instance and back to the requesting instance. If your CPU has limited idle time
-- and your system typically processes long-running queries, then the latency may
-- be higher. However, it is possible to have an average latency of less than one
-- millisecond with User-mode IPC. Latency can be influenced by a high value for
-- the DB_MULTI_BLOCK_READ_COUNT parameter. This is because a requesting process
-- can issue more than one request for a block depending on the setting of this
-- parameter. Correspondingly, the requesting process may wait longer. Also check
-- interconnect badwidth, OS tcp settings, and OS udp settings if
-- AVG CR BLOCK RECEIVE TIME is high.
--
set numwidth 20
column "AVG CR BLOCK RECEIVE TIME (ms)" format 9999999.9
select b1.inst_id, b2.value "GCS CR BLOCKS RECEIVED",
b1.value "GCS CR BLOCK RECEIVE TIME",
((b1.value / b2.value) * 10) "AVG CR BLOCK RECEIVE TIME (ms)"
from gv$sysstat b1, gv$sysstat b2
where b1.name = 'global cache cr block receive time' and
b2.name = 'global cache cr blocks received' and b1.inst_id = b2.inst_id
or b1.name = 'gc cr block receive time' and
b2.name = 'gc cr blocks received' and b1.inst_id = b2.inst_id ;
-- =======================================================================
-- GLOBAL CACHE LOCK PERFORMANCE
-- This shows the average global enqueue get time.
-- Typically AVG GLOBAL LOCK GET TIME should be 20-30 milliseconds. the elapsed
-- time for a get includes the allocation and initialization of a new global
-- enqueue. If the average global enqueue get (global cache get time) or average
-- global enqueue conversion times are excessive, then your system may be
-- experiencing timeouts. See the 'WAITING SESSIONS', 'GES LOCK BLOCKERS',
-- 'GES LOCK WAITERS', and 'TOP 10 WAIT EVENTS ON SYSTEM' sections if the
-- AVG GLOBAL LOCK GET TIME is high.
--
set numwidth 20
column "AVG GLOBAL LOCK GET TIME (ms)" format 9999999.9
select b1.inst_id, (b1.value + b2.value) "GLOBAL LOCK GETS",
b3.value "GLOBAL LOCK GET TIME",
(b3.value / (b1.value + b2.value) * 10) "AVG GLOBAL LOCK GET TIME (ms)"
from gv$sysstat b1, gv$sysstat b2, gv$sysstat b3
where b1.name = 'global lock sync gets' and
b2.name = 'global lock async gets' and b3.name = 'global lock get time'
and b1.inst_id = b2.inst_id and b2.inst_id = b3.inst_id
or b1.name = 'global enqueue gets sync' and
b2.name = 'global enqueue gets async' and b3.name = 'global enqueue get time'
and b1.inst_id = b2.inst_id and b2.inst_id = b3.inst_id;
-- =======================================================================
-- RESOURCE USAGE
-- This section will show how much of our resources we have used.
--
set numwidth 8
select inst_id, resource_name, current_utilization, max_utilization,
initial_allocation
from gv$resource_limit
where max_utilization > 0
order by inst_id, resource_name;
-- =======================================================================
-- DLM TRAFFIC INFORMATION
-- This section shows how many tickets are available in the DLM. If the
-- TCKT_WAIT columns says "YES" then we have run out of DLM tickets which could
-- cause a DLM hang. Make sure that you also have enough TCKT_AVAIL.
--
set numwidth 5
select * from gv$dlm_traffic_controller
order by TCKT_AVAIL;
-- =======================================================================
-- DLM MISC
--
set numwidth 10
select * from gv$dlm_misc;
-- =======================================================================
-- LOCK CONVERSION DETAIL:
-- This view shows the types of lock conversion being done on each instance.
--
select * from gv$lock_activity;
-- =======================================================================
-- TOP 10 WRITE PINGING/FUSION OBJECTS
-- This view shows the top 10 objects for write pings accross instances.
-- The inst_id column shows the node that the block was pinged on. The name
-- column shows the object name of the offending object. The file# shows the
-- offending file number (gc_files_to_locks). The STATUS column will show the
-- current status of the pinged block. The READ_PINGS will show us read converts
-- and the WRITE_PINGS will show us objects with write converts. Any rows that
-- show up are objects that are concurrently accessed across more than 1 instance.
--
set numwidth 8
column name format a20 tru
column kind format a10 tru
select inst_id, name, kind, file#, status, BLOCKS,
READ_PINGS, WRITE_PINGS
from (select p.inst_id, p.name, p.kind, p.file#, p.status,
count(p.block#) BLOCKS, sum(p.forced_reads) READ_PINGS,
sum(p.forced_writes) WRITE_PINGS
from gv$ping p, gv$datafile df
where p.file# = df.file# (+)
group by p.inst_id, p.name, p.kind, p.file#, p.status
order by sum(p.forced_writes) desc)
where rownum < 11
order by WRITE_PINGS desc;
-- =======================================================================
-- TOP 10 READ PINGING/FUSION OBJECTS
-- This view shows the top 10 objects for read pings. The inst_id column shows
-- the node that the block was pinged on. The name column shows the object name
-- of the offending object. The file# shows the offending file number
-- (gc_files_to_locks). The STATUS column will show the current status of the
-- pinged block. The READ_PINGS will show us read converts and the WRITE_PINGS
-- will show us objects with write converts. Any rows that show up are objects
-- that are concurrently accessed across more than 1 instance.
--
set numwidth 8
column name format a20 tru
column kind format a10 tru
select inst_id, name, kind, file#, status, BLOCKS,
READ_PINGS, WRITE_PINGS
from (select p.inst_id, p.name, p.kind, p.file#, p.status,
count(p.block#) BLOCKS, sum(p.forced_reads) READ_PINGS,
sum(p.forced_writes) WRITE_PINGS
from gv$ping p, gv$datafile df
where p.file# = df.file# (+)
group by p.inst_id, p.name, p.kind, p.file#, p.status
order by sum(p.forced_reads) desc)
where rownum < 11
order by READ_PINGS desc;
-- =======================================================================
-- TOP 10 FALSE PINGING OBJECTS
-- This view shows the top 10 objects for false pings. This can be avoided by
-- better gc_files_to_locks configuration. The inst_id column shows the node
-- that the block was pinged on. The name column shows the object name of the
-- offending object. The file# shows the offending file number
-- (gc_files_to_locks). The STATUS column will show the current status of the
-- pinged block. The READ_PINGS will show us read converts and the WRITE_PINGS
-- will show us objects with write converts. Any rows that show up are objects
-- that are concurrently accessed across more than 1 instance.
--
set numwidth 8
column name format a20 tru
column kind format a10 tru
select inst_id, name, kind, file#, status, BLOCKS,
READ_PINGS, WRITE_PINGS
from (select p.inst_id, p.name, p.kind, p.file#, p.status,
count(p.block#) BLOCKS, sum(p.forced_reads) READ_PINGS,
sum(p.forced_writes) WRITE_PINGS
from gv$false_ping p, gv$datafile df
where p.file# = df.file# (+)
group by p.inst_id, p.name, p.kind, p.file#, p.status
order by sum(p.forced_writes) desc)
where rownum < 11
order by WRITE_PINGS desc;
-- =======================================================================
-- INITIALIZATION PARAMETERS:
-- Non-default init parameters for each node.
--
set numwidth 5
column name format a30 tru
column value format a50 wra
column description format a60 tru
select inst_id, name, value, description
from gv$parameter
where isdefault = 'FALSE'
order by inst_id, name;
-- =======================================================================
-- TOP 10 WAIT EVENTS ON SYSTEM
-- This view will provide a summary of the top wait events in the db.
--
set numwidth 10
column event format a25 tru
select inst_id, event, time_waited, total_waits, total_timeouts
from (select inst_id, event, time_waited, total_waits, total_timeouts
from gv$system_event where event not in ('rdbms ipc message','smon timer',
'pmon timer', 'SQL*Net message from client','lock manager wait for remote message',
'ges remote message', 'gcs remote message', 'gcs for action', 'client message',
'pipe get', 'null event', 'PX Idle Wait', 'single-task message',
'PX Deq: Execution Msg', 'KXFQ: kxfqdeq - normal deqeue',
'listen endpoint status','slave wait','wakeup time manager')
order by time_waited desc)
where rownum < 11
order by time_waited desc;
-- =======================================================================
-- SESSION/PROCESS REFERENCE:
-- This section is very important for most of the above sections to find out
-- which user/os_user/process is identified to which session/process.
--
set numwidth 7
column event format a30 tru
column program format a25 tru
column username format a15 tru
select p.inst_id, s.sid, s.serial#, p.pid, p.spid, p.program, s.username,
p.username os_user, sw.event, sw.seconds_in_wait sec
from gv$process p, gv$session s, gv$session_wait sw
where (p.inst_id = s.inst_id and p.addr = s.paddr)
and (s.inst_id = sw.inst_id and s.sid = sw.sid)
order by p.inst_id, s.sid;
-- =======================================================================
-- SYSTEM STATISTICS:
-- All System Stats with values of > 0. These can be referenced in the
-- Server Reference Manual
--
set numwidth 5
column name format a60 tru
column value format 9999999999999999999999999
select inst_id, name, value
from gv$sysstat
where value > 0
order by inst_id, name;
-- =======================================================================
-- CURRENT SQL FOR WAITING SESSIONS:
-- Current SQL for any session in the WAITING SESSIONS list
--
set numwidth 5
column sql format a80 wra
select sw.inst_id, sw.sid, sw.seconds_in_wait sec, sa.sql_text sql
from gv$session_wait sw, gv$session s, gv$sqlarea sa
where sw.sid = s.sid (+)
and sw.inst_id = s.inst_id (+)
and s.sql_address = sa.address
and sw.event not in ('rdbms ipc message','smon timer','pmon timer',
'SQL*Net message from client','lock manager wait for remote message',
'ges remote message', 'gcs remote message', 'gcs for action', 'client message',
'pipe get', 'null event', 'PX Idle Wait', 'single-task message',
'PX Deq: Execution Msg', 'KXFQ: kxfqdeq - normal deqeue',
'listen endpoint status','slave wait','wakeup time manager')
and seconds_in_wait > 0
order by sw.seconds_in_wait desc;
-- ===========================================================================
-- Lista as sessões que estão aguardando por um determinado evento de espera.
-- ===========================================================================
col event for a40
SELECT a.inst_id,
a.sid,
a.serial#,
b.event,
b.seconds_in_wait,
a.sql_hash_value,
a.username,
a.status,
to_char(a.logon_time,'dd/mm/yyyy hh24:mi:ss') dtr,
round((a.last_call_et/60),0) LAST_CALL_ET__MIN,
a.program,
a.prev_hash_value,
a.module,
a.machine,
a.osuser,
'alter system kill session '''||a.sid||','||a.serial#||''' immediate;' as "Kill Session"
FROM gv$session a, gv$session_wait b
WHERE a.sid = b.sid
AND a.username IS NOT NULL
AND b.event = ('&1')
ORDER BY b.seconds_in_wait
/
set lines 200;
column owner format a15;
column segment_name format a30;
select
a.owner,
a.segment_name,
a.segment_type,
round(a.bytes/1024/1024,0) MBS,
round((a.bytes-(b.num_rows*b.avg_row_len) )/1024/1024,0) WASTED
from dba_segments a, dba_tables b
where a.owner=b.owner
and a.owner not like 'SYS%'
and a.segment_name = b.table_name
and a.segment_type='TABLE'
group by a.owner, a.segment_name, a.segment_type, round(a.bytes/1024/1024,0) ,round((a.bytes-(b.num_rows*b.avg_row_len) )/1024/1024,0)
having round(bytes/1024/1024,0) >100
order by round(bytes/1024/1024,0) desc ;
-- =======================================================================
-- Exibe o plano de execução da query na sessão atual.
-- =======================================================================
set pagesize 100
set hea off
select * from table(dbms_xplan.display());
set hea on
set pagesize 14
/* -- FLASHBACK TABLE tabela -- */
DELETE FROM hr.departments WHERE department_name = 'IT';
SELECT * FROM hr.departments WHERE department_name = 'IT';
no rows selected
FLASHBACK TABLE hr.employees, hr.departments TO TIMESTAMP systimestamp - interval '15' minute;
Flashback complete.
/* ---------------------------------------------------------------------------------------------------
Quando uma operação de flashback está em andamento, os gatilhos na tabela estão desativados.
Se você deseja que os gatilhos diparem durante o procedimento, adicionar no comando ENABLE TRIGGERS
--------------------------------------------------------------------------------------------------- */
FLASHBACK TABLE hr.employees TO TIMESTAMP TO_TIMESTAMP('02NOV12 22:00'. 'DDMONYY HH24:MI') ENABLE TRIGGERS;
Flashback complete.
/* -- FLASHBACK TABLE...TO BEFORE DROP -- */
drop table order_items;
SELECT order_id, line_item_id, product_id
FROM order_items
FROM order_items
*
ERROR at line 2:
ORA-00942: table or view does not exist
flashback table order_items to before drop;
Flashback complete.
SELECT order_id, line_item_id, product_id FROM order_items;
ORDER_ID LINE_ITEM_ID PRODUCT_ID
---------- ------------ ----------
2355 1 2289
2356 1 2264
2357 1 2211
2358 1 1781
drop table order_items;
/* --- RECUPERANDO E JA RENOMEANDO --- */
flashback TABLE order_items TO BEFORE DROP rename TO order_items_old_version;
select order_id, line_item_id, product_id from order_items_old_version;
ORDER_ID LINE_ITEM_ID PRODUCT_ID
---------- ------------ ----------
2355 1 2289
2356 1 2264
2357 1 2211
2358 1 1781
/* -- AS OF TIMESTAMP -- */
SELECT * FROM vms.dvbt606a
AS OF TIMESTAMP to_timestamp ('12-Sep-12 12:20', 'DD-Mon-RR HH24:MI');
INSERT INTO vms.dvbt606a
SELECT * FROM vms.dvbt606a
AS OF TIMESTAMP to_timestamp ('12-Sep-12 12:20', 'DD-Mon-RR HH24:MI')
WHERE TRANS_DATE BETWEEN TO_DATE('01-MAY-12','DD-MON-YY')
AND TO_DATE('31-MAY-12','DD-MON-YY');
SELECT
file#,
error
FROM
v$recover_file;
FILE# ERROR
---------- ---------------------------------------------
4 FILE NOT FOUND
11 FILE NOT FOUND
/* v$datafile COM v$recover_file */
SELECT
file#,
name
FROM
v$datafile
join v$recover_file using (file#);
FILE# NAME
---------- ----------------------------------------
4 /u05/oradata/ord/users01.dbf
11 /u08/oradata/ord/idx02.dbf
SELECT
file_type,
percent_space_used psu,
percent_space_reclaimable psr,
number_of_files nf
FROM
v$recovery_area_usage;
FILE_TYPE PSU PSR NF
----------------------- ---------- ---------- ----------
CONTROL FILE 0 0 0
REDO LOG 0 0 0
ARCHIVED LOG 0 0 1
BACKUP PIECE 16.57 0 4
IMAGE COPY 0 0 0
FLASHBACK LOG 3.42 0 7
FOREIGN ARCHIVED LOG 0 0 0
AUXILIARY DATAFILE COPY 0 0 0
SELECT LOG_MODE FROM V$DATABASE;
-- =======================================================================
-- Configurando para ARCHIVELOG
-- =======================================================================
STARTUP MOUNT
ALTER DATABASE ARCHIVELOG;
ALTER DATABASE OPEN;
/* --- Verifica se foi modificada para Archivelog ---*/
ARCHIVE LOG LIST
/* --- Esta impaciente e quer vê logo?! ---*/
ALTER SYSTEM ARCHIVE LOG CURRENT;
/* --- Navegue na Fast Recovery Area - FRA, e verá os seus arquivo em um subdiretório com a data de hoje ---*/
-- =======================================================================
-- Configurando para NOARCHIVELOG
-- =======================================================================
STARTUP MOUNT
ALTER DATABASE NOARCHIVELOG;
ALTER DATABASE OPEN;
ALTER DATABASE CLEAR LOGFILE GROUP 3;
ALTER SYSTEM SWITCH LOGFILE;
ALTER SYSTEM CHECKPOINT;
-- =======================================================================
-- Create SQL Profile based on Outline hints in V$SQL.OTHER_XML
-- This scripts prompts for five values.
--
-- sql_id: the sql_id of the statement to attach the profile to (must be in the shared pool and in AWR history)
-- plan_hash_value: the plan_hash_value of the statement in AWR history
-- profile_name: the name of the profile to be generated
-- category: the name of the category for the profile
-- force_macthing: a toggle to turn on or off the force_matching feature
--
-- @rg_sqlprof1 '&&sql_id' &&child_no '&&category' '&force_matching'
-- =======================================================================
set feedback off
set sqlblanklines on
accept sql_id -
prompt 'Enter value for sql_id: ' -
default 'X0X0X0X0'
accept plan_hash_value -
prompt 'Enter value for plan_hash_value: '
accept profile_name -
prompt 'Enter value for profile_name (PROF_sqlid_planhash): ' -
default 'X0X0X0X0'
accept category -
prompt 'Enter value for category (DEFAULT): ' -
default 'DEFAULT'
accept force_matching -
prompt 'Enter value for force_matching (FALSE): ' -
default 'false'
declare
ar_profile_hints sys.sqlprof_attr;
cl_sql_text clob;
l_profile_name varchar2(30);
begin
select
extractvalue(value(d), '/hint') as outline_hints
bulk collect
into
ar_profile_hints
from
xmltable('/*/outline_data/hint'
passing (
select
xmltype(other_xml) as xmlval
from
dba_hist_sql_plan
where
sql_id = '&&sql_id'
and plan_hash_value = &&plan_hash_value
and other_xml is not null
)
) d;
select
sql_text,
decode('&&profile_name','X0X0X0X0','PROF_&&sql_id'||'_'||'&&plan_hash_value','&&profile_name')
into
cl_sql_text, l_profile_name
from
dba_hist_sqltext
where
sql_id = '&&sql_id';
dbms_sqltune.import_sql_profile(
sql_text => cl_sql_text,
profile => ar_profile_hints,
category => '&&category',
name => l_profile_name,
force_match => &&force_matching
-- replace => true
);
dbms_output.put_line(' ');
dbms_output.put_line('SQL Profile '||l_profile_name||' created.');
dbms_output.put_line(' ');
exception
when NO_DATA_FOUND then
dbms_output.put_line(' ');
dbms_output.put_line('ERROR: sql_id: '||'&&sql_id'||' Plan: '||'&&plan_hash_value'||' not found in AWR.');
dbms_output.put_line(' ');
end;
/
undef sql_id
undef plan_hash_value
undef profile_name
undef category
undef force_matching
set sqlblanklines off
set feedback on
set heading off
--
select 'create user ' || USERNAME || ' identified by values ''' || PASSWORD || ''''
from SYS.DBA_USERS
where USERNAME = upper( '&&1' )
union all
select ' default tablespace ' || DEFAULT_TABLESPACE
from SYS.DBA_USERS
where USERNAME = upper( '&&1' )
union all
select ' temporary tablespace ' || TEMPORARY_TABLESPACE
from SYS.DBA_USERS
where USERNAME = upper( '&&1' )
union all
select ' quota ' || decode( MAX_BYTES, -1, 'unlimited', MAX_BYTES ) || ' on ' || TABLESPACE_NAME
from SYS.DBA_TS_QUOTAS
where USERNAME = upper( '&&1' )
and TABLESPACE_NAME in ( select TABLESPACE_NAME
from SYS.DBA_TABLESPACES )
union all
select ' profile ' || PROFILE || chr(10) ||
' account ' || decode( ACCOUNT_STATUS, 'OPEN', 'UNLOCK', 'LOCK' ) || ';' --, EXTERNAL_NAME
from SYS.DBA_USERS
where USERNAME = upper( '&&1' );
--
select 'grant ' || GRANTED_ROLE || ' to ' || GRANTEE || decode( ADMIN_OPTION, 'YES', ' with admin option;', ';' )
from SYS.DBA_ROLE_PRIVS
where GRANTEE = upper( '&&1' );
--
break on ALTER nodup
column ALTER format a54
select 'alter user ' || GRANTEE || ' default role ' "ALTER", GRANTED_ROLE
from SYS.DBA_ROLE_PRIVS
where GRANTEE = upper( '&&1' )
and DEFAULT_ROLE = 'YES';
clear breaks
--
select 'grant ' || PRIVILEGE || ' to ' || GRANTEE || decode( ADMIN_OPTION, 'YES', ' with admin option;', ';' )
from SYS.DBA_SYS_PRIVS
where GRANTEE = upper( '&&1' );
--
select 'grant ' || PRIVILEGE || ' on ' || OWNER || '.' || TABLE_NAME || '.' || COLUMN_NAME || ' to ' || GRANTEE ||
decode( GRANTABLE, 'YES', ' with grant option;', ';' )
from SYS.DBA_COL_PRIVS
where GRANTEE = upper( '&&1' )
order by OWNER, TABLE_NAME, PRIVILEGE, GRANTABLE;
--
select 'grant ' || PRIVILEGE || ' on ' || OWNER || '.' || TABLE_NAME || ' to ' || GRANTEE ||
decode( GRANTABLE, 'YES', ' with grant option;', ';' )
from SYS.DBA_TAB_PRIVS
where GRANTEE = upper( '&&1' )
order by OWNER, TABLE_NAME, GRANTABLE;
--
-- =======================================================================
-- Cria o usuário EXPIMP e concedeu seus privilégios
-- =======================================================================
create user expimp identified by exp$imp;
grant CREATE SESSION to expimp;
grant EXP_FULL_DATABASE to expimp;
grant IMP_FULL_DATABASE to expimp;
set lines 120 pages 40
SELECT
ses.sid "CURRENT SID",
stat.name,
ses.VALUE
FROM
v$sesstat ses,
v$statname stat
WHERE
stat.statistic#= ses.statistic#
AND ses.sid =
(
SELECT sid
FROM v$mystat
WHERE rownum < 2
)
--and ses.statistic# in (132, 133, 215)
AND
(
LOWER(stat.name) LIKE '%redo%'
OR LOWER(stat.name) LIKE '%undo%'
)
AND ses.VALUE > 0
/
-- =======================================================================
-- shows the currently running SQl statements, excluding this one
-- =======================================================================
SID SERIAL# USER_NAME
---------- ---------- ------------
SQL_TEXT
----------------------------------------------------------------------------------------------------
99 4352 EM630
SELECT t9.CODE, t9.DATA_CENTER, t9.DB_BASE_LEVEL, t9.DB_UPDATE_LEVEL, t9.ACTIVE_NET_NAME, t9.PLATFOR
M, t9.PROTOCOL, t9.CONTROL_M_VER, t9.CONTROL_R, t9.TIME_ZONE, t9.CTM_DAILY_TIME, t9.SUMMER_TIME, t9.
CTM_ODATE, t9.ENABLED, t9.CTM_HOST_NAME, t9.CTM_PORT_NUMBER, t9.GTW_HOST_NAME, t9.GTW_PORT_NUMBER, t
9.DESCRIPTION, t9.CONTACT, t9.LEVEL1, t9.LEVEL2, t9.LEVEL3, t9.LEVEL4, t9.LEVEL5, t9.CTM_ADMIN_PORT,
t9.DESIRED_STATE, t9.START_DAY_OF_WEEK, t9.START_DST_DATE, t9.END_DST_DATE, t9.CMC_MANAGED, t9.UPPE
RCASE, t9.CONTROL_B, t9.CONTROL_T FROM COMM t9
=================inicio==================================================================================
set pagesize 60
set newpage 1
set linesize 200
COL sql_text FOR a100 wrap
COL user_name FOR a12
SELECT u.sid, u.serial#,SUBSTR(u.username,1,12) user_name, s.sql_text
FROM V$SQL s, V$SESSION u
WHERE s.hash_value = u.sql_hash_value
AND sql_text
not like '%from v$sql s, v$session u%'
ORDER BY u.sid;
================final ===================================================================================
-- =============================
-- Show currently committing
-- =============================
SAMPLE OUTPUT Go to Script
--------------------------------------------------------------------------------
USERNAME PROGRAM STATUS LOGONTIME EXECUTIONS SQL_TEXT
--------------- ------------------------------ -------- ------------- ---------- --------------------------------------------------
INSIDEUSER JDBC Connect Client INACTIVE 09Mar05 13:41 39 set transaction isolation level read committed
OUTSIDEUSER JDBC Connect Client INACTIVE 09Mar05 13:40 39 set transaction isolation level read committed
EMPLOYEES JDBC Connect Client INACTIVE 09Mar05 13:41 39 set transaction isolation level read committed
SYS sqlplus@servername.subnet.dns ACTIVE 09Mar05 13:48 2 select s.username,s.program,s.status,to_char(s.log
on_time,'ddMonyy hh24:mi') logontime,executions, s
ql_text from v$session s, v$sqlarea a where a.hash
_value = s.sql_hash_value and a.address = s.sql_ad
dress and upper(a.sql_text) like '%COMMIT%' and us
ername is not null order by 5 desc
SCRIPT Go to Top
------------------------------------------------------------------------------------------------------------------------------------
set pagesize 140
col program for a30 trunc
col s.username a15
col sql_text for a50
set linesize 200
select s.username,s.program,s.status,to_char(s.logon_time,'ddMonyy hh24:mi') logontime,executions, sql_text
from V$SESSION s, V$SQLAREA a where a.hash_value = s.sql_hash_value and a.address = s.sql_address
and upper(a.sql_text) like '%COMMIT%' and username is not null order by 5 desc;
-- ===============================================================================
-- Lista a quantidade de sessões por usuário, program, osuser e sql_hash_value.
-- ===============================================================================
select USERNAME, COUNT(USERNAME)
from V$SESSION
group by USERNAME
having COUNT(USERNAME) > 10
order by 2 desc
/
select PROGRAM, COUNT(PROGRAM)
from V$SESSION
group by PROGRAM
having COUNT(PROGRAM) > 10
order by 2 desc
/
select OSUSER, COUNT(OSUSER)
from V$SESSION
group by OSUSER
having COUNT(OSUSER) > 10
order by 2 desc
/
select SQL_HASH_VALUE, COUNT(SQL_HASH_VALUE)
from V$SESSION
group by SQL_HASH_VALUE
having COUNT(SQL_HASH_VALUE) > 10
order by 2 desc
/
select username, program, logon_time, status, floor(last_call_et / 60/ 60) "horas desde Active"
from v$session
where OSUSER='XXXX'
order by last_call_et desc;
SELECT TABLESPACE_NAME, COUNT(1) DATAFILES
FROM DBA_DATA_FILES
WHERE TABLESPACE_NAME = UPPER('&tablespace')
GROUP BY TABLESPACE_NAME;
-- =======================================================================
-- Exibe informações sobre os arquivos de controles (CONTROL FILES).
-- =======================================================================
col NAME for a70
set feedback off
select * from v$controlfile;
/* ------------------------------------------------------------------------------------------------------
CONTROL_FILE_RECORD_KEEP_TIME:
Specifies the minimum number of days before a reusable record in the control file can be reused.
In the event a new record needs to be added to a reusable section and the
oldest record has not aged enough, the record section expands.
If this parameter is set to 0, then reusable sections never expand, and records are reused as needed.
------------------------------------------------------------------------------------------------------ */
col NAME for a30
col VALUE for a10
select NAME, VALUE from V$PARAMETER where NAME = 'control_file_record_keep_time';
select * from V$CONTROLFILE_RECORD_SECTION;
/* ------------------------------------------------------------------------------------------------------
TYPE - Identifies the type of record section: DATABASE, CKPT PROGRESS, REDO THREAD,
" REDO LOG, DATAFILE, FILENAME, TABLESPACE, LOG HISTORY, OFFLINE RANGE, ARCHIVED LOG,
" BACKUP SET, BACKUP PIECE, BACKUP DATAFILE, BACKUP REDOLOG, DATAFILE COPY,
" BACKUP CORRUPTION, COPY CORRUPTION, DELETED OBJECT, or PROXY COPY.
RECORD_SIZE - Record size in bytes
RECORDS_TOTAL - Number of records allocated for the section
RECORDS_USED - Number of records used in the section
FIRST_INDEX - Index (position) of the first record
LAST_INDEX - Index of the last record
LAST_RECID - Record ID of the last record
------------------------------------------------------------------------------------------------------ */
set feedback on
-- =======================================================================
-- Exibe as restrições de integridade(constraints) de uma determinada tabela.
-- =======================================================================
set verify off
col OWNER for a8
select OWNER,
CONSTRAINT_NAME,
CONSTRAINT_TYPE,
TABLE_NAME,
SEARCH_CONDITION,
R_OWNER,
R_CONSTRAINT_NAME,
DELETE_RULE,
STATUS,
DEFERRABLE,
DEFERRED,
VALIDATED
from dba_constraints
where owner = upper('&1')
and table_name = upper('&2')
order by CONSTRAINT_TYPE
/
col COLUMN_NAME for a30
select OWNER, CONSTRAINT_NAME, TABLE_NAME, COLUMN_NAME, POSITION
from DBA_CONS_COLUMNS
where CONSTRAINT_NAME = '&3'
/
set verify on
-- =======================================================================
-- Lista os totais de usuários conectados.
-- =======================================================================
col status format a8
--
@cab;
--
select a.STATUS,
count(0) QTD
from V$SESSION a, V$PROCESS b
where a.TYPE != 'BACKGROUND'
and b.ADDR (+) = a.PADDR
group by a.STATUS;
--
set heading off;
select 'Total: ' || count(0)
from V$SESSION a, V$PROCESS b
where a.TYPE != 'BACKGROUND'
and b.ADDR (+) = a.PADDR;
set heading on;
prompt;
--
@rod;
-- =======================================================================
-- Verifica as querys que consumiram CPU.
-- =======================================================================
set linesize 2000
set buffer 2000
set pagesize 20
--
select
substr(to_char(s.pct, '99.00'), 2) || '%' load,
p.address,
s.executions executes,
p.sql_text
from (select address,
disk_reads,
executions,
pct,
rank() over (order by disk_reads desc) ranking
from (select address,
disk_reads,
executions, 100 * ratio_to_report(disk_reads) over () pct
from sys.v_$sql
where command_type != 47 )
where disk_reads > 50 * executions ) s, sys.v_$sqltext p
where s.ranking <= 70 and p.address = s.address
order by 1, s.address, p.piece
/
-- =======================================================================
-- Lista de colunas da tabela &1 &2
-- UTILIZAÇÃO:
-- @columns [owner] [table_name]
-- =======================================================================
set verify off
column column_name format a30
column DATA_LENGTH format 999999
column DATA_TYPE format a10
column PRECISION format 999999
column SCALE format a5
column NULLABLE format a8
column NUM_DISTINCT format 99999999999
column LAST_ANALYZED format a18
select column_name ,
DATA_TYPE ,
decode(NULLABLE,'Y',null,'NOT NULL') nullable,
case DATA_TYPE
when 'DATE' then null
when 'NUMBER' then null
else
DATA_LENGTH
end DATA_LENGTH,
case DATA_TYPE
when 'VARCHAR2' then DATA_LENGTH
else
DATA_PRECISION
end PRECISION ,
case DATA_SCALE
when 0 then NULL
else
to_char(DATA_SCALE)
end SCALE,
NUM_DISTINCT ,
to_char(LAST_ANALYZED,'dd/mm/rr hh24:mi:ss') last_analyzed
from dba_tab_columns
where owner = upper('&1')
and table_name = upper('&2')
order by 1
/
select tablespace_name,
num_rows,
initial_extent,
next_extent,
pct_increase,
num_rows,
blocks,
logging
from dba_tables
where owner = upper('&1')
and table_name = upper('&2')
/
clear screen
-- =======================================================================
-- As tabelas que utilizam uma constraint(PK ou UK) de uma tabela pai
-- =======================================================================
set verify off
select OWNER,
CONSTRAINT_NAME,
CONSTRAINT_TYPE,
TABLE_NAME,
R_OWNER,
R_CONSTRAINT_NAME
from dba_constraints
where R_CONSTRAINT_NAME = upper('&1')
/
set verify on
-- =======================================================================
-- Verifica a situação das estruturas de Memória e sugere melhorias
-- =======================================================================
@cab
SELECT *
FROM v$database;
PROMPT
DECLARE
v_value NUMBER;
FUNCTION Format(p_value IN NUMBER)
RETURN VARCHAR2 IS
BEGIN
RETURN LPad(To_Char(Round(p_value,2),'990.00') || '%',8,' ') || ' ';
END;
BEGIN
-- --------------------------
-- Dictionary Cache Hit Ratio
-- --------------------------
SELECT (1 - (Sum(getmisses)/(Sum(gets) + Sum(getmisses)))) * 100
INTO v_value
FROM v$rowcache;
DBMS_Output.Put('Dictionary Cache Hit Ratio : ' || Format(v_value));
IF v_value < 90 THEN
DBMS_Output.Put_Line('Aumentar SHARED_POOL_SIZE até estar superior a 90%');
ELSE
DBMS_Output.Put_Line('OK');
END IF;
-- -----------------------
-- Library Cache Hit Ratio
-- -----------------------
SELECT (1 -(Sum(reloads)/(Sum(pins) + Sum(reloads)))) * 100
INTO v_value
FROM v$librarycache;
DBMS_Output.Put('Library Cache Hit Ratio : ' || Format(v_value));
IF v_value < 99 THEN
DBMS_Output.Put_Line('Aumentar SHARED_POOL_SIZE até estar próximo de 99%');
ELSE
DBMS_Output.Put_Line('OK');
END IF;
-- -------------------------------
-- DB Block Buffer Cache Hit Ratio
-- -------------------------------
SELECT (1 - (phys.value / (db.value + cons.value))) * 100
INTO v_value
FROM v$sysstat phys,
v$sysstat db,
v$sysstat cons
WHERE phys.name = 'physical reads'
AND db.name = 'db block gets'
AND cons.name = 'consistent gets';
DBMS_Output.Put('DB Block Buffer Cache Hit Ratio : ' || Format(v_value));
IF v_value < 89 THEN
DBMS_Output.Put_Line('Aumentar DB_BLOCK_BUFFERS até estar próximo de 90%');
ELSE
DBMS_Output.Put_Line('OK');
END IF;
-- ---------------
-- Latch Hit Ratio
-- ---------------
SELECT (1 - (Sum(misses) / Sum(gets))) * 100
INTO v_value
FROM v$latch;
DBMS_Output.Put('Latch Hit Ratio : ' || Format(v_value));
IF v_value < 98 THEN
DBMS_Output.Put_Line('Aumentar o número de latches até atingir 98%');
ELSE
DBMS_Output.Put_Line('OK');
END IF;
-- -----------------------
-- Disk Sort Ratio
-- -----------------------
SELECT (disk.value/mem.value) * 100
INTO v_value
FROM v$sysstat disk,
v$sysstat mem
WHERE disk.name = 'sorts (disk)'
AND mem.name = 'sorts (memory)';
DBMS_Output.Put('Disk Sort Ratio : ' || Format(v_value));
IF v_value > 5 THEN
DBMS_Output.Put_Line('Aumentar a SORT_AREA_SIZE para que permaneça abaixo 5%');
ELSE
DBMS_Output.Put_Line('OK');
END IF;
-- ----------------------
-- Rollback Segment Waits
-- ----------------------
SELECT (Sum(waits) / Sum(gets)) * 100
INTO v_value
FROM v$rollstat;
DBMS_Output.Put('Rollback Segment Waits : ' || Format(v_value));
IF v_value > 5 THEN
DBMS_Output.Put_Line('Aumentar o número de rollback segments para que fique abaixo 5%');
ELSE
DBMS_Output.Put_Line('OK');
END IF;
-- -------------------
-- Dispatcher Workload
-- -------------------
SELECT NVL((Sum(busy) / (Sum(busy) + Sum(idle))) * 100,0)
INTO v_value
FROM v$dispatcher;
DBMS_Output.Put('Dispatcher Workload : ' || Format(v_value));
IF v_value > 50 THEN
DBMS_Output.Put_Line('Aumentar MTS_DISPATCHERS até que permaneça com valores abaixo 50%');
ELSE
DBMS_Output.Put_Line('OK');
END IF;
END;
/
-- ================================================================
-- Ajusta o ambiente do SQL*Plus.
-- ================================================================
clear breaks
set feedback off
set verify off
set pagesize 9000
set trimspool on
set serveroutput on;
-- ================================================================
-- Detectando sessões bloqueadoras e sessões bloqueadas no Oracle:
-- DBA_WAITERS, V$LOCKED_OBJECT, V$LOCK, V$SESSION
-- ================================================================
SET SERVEROUTPUT ON
BEGIN
DBMS_OUTPUT.enable (1000000);
FOR do_loop IN
(
SELECT session_id,
a.object_id,
xidsqn,
oracle_username,
b.owner owner,
b.object_name object_name,
b.object_type object_type
FROM v$locked_object a,
dba_objects b
WHERE xidsqn != 0
AND b.object_id = a.object_id
)
LOOP
dbms_output.put_line ('.');
dbms_output.put_line ('Blocking Session: ' || do_loop.session_id);
dbms_output.put_line ( 'Object (Owner/Name): ' || do_loop.owner || '.' || do_loop.object_name);
dbms_output.put_line ('Object Type: ' || do_loop.object_type);
FOR next_loop IN (
SELECT sid
FROM v$lock
WHERE id2 = do_loop.xidsqn
AND sid != do_loop.session_id)
LOOP
dbms_output.put_line ( 'Sessions being blocked: '|| next_loop.sid);
END LOOP;
END LOOP;
END;
/
-- ==================================================================================
-- Mostra objetos cujos blocos estão atualmente no cache de buffer do banco de dados
-- ==================================================================================
select object_name, object_type, count(*) num_buff
from x$bh a, sys.dba_objects b
where a.obj = b.object_id
and owner not in ('SYS','SYSTEM')
group by object_name, object_type;
-- =======================================================================
-- block tabela
-- =======================================================================
@@init
ttitle off
btitle off
accept t prompt "Entre com o nome da tabela: "
set pause off ver off feed off
col a heading "Arquivos"
col b heading "Blocos"
col c heading "Linhas"
col d heading "Linhas|Bloco"
col e heading "Blocos|Usados"
select /*+ rule */ count(distinct substr(rowid,15,4)) a
, count(distinct substr(rowid,1 ,8)) b
, count(substr(rowid,10,4)) c
,round(count(substr(rowid,10,4))/count(distinct substr(rowid,1,8))) d
, count(distinct(substr(rowid,1,8)||substr(rowid,15,4))) e
from &t
/
@@init
-- =======================================================================
-- Block Wait
-- =======================================================================
set feed off
set wrap off
set lines 130
set pages 100
alter session set nls_date_format='dd/mm/yyyy-hh24:mi:ss';
PROMPT =============================================================================================================
col kinstance_name for a12 heading 'Instancia'
col khostname for a20 heading 'Servidor'
col kstatus heading 'Estado'
col ksessions for 9999 heading 'Sessoes'
col start_time for a20 heading 'Start_Time'
col today for a20 heading 'Today'
col days_running for 9999 heading 'Days_Running'
col sql_text for A100 heading Sql word wrap
col child_number for 99999 heading Child#
select decode(i.instance_name, null, ' ', '>> ') ||
c.instance_name kinstance_name,
c.host_name khostname,
c.status kstatus,
l.sessions_current ksessions,
i.startup_time start_time,
sysdate today,
trunc(sysdate - i.startup_time) days_running
from gv$instance c,
gv$license l,
v$instance i
where c.instance_number = i.instance_number (+)
and c.thread# = i.thread# (+)
and l.inst_id = c.inst_id;
PROMPT
PROMPT =============================================================================================================
set feed on
set lines 150
SET SERVEROUTPUT ON
set echo off
DECLARE
csid1 gv$session.sid%type;
cusr1 gv$session.username%type;
cmac1 gv$session.machine%type;
cprg1 gv$session.program%type;
csid2 gv$session.sid%type;
cusr2 gv$session.username%type;
cmac2 gv$session.machine%type;
cprg2 gv$session.program%type;
contador number;
c2sid gv$session.sid%type;
c2serial gv$session.serial#%type;
c2username gv$session.username%type;
c2osuser gv$session.osuser%type;
c2machine gv$session.machine%type;
c2program gv$session.program%type;
c2instance gv$instance.instance_name%type;
c2host gv$instance.host_name%type;
c2spid gv$process.spid%type;
c2hash gv$session.sql_hash_value%type;
c2status gv$session.status%type;
c2logon gv$session.logon_time%type;
c3child v$sql.child_number%type;
c3text v$sqltext.sql_text%type;
CURSOR c1
IS
select /*+ rule */ s1.sid ,s1.username,s1.machine, s1.program, s2.sid,s2.username,s2.machine, s2.program
from gv$lock l1, gv$session s1, gv$lock l2, gv$session s2
where s1.sid=l1.sid
and s2.sid=l2.sid
and l1.BLOCK=1
and l2.request > 0
and l1.id1 = l2.id1
and l2.id2 = l2.id2;
CURSOR c2
IS
select s.sid, s.serial#, s.username, s.osuser, s.machine, s.program, i.instance_name, i.host_name, p.spid, s.sql_hash_value, s.status,s.logon_time
from gv$session s, gv$process p, gv$instance i
where s.sid = csid1
and s.paddr = p.addr
and p.inst_id = i.inst_id;
CURSOR c3
IS
select s.child_number, t.sql_text
from v$sqltext t, v$sql s
where s.hash_value = c2hash
and s.address = t.address
and s.hash_value = t.hash_value
order by s.child_number, t.piece;
BEGIN
open c1;
contador := 0;
LOOP
fetch c1 into csid1,cusr1,cmac1,cprg1,csid2,cusr2,cmac2,cprg2;
if c1%found then
contador := contador + 1;
DBMS_OUTPUT.PUT_LINE('A SESSAO SID='||csid1||' USER='||cusr1||'@'||substr(cprg1,1,7)||'@'||cmac1||' esta bloqueando o SID='||csid2||' USER='||cusr2||'@'||substr(cprg2,1,7)||'@'||cmac2);
end if;
if contador = 0 then
DBMS_OUTPUT.PUT_LINE('NAO HA SESSOES EM LOCK!!!');
end if;
EXIT WHEN c1%NOTFOUND;
END LOOP;
if contador <> 0 then
open c2;
open c3;
fetch c2 into c2sid, c2serial, c2username, c2osuser, c2machine, c2program, c2instance, c2host, c2spid, c2hash, c2status, c2logon;
fetch c3 into c3child, c3text ;
DBMS_OUTPUT.PUT_LINE ('=============================================================================================================');
dbms_output.put_line('Sid..............: ' || c2sid);
dbms_output.put_line('Serial#..........: ' || c2serial);
dbms_output.put_line('Status...........: ' || c2status);
dbms_output.put_line('Username.........: ' || c2username);
dbms_output.put_line('Maquina..........: ' || c2machine);
dbms_output.put_line('Programa.........: ' || c2program);
dbms_output.put_line('OS User..........: ' || c2osuser);
dbms_output.put_line('Host.............: ' || c2host);
dbms_output.put_line('Instance.........: ' || c2instance);
dbms_output.put_line('SQL Hash Value...: ' || c2hash);
dbms_output.put_line('PID..............: ' || c2spid);
dbms_output.put_line('Logon Time ......: ' || c2logon);
dbms_output.put_line('Child Number.....: ' || c3child);
dbms_output.put_line('Query ...........: ' || c3text);
DBMS_OUTPUT.PUT_LINE ('=======================================================');
DBMS_OUTPUT.PUT_LINE ('=DIRECIONAR O CHAMADO AO CLIENTE COM ESTAS INFORMACOES=');
DBMS_OUTPUT.PUT_LINE ('=======================================================');
close c2;
close c3;
end if;
close c1;
END;
/
-- =======================================================================
-- Este script fornece informações sobre o cache de buffer(buffer_cache).
-- =======================================================================
set feedback off
select NAME,
trunc(VALUE/1024/1024,0) as value_mb
from v$parameter
where NAME in ('sga_max_size',
'db_cache_size',
'db_keep_cache_size',
'db_recycle_cache_size',
'db_2k_cache_size',
'db_4k_cache_size',
'db_8k_cache_size',
'db_16k_cache_size',
'db_32k_cache_size'
)
order by 2 desc
/
SELECT round(((1 - (phy.value - lob.value - dir.value) / ses.value)*100),2) "TOTAL_CACHE_HIT_HATIO__PCT"
FROM v$sysstat ses, v$sysstat lob, v$sysstat dir, v$sysstat phy
WHERE ses.name = 'session logical reads'
AND dir.name = 'physical reads direct'
AND lob.name = 'physical reads direct (lob)'
AND phy.name = 'physical reads'
/
select name, block_size, round(((1 - (physical_reads / (db_block_gets + consistent_gets)))*100),2) "HIT_HATIO_PCT"
from v$buffer_pool_statistics
where db_block_gets + consistent_gets > 0
/
set pages 24
select NAME,
BLOCK_SIZE,
SIZE_FOR_ESTIMATE,
SIZE_FACTOR,
BUFFERS_FOR_ESTIMATE,
ESTD_PHYSICAL_READ_FACTOR,
ESTD_PHYSICAL_READS
from v$db_cache_advice
/
set feedback on
set pages 3000
-- =======================================================================
-- Este script busca os objetos com o nome especificado.
-- =======================================================================
set linesize 2000
set buffer 2000
col OBJECT_NAME for a30
col OWNER for a15
select OWNER,
OBJECT_NAME,
OBJECT_TYPE,
STATUS,
CREATED,
LAST_DDL_TIME,
TIMESTAMP
from DBA_OBJECTS
where OBJECT_NAME like upper('%&1%');
SET HEA OFF
SET PAGESIZE 250
SPOOL C:\temp_script\tablespace_benginBackup.sql
SELECT 'ALTER TABLESPACE ' || TABLESPACE_NAME || ' BEGIN BACKUP;'
FROM DBA_TABLESPACES
WHERE CONTENTS IN ('PERMANENT','UNDO')
AND STATUS <> 'READ ONLY'
/
SPOOL OFF
@C:\temp_script\tablespace_benginBackup.sql
-- =======================================================================
-- Este script coloca as tablespaces do banco em begin backup.
-- =======================================================================
SELECT
'alter tablespace ' || tablespace_name || ' begin backup;' AS "Coloca AS TBS em BEGIN Backup"
FROM
dba_tablespaces
ORDER BY
1
/
ALTER database BEGIN backup;
-- =======================================================================
-- Verifica se há indices maiores que suas tabelas(owner).
-- =======================================================================
set feedback off
set verify off
col TABLE_OWNER for a12
col TABLE_NAME for a30
col INDEX_OWNER for a12
col INDEX_NAME for a30
-- col TAB_TAM_MB for 999,999,999
-- col TAB_IDX_MB for 999,999,999
select tab.OWNER as TABLE_OWNER,
tab.SEGMENT_NAME as TABLE_NAME,
trunc(tab.TAM_MB,0) as TAB_TAM_MB,
idx.OWNER as INDEX_OWNER,
idx.SEGMENT_NAME as INDEX_NAME,
trunc(idx.TAM_MB,0) as TAB_IDX_MB
from dba_indexes DBA,
(select OWNER, SEGMENT_NAME, BYTES/1024/1024 AS TAM_MB
from dba_segments
where segment_type = 'TABLE') TAB,
(select OWNER, SEGMENT_NAME, BYTES/1024/1024 AS TAM_MB
from dba_segments
where segment_type = 'INDEX') IDX
where dba.INDEX_NAME = idx.SEGMENT_NAME
and dba.TABLE_NAME = tab.SEGMENT_NAME
and idx.TAM_MB > tab.TAM_MB
and idx.TAM_MB > 10
order by 6 desc
/
set feedback on
set verify on
SET PAGESIZE 60
SET LINESIZE 300
COLUMN sql_text FORMAT A120
COLUMN sql_id FORMAT A13
COLUMN bind_name FORMAT A10
COLUMN bind_value FORMAT A26
SELECT
sql_id,
t.sql_text sql_text,
b.name bind_name,
b.value_string bind_value
FROM
DBA_HIST_SQLTEXT t
JOIN
DBA_HIST_SQLBIND b using (sql_id)
WHERE
b.value_string is not null
AND
sql_id='&sqlid';
set lines 180 pages 500
col end_time for a25
col start_time for a25
SELECT
*
FROM
(
SELECT
SESSION_KEY,
INPUT_TYPE,
STATUS,
OUTPUT_DEVICE_TYPE AS DEVICE_TYPE,
to_char(START_TIME, 'dd/mm/yy hh24:mi') start_time,
to_char(END_TIME, 'dd/mm/yy hh24:mi') end_time,
elapsed_seconds / 3600 hrs
FROM
V$RMAN_BACKUP_JOB_DETAILS
ORDER BY
session_key DESC
)
WHERE
rownum < 100
/
--traceUser.sql - Trace Current User
--SAMPLE OUTPUT Go to Script
-------------------------------------------------
--SQL > @traceUser
--Enter User to create trace on: SCTBXS
--TURNON
-------------------------------------------------
--exec sys.dbms_system.set_ev(11,5,10046,12,'');
--TURNOFF
-------------------------------------------------
--exec sys.dbms_system.set_ev(11,5,10046,0,'');
--SCRIPT Go to Top
--============= inicio ======================================================================
set verify off
SET LINESIZE 132
SET PAGESIZE 100
COL VALUES FORMAT A60
PROMPT
PROMPT
PROMPT LOG DE TRACE SERA GERADO EM
SELECT VALUE FROM V$PARAMETER WHERE NAME='user_dump_dest'
/
ACCEPT tuser PROMPT 'Enter User to create trace on: '
PROMPT
PROMPT 'ABAIXO SEQUENCIA PARA ATIVAR O TRACE'
PROMPT
select 'exec sys.dbms_system.set_ev('||sid||','||serial#||','||'10046,12,'''||''');' TurnOn
from V$SESSION where username=UPPER('&tuser') and status='ACTIVE';
PROMPT 'ABAIXO SEQUENCIA PARA DESATIVAR O TRACE'
PROMPT
select 'exec sys.dbms_system.set_ev('||sid||','||serial#||','||'10046,0,'''||''');' TurnOff
from V$SESSION where username=UPPER('&tuser') and status='ACTIVE';
--============= final ========================================================================
SELECT AVG(TRUNC(SUM(BYTES/1024/1024/1024),0)) as "GBYTES P/ MÊS"
FROM V$DATAFILE
WHERE MONTHS_BETWEEN(SYSDATE, CREATION_TIME) < 12
GROUP BY TO_CHAR(CREATION_TIME,'yyyy-mm')
/
-- =======================================================================
-- Display Execution plan from AWR
-- Parameters : 1 - SQL_ID
-- : 2 - PLAN_HASH_VALUE (Use % for ALL)
-- =======================================================================
SET verify OFF
VARIABLE sql_id VARCHAR2(13)
VARIABLE plan_hash_value VARCHAR2(20)
variable dbid number;
BEGIN
SELECT DISTINCT dbid
INTO :dbid
FROM v$database;
END;
/
BEGIN
:sql_id := '&&1';
:plan_hash_value := '%';
IF :plan_hash_value = '' OR :plan_hash_value IS NULL THEN
:plan_hash_value := '0';
END IF;
IF :plan_hash_value = '%' THEN
:plan_hash_value := NULL;
END IF;
END;
/
PROMPT
PROMPT #################################################################
PROMPT # A L L S Q L P L A N H A S H V A L U E
PROMPT #################################################################
COLUMN sql_id HEADING "SQL_ID" FORMAT a13
COLUMN plan_hash_value HEADING "PLAN_HASH_VALUE" FORMAT 9999999999999999
COLUMN cost HEADING "Cost" FORMAT 9999999999
COLUMN last_used HEADING "Last_Used" FORMAT a20
COLUMN first_used HEADING "First_Used" FORMAT a20
COLUMN first_parsed HEADING "First_Parsed" FORMAT a20
set lin 1000
SELECT p.sql_id
, p.plan_hash_value
, p.cost
, to_char(MAX(s.end_interval_time) ,'DD-MON-YY HH24:MI:SS') last_used
, to_char(MIN(s.end_interval_time) ,'DD-MON-YY HH24:MI:SS') first_used
, to_char(MIN(p.timestamp) ,'DD-MON-YY HH24:MI:SS') first_parsed
FROM v$database d
, dba_hist_sql_plan p
, dba_hist_sqlstat ss
, dba_hist_snapshot s
WHERE d.dbid = p.dbid
AND p.dbid = ss.dbid (+)
AND p.sql_id = ss.sql_id (+)
AND p.plan_hash_value = ss.plan_hash_value
AND ss.dbid = s.dbid (+)
AND ss.instance_number = s.instance_number (+)
AND ss.snap_id = s.snap_id (+)
AND p.id = 0 -- Top row which has cost as well
AND p.sql_id = :sql_id
GROUP BY p.sql_id
, p.plan_hash_value
, p.cost
ORDER BY MAX(s.end_interval_time) ASC
/
DEF sql_id = '&&1';
PRO
WITH
p AS (
SELECT plan_hash_value
FROM gv$sql_plan
WHERE sql_id = TRIM('&&1')
AND other_xml IS NOT NULL
UNION
SELECT plan_hash_value
FROM dba_hist_sql_plan
WHERE sql_id = TRIM('&&1')
AND other_xml IS NOT NULL ),
m AS (
SELECT plan_hash_value,
SUM(elapsed_time)/SUM(executions) avg_et_secs
FROM gv$sql
WHERE sql_id = TRIM('&&1')
AND executions > 0
GROUP BY
plan_hash_value ),
a AS (
SELECT plan_hash_value,
SUM(elapsed_time_total)/SUM(executions_total) avg_et_secs
FROM dba_hist_sqlstat
WHERE sql_id = TRIM('&&1')
AND executions_total > 0
GROUP BY
plan_hash_value )
SELECT p.plan_hash_value,
ROUND(NVL(m.avg_et_secs, a.avg_et_secs)/1e6, 3) avg_et_secs
FROM p, m, a
WHERE p.plan_hash_value = m.plan_hash_value(+)
AND p.plan_hash_value = a.plan_hash_value(+)
ORDER BY
avg_et_secs NULLS LAST;
PROMPT
PROMPT
PROMPT #################################################################
PROMPT # A L L E X E C U T I O N P L A N S
PROMPT #################################################################
PROMPT
SET long 4000
SET longchunksize 4000
set pages 0
set lines 250
COLUMN plan_table_output HEADING "SQLText" FORMAT a200 WRAP
SELECT *
FROM TABLE (DBMS_XPLAN.display_awr ('&&1',
:plan_hash_value,
:dbid,
'ADVANCED'
)
);
exec :sql_id := NULL;
exec :plan_hash_value := NULL;
undefine 1
undefine 2
set pages 100
-- =======================================================================
-- Verifica se há tablespaces em begin backup.
-- =======================================================================
select FILE#,
STATUS,
CHANGE#,
to_char(TIME, 'dd/mm/yyyy hh24:mi:ss') as TIME
from V$BACKUP
where status = 'ACTIVE'
/
col name for a30
col path for a70
set lines 300
set pages 9000
SELECT name, header_status, path FROM V$ASM_DISK;
/* -- Verifica apenas os DGs do ASM -- */
SET lines 180
SET pages 1000
col COMPATIBILITY for a15
col DATABASE_COMPATIBILITY for a15
SELECT
group_number,
name,
total_mb,
free_mb,
round(((total_mb - free_mb) * 100 / total_mb), 2) AS PERC,
state,
COMPATIBILITY,
DATABASE_COMPATIBILITY
FROM
v$asm_diskgroup
ORDER BY
group_number;
-- =======================================================================
-- Informações sobre os diskgroups e discos ASM usados pela instância.
-- =======================================================================
set feedback off
set pages 20
/* -- Espaço livre por DG -- */
SELECT
NAME,
TOTAL_MB,
FREE_MB,
STATE,
TYPE,
OFFLINE_DISKS,
UNBALANCED
FROM
V$ASM_DISKGROUP
ORDER BY 2 DESC
/
col NAME for a30
col PATH for a45
/* -- Espaço livre em cada disco de cada DG -- */
SELECT
NAME,
GROUP_NUMBER,
DISK_NUMBER,
TOTAL_MB,
FREE_MB,
MOUNT_STATUS,
PATH
FROM
V$ASM_DISK
ORDER BY
2,3
/
set feedback on
-- =======================================================================
-- Informa quantidade archive GENERATED DELETED
-- =======================================================================
SELECT
SUM_ARCH.DAY,
SUM_ARCH.GENERATED_MB,
SUM_ARCH_DEL.DELETED_MB,
SUM_ARCH.GENERATED_MB - SUM_ARCH_DEL.DELETED_MB "REMAINING_MB"
FROM
(
SELECT
TO_CHAR (COMPLETION_TIME, 'DD/MM/YYYY') DAY,
SUM (ROUND ( (blocks * block_size) / (1024 * 1024), 2)) GENERATED_MB
FROM
V$ARCHIVED_LOG
WHERE
ARCHIVED = 'YES'
GROUP BY
TO_CHAR (COMPLETION_TIME, 'DD/MM/YYYY')
)
SUM_ARCH,
(
SELECT
TO_CHAR (COMPLETION_TIME, 'DD/MM/YYYY') DAY,
SUM (ROUND ( (blocks * block_size) / (1024 * 1024), 2)) DELETED_MB
FROM
V$ARCHIVED_LOG
WHERE
ARCHIVED = 'YES'
AND DELETED = 'YES'
GROUP BY
TO_CHAR (COMPLETION_TIME, 'DD/MM/YYYY')
)
SUM_ARCH_DEL
WHERE
SUM_ARCH.DAY = SUM_ARCH_DEL.DAY( + )
ORDER BY
TO_DATE (DAY, 'DD/MM/YYYY');
-- =======================================================================
-- Informa quantidade archive gerado por dia / hora
-- =======================================================================
set pages 1000
col Day for a10
col MB for 99999999
select
trunc(COMPLETION_TIME,'DD') Day,
thread#,
count(*) Archives_Generated,
round(sum(BLOCKS*BLOCK_SIZE)/1048576) MB
from v$archived_log
where trunc(COMPLETION_TIME,'DD') >= sysdate - 30
group by trunc(COMPLETION_TIME,'DD'),thread# order by 1;
-- Archivelog generation on a daily basis:
select
trunc(COMPLETION_TIME,'DD') Day,
thread#,
round(sum(BLOCKS*BLOCK_SIZE)/1048576) MB,
round((sum(BLOCKS*BLOCK_SIZE)/1048576)/1024) GB,
count(*) Archives_Generated
from v$archived_log
group by trunc(COMPLETION_TIME,'DD'),thread# order by 1;
-- Archive log generation on an hourly basis:
select
trunc(COMPLETION_TIME,'HH') Hour, thread# ,
round(sum(BLOCKS*BLOCK_SIZE)/1048576) MB,
round(sum(BLOCKS*BLOCK_SIZE)/1048576)/1024 GB,
count(*) Archives
from v$archived_log
group by trunc(COMPLETION_TIME,'HH'),thread# order by 1 ;
-- =======================================================================
-- Cria uma matriz com a quantidade de archives gerados por dia e hora.
-- =======================================================================
col DAY for a3
col TOTAL for a6
col H00 for a4
col H01 for a4
col H02 for a4
col H03 for a4
col H04 for a4
col H05 for a4
col H06 for a4
col H07 for a4
col H08 for a4
col H09 for a4
col H10 for a4
col H11 for a4
col H12 for a4
col H13 for a4
col H14 for a4
col H15 for a4
col H16 for a4
col H17 for a4
col H18 for a4
col H19 for a4
col H20 for a4
col H21 for a4
col H22 for a4
col H23 for a4
SELECT
trunc(first_time) "Date",
to_char(first_time, 'Dy') "Day",
substr(count(1),1,5) as "Total",
THREAD#,
substr(SUM(decode(to_char(first_time, 'hh24'),'00',1,0)),1,3) as "h00",
substr(SUM(decode(to_char(first_time, 'hh24'),'01',1,0)),1,3) as "h01",
substr(SUM(decode(to_char(first_time, 'hh24'),'02',1,0)),1,3) as "h02",
substr(SUM(decode(to_char(first_time, 'hh24'),'03',1,0)),1,3) as "h03",
substr(SUM(decode(to_char(first_time, 'hh24'),'04',1,0)),1,3) as "h04",
substr(SUM(decode(to_char(first_time, 'hh24'),'05',1,0)),1,3) as "h05",
substr(SUM(decode(to_char(first_time, 'hh24'),'06',1,0)),1,3) as "h06",
substr(SUM(decode(to_char(first_time, 'hh24'),'07',1,0)),1,3) as "h07",
substr(SUM(decode(to_char(first_time, 'hh24'),'08',1,0)),1,3) as "h08",
substr(SUM(decode(to_char(first_time, 'hh24'),'09',1,0)),1,3) as "h09",
substr(SUM(decode(to_char(first_time, 'hh24'),'10',1,0)),1,3) as "h10",
substr(SUM(decode(to_char(first_time, 'hh24'),'11',1,0)),1,3) as "h11",
substr(SUM(decode(to_char(first_time, 'hh24'),'12',1,0)),1,3) as "h12",
substr(SUM(decode(to_char(first_time, 'hh24'),'13',1,0)),1,3) as "h13",
substr(SUM(decode(to_char(first_time, 'hh24'),'14',1,0)),1,3) as "h14",
substr(SUM(decode(to_char(first_time, 'hh24'),'15',1,0)),1,3) as "h15",
substr(SUM(decode(to_char(first_time, 'hh24'),'16',1,0)),1,3) as "h16",
substr(SUM(decode(to_char(first_time, 'hh24'),'17',1,0)),1,3) as "h17",
substr(SUM(decode(to_char(first_time, 'hh24'),'18',1,0)),1,3) as "h18",
substr(SUM(decode(to_char(first_time, 'hh24'),'19',1,0)),1,3) as "h19",
substr(SUM(decode(to_char(first_time, 'hh24'),'20',1,0)),1,3) as "h20",
substr(SUM(decode(to_char(first_time, 'hh24'),'21',1,0)),1,3) as "h21",
substr(SUM(decode(to_char(first_time, 'hh24'),'22',1,0)),1,3) as "h22",
substr(SUM(decode(to_char(first_time, 'hh24'),'23',1,0)),1,3) as "h23"
FROM gv$log_history
GROUP BY
trunc(first_time), to_char(first_time, 'Dy'), THREAD#
ORDER BY
trunc(first_time) , THREAD#
/
Both the SPFILE and PFILE are located in directory:
$ORACLE_HOME/dbs
SHOW PARAMETER SPFILE;
SELECT name, value FROM v$parameter WHERE name = 'spfile';
-- Para criar o PFILE a partir do SPFILE:
CREATE PFILE='$PATH/PFILE_name' FROM SPFILE='$PATH/SPFILE_name';
-- Para criar o SPFILE a partir do PFILE:
CREATE SPFILE FROM PFILE;
CREATE SPFILE FROM PFILE='/u01/app/oracle/product/12.2.0/dbhome_1/dbs/init.ora'
CREATE SPFILE='/u01/app/oracle/product/12.2.0/dbhome_1/dbs/SPFILE.ora' FROM PFILE='/backup/init.ora'
STARTUP PFILE='/u01/app/oracle/product/12.2.0/dbhome_1/dbs/init.ora';
CREATE SPFILE FROM PFILE='/u01/admin/prod/PFILE/initprod.ora';
-- Necessário Reiniciar, A reinicialização utilizará o SPFILE criado.
SHUTDOWN IMMEDIATE;
STARTUP;
CREATE SPFILE='/u01/app/oracle/product/12.2.0/dbhome_1/dbs/initSID.ora' FROM PFILE='/storage/oracle/initnewdb.ora'
CREATE PFILE ='/u01/app/oracle/product/12.2.0/dbhome_1/dbs/initSID_BACKUP.ora' FROM SPFILE;
CREATE SPFILE FROM MEMORY;
CREATE PFILE FROM MEMORY;
CREATE PFILE='/tmp/initSID.ora' FROM SPFILE;
CREATE PFILE='/tmp/initSID_memory.ora' FROM memory;
CREATE PFILE='/u01/app/oracle/product/VERSAO/db_1/dbs/init.ora' FROM memory;
CREATE PFILE ='/u01/app/oracle/product/VERSAO/db_1/dbs/PFILE.ora' FROM SPFILE='/u01/app/oracle/product/VERSAO/db_1/dbs/SPFILESID.ora';
CREATE SPFILE='/u01/app/oracle/product/VERSAO/db_1/dbs/SPFILESID.ora' FROM PFILE ='/u01/app/oracle/product/VERSAO/db_1/dbs/init.ora';
-- Falha e a solução:
LRM-00109: could not open parameter file '/u01/app/oracle/product/11.2.0.4/db_1/dbs/init.ora';
STARTUP FORCE PFILE='/u01/app/oracle/product/11.2.0.4/db_1/dbs/init.ora';
--STARTUP database with PFILE or SPFILE
STARTUP [NOMOUNT | MOUNT | OPEN] PFILE='/backup/init.ora'
SQL> STARTUP NOMOUNT PFILE='/storage/oracle/initnewdb.ora';
STARTUP PFILE='';
STARTUP SPFILE='';
STARTUP SPFILE='/u01/app/oracle/product/12.2.0/dbhome_1/dbs/SPFILESID.ora';
restore SPFILE to PFILE '/tmp/initnewdb.ora' FROM '/tmp/SPFILESID.ora';
SET DBID 1234567890;
STARTUP FORCE NOMOUNT; # RMAN starts instance with dummy parameter file
RESTORE SPFILE FROM AUTOBACKUP; # restore a server parameter file
STARTUP FORCE; # restart instance with restored server parameter file
-- =======================================================================
-- The V$X$DBGALERTEXT ==> V$ALERT_LOG :: View Config.
-- =======================================================================
desc X$DBGALERTEXT
SQL> create or replace view sys.v_$alert_log as SELECT * FROM x$dbgalertext;
View SYS.V_$ALERT_LOG created.
SQL> create public synonym v$alert_log for sys.v_$alert_log;
Synonym V$ALERT_LOG created.
SQL> grant SELECT on v$alert_log to c##USER;
Grant succeeded.
-- =======================================================================
-- Table X$DBGDIREXT - [diagnostic_dest]/diag :: --
-- =======================================================================
SELECT
lpad(' ', lvl, ' ') || logical_file file_name
FROM
x$dbgdirext
WHERE
rownum <= 20;
-- =======================================================================
-- MESSAGE_LEVEL [ 1: CRITICAL 2: INCIDENT_ERROR 3: ERROR ]
-- =======================================================================
SELECT message_text FROM x$dbgalertext WHERE message_level = 1;
SELECT message_text FROM x$dbgalertext WHERE message_type IN (2, 3);
-- =======================================================================
-- ERROR
-- =======================================================================
SELECT DISTINCT
message_text
FROM
x$dbgalertext
WHERE
originating_timestamp > sysdate - 2
AND message_text like '%ORA-00600%'
OR message_text like '%Fatal%';
SELECT
rownum "line",
message_text "error"
FROM
x$dbgalertext
WHERE
originating_timestamp > (sysdate - 5 / 1440)
AND message_text like '%ORA-%'
ORDER BY
originating_timestamp;
-- =============================================================
-- Todos as ultimas 200 linhas do ALERT do banco de dados
-- =============================================================
set lines 300
set pages 2000
col data for a20
col MESSAGE_TEXT for a120
SELECT
to_char (ORIGINATING_TIMESTAMP, 'DD-MM-YYYY HH24:MI') data,
message_text
FROM
x$dbgalertext
WHERE
indx > (SELECT COUNT(*) - 200 FROM x$dbgalertext );
set linesize 160 pagesize 200
col RECORD_ID for 9999999 head ID
col ORIGINATING_TIMESTAMP for a20 head Date
col MESSAGE_TEXT for a120 head Message
SELECT
record_id,
to_char(originating_timestamp, 'DD.MM.YYYY HH24:MI:SS'),
message_text
FROM
x$dbgalertext;
-- ==========================================================
-- ALERT LOG: Todos os erros ORA nas ultimas 24 horas
-- ==========================================================
set lines 300
set pages 2000
col data for a20
col MESSAGE_TEXT for a100
SELECT
to_char (ORIGINATING_TIMESTAMP, 'DD-MM-YYYY HH24:MI') data,
message_text
FROM
x$dbgalertext
WHERE
ORIGINATING_TIMESTAMP > (SYSDATE - 1)
AND message_text LIKE '%ORA-%';
-- ==========================================================
-- ALERT LOG: Todos os erros ORA nas ultimas 1 hora
-- ==========================================================
col TIMESTAMP for a22
col message_text for a100
SELECT DISTINCT
TO_CHAR(originating_timestamp, 'DD-MM-RRRR HH24:MI:SS') timestamp,
message_text
FROM
x$dbgalertext
WHERE
originating_timestamp > sysdate - 1 / 24
ORDER BY 1;
-- ==========================================================
-- ALERT LOG
-- ==========================================================
$ORACLE_BASE/diag/rdbms/$DB_UNIQUE_NAME/$ORACLE_SID/trace/
SQL> set lines 200
SQL> col name format a10
SQL> col value format a60
SQL> SELECT inst_id,name,value FROM v$diag_info WHERE name = 'Diag Trace';
INST_ID NAME VALUE
---------- ---------- ------------------------------------------------------
1 Diag Trace /u01/app/oracle/diag/rdbms/dbname/instance_name/trace
SQL> SHOW PARAMETER BACKGROUND_DUMP_DEST
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------------------
background_dump_dest string /u01/app/oracle/diag/rdbms/DB_UNIQUE_NAME/SID/trace
-- locate command
locate alert_$ORACLE_SID.log
-- Leitura -- (more/less/cat)
cat Alert_SID.log
tail -F Alert_SID.log
tail -f $ORACLE_BASE/diag/rdbms/dbname/instance_name/trace/alert_SID.log
-- Localizando arquivos de Trace
SQL> SELECT VALUE FROM V$DIAG_INFO;
-- Para determinar o arquivo de rastreamento para cada processo do banco de dados Oracle
SQL> SELECT PID, PROGRAM, TRACEFILE FROM V$PROCESS;
--For 9i and 10g
$ORACLE_BASE/admin/$ORACLE_SID/bdump/
-- ==========================================================
-- ALERT LOG - Limpeza
-- ==========================================================
find /u01/app/oracle/diag/rdbms/dbname/instance_name/trace -name "*.trc" -mtime +3 -exec rm {} \;
find /u01/app/oracle/diag/rdbms/dbname/instance_name/trace -name "*.trm" -mtime +3 -exec rm {} \;
find /u01/app/oracle/diag/rdbms/dbname/instance_name/trace -name "*.gz" -mtime +3 -exec rm {} \;
find /u01/app/oracle/diag/tnslsnr/hostname/listener_dbname/alert -name ""log*xml"" -mtime +3 -exec rm {} \;
(or)
find . -name "*.aud" -mtime +7 -exec rm -f {} \;
find /u01/app/oracle/diag/rdbms/dbname/instance_name/cdmp* -mtime +1 -exec rm {} \;
export ORACLE_SID=database
-- ==========================================================
-- Connect database as sysdba
-- ==========================================================
sqlplus / as sysdba
SELECT INSTANCE_NAME, STATUS, LOGINS FROM V$INSTANCE;
STARTUP MOUNT EXCLUSIVE RESTRICT FORCE
SELECT INSTANCE_NAME, STATUS, LOGINS FROM V$INSTANCE;
DROP DATABASE;
QUIT
-- =======================================================================
-- This SQL script identifies tables in an Oracle database with significant space wastage by comparing the physical size of table segments with the actual amount of data stored.
-- =======================================================================
SELECT
a.owner,
a.segment_name,
a.segment_type,
round(a.bytes / 1024 / 1024, 0) MBS,
round((a.bytes - (b.num_rows*b.avg_row_len) ) / 1024 / 1024, 0) WASTED
FROM
dba_segments a,
dba_tables b
WHERE
a.owner = b.owner
AND a.owner NOT LIKE 'SYS%'
AND a.segment_name = b.table_name
AND a.segment_type = 'TABLE'
GROUP BY
a.owner,
a.segment_name,
a.segment_type,
round(a.bytes / 1024 / 1024, 0),
round((a.bytes - (b.num_rows*b.avg_row_len) ) / 1024 / 1024, 0)
HAVING
round(bytes / 1024 / 1024, 0) > 100
ORDER BY
round(bytes / 1024 / 1024, 0) DESC
/
history
# Executar uma linha especifica
!3
# Remover uma linha especifica [-d]
history -d 7
# Limpar todo o historico
history -c
# Limpar todo o historico
history >> arquivo.txt
# Procurar um comando digitado
history | grep 'comando'
# Procurar um comando digitado
CTRL+R (Reverse-i-search)
# Repetir o ultimo comando
!!
-- ==========================================================
-- To disable automatic statistics gathering, use the DISABLE
-- ==========================================================
BEGIN
DBMS_AUTO_TASK_ADMIN.DISABLE (
client_name=>'auto optimizer stats collection',
operation=>NULL, window_name=>NULL);
END;
-- ==========================================================
-- To enable automatic statistics gathering, use the ENABLE
-- ==========================================================
BEGIN
DBMS_AUTO_TASK_ADMIN.ENABLE (
client_name=>'auto optimizer stats collection',
operation=>NULL, window_name=>NULL);
END;
-- ==========================================================
-- To view the status of AutoTask jobs
-- ==========================================================
SQL> SELECT client_name, status FROM dba_autotask_client;
CLIENT_NAME STATUS
-------------------------------------- --------
auto optimizer stats collection ENABLED
auto space advisor ENABLED
sql tuning advisor ENABLED
-- ==========================================================
-- Oracle query command to CHECK the SID (or instance name):
-- ==========================================================
SELECT sys_context('userenv', 'instance_name') FROM DUAL;
-- ==========================================================
-- Oracle query command TO CHECK database name (OR server host):
-- ==========================================================
SELECT sys_context('userenv', 'server_host') FROM DUAL;
-- ==========================================================
-- Verifica SPID a partir do SID
-- ==========================================================
SET echo off
SET long 50000
SET pages 1000
SET lines 150
COL username format a15
COL osuser format a20
COL cmd format a200
SELECT
P.SPID, S.SID, S.SERIAL#
FROM
gV$PROCESS P, gV$SESSION S
WHERE
P.ADDR = S.PADDR
AND
S.SID =1604;
SELECT
s.sid || ',' || s.serial# "SID/SERIAL",s.username,s.osuser,p.spid "OS PID",s.program
FROM
v$session s,v$process p
WHERE
s.paddr = p.addr
order by
to_number(p.spid)
-- ==========================================================
-- Verifica sql com o SID
-- ==========================================================
SET linesize 160
SET pagesize 66
COL c1 for a15
COL c1 heading "OS User"
COL c2 for a16
COL c2 heading "Oracle User"
COL b1 for a10
COL b1 heading "Unix PID"
COL b2 for 9999 justify left
COL b2 heading "ORA SID"
COL b3 for 999999 justify left
COL b3 heading "SERIAL#"
COL sql_text for a65
COL logon_time format a20
SET space 1
break on b1 nodup on c1 nodup on c2 nodup on b2 nodup on b3 skip 3
SELECT
c.spid b1,
b.osuser c1,
b.username c2,
b.sid b2,
b.serial# b3,
a.sql_text,
b.status
--,to_char(b.logon_time, 'DD-MON-YYYY HH24:MI:SS') logon_time
FROM
v$sqltext a, v$session b, v$process c
WHERE
a.address = b.sql_address
-- AND b.status = 'ACTIVE'
AND b.paddr = c.addr
AND a.hash_value = b.sql_hash_value
AND b.username IS NOT NULL
AND b.sid=1730
ORDER BY c.spid,a.hash_value,a.piece
-- ==========================================================
-- Verifica SQL com o PID
-- ==========================================================
SET linesize 400
SET pagesize 66
COL c1 for a15
COL c1 heading "OS User"
COL c2 for a16
COL c2 heading "Oracle User"
COL b1 for a10
COL b1 heading "Unix PID"
COL b2 for 9999 justify left
COL b2 heading "ORA SID"
COL b3 for 999999 justify left
COL b3 heading "SERIAL#"
COL sql_text for a65
COL logon_time format a20
SET space 1
break on b1 nodup on c1 nodup on c2 nodup on b2 nodup on b3 skip 3
SELECT
c.spid b1,
b.osuser c1,
b.username c2,
b.sid b2,
b.MACHINE,
b.serial# b3,
a.sql_text,
b.status,
b.logon_time,
to_char(b.logon_time, 'DD-MON-YYYY HH24:MI:SS') logon_time
FROM
v$sqltext a, v$session b, v$process c
WHERE a.address = b.sql_address
AND b.status = 'ACTIVE'
AND b.paddr = c.addr
AND a.hash_value = b.sql_hash_value
-- c.spid=29553
AND b.username is not null
ORDER BY c.spid,a.hash_value,a.piece;
-- ==========================================================
-- Verifica informacoes usuarios com o SPID
-- ==========================================================
COL "SID/SERIAL" format a10
COL username format a15
COL osuser format a15
COL program format a40
SELECT
s.sid || ',' || s.serial # "SID / SERIAL",
s.username,
s.osuser,
p.spid "OS PID",
s.program
FROM
v$session s,
v$process p
WHERE
s.paddr = p.addr
ORDER BY
to_number(p.spid);
-- ==========================================================
-- Mostra todos os Usuario Conectados
-- ==========================================================
SELECT
username,
sid || ',' || serial # "ID",
status,
last_call_et "Last Activity"
FROM
v$session
WHERE
username IS NOT NULL
ORDER BY
status DESC,
last_call_et DESC;
-- ==========================================================
-- Verifica um determinado processo &=???
-- ==========================================================
SELECT
a.sid SID,
a.serial # SERIAL #,
a.USERNAME,
osuser,
a.sql_id,
a.machine,
a.terminal,
a.program,
sql_text cmd
FROM
v$session a,
v$process b,
v$sqlarea c
WHERE
a.sql_address = c.address
AND a.paddr = b.addr
AND b.spid =&spid
ORDER BY 3,4;
-- ==========================================================
-- Verifica um determinado processo(exemplo 123456)
-- ==========================================================
SELECT
a.sid SID,
a.serial # SERIAL #,
a.USERNAME,
osuser,
a.sql_id,
a.machine,
a.terminal,
a.program,
a.status,
a.MODULE,
a.action
FROM
v$session a,
v$process b,
v$sqlarea c
WHERE
a.sql_address = c.address
AND a.paddr = b.addr
AND b.spid = 123456
ORDER BY 3,4;
SELECT
a.sid SID,
a.serial # SERIAL #,
a.USERNAME,
osuser,
a.sql_id,
a.machine,
a.terminal,
a.program,
a.status
FROM
v$session a,
v$process b,
v$sqlarea c
WHERE
a.sql_address = c.address
AND a.paddr = b.addr --AND a.sql_address = 'cxnww1xc46jh7'
AND a.sid = 490
ORDER BY 3,4;
SELECT
a.sid SID,
a.status,
sql_text
FROM
v $ session a,
v $ process b,
v $ sqlarea c
WHERE
a.sql_address = c.address
AND a.paddr = b.addr;
AND a.sid = 4271;
SELECT
a.sid SID,
a.status,
sql_text
FROM
v$session a,
v$process b,
v$sqlarea c
WHERE
a.sql_address = c.address
AND a.paddr = b.addr
AND a.sid = 123;
-- ==========================================================
-- Verifica todos os Processos
-- ==========================================================
SET line 600
SELECT
a.sid SID,
a.serial # SERIAL #,
a.USERNAME,
osuser,
sql_text cmd
FROM
gv$session a,
gv$process b,
gv$sqlarea c
WHERE
a.sql_address = c.address
AND a.paddr = b.addr;
-- ==========================================================
-- Verifica todos os Processos de Rollback
-- ==========================================================
COL machine for a10
COL logon for a20
COL username for a10
COL osuser for a10
COL "RB Segment Name" for a15
COL program for a42
SELECT
r.NAME "RB Segment Name",
dba_seg.size_mb,
DECODE(TRUNC(SYSDATE - LOGON_TIME), 0, NULL, TRUNC(SYSDATE - LOGON_TIME) || ' Days' || ' + ')
|| TO_CHAR(TO_DATE(TRUNC(MOD(SYSDATE - LOGON_TIME, 1) * 86400), 'SSSSS'), 'HH24:MI:SS') LOGON,
v$session.SID,
v$session.SERIAL #,
v$session.process,
v$session.USERNAME,
v$session.STATUS,
v$session.OSUSER,
v$session.MACHinE,
v$session.PROGRAM
FROM
v$lock l,
v$process p,
v$rollname r,
v$session,
(
SELECT
segment_name,
ROUND(bytes / (1024*1024), 2) size_mb
FROM
dba_segments
WHERE
segment_type = 'TYPE2 UNDO'
ORDER BY
bytes DESC
)
dba_seg
WHERE
l.SID = p.pid( + )
AND v$session.SID = l.SID
AND TRUNC (l.id1( + ) / 65536) = r.usn
AND l.TYPE( + ) = 'TX'
AND l.lmode( + ) = 6
AND r.NAME = dba_seg.segment_name --AND v$session.username = 'SYSTEM'
--AND status = 'inACTIVE'
ORDER BY
size_mb DESC;
-- ==========================================================
-- Executa o Explain
-- ==========================================================
SET pages 1200
SET lin 300
COL sql_text form a100
break on sql_id skip 1 on report
-- executa o explain informando o sql_id
DELETE FROM plan_table;
COMMIT;
SELECT *
FROM TABLE(dbms_xplan.display_cursor('cxnww1xc46jh7'));
SET echo off
SET long 50000
SET pages 1000
SET lines 150
COL username format a15
COL osuser format a20
COL cmd format a200
SELECT P.SPID, S.SID, S.SERIAL#
FROM gV$PROCESS P, gV$SESSION S
WHERE P.ADDR = S.PADDR
AND S.SID =1604;
SELECT
s.sid || ',
' || s.serial# "SID/SERIAL",
s.username,
s.osuser,
p.spid "OS PID",
s.program
FROM
v$session s,v$process p
WHERE
s.paddr = p.addr
order by
to_number(p.spid);
SELECT
name,
(space_limit/1024/1024) ||'MB' AS Space_Limit,
(space_used/1024/1024)||'MB' AS Space_Used
FROM
v$recovery_file_dest;
SELECT
s.sid,
username AS "User",
program,
module,
action,
logon_time "Logon",
l.*
FROM
v$session s, v$enqueue_lock l
WHERE
l.sid = s.sid
AND
l.type = 'CF'
AND
l.id1 = 0
AND
l.id2 = 2;
SELECT
SID,WAIT_TIME,
SECONDS_in_WAIT,
STATE,event
FROM
v$session_wait
WHERE
sid= 855
SELECT
SID,EVENT,
SUM(TOTAL_WAITS),
SUM(TOTAL_TIMEOUTS),
SUM(TIME_WAITED),
SUM(AVERAGE_WAIT),
MAX_WAIT
FROM
V$SESSION_EVENT
WHERE
sid= 855
GROUP BY
SID,EVENT,MAX_WAIT;
SET SERVEROUTPUT ON SIZE 1000000
declare
nls_1 varchar (20);
nls_2 varchar (20);
nls_3 varchar (20);
so varchar (100);
begin
SELECT banner into so FROM v$version WHERE banner like '%TNS%';
SELECT value inTO nls_1 FROM nls_databASe_parameters WHERE parameter IN ('NLS_CHARACTERSET');
SELECT value inTO nls_3 FROM nls_databASe_parameters WHERE parameter IN ('NLS_TERRITORY');
SELECT value inTO nls_2 FROM nls_databASe_parameters WHERE parameter IN ('NLS_LANGUAGE');
if so like '%Win%' then
dbms_output.put_line('SET NLS_LANG='||nls_2||'_'||nls_3||'.'||nls_1);
else
dbms_output.put_line('export NLS_LANG='||nls_2||'_'||nls_3||'.'||nls_1);
end if;
end;
/
SELECT
OWNER,SEGMENT_NAME,
SEGMENT_TYPE,
TABLESPACE_NAME,
BYTES/1024/1024,
NEXT_EXTENT/1024/1024,
EXTENTS,
MAX_EXTENTS
FROM
dba_segments
WHERE
SEGMENT_NAME='EDI40';
ALTER TABLE SAPR3.EDI40 storage (maxextents 600);
COL resource_name for a30
COL limit_value for a20
SELECT
resource_name,
current_utilization,
max_utilization,
limit_value
FROM
v$resource_limit
WHERE
resource_name IN ( 'sessions', 'processes');
TTITLE LEFT SKIP 1 "NUMERO DE REDO LOGS ESCRITOS POR DIA DO MES" SKIP 2
SET lines 200 PAGES 100
CLEAR COLUMNS
COL np NOPRinT
COL "00" FORM 099
COL "01" FORM 099
COL "02" FORM 099
COL "03" FORM 099
COL "04" FORM 099
COL "05" FORM 099
COL "06" FORM 099
COL "07" FORM 099
COL "08" FORM 099
COL "09" FORM 099
COL "10" FORM 099
COL "11" FORM 099
COL "12" FORM 099
COL "13" FORM 099
COL "14" FORM 099
COL "15" FORM 099
COL "16" FORM 099
COL "17" FORM 099
COL "18" FORM 099
COL "19" FORM 099
COL "20" FORM 099
COL "21" FORM 099
COL "22" FORM 099
COL "23" FORM 099
SELECT
TRUNC(first_time) np, TO_CHAR(first_time,'DD/MM-DY') "DIA",
SUM(DECODE(TO_CHAR(first_time,'HH24'),'00',1,0)) "00" ,
SUM(DECODE(TO_CHAR(first_time,'HH24'),'01',1,0)) "01" ,
SUM(DECODE(TO_CHAR(first_time,'HH24'),'02',1,0)) "02" ,
SUM(DECODE(TO_CHAR(first_time,'HH24'),'03',1,0)) "03" ,
SUM(DECODE(TO_CHAR(first_time,'HH24'),'04',1,0)) "04" ,
SUM(DECODE(TO_CHAR(first_time,'HH24'),'05',1,0)) "05" ,
SUM(DECODE(TO_CHAR(first_time,'HH24'),'06',1,0)) "06" ,
SUM(DECODE(TO_CHAR(first_time,'HH24'),'07',1,0)) "07" ,
SUM(DECODE(TO_CHAR(first_time,'HH24'),'08',1,0)) "08" ,
SUM(DECODE(TO_CHAR(first_time,'HH24'),'09',1,0)) "09" ,
SUM(DECODE(TO_CHAR(first_time,'HH24'),'10',1,0)) "10" ,
SUM(DECODE(TO_CHAR(first_time,'HH24'),'11',1,0)) "11" ,
SUM(DECODE(TO_CHAR(first_time,'HH24'),'12',1,0)) "12" ,
SUM(DECODE(TO_CHAR(first_time,'HH24'),'13',1,0)) "13" ,
SUM(DECODE(TO_CHAR(first_time,'HH24'),'14',1,0)) "14" ,
SUM(DECODE(TO_CHAR(first_time,'HH24'),'15',1,0)) "15" ,
SUM(DECODE(TO_CHAR(first_time,'HH24'),'16',1,0)) "16" ,
SUM(DECODE(TO_CHAR(first_time,'HH24'),'17',1,0)) "17" ,
SUM(DECODE(TO_CHAR(first_time,'HH24'),'18',1,0)) "18" ,
SUM(DECODE(TO_CHAR(first_time,'HH24'),'19',1,0)) "19" ,
SUM(DECODE(TO_CHAR(first_time,'HH24'),'20',1,0)) "20" ,
SUM(DECODE(TO_CHAR(first_time,'HH24'),'21',1,0)) "21" ,
SUM(DECODE(TO_CHAR(first_time,'HH24'),'22',1,0)) "22" ,
SUM(DECODE(TO_CHAR(first_time,'HH24'),'23',1,0)) "23"
FROM
v$loghist
GROUP BY
TRUNC(first_time), TO_CHAR(first_time,'DD/MM-DY')
ORDER
BY TRUNC(first_time);
TTITLE OFF
SELECT 'DROP TABLE ' || OWNER || '.' ||TABLE_NAME|| ' CASCADE CONSTRAINT; '
FROM dba_tables
WHERE OWNER = 'PONTO';
--WHERE OWNER IN ('CAUSO', 'CAUSU', 'TELEMAT', 'USUTCP01', 'USUTCP02', 'USUTCP03');
SELECT 'DROP ' ||OBJECT_TYPE|| ' ' || OWNER || '.' || OBJECT_NAME || ';'
FROM dba_objects WHERE object_type NOT IN ('TABLE','inDEX','DATABASE LinK')
AND OWNER = 'PONTO';
--AND OWNER IN ('CAUSO', 'CAUSU', 'TELEMAT', 'USUTCP01', 'USUTCP02', 'USUTCP03');
--'SYNONYM')
'PONTO', 'CAUSO', 'CAUSU', 'TELEMAT', 'USUTCP01', 'USUTCP02', 'USUTCP03'
CREATE OR REPLACE DIRECTORY DBATIVIT AS '/export/home/oracle/TAS000001433019';
expdp DIRECTORY=DBATIVIT DUMPFILE=FULL_ZDBDEV_20121002.DMP LOGFILE=FULL_ZDBDEV_20121002.LOG FULL=Y
impdp DIRECTORY=TIVIT DUMPFILE=catracAS.dmp LOGFILE=import_catracAS.log FULL=
impdp DIRECTORY=TIVIT DUMPFILE=ponto.dmp LOGFILE=import_ponto.log FULL=Y
-->> Linux<<--
dos2unix Script.txt > new_Script.txt
fuser /u01/oracle/oradata/softway/temp01.dbf
lsof | grep -i delete
SELECT 'datafile : '|| name AS FILES FROM v$datafile
UNION
SELECT 'tempfile : '|| name FROM v$tempfile
UNION
SELECT 'controlfile: '|| name FROM v$controlfile
UNION
SELECT 'logfile : '|| member FROM v$logfile;
ALTER database backup controlfile to trace;
SET pagesize 0
SET lines 300
!rm drop_objectos.sql
spo drop_objectos.sql
SELECT
'DROP ' || object_type || ' ' || owner || '.' || object_name || ' cAScade constraints;' AS COMANDO
FROM
dba_objects
WHERE
owner = 'CCA'
AND
object_type = 'TABLE'
ORDER BY
object_type, object_name;
SELECT
'DROP ' || object_type || ' ' || owner || '.' || object_name || ';' AS COMANDO
FROM
dba_objects
WHERE
owner = 'CCA'
AND
object_type IN ('FUNCTION','inDEX','LIBRARY','PACKAGE','PROCEDURE','SEQUENCE','TRIGGER','TYPE','VIEW')
ORDER BY
object_type, object_name;
spo off
!ls -ltr drop_objectos.sql
SELECT *
FROM dba_tab_privs
WHERE OWNER = 'sys'
AND TABLE_NAME = 'TABELA';
SELECT 'grant '||privilege||' on '||owner||'.'||table_name||' to '||grantee||';'
FROM dba_tab_privs
WHERE grantee = upper('&1')
ORDER BY grantee;
SELECT privilege, owner, table_name, grantee
FROM dba_tab_privs
WHERE grantee= 'ORWMSSEL'
//CONCEDER
SELECT 'grant ' ||privilege||' on '||owner||'.'||table_name||' to '||grantee||';' FROM dba_tab_privs p where p.owner = 'XXX' ORDER BY grantee;
//REVOGAR
SELECT 'REVOKE '||privilege||' on '||owner||'.'||table_name||' FROM '||grantee||';' FROM dba_tab_privs p where p.owner = 'XXX' ORDER BY grantee;
ttitle left skip 1 "QUANTIDADE DOS OBJETOS DO USUÁRIO" skip 2
SET lines 125 pages 300
clear columns
COL owner for a20
COL object_type for a20
SELECT
owner,
object_type,
status,
count(*) "TOTAL"
FROM
dba_objects
WHERE
owner IN ('PONTO', 'CAUSO', 'CAUSU', 'TELEMAT', 'USUTCP01', 'USUTCP02', 'USUTCP03')
--, 'CCACONTAB', 'CCAMKT', 'CCAAPLIC')
GROUP BY
owner, object_type, status
ORDER BY
owner, object_type;
ttitle off;
-- RECOMPILA TODOS OS OBJETOS
# exec sys.utl_recomp.recomp_serial();
SELECT status, count(*) FROM dba_objects GROUP BY status;
SELECT owner, status , count(*) FROM dba_objects WHERE status <> 'VALID' GROUP BY owner, status;
SELECT owner, object_name, object_type status FROM dba_objects WHERE status <> 'VALID' ORDER BY 1,3 ;
ttitle left skip 1 "QUANTIDADE DOS OBJETOS INVÁLIDOS" skip 2
SET lines 125 pages 300
clear columns
COL owner for a20
COL object_type for a20
SELECT owner,
object_type,
status,
count(*) "TOTAL"
FROM dba_objects
WHERE status <> 'VALID'
GROUP BY owner, object_type, status
ORDER BY owner, object_type;
ttitle off;
ttitle left skip 1 "LISTA DOS OBJETOS INVÁLIDOS" skip 2
SET pagesize 300
SET lines 125
COL owner for a30
COL object_type for a20
COL object_name for a40
SELECT owner,
object_name,
object_type,
status
FROM dba_objects
WHERE status='inVALID'
AND OWNER = 'BIL'
ORDER BY owner, object_name, object_type;
ttitle off;
SELECT 'ALTER '
|| OBJECT_TYPE
|| ' '
|| OWNER || '.'
|| OBJECT_NAME
|| ' COMPILE;'
FROM
DBA_OBJECTS
WHERE STATUS <> 'VALID';
SELECT line,text FROM dba_source WHERE NAME ='P_ABTCCAPER';
SET linesize 2000;
SET pagesize 1000;
SET long 9999999;
SET ECHO off;
SET FEED off;
SET HEAD off;
SET time off;
COLUMN DDL FORMAT a9999;
exec dbms_metadata.SET_transform_param(dbms_metadata.session_transform,'SQLTERMinATOR',true);
SELECT
dbms_metadata.get_ddl('PROCEDURE','KILL_SESSION_FACMUTUO','SYSTEM') "DDL"
FROM
dual;
SPOOL OFF
SET FEED on;
SET HEAD on;
SET time on;
SELECT 'create '||DECODE(U.NAME,'PUBLIC','public ')||'databASe link '||CHR(10)
||DECODE(U.NAME,'PUBLIC',Null, U.NAME||'.')|| L.NAME||chr(10)
||'connect to ' || L.USERID || ' identified by '
||L.PASSWORD||' using ''' || L.host || ''''
||chr(10)||';' TEXT
FROM sys.link$ L, sys.user$ U
WHERE L.OWNER# = U.USER#;
SET lines 200;
SET pages 200;
SELECT
'create '
||decode(owner#,1,'public ',' ')
||'databASe link '
||NAME||' connect to '
||USERID||' identified by values '''
||password||''' using '''
||host||''';'
FROM
sys.link$;
COL state for a10
COL name for a10
COL failgroup for a10
COL label for a15
COL path for a15
SET lines 200
SET pages 200
SELECT
GROUP_NUMBER,
DISK_NUMBER,
MOUNT_STATUS,
MODE_STATUS,
STATE,
REDUNDANCY,
TOTAL_MB,
FREE_MB,
NAME,
FAILGROUP,
LABEL,
PATH,
to_char(MOUNT_DATE,'DD-MM-YYYY HH24/:MI/:SS')
FROM
v$ASM_disk
/
ALTER tablespace ADD datafile SIZE M;
SET lines 200 pages 200
COL path format a30
COL name format a20
COL state format a10
COL mount_status format a10
SET feedback off
SELECT
GROUP_NUMBER,
NAME,
TOTAL_MB,
FREE_MB,
STATE,
OFFLINE_DISKS,
round((FREE_MB / TOTAL_MB)*100, 1) " % FREE"
FROM
v$ASM_diskgroup;
------------------------------------------------------------------
SET pagesize 5555
SET linesize 500
SELECT
name,
total_mb - free_mb "OCUP_MB",
free_mb,
total_mb,
round((total_mb - free_mb)*100 / TOTAL_MB, 2) "PER_OCUP",
round(FREE_MB*100 / TOTAL_MB, 2) "PER_FREE"
FROM
v$ASM_diskgroup;
TTITLE LEFT SKIP 1 "ASM DISK GROUPS" SKIP 2
SET LINES 120 PAGES 999
CLEAR COLUMNS
COLUMN "HOSTNAME" FORMAT a15
COLUMN "INSTANCE" FORMAT a10
COLUMN "INST_CAPTURA" FORMAT a18
COLUMN "GROUP" FORMAT 999
COLUMN "GROUP_NAME" FORMAT a15
COLUMN "STATE" FORMAT a10
COLUMN "TYPE" FORMAT a7
COLUMN "TOTAL_MB" FORMAT 9,999,000
COLUMN "FREE_MB" FORMAT 9,999,000
SELECT
host_name "HOSTNAME",
instance_name "INSTANCE",
SUBSTR(TO_CHAR(sysdate,' dd/mm/yy hh24:mi:ss'),1,20) "INST_CAPTURA",
group_number "GROUP",
name "GROUP_NAME",
state "STATE",
type "TYPE",
total_mb "TOTAL_MB",
free_mb "FREE_MB" ,
DECODE(100 - ceil(FREE_MB/TOTAL_MB*100), NULL, 100, 100 - ceil(FREE_MB/TOTAL_MB*100)) "% USADO"
FROM v$ASm_diskgroup, v$instance;
TTITLE OFF
select * from V$log;
select * from V$logFile;
select * from V$log_history;
SET lINes 200
SET pagesize 100
COL owner for a10
COL job_name for a30
COL actual_start_date for a20
COL STATUS for a10
COL RUN_DURATION for a20
COL additional_INfo for a60
SELECT
owner,
job_name,
status,
error#,
TO_CHAR(actual_start_date, 'dd/mm/yyyy hh24:mi:ss') actual_start_date,
run_duration, additional_info
FROM
dba_scheduler_job_run_details
WHERE
job_name ='SYNC'
ORDER BY 5;
TTITLE LEFT SKIP 1 "JOBS" SKIP 2
SET LINES 160 PAGES 100
CLEAR COLUMNS
COL job FORM 999999
COL what FORM a35 TRUNC
COL INterval FORM a45
COL schema_user FORM a15
COL failures FORM 9999
ALTER SESSION SET nls_date_format='dd/mm/yyyy hh24:mi:ss';
SELECT job,
schema_user,
lASt_date,
next_date,
INterval,
broken,
failures,
what
FROM dba_jobs
ORDER BY job;
TTITLE OFF
/*-- Script – List status of all submitted DBMS jobs --*/
SET pagesize 100
SET lINesize 120
ttitle -
center 'Submitted DBMS Jobs' skip 2
COL job format 99999 headINg 'job#'
COL subu format a10 headINg 'Submitter' trunc
COL lsd format a5 headINg 'LASt|Ok|Date'
COL lst format a5 headINg 'LASt|Ok|Time'
COL nrd format a5 headINg 'Next|Run|Date'
COL nrt format a5 headINg 'Next|Run|Time'
COL fail format 999 headINg 'Errs'
COL ok format a2 headINg 'Ok'
SELECT
job,
log_user subu,
what proc,
to_char(lASt_date,'MM/DD') lsd,
substr(lASt_sec,1,5) lst,
to_char(next_date,'MM/DD') nrd,
substr(next_sec,1,5) nrt,
failures fail,
decode(broken,'Y','N','Y') ok
FROM
sys.dba_jobs
WHERE lASt<>'OK';
/*---- JOBS EM EXECUÇÃO ----*/
TTITLE LEFT SKIP 1 "JOBS EM EXECUÇÃO" SKIP 2
SET LINES 200 PAGES 100
CLEAR COLUMNS
COL job FORM 9999
COL INterval FORM a40
COL schema_user FORM a15
COL failures FORM 9999
ALTER SESSION SET nls_date_format='dd/mm/yyyy hh24:mi:ss';
SELECT sid,
job,
lASt_date,
lASt_sec,
this_date,
this_sec,
failures,
instance
FROM dba_jobs_running
ORDER BY job;
TTITLE OFF
ANALYZE TABLE [OWNER].[TABELA] COMPUTE STATISTICS;
select 'Analyze Table '||table_name||' compute statistics;' from user_tables;
select 'Analyze Index '||index_name||' compute statistics;' from user_indexes;
exec dbms_system.set_sql_trace_in_session(2087,58516,TRUE);
exec dbms_system.set_sql_trace_in_session(2087,58516,TRUE);
exec sys.dbms_system.set_sql_trace_in_session(17,49302,FALSE);
tkprof sys=no
ALTER SESSION SET nls_date_format='dd/mm/yy hh24:mi';
SET lines 200 trims on
SET pagesize 5000
col username for a15
col osuser for a15
col machine for a30
col client_info for a20
col module for a20
col logon_time for a16
SELECT p.spid as "ID_SO",
s.sid as "ID_BD",
s.serial#,
s.username,
s.osuser,
s.machine,
s.client_info,
s.module,
s.status,
-- s.inst_id,
s.logon_time
FROM gv$session s,
v$process p
WHERE s.paddr = p.addr
AND s.status='ACTIVE'
-- AND s.sid=18
-- AND p.spid=1672
-- AND s.username in ('M554670','M5568714','ADMGID')
/
/* ===========> SESSÕES ATIVAS - ( RAC ) <=========== */
TTITLE SKIP 1 "SESSÕES AMBIENTE RAC" SKIP 2
SET LINES 250 PAGES 1000
CLEAR COLUMNS
COLUMN log_time FORMAT a19
COLUMN sid FORMAT 9999
COLUMN username FORMAT a15
COLUMN osuser FORMAT a20
COLUMN serial# FORMAT 99999
COLUMN spid FORMAT a10
COLUMN lockwait FORMAT 99999
COLUMN MODULE format a10 trunc
COLUMN LAST_CALL_ET format 9999
COLUMN action format a10 trunc
COLUMN St FORMAT a2
COLUMN cx FORMAT a2
COLUMN machine FORMAT a10 TRUNC
COLUMN program FORMAT a10 TRUNC
SELECT *
FROM (SELECT a.sid,
a.serial#,
a.username,
SUBSTR(TO_CHAR(a.logon_time,' dd/mm/yy hh24:mi:ss'),1,20) log_time,
a.process,
a.osuser,
b.spid,
SUBSTR(a.status,1,2) st,
a.lockwait,
a.MODULE, a.action, a.LAST_CALL_ET/60 LAST_CALL,
DECODE(a.server,'NONE','',SUBSTR(a.server,1,2)) cx,
a.machine,
a.program,
a.ROW_WAIT_BLOCK#
FROM gv$session a, gv$process b
WHERE a.paddr = b.addr
--AND a.username = 'TS_CONSULTA'
AND a.sid = 150
--AND b.spid = 15281
--AND a.lockwait IS NOT NULL
--AND SUBSTR(a.status,1,1) = 'A'
ORDER BY 4 DESC);
--ORDER BY 4 ASC);
TTITLE OFF;
/* -- GERA COMANDO PARA MATAR AS SESSOES EM LOCK -- */
-- AND SUBSTR(a.status,1,1) = 'I'
/*-- LISTA SESSOES QUE ESTÃO BLOQUEANDO AS SESSOES -- */
SET lines 300
SET pages 1000
COLUMN blocker format a25
COLUMN blockee format a25
COLUMN sid_serial format a10
SELECT
(SELECT username || ' - ' || osuser FROM v$session WHERE sid=a.sid) blocker, a.sid || ', ' ||
(SELECT serial# FROM v$session WHERE sid=a.sid) sid_serial,' Está Bloqueando ',
(SELECT username || ' - ' || osuser FROM v$session WHERE sid=b.sid) blockee, b.sid || ', ' ||
(SELECT serial# FROM v$session WHERE sid=b.sid) sid_serial
FROM v$lock a, v$lock b
WHERE a.block = 1
AND b.request > 0
AND a.id1 = b.id1
AND a.id2 = b.id2;
ALTER SYSTEM kill SESSION '&SID, &SERIAL' IMMEDIATE;
/* ------------------------------------------------
ALTER SYSTEM kill SESSION '1604,382' IMMEDIATE;
ALTER SYSTEM kill SESSION '159,3422' IMMEDIATE;
ALTER SYSTEM kill SESSION '159,3413' IMMEDIATE;
--------------------------------------------------- */
/* =========== LISTA SESSOES QUE estao inativas ===========*/
SELECT v$session.sid, v$session.serial#, v$session.user#, v$session.username, v$session.osuser,
v$session_wait.seconds_in_wait,v$session.status, v$session_wait.state
FROM
v$session, v$session_wait
WHERE
v$session.sid = v$session_wait.sid AND
v$session.status in ('INACTIVE', 'KILLED')
SET echo off
SET long 50000
SET pages 1000
SET lines 1000 trims on
col USR_BANC format a15;
col QUERY format a50
col SO_PROC format a15
COLUMN sid format 999999
COLUMN serial# format 9999999999
COLUMN logon format a15
SELECT
a.sid SID,
a.sql_id,
a.serial# SERIAL#,
a.inst_id,
a.username USR_BANC,
b.spid SO_PROC,
to_char(logon_time,'dd/mm/yy hh24:mi') logon,
c.sql_text QUERY
FROM
gv$session a, gv$process b, gv$sqlarea c
WHERE
a.sql_address=c.address
AND
a.paddr=b.addr
AND
a.STATUS = 'ACTIVE';
--AND a.username not in ('SYSTEM','SYS') AND A.USERNAME IS NOT NULL;
/*====> VERIFICAR SESSÕES COM VALORES ALTO NA COLUNA LAST_CALL_ET E IDENTIFICAR A QUERIE <=====*/
SELECT sid,serial#, username, last_call_et
FROM v$session WHERE status='ACTIVE'
AND USERNAME IS NOT NULL
order by last_call_et desc;
SELECT sid,serial#, username, last_call_et
FROM v$session WHERE USERNAME IS NOT NULL;
/* ---- VERIFICAR NA V$SESSION_WAIT ---- */
SET LINESIZE 200
SET PAGESIZE 1000
COLUMN username FORMAT A20
COLUMN event FORMAT A30
SELECT NVL(s.username, '(oracle)') AS username,
s.sid,
s.serial#,
sw.event,
sw.wait_time,
sw.seconds_in_wait,
sw.state
FROM v$session_wait sw,
v$session s
WHERE
s.sid = sw.sid
AND
sw.event not like 'SQL%'
AND
sw.event not like 'rdbms%'
ORDER BY
sw.seconds_in_wait DESC;
SELECT
sql_id,plan_hash_value,
SUM(elapsed_time_total)/SUM(executions_total)/1000000 avg_elapsedt_secs
FROM
dba_hist_sqlstat
WHERE
sql_id = '7jmmw9f9749q6'
GROUP BY
sql_id,plan_hash_value ;
SET linesize 180
SET pagesize 100
SELECT * FROM table( DBMS_XPLAN.display_cursor('7jmmw9f9749q6',NULL, 'ALL'));
/* ----> I/O de cada processo <---- */
SELECT
A.SID,
A.USERNAME,
A.OSUSER,
D.SPID,
C.NAME,
B.VALUE
FROM
V$SESSION A,
V$SESSTAT B,
V$STATNAME C,
V$PROCESS D
WHERE
A.SID = B.SID
AND
A.PADDR = D.ADDR
AND
B.STATISTIC# = C.STATISTIC#
AND
C.NAME LIKE 'PHYSICAL%'
AND
VALUE > 1000
AND
A.SID=&SID
ORDER BY
B.VALUE;
DECLARE
Porta NUMBER;
BEGIN
Porta := dbms_xdb_config.gethttpport from Dual;
END;
/
SELECT dbms_xdb_config.gethttpport FROM dual;
GETHTTPSPORT
------------
5500
EXEC DBMS_XDB_CONFIG.sethttpsport(5500);
# alter system enable restricted session;
# alter system disable restricted session;
SELECT /*+ RULE */
S1.STATUS,
substr(s1.username,1,12) "LOCADA(WAINTTING_USER)",
substr(s1.osuser,1,8) OS_LOCADA,
substr(to_char(w.session_id),1,5) Sid_LOCADA,
P1.spid,
substr(s2.username,1,12) "LOCANDO(HOLDING_User)",
S2.STATUS ,
substr(s2.osuser,1,8) OS_LOCANDO,
to_number(substr(to_char(h.session_id),1,5)) Sid_LOCANDO,
'kill -9 ' ,P2.spid PID
FROM sys.v_$process P1,
sys.v_$process P2,
sys.v_$session S1,
sys.v_$session S2,
sys.dba_lock w,
sys.dba_lock h
WHERE h.mode_held != 'None'
AND h.mode_held != 'Null'
AND w.mode_requested != 'None'
AND w.lock_type (+) = h.lock_type
AND w.lock_id1 (+) = h.lock_id1
AND w.lock_id2 (+) = h.lock_id2
AND w.session_id = S1.sid (+)
AND h.session_id = S2.sid (+)
AND S1.paddr = P1.addr (+)
AND S2.paddr = P2.addr (+)
ORDER BY 7;
set lines 200
col datafile for a60
col file_name for a50
SELECT dfs.tablespace_name tablespace,
ddf.file_name datafile,
dfs.bytes / 1024 / 1024 free_mb,
dfs.block_id start_block,
(dfs.block_id + dfs.blocks) - 1 end_block,
ddf.blocks last_files_block
from dba_free_space dfs, dba_data_files ddf
where dfs.tablespace_name = upper('&tablespace')
and dfs.file_id = ddf.file_id
order by ddf.file_name, dfs.block_id;
/*-- --*/
select
TABLE_NAME,
ROUND((AVG_ROW_LEN * NUM_ROWS / 1024), 2) SIZE_KB
from
dba_TABLES
where
TABLE_NAME = 'LF_DETREL';
select 'alter database datafile ''' || file_name || ''' resize ' ||
ceil( (nvl(hwm,1)*8192*1.2)/1024/1024 ) || 'm;' cmd
from dba_data_files a,
( select file_id, max(block_id+blocks-1) hwm
from dba_extents
group by file_id ) b
where a.file_id = b.file_id(+)
and ceil( (nvl(hwm,1)*8192*1.2)/1024/1024 ) < ceil( blocks*8192/1024/1024)
and ceil( (nvl(hwm,1)*8192*1.2)/1024/1024 ) > 100;
set lines 1000
set pages 2000
col tablespace_name for a24
col name for a60
col Total(Mb) for a20
col status1 for a7
col status2 for a7
col status3 for a9
col online_status for a10
col st_backup for a10
col recover for a7
col error for a10
col "FILE#" for 9999
SELECT df.tablespace_name,
d.FILE#,
d.NAME,
df.autoextensible,
to_char(round(df.bytes/1024/1024,0),99999999.99) "Total(Mb)",
d.status VDTFILE,
df.STATUS DDTFILE,
dh.status HDTFILE,
--df.online_status,
b.STATUS st_backup,
dh.RECOVER
--dh.ERROR
from v$datafile d,
dba_data_files df,
v$backup b,
v$datafile_header dh
where
d.FILE# = dh.FILE#(+)
and d.FILE# = b.FILE#(+)
and d.FILE# = df.file_id(+)
order by df.tablespace_name, d.NAME;
and df.tablespace_name LIKE '&APPS_TS_TX_IDX';
alter database datafile [datafile] resize 4000m;
select
a.tablespace_name,
a.file_id,
a.block_id,
a.blocks,
b.block_id
from dba_free_space a, dba_free_space b
where
a.tablespace_name=b.tablespace_name and
a.file_id=b.file_id and
a.block_id + a.blocks= b.block_id and
A.tablespace_name != 'TEMP' and
b.tablespace_name != 'TEMP';
SELECT
TABLESPACE_NAME,
INITIAL_EXTENT,
NEXT_EXTENT,
PCT_INCREASE
FROM
DBA_TABLESPACES
WHERE
TABLESPACE_NAME='USERS'
SET LINESIZE 190
COLUMN spid FORMAT A10
COLUMN username FORMAT A14
COLUMN PROGRAM FORMAT A40
COLUMN PROGRAM MACHINE A40
SELECT s.inst_id,
s.sid,
s.serial#,
p.spid,
s.username,
s.program, s.status, s.machine, to_char(s.LOGON_TIME,'dd-mm-yyyy HH24:MM') LOGON_TIME
FROM gv$session s
JOIN gv$process p ON p.addr = s.paddr AND p.inst_id = s.inst_id
WHERE s.type != 'BACKGROUND' order by s.STATUS;
Clear Columns Computes Breaks
set lines 200
set pages 200
col "Total(Mb)" for a10
col "% Free" for a10
compute sum of "Total(Mb)" on report
compute sum of "Free(Mb)" on report
break on report
SELECT t.tablespace_name,
ts.contents,
substr(ts.status,0,7) STATUS,
to_char(round(nvl(t.bytes,0)/1024/1024,1)) "Total(Mb)",
round((nvl(nvl(f.free,ft.free),0)/1024/1024),1) "Free(Mb)",
to_char(round((nvl(f.free,ft.free)*100)/t.bytes,1),999) "% Free"
FROM (SELECT d.tablespace_name, sum(d.bytes) bytes FROM dba_data_files d GROUP BY tablespace_name
UNION
SELECT d.tablespace_name, sum(d.bytes) bytes FROM dba_TEMP_files d GROUP BY tablespace_name) t,
(SELECT tablespace_name,sum(bytes) free FROM dba_free_space GROUP BY tablespace_name) f,
(SELECT TABLESPACE_NAME, sum(bytes_free) free from V$TEMP_SPACE_HEADER group by tablespace_name) ft, dba_tablespaces ts
WHERE t.tablespace_name = f.tablespace_name(+)
AND t.tablespace_name = ft.tablespace_name(+)
AND t.tablespace_name = ts.tablespace_name
AND t.tablespace_name LIKE '%&Tablespace%'
ORDER BY 6;
/*-- LOGS DO NETBACKUP--*/
/usr/openv/netbackup/logs/user_ops/dbext/logs
SELECT TO_CHAR(sysdate,'dd/mm/yyyy hh24:mi:ss') instante FROM dual;
select SID,WAIT_TIME,SECONDS_IN_WAIT,STATE,event from gv$session_wait where sid= 661
select
SID,
EVENT,
sum(TOTAL_WAITS),
sum(TOTAL_TIMEOUTS),
sum(TIME_WAITED),
sum(AVERAGE_WAIT),
MAX_WAIT
from gV$SESSION_EVENT
where sid=661
group by SID,EVENT,MAX_WAIT;
/*----- waits oracle ------*/
select a.sid,
b.username,
a.wait_class,
a.total_waits,
round((a.time_waited / 100),2) time_waited_secs
from sys.v_$session_wait_class a,
sys.v_$session b
where b.sid = a.sid and
b.username is not null and
a.wait_class != 'Idle' and
a.sid='578'
order by 5 desc;
col startup_time for a20
col instance_name for a15
col host_name for a30
SET lines 200
SELECT instance_name, i.host_name, to_char(startup_time,'dd/mm/yyyy hh24:mi:ss') startup_time,
d.log_mode, i.status, i.logins, d.open_mode
FROM gv$instance i,gv$database d;
col startup_time for a20
col instance_name for a15
col host_name for a30
SET lines 200
SELECT distinct
instance_name,
i.host_name,
to_char(startup_time,'dd/mm/yyyy hh24:mi:ss') startup_time,
d.log_mode,
i.status,
i.logins,
d.open_mode
FROM gv$instance i,gv$database d;
set linesize 2000;
set pagesize 1000;
set long 9999999;
set ECHO off;
set FEED off;
set HEAD off;
set time off;
COLUMN DDL FORMAT a9999;
spool PAGAMENTO_CONTA_CORRENTE.bkp
exec dbms_metadata.set_transform_param(dbms_metadata.session_transform,'SQLTERMINATOR',true);
select dbms_metadata.get_ddl('TABLE','PAGAMENTO_CONTA_CORRENTE','TS') "DDL" from dual;
spool off
set FEED on;
set HEAD on;
set time on;
---------------------------------------------------------------------------------------
set lines 10000 pages 10000 long 99999999 longc 99999999 trimspool on echo on
spool P_CALC_BASE_INDIC_backup.txt
select dbms_metadata.get_ddl('PROCEDURE','P_CALC_BASE_INDIC','AESPROD') from dual;
spool off;
Exec dbms_ddl.alter_compile ( 'PACKAGE BODY' ,'MAR_ITF_INTEGRACAO_FAT_RET_SAP','TS');
/* Reconstroi enterprise manager */
emca -config dbcontrol db -repos recreate
select plan_table_output from table(dbms_xplan.display('plan_table','300','serial'));
explain plan SET STATEMENT_ID='27' for select distinct
col SPID for 99999999
col USER_SO for a10
col USER_DB for a10
col SID for 99999
col SERIAL for 999999
select b.sid SID,
b.serial# SERIAL,
b.username USER_DB,
b.osuser USER_SO,
c.spid SPID,
b.machine HOST_CLIENT,
b.status STATUS,
to_char(b.logon_time, 'DD-MON-YYYY HH24:MI:SS') LOGON,
b.inst_id INST_RAC
from gv$session b,
gv$process c
where b.paddr = c.addr
and b.inst_id = c.inst_id
and b.username is not null
-- and STATUS='ACTIVE'
and SID=15044
order by c.spid;
select
s.SID,
p.spid,
piece,
s.status,
to_char(s.logon_time,'DD/MM/YYYY HH24:Mi:SS') QUANDO,
c.sql_text
from
gv$session s,
gv$process p,
gV$sqltext c
where c.address = s.sql_address
and s.paddr = p.addr(+)
group by s.sid,p.spid,piece,s.status,s.logon_time,c.sql_text
order by s.sid, piece;
CREATE USER usuario
IDENTIFIED BY senha
DEFAULT TABLESPACE users
TEMPORARY TABLESPACE temp
QUOTA UNLIMITED ON users
PROFILE default
PASSWORD EXPIRE
ACCOUNT UNLOCK;
SELECT substr(DECODE(request,0,'Bloqueador: ','Bloqueado: ')||sid,1,20) sessao,
id1, id2, lmode, request, type, inst_id instance FROM GV$LOCK
WHERE (id1, id2, type) IN
(SELECT id1, id2, type FROM GV$LOCK WHERE request>0)
ORDER BY id1, request;
########################
SELECT s.inst_id,
s.sid,
s.serial#,
p.spid,
s.username,
s.program
FROM gv$session s
JOIN gv$process p ON p.addr = s.paddr AND p.inst_id = s.inst_id
WHERE s.username='SADMIN';
SET LINESIZE 100
COLUMN spid FORMAT A10
COLUMN username FORMAT A10
COLUMN program FORMAT A45
SELECT s.inst_id,
s.sid,
s.serial#,
p.spid,
s.username,
s.program
FROM gv$session s
JOIN gv$process p ON p.addr = s.paddr AND p.inst_id = s.inst_id
WHERE s.type != 'BACKGROUND'
AND s.username='CON13673';