Oracle feature usage ....
col currently_used for a15
col name format a60
col detected_usages format 999999999999
select u1.name, u1.version ,u1.currently_used , u1.detected_usages 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;
force to update above view default update time 1 week
alter session set nls_date_format='DD-MM-YYYY HH24:mi' ;
SELECT MAX(last_usage_date) last_update_time FROM dba_feature_usage_statistics;
LAST_UPDATE_TIME
----------------
04-03-2018 05:26
SQL> EXEC DBMS_FEATURE_USAGE_INTERNAL.exec_db_usage_sampling(SYSDATE);
PL/SQL procedure successfully completed.
alter session set nls_date_format='DD-MM-YYYY HH24:mi' ;
SELECT sysdate, MAX(last_usage_date) last_update_time FROM dba_feature_usage_statistics;
SYSDATE LAST_UPDATE_TIME
---------------- ----------------
06-03-2018 03:36 06-03-2018 03:34
Database Licensing Information User Manual
https://docs.oracle.com/database/121/DBLIC/editions.htm#DBLIC109
https://docs.oracle.com/cd/E11882_01/license.112/e47877/editions.htm#DBLIC116
http://anuj-singh.blogspot.co.uk/2011_11_21_archive.html
Database Options/Management Packs Usage Reporting for Oracle Databases 11gR2, 12c and 12cR2 (Doc ID 1317265.1)
select product
, decode(usage, 'NO_USAGE','NO', usage ) "Used"
, last_sample_date
, first_usage_date
, last_usage_date
------- following sql is based on options_packs_usage_statistics.sql --> MOS Note 1317265.1
from (
with
MAP as (
-- mapping between features tracked by DBA_FUS and their corresponding database products (options or packs)
select '' PRODUCT, '' feature, '' MVERSION, '' CONDITION from dual union all
SELECT 'Active Data Guard' , 'Active Data Guard - Real-Time Query on Physical Standby' , '^11\.2|^12\.' , ' ' from dual union all
SELECT 'Active Data Guard' , 'Global Data Services' , '^12\.' , ' ' from dual union all
SELECT 'Advanced Analytics' , 'Data Mining' , '^11\.2|^12\.' , ' ' from dual union all
SELECT 'Advanced Compression' , 'ADVANCED Index Compression' , '^12\.' , 'BUG' from dual union all
SELECT 'Advanced Compression' , 'Advanced Index Compression' , '^12\.' , 'BUG' from dual union all
SELECT 'Advanced Compression' , 'Backup HIGH Compression' , '^11\.2|^12\.' , ' ' from dual union all
SELECT 'Advanced Compression' , 'Backup LOW Compression' , '^11\.2|^12\.' , ' ' from dual union all
SELECT 'Advanced Compression' , 'Backup MEDIUM Compression' , '^11\.2|^12\.' , ' ' from dual union all
SELECT 'Advanced Compression' , 'Backup ZLIB Compression' , '^11\.2|^12\.' , ' ' from dual union all
SELECT 'Advanced Compression' , 'Data Guard' , '^11\.2|^12\.' , 'C001' from dual union all
SELECT 'Advanced Compression' , 'Flashback Data Archive' , '^11\.2\.0\.[1-3]\.' , ' ' from dual union all
SELECT 'Advanced Compression' , 'Flashback Data Archive' , '^(11\.2\.0\.[4-9]\.|12\.)' , 'INVALID' from dual union all -- licensing required by Optimization for Flashback Data Archive
SELECT 'Advanced Compression' , 'HeapCompression' , '^11\.2|^12\.1' , 'BUG' from dual union all
SELECT 'Advanced Compression' , 'HeapCompression' , '^12\.[2-9]' , ' ' from dual union all
SELECT 'Advanced Compression' , 'Heat Map' , '^12\.1' , 'BUG' from dual union all
SELECT 'Advanced Compression' , 'Heat Map' , '^12\.[2-9]' , ' ' from dual union all
SELECT 'Advanced Compression' , 'Hybrid Columnar Compression Row Level Locking' , '^12\.' , ' ' from dual union all
SELECT 'Advanced Compression' , 'Information Lifecycle Management' , '^12\.' , ' ' from dual union all
SELECT 'Advanced Compression' , 'Oracle Advanced Network Compression Service' , '^12\.' , ' ' from dual union all
SELECT 'Advanced Compression' , 'Oracle Utility Datapump (Export)' , '^11\.2|^12\.' , 'C001' from dual union all
SELECT 'Advanced Compression' , 'Oracle Utility Datapump (Import)' , '^11\.2|^12\.' , 'C001' from dual union all
SELECT 'Advanced Compression' , 'SecureFile Compression (user)' , '^11\.2|^12\.' , ' ' from dual union all
SELECT 'Advanced Compression' , 'SecureFile Deduplication (user)' , '^11\.2|^12\.' , ' ' from dual union all
SELECT 'Advanced Security' , 'ASO native encryption and checksumming' , '^11\.2|^12\.' , 'INVALID' from dual union all -- no longer part of Advanced Security
SELECT 'Advanced Security' , 'Backup Encryption' , '^11\.2' , ' ' from dual union all
SELECT 'Advanced Security' , 'Backup Encryption' , '^12\.' , 'INVALID' from dual union all -- licensing required only by encryption to disk
SELECT 'Advanced Security' , 'Data Redaction' , '^12\.' , ' ' from dual union all
SELECT 'Advanced Security' , 'Encrypted Tablespaces' , '^11\.2|^12\.' , ' ' from dual union all
SELECT 'Advanced Security' , 'Oracle Utility Datapump (Export)' , '^11\.2|^12\.' , 'C002' from dual union all
SELECT 'Advanced Security' , 'Oracle Utility Datapump (Import)' , '^11\.2|^12\.' , 'C002' from dual union all
SELECT 'Advanced Security' , 'SecureFile Encryption (user)' , '^11\.2|^12\.' , ' ' from dual union all
SELECT 'Advanced Security' , 'Transparent Data Encryption' , '^11\.2|^12\.' , ' ' from dual union all
SELECT 'Change Management Pack' , 'Change Management Pack' , '^11\.2' , ' ' from dual union all
SELECT 'Configuration Management Pack for Oracle Database' , 'EM Config Management Pack' , '^11\.2' , ' ' from dual union all
SELECT 'Data Masking Pack' , 'Data Masking Pack' , '^11\.2' , ' ' from dual union all
SELECT '.Database Gateway' , 'Gateways' , '^12\.' , ' ' from dual union all
SELECT '.Database Gateway' , 'Transparent Gateway' , '^12\.' , ' ' from dual union all
SELECT 'Database In-Memory' , 'In-Memory Aggregation' , '^12\.' , ' ' from dual union all
SELECT 'Database In-Memory' , 'In-Memory Column Store' , '^12\.1\.0\.2\.0' , 'BUG' from dual union all
SELECT 'Database In-Memory' , 'In-Memory Column Store' , '^12\.1\.0\.2\.[^0]|^12\.2' , ' ' from dual union all
SELECT 'Database Vault' , 'Oracle Database Vault' , '^11\.2|^12\.' , ' ' from dual union all
SELECT 'Database Vault' , 'Privilege Capture' , '^12\.' , ' ' from dual union all
SELECT 'Diagnostics Pack' , 'ADDM' , '^11\.2|^12\.' , ' ' from dual union all
SELECT 'Diagnostics Pack' , 'AWR Baseline' , '^11\.2|^12\.' , ' ' from dual union all
SELECT 'Diagnostics Pack' , 'AWR Baseline Template' , '^11\.2|^12\.' , ' ' from dual union all
SELECT 'Diagnostics Pack' , 'AWR Report' , '^11\.2|^12\.' , ' ' from dual union all
SELECT 'Diagnostics Pack' , 'Automatic Workload Repository' , '^12\.' , ' ' from dual union all
SELECT 'Diagnostics Pack' , 'Baseline Adaptive Thresholds' , '^11\.2|^12\.' , ' ' from dual union all
SELECT 'Diagnostics Pack' , 'Baseline Static Computations' , '^11\.2|^12\.' , ' ' from dual union all
SELECT 'Diagnostics Pack' , 'Diagnostic Pack' , '^11\.2' , ' ' from dual union all
SELECT 'Diagnostics Pack' , 'EM Performance Page' , '^12\.' , ' ' from dual union all
SELECT '.Exadata' , 'Exadata' , '^11\.2|^12\.' , ' ' from dual union all
SELECT '.GoldenGate' , 'GoldenGate' , '^12\.' , ' ' from dual union all
SELECT '.HW' , 'Hybrid Columnar Compression' , '^12\.1' , 'BUG' from dual union all
SELECT '.HW' , 'Hybrid Columnar Compression' , '^12\.[2-9]' , ' ' from dual union all
SELECT '.HW' , 'Hybrid Columnar Compression Row Level Locking' , '^12\.' , ' ' from dual union all
SELECT '.HW' , 'Sun ZFS with EHCC' , '^12\.' , ' ' from dual union all
SELECT '.HW' , 'ZFS Storage' , '^12\.' , ' ' from dual union all
SELECT '.HW' , 'Zone maps' , '^12\.' , ' ' from dual union all
SELECT 'Label Security' , 'Label Security' , '^11\.2|^12\.' , ' ' from dual union all
SELECT 'Multitenant' , 'Oracle Multitenant' , '^12\.' , 'C003' from dual union all -- licensing required only when more than one PDB containers are created
SELECT 'Multitenant' , 'Oracle Pluggable Databases' , '^12\.' , 'C003' from dual union all -- licensing required only when more than one PDB containers are created
SELECT 'OLAP' , 'OLAP - Analytic Workspaces' , '^11\.2|^12\.' , ' ' from dual union all
SELECT 'OLAP' , 'OLAP - Cubes' , '^12\.' , ' ' from dual union all
SELECT 'Partitioning' , 'Partitioning (user)' , '^11\.2|^12\.' , ' ' from dual union all
SELECT 'Partitioning' , 'Zone maps' , '^12\.' , ' ' from dual union all
SELECT '.Pillar Storage' , 'Pillar Storage' , '^12\.' , ' ' from dual union all
SELECT '.Pillar Storage' , 'Pillar Storage with EHCC' , '^12\.' , ' ' from dual union all
SELECT '.Provisioning and Patch Automation Pack' , 'EM Standalone Provisioning and Patch Automation Pack' , '^11\.2' , ' ' from dual union all
SELECT 'Provisioning and Patch Automation Pack for Database' , 'EM Database Provisioning and Patch Automation Pack' , '^11\.2' , ' ' from dual union all
SELECT 'RAC or RAC One Node' , 'Quality of Service Management' , '^12\.' , ' ' from dual union all
SELECT 'Real Application Clusters' , 'Real Application Clusters (RAC)' , '^11\.2|^12\.' , ' ' from dual union all
SELECT 'Real Application Clusters One Node' , 'Real Application Cluster One Node' , '^12\.' , ' ' from dual union all
SELECT 'Real Application Testing' , 'Database Replay: Workload Capture' , '^11\.2|^12\.' , 'C004' from dual union all
SELECT 'Real Application Testing' , 'Database Replay: Workload Replay' , '^11\.2|^12\.' , 'C004' from dual union all
SELECT 'Real Application Testing' , 'SQL Performance Analyzer' , '^11\.2|^12\.' , 'C004' from dual union all
SELECT '.Secure Backup' , 'Oracle Secure Backup' , '^12\.' , 'INVALID' from dual union all -- does not differentiate usage of Oracle Secure Backup Express, which is free
SELECT 'Spatial and Graph' , 'Spatial' , '^11\.2' , 'INVALID' from dual union all -- does not differentiate usage of Locator, which is free
SELECT 'Spatial and Graph' , 'Spatial' , '^12\.' , ' ' from dual union all
SELECT 'Tuning Pack' , 'Automatic Maintenance - SQL Tuning Advisor' , '^12\.' , 'INVALID' from dual union all -- system usage in the maintenance window
SELECT 'Tuning Pack' , 'Automatic SQL Tuning Advisor' , '^11\.2|^12\.' , 'INVALID' from dual union all -- system usage in the maintenance window
SELECT 'Tuning Pack' , 'Real-Time SQL Monitoring' , '^11\.2' , ' ' from dual union all
SELECT 'Tuning Pack' , 'Real-Time SQL Monitoring' , '^12\.' , 'INVALID' from dual union all -- default
SELECT 'Tuning Pack' , 'SQL Access Advisor' , '^11\.2|^12\.' , ' ' from dual union all
SELECT 'Tuning Pack' , 'SQL Monitoring and Tuning pages' , '^12\.' , ' ' from dual union all
SELECT 'Tuning Pack' , 'SQL Profile' , '^11\.2|^12\.' , ' ' from dual union all
SELECT 'Tuning Pack' , 'SQL Tuning Advisor' , '^11\.2|^12\.' , ' ' from dual union all
SELECT 'Tuning Pack' , 'SQL Tuning Set (user)' , '^12\.' , 'INVALID' from dual union all -- no longer part of Tuning Pack
SELECT 'Tuning Pack' , 'Tuning Pack' , '^11\.2' , ' ' from dual union all
SELECT '.WebLogic Server Management Pack Enterprise Edition' , 'EM AS Provisioning and Patch Automation Pack' , '^11\.2' , ' ' from dual union all
select '' PRODUCT, '' FEATURE, '' MVERSION, '' CONDITION from dual
),
FUS as (
-- the current data set to be used: DBA_FEATURE_USAGE_STATISTICS or CDB_FEATURE_USAGE_STATISTICS for Container Databases(CDBs)
select
0 as CON_ID,
NULL as CON_NAME,
-- Detect and mark with Y the current DBA_FUS data set = Most Recent Sample based on LAST_SAMPLE_DATE
case when DBID || '#' || VERSION || '#' || to_char(LAST_SAMPLE_DATE, 'YYYYMMDDHH24MISS') =
first_value (DBID ) over (partition by 0 order by LAST_SAMPLE_DATE desc nulls last, DBID desc) || '#' ||
first_value (VERSION ) over (partition by 0 order by LAST_SAMPLE_DATE desc nulls last, DBID desc) || '#' ||
first_value (to_char(LAST_SAMPLE_DATE, 'YYYYMMDDHH24MISS'))
over (partition by 0 order by LAST_SAMPLE_DATE desc nulls last, DBID desc)
then 'Y'
else 'N'
end as CURRENT_ENTRY,
NAME ,
LAST_SAMPLE_DATE,
DBID ,
VERSION ,
DETECTED_USAGES ,
TOTAL_SAMPLES ,
CURRENTLY_USED ,
FIRST_USAGE_DATE,
LAST_USAGE_DATE ,
AUX_COUNT ,
FEATURE_INFO
from DBA_FEATURE_USAGE_STATISTICS xy
),
PFUS as (
-- Product-Feature Usage Statitsics = DBA_FUS entries mapped to their corresponding database products
select
CON_ID,
CON_NAME,
PRODUCT,
NAME as FEATURE_BEING_USED,
case when CONDITION = 'BUG'
--suppressed due to exceptions/defects
then '3.SUPPRESSED_DUE_TO_BUG'
when detected_usages > 0 -- some usage detection - current or past
and CURRENTLY_USED = 'TRUE' -- usage at LAST_SAMPLE_DATE
and CURRENT_ENTRY = 'Y' -- current record set
and ( trim(CONDITION) is null -- no extra conditions
or CONDITION_MET = 'TRUE' -- extra condition is met
and CONDITION_COUNTER = 'FALSE' ) -- extra condition is not based on counter
then '6.CURRENT_USAGE'
when detected_usages > 0 -- some usage detection - current or past
and CURRENTLY_USED = 'TRUE' -- usage at LAST_SAMPLE_DATE
and CURRENT_ENTRY = 'Y' -- current record set
and ( CONDITION_MET = 'TRUE' -- extra condition is met
and CONDITION_COUNTER = 'TRUE' ) -- extra condition is based on counter
then '5.PAST_OR_CURRENT_USAGE' -- FEATURE_INFO counters indicate current or past usage
when detected_usages > 0 -- some usage detection - current or past
and ( trim(CONDITION) is null -- no extra conditions
or CONDITION_MET = 'TRUE' ) -- extra condition is met
then '4.PAST_USAGE'
when CURRENT_ENTRY = 'Y'
then '2.NO_CURRENT_USAGE' -- detectable feature shows no current usage
else '1.NO_PAST_USAGE'
end as USAGE,
LAST_SAMPLE_DATE,
DBID ,
VERSION ,
DETECTED_USAGES ,
TOTAL_SAMPLES ,
CURRENTLY_USED ,
case when CONDITION like 'C___' and CONDITION_MET = 'FALSE'
then to_date('')
else FIRST_USAGE_DATE
end as FIRST_USAGE_DATE,
case when CONDITION like 'C___' and CONDITION_MET = 'FALSE'
then to_date('')
else LAST_USAGE_DATE
end as LAST_USAGE_DATE,
EXTRA_FEATURE_INFO
from (
select m.PRODUCT, m.CONDITION, m.MVERSION,
-- if extra conditions (coded on the MAP.CONDITION column) are required, check if entries satisfy the condition
case
when CONDITION = 'C001' and ( regexp_like(to_char(FEATURE_INFO), 'compression used:[ 0-9]*[1-9][ 0-9]*time', 'i')
or regexp_like(to_char(FEATURE_INFO), 'compression used: *TRUE', 'i') )
then 'TRUE' -- compression has been used
when CONDITION = 'C002' and ( regexp_like(to_char(FEATURE_INFO), 'encryption used:[ 0-9]*[1-9][ 0-9]*time', 'i')
or regexp_like(to_char(FEATURE_INFO), 'encryption used: *TRUE', 'i') )
then 'TRUE' -- encryption has been used
when CONDITION = 'C003' and CON_ID=1 and AUX_COUNT > 1
then 'TRUE' -- more than one PDB are created
when CONDITION = 'C004' and 'N'= 'N'
then 'TRUE' -- not in oracle cloud
else 'FALSE'
end as CONDITION_MET,
-- check if the extra conditions are based on FEATURE_INFO counters. They indicate current or past usage.
case
when CONDITION = 'C001' and regexp_like(to_char(FEATURE_INFO), 'compression used:[ 0-9]*[1-9][ 0-9]*time', 'i')
then 'TRUE' -- compression counter > 0
when CONDITION = 'C002' and regexp_like(to_char(FEATURE_INFO), 'encryption used:[ 0-9]*[1-9][ 0-9]*time', 'i')
then 'TRUE' -- encryption counter > 0
else 'FALSE'
end as CONDITION_COUNTER,
case when CONDITION = 'C001'
then regexp_substr(to_char(FEATURE_INFO), 'compression used:(.*?)(times|TRUE|FALSE)', 1, 1, 'i')
when CONDITION = 'C002'
then regexp_substr(to_char(FEATURE_INFO), 'encryption used:(.*?)(times|TRUE|FALSE)', 1, 1, 'i')
when CONDITION = 'C003'
then 'AUX_COUNT=' || AUX_COUNT
when CONDITION = 'C004' and 'N'= 'Y'
then 'feature included in Oracle Cloud Services Package'
else ''
end as EXTRA_FEATURE_INFO,
f.CON_ID ,
f.CON_NAME ,
f.CURRENT_ENTRY ,
f.NAME ,
f.LAST_SAMPLE_DATE,
f.DBID ,
f.VERSION ,
f.DETECTED_USAGES ,
f.TOTAL_SAMPLES ,
f.CURRENTLY_USED ,
f.FIRST_USAGE_DATE,
f.LAST_USAGE_DATE ,
f.AUX_COUNT ,
f.FEATURE_INFO
from MAP m
join FUS f on m.FEATURE = f.NAME and regexp_like(f.VERSION, m.MVERSION)
where nvl(f.TOTAL_SAMPLES, 0) > 0 -- ignore features that have never been sampled
)
where nvl(CONDITION, '-') != 'INVALID' -- ignore features for which licensing is not required without further conditions
and not (CONDITION = 'C003' and CON_ID not in (0, 1)) -- multiple PDBs are visible only in CDB$ROOT; PDB level view is not relevant
)
select
grouping_id(CON_ID) as gid,
CON_ID ,
decode(grouping_id(CON_ID), 1, '--ALL--', max(CON_NAME)) as CON_NAME,
PRODUCT ,
decode(max(USAGE),
'1.NO_PAST_USAGE' , 'NO_USAGE' ,
'2.NO_CURRENT_USAGE' , 'NO_USAGE' ,
'3.SUPPRESSED_DUE_TO_BUG', 'SUPPRESSED_DUE_TO_BUG',
'4.PAST_USAGE' , 'PAST_USAGE' ,
'5.PAST_OR_CURRENT_USAGE', 'PAST_OR_CURRENT_USAGE',
'6.CURRENT_USAGE' , 'CURRENT_USAGE' ,
'UNKNOWN') as USAGE,
max(LAST_SAMPLE_DATE) as LAST_SAMPLE_DATE,
min(FIRST_USAGE_DATE) as FIRST_USAGE_DATE,
max(LAST_USAGE_DATE) as LAST_USAGE_DATE
from PFUS
where USAGE in ('2.NO_CURRENT_USAGE', '4.PAST_USAGE', '5.PAST_OR_CURRENT_USAGE', '6.CURRENT_USAGE') -- ignore '1.NO_PAST_USAGE', '3.SUPPRESSED_DUE_TO_BUG'
group by rollup(CON_ID), PRODUCT
having not (max(CON_ID) in (-1, 0) and grouping_id(CON_ID) = 1) -- aggregation not needed for non-container databases
order by GID desc, CON_ID, decode(substr(PRODUCT, 1, 1), '.', 2, 1), PRODUCT );
=================
SET LINESIZE 300SET PAGESIZE 1000SET FEEDBACK OFFCOL "Host Name" FORMAT A50COL "Option/Management Pack" FORMAT A60COL "Used" FORMAT A5with features as(select a OPTIONS, b NAME from(select 'Active Data Guard' a, 'Active Data Guard - Real-Time Query on Physical Standby' b from dualunion allselect 'Advanced Compression', 'HeapCompression' from dualunion allselect 'Advanced Compression', 'Backup BZIP2 Compression' from dualunion allselect 'Advanced Compression', 'Backup DEFAULT Compression' from dualunion allselect 'Advanced Compression', 'Backup HIGH Compression' from dualunion allselect 'Advanced Compression', 'Backup LOW Compression' from dualunion allselect 'Advanced Compression', 'Backup MEDIUM Compression' from dualunion allselect 'Advanced Compression', 'Backup ZLIB, Compression' from dualunion allselect 'Advanced Compression', 'SecureFile Compression (user)' from dualunion allselect 'Advanced Compression', 'SecureFile Deduplication (user)' from dualunion allselect 'Advanced Compression', 'Data Guard' from dualunion allselect 'Advanced Compression', 'Oracle Utility Datapump (Export)' from dualunion allselect 'Advanced Compression', 'Oracle Utility Datapump (Import)' from dualunion allselect 'Advanced Security', 'ASO native encryption and checksumming' from dualunion allselect 'Advanced Security', 'Transparent Data Encryption' from dualunion allselect 'Advanced Security', 'Encrypted Tablespaces' from dualunion allselect 'Advanced Security', 'Backup Encryption' from dualunion allselect 'Advanced Security', 'SecureFile Encryption (user)' from dualunion allselect 'Change Management Pack', 'Change Management Pack (GC)' from dualunion allselect 'Data Masking Pack', 'Data Masking Pack (GC)' from dualunion allselect 'Data Mining', 'Data Mining' from dualunion allselect 'Diagnostic Pack', 'Diagnostic Pack' from dualunion allselect 'Diagnostic Pack', 'ADDM' from dualunion allselect 'Diagnostic Pack', 'AWR Baseline' from dualunion allselect 'Diagnostic Pack', 'AWR Baseline Template' from dualunion allselect 'Diagnostic Pack', 'AWR Report' from dualunion allselect 'Diagnostic Pack', 'Baseline Adaptive Thresholds' from dualunion allselect 'Diagnostic Pack', 'Baseline Static Computations' from dualunion allselect 'Tuning Pack', 'Tuning Pack' from dualunion allselect 'Tuning Pack', 'Real-Time SQL Monitoring' from dualunion allselect 'Tuning Pack', 'SQL Tuning Advisor' from dualunion allselect 'Tuning Pack', 'SQL Access Advisor' from dualunion allselect 'Tuning Pack', 'SQL Profile' from dualunion allselect 'Tuning Pack', 'Automatic SQL Tuning Advisor' from dualunion allselect 'Database Vault', 'Oracle Database Vault' from dualunion allselect 'WebLogic Server Management Pack Enterprise Edition', 'EM AS Provisioning and Patch Automation (GC)' from dualunion allselect 'Configuration Management Pack for Oracle Database', 'EM Config Management Pack (GC)' from dualunion allselect 'Provisioning and Patch Automation Pack for Database', 'EM Database Provisioning and Patch Automation (GC)' from dualunion allselect 'Provisioning and Patch Automation Pack', 'EM Standalone Provisioning and Patch Automation Pack (GC)' from dualunion allselect 'Exadata', 'Exadata' from dualunion allselect 'Label Security', 'Label Security' from dualunion allselect 'OLAP', 'OLAP - Analytic Workspaces' from dualunion allselect 'Partitioning', 'Partitioning (user)' from dualunion allselect 'Real Application Clusters', 'Real Application Clusters (RAC)' from dualunion allselect 'Real Application Testing', 'Database Replay: Workload Capture' from dualunion allselect 'Real Application Testing', 'Database Replay: Workload Replay' from dualunion allselect 'Real Application Testing', 'SQL Performance Analyzer' from dualunion allselect 'Spatial' ,'Spatial (Not used because this does not differential usage of spatial over locator, which is free)' from dualunion allselect 'Total Recall', 'Flashback Data Archive' from dual))select t.o "Option/Management Pack",t.u "Used",d.DBID "DBID",d.name "DB Name",i.version "DB Version",i.host_name "Host Name",to_char(sysdate, 'dd-mm-YYYY HH24:MI:SS') "ReportGen Time"from(select OPTIONS o, DECODE(sum(num),0,'NO','YES') ufrom(select f.OPTIONS OPTIONS, casewhen f_stat.name is null then 0when ( ( f_stat.currently_used = 'TRUE' andf_stat.detected_usages > 0 and(sysdate - f_stat.last_usage_date) < 366 andf_stat.total_samples > 0)or(f_stat.detected_usages > 0 and(sysdate - f_stat.last_usage_date) < 366 andf_stat.total_samples > 0)) and( f_stat.name not in('Data Guard', 'Oracle Utility Datapump (Export)', 'Oracle Utility Datapump (Import)')or(f_stat.name in('Data Guard', 'Oracle Utility Datapump (Export)', 'Oracle Utility Datapump (Import)') andf_stat.feature_info is not null and trim(substr(to_char(feature_info), instr(to_char(feature_info), 'compression used: ',1,1) + 18, 2)) != '0'))then 1else 0end numfrom features f,sys.dba_feature_usage_statistics f_statwhere f.name = f_stat.name(+)) group by options) t,v$instance i,v$database dorder by 2 desc,1;
======
Set linesize 200 pagesize 300
Col name format a75 heading "Feature"
Col version format a10 heading "Version"
Col detected_usages format 999,990 heading "Detected|usages"
Col currently_used format a06 heading "Curr.|used?"
Col first_usage_date format a10 heading "First use"
Col last_usage_date format a10 heading "Last use"
Col nop noprint
Break on nop skip 1 on name
Select decode(detected_usages,0,2,1) nop,
name, version, detected_usages, currently_used,
to_char(first_usage_date,'DD/MM/YYYY') first_usage_date,
to_char(last_usage_date,'DD/MM/YYYY') last_usage_date
from dba_feature_usage_statistics
order by nop, 1, 2
/
Detected Curr.
Feature Version usages used? First use Last use
--------------------------------------------------------------------------- ---------- -------- ------ ---------- ----------
ACFS 12.2.0.1.0 209 TRUE 02/06/2017 10/07/2021
ADDM 12.2.0.1.0 12 FALSE 02/09/2017 03/07/2021
AWR Report 12.2.0.1.0 13 TRUE 26/08/2017 10/07/2021
Adaptive Plans 12.2.0.1.0 209 TRUE 02/06/2017 10/07/2021