43-Oracle 系统视图一览

发布于:2025-06-19 ⋅ 阅读:(16) ⋅ 点赞:(0)

小伙伴们有没有发现,Oracle各个版本的系统默认的视图,功能强大数量之多,是不是冒出新的,而解决了一直很难定位的性能问题,提供系统性、体系化、多视角看数据库元数据。

Oracle系统视图绝非简单的“元数据查询工具”,其实是数据库运维的中不可或缺的工具视角。到了23ai之后,有了ai模型、向量加持后,这些窥探数据库元数据之眼有了什么样的变化和演进。

一、系统视图核心功能与分类

系统视图是Oracle数据库的 元数据门户,提供数据库对象、性能指标及安全配置的实时洞察,分为三大类:
  1. 数据字典视图(对象元数据)​
  • DBA_​:全库对象(需DBA权限),如 DBA_TABLES(表结构)、DBA_INDEXES(索引定义)
  • ALL_​:当前用户可见对象(如 ALL_TABLES)
  • USER_​:用户私有对象(如 USER_VIEWS)特点:存储对象定义,不包含实际数据,查询动态更新
  1. 动态性能视图(实时监控)​
  • ​V$:单实例性能指标(如 V$SESSION 会话状态)
  • ​GV$​:RAC全局视图(如 GV$LOCK 跨实例锁)作用:诊断性能瓶颈、锁竞争、SQL执行效率
  1. 安全与存储视图
  • 权限控制​:DBA_TAB_PRIVS(表权限)、DBA_SYS_PRIVS(系统权限)
  • 存储管理​:DBA_FREE_SPACE(表空间剩余)、DBA_SEGMENTS(段存储详情)

二、新增对比:11g → 19c → 23ai​ 

 

​版本​

​代表视图

​核心能力​

​创新点

​11g​

V$SQL

SQL执行统计(逻辑读/CPU消耗)

基础性能监控

​19c

V$SQL_MONITOR

实时SQL执行追踪

自动化诊断优化

​23ai

VECSYS.VECTOR$INDEX

向量索引元数据管理

AI原生支持(语义搜索)

DBA_JSON_DUALITY_VIEWS

JSON-关系双向映射

多模数据统一访问

三、系统视图目录查询途径​

​​​​​ 数据字典视图
    1. DBA_VIEWS:查看所有视图定义
    2. USER_TAB_COLUMNS:查询视图列信息

-- 获取视图定义SQL
SELECT view_name, text FROM USER_VIEWS;
--
^^^
7,939 rows selected.
SYS@CDB$ROOT>
    • 动态性能视图目录
    1. V$FIXED_TABLE:列出所有V$和GV$视图
    SELECT NAME, OBJECT_ID,TYPE,TABLE_NUM,CON_ID FROM V$FIXED_TABLE WHERE name LIKE 'GV$%';
    --
    …………
    GV$CONNECTION_STORM                        4294956815 VIEW           65537         0
    GV$JSON_STATS                              4294956999 VIEW           65537         0
    
    860 rows selected.
    •  版本自适应查询技巧​ 使用 DBMS_XMLGEN 动态生成SQL
    1. 规避版本差异报错(如查询目录信息):
    SELECT DBMS_XMLGEN.GETXML('SELECT * FROM ' || 
    (CASE WHEN version LIKE '11%' THEN 'dba_directories' ELSE 'cdb_directories' END)
    ) FROM v$instance;
    --19c
    Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
    Version 19.3.0.0.0
    
    SELECT DBMS_XMLGEN.GETXML('SELECT * FROM ' ||
    (CASE WHEN version LIKE '11%' THEN 'dba_directories' ELSE 'cdb_directories' END)
      3  ) FROM v$instance;
    
    DBMS_XMLGEN.GETXML('SELECT*FROM'||(CASEWHENVERSIONLIKE'11%'THEN'DBA_DIRECTORIES'
    --------------------------------------------------------------------------------
    <?xml version="1.0"?>
    <ROWSET>
     <ROW>
      <OWNER>SYS</OWNER>
      <DIRECTORY_NAME>DMP
      --23ai
      SYS@CDB$ROOT> SELECT DBMS_XMLGEN.GETXML('SELECT * FROM ' ||
      2     (CASE WHEN version LIKE '11%' THEN 'dba_directories' ELSE 'cdb_directories' END)
      3* ) FROM v$instance;
    
    DBMS_XMLGEN.GETXML('SELECT*FROM'||(CASEWHENVERSIONLIKE'11%'THEN'DBA_DIRECTORIES'ELSE'CDB_DIRECTORIES'END))
    _____________________________________________________________________________________________________________
    <?xml version="1.0"?>
    <ROWSET>
     <ROW>
      <OWNER>SYS</OWNER>
      <DIRECTORY_NAME>SDO

    四、元数据管理:数据库的“自描述”核心系统

    视图类型​:DBA_/ALL_/USER_前缀视图(如DBA_TABLES、USER_OBJECTS)
    • 对象拓扑自动发现
    SELECT owner, object_name, object_type FROM DBA_OBJECTS 
    WHERE owner='HR';  
    -- 快速定位HR模式下的所有对象
    --
    SYS@CDB$ROOT> SELECT owner, object_name, object_type FROM DBA_OBJECTS WHERE owner='HR';
    
    OWNER    OBJECT_NAME                OBJECT_TYPE
    ________ __________________________ ______________
    HR       REG_ID_PK                  INDEX
    HR       REGIONS                    TABLE
    HR       COUNTRIES                  TABLE
    HR       COUNTRY_C_ID_PK            INDEX
    HR       LOCATIONS                  TABLE
    HR       LOC_ID_PK                  INDEX
    …………
    HR       UPDATE_JOB_HISTORY         TRIGGER
    34 rows selected.
    •  依赖关系溯源
    SELECT * FROM ALL_DEPENDENCIES WHERE referenced_name='EMPLOYEES';
    -- 检查EMPLOYEES表被哪些对象依赖
    
    SYS@CDB$ROOT> SELECT * FROM ALL_DEPENDENCIES WHERE referenced_name='EMPLOYEES';
    
    OWNER    NAME                  TYPE       REFERENCED_OWNER    REFERENCED_NAME    REFERENCED_TYPE    REFERENCED_LINK_NAME    DEPENDENCY_TYPE
    ________ _____________________ __________ ___________________ __________________ __________________ _______________________ __________________
    HR       SECURE_EMPLOYEES      TRIGGER    HR                  EMPLOYEES          TABLE                                      HARD        
    HR       EMP_DETAILS_VIEW      VIEW       HR                  EMPLOYEES          TABLE                                      HARD        
    HR       UPDATE_JOB_HISTORY    TRIGGER    HR                  EMPLOYEES          TABLE                                      HARD        
    •  存储空间治理​
    -- 监控表空间剩余
    SELECT tablespace_name, SUM(bytes)/1024/1024 AS free_mb 
    FROM DBA_FREE_SPACE GROUP BY tablespace_name;
    --
    TABLESPACE_NAME       FREE_MB
    __________________ __________
    SYSTEM                633.375
    SYSAUX                39.8125
    UNDOTBS1              315.875
    USERS                  0.8125
    HR_DATA                92.375
    OE_DATA               93.9375
    SH_DATA                92.375
    CO_DATA               88.3125
    SHRINK_TS             43.9375
    SECURE_LOB_TS          92.375
    ASSM_TS               90.8125
    
    11 rows selected.

    五、实时监控:性能瓶颈的“诊断仪”​

    视图类型​:V$/GV$动态视图(如V$SESSION、V$SQL)
    • 性能瓶颈定位​,结合V$SQL分析低效SQL执行计划
    -- 识别阻塞会话,
    SELECT sid, sql_id, event, wait_time FROM V$SESSION 
    WHERE status='ACTIVE' AND wait_class!='Idle';
    --
         SID           SQL_ID                           EVENT    WAIT_TIME
    ________ ________________ _______________________________ ____________
        4674 61th6m59341s7    library cache pin                          0
        7574 g0sp2zz0h9rv3    resmgr:internal state change              10
       13207 7ccbd37f8xxf3    SQL*Net message to client                 -1
       15139 gc5rjdrwfurbm    resmgr:internal state change              10
       17229 g0vy27tkcx9f2    SQL*Net message from dblink                0
    •  资源消耗追踪
    -- 监控I/O压力
    SELECT * FROM V$SYSSTAT 
    WHERE name IN ('physical reads', 'logical reads');
    --19c RAC
      STATISTIC#              NAME    CLASS       VALUE       STAT_ID    CON_ID
    _____________ _________________ ________ ___________ _____________ _________
              172 physical reads           8    90181620    2263124246         0
    •  高可用状态查询
    -- 检查主备库状态
    SELECT database_role, open_mode FROM V$DATABASE;  
    --RAC+ADG
       DATABASE_ROLE     OPEN_MODE
    ________________ _____________
    PRIMARY          READ WRITE

    六、权限查询控制

    视图类型​:权限视图(如DBA_TAB_PRIVS、ROLE_TAB_PRIVS)
    • 权限视图查询
    SYS@CDB$ROOT> SELECT GRANTEE,TABLE_NAME,PRIVILEGE,HIERARCHY FROM  DBA_TAB_PRIVS;
    --^^^^
    CTXSYS                        XDB                               INHERIT PRIVILEGES           NO
    PUBLIC                        HR                                INHERIT PRIVILEGES           NO
    PUBLIC                        CO                                INHERIT PRIVILEGES           NO
    PUBLIC                        SH                                INHERIT PRIVILEGES           NO
    PUBLIC                        OE                                INHERIT PRIVILEGES           NO
    PUBLIC                        SHRINK_USER                       INHERIT PRIVILEGES           NO
    PUBLIC                        APP_USER                          INHERIT PRIVILEGES           NO
    PUBLIC                        XS$NULL                           INHERIT PRIVILEGES           NO
    
    47,657 rows selected.
    • 角色权限查询
    SYS@CDB$ROOT> SELECT * FROM ROLE_TAB_PRIVS;
    ---
    DATAPUMP_IMP_FULL_DATABASE    SYS                  SDO_RDF_EXP_IMP                                  EXECUTE      NO           YES       YES
    EXECUTE_CATALOG_ROLE          SYS                  SDO_RDF_EXP_IMP                                  EXECUTE      NO           YES       YES
    DATAPUMP_CLOUD_IMP            SYS                  SDO_RDF_EXP_IMP                                  EXECUTE      NO           YES       YES
    EXECUTE_CATALOG_ROLE          LBACSYS              OLS$LAB_SEQUENCE                                 ALTER        NO           YES       YES
    SELECT_CATALOG_ROLE           LBACSYS              CDB_SA_TABLE_POLICIES                            SELECT       NO           YES       YES
    SELECT_CATALOG_ROLE           LBACSYS              DBA_SA_USER_LEVELS                               SELECT       NO           YES       YES
    SELECT_CATALOG_ROLE           LBACSYS              CDB_SA_USER_LEVELS                               SELECT       NO           YES       YES
    SELECT_CATALOG_ROLE           LBACSYS              DBA_SA_USERS                                     SELECT       NO           YES       YES
    
    8,210 rows selected.
    
    SYS@CDB$ROOT>
    
    • 权限合规查询​
     -- 审计HR表权限分配
    SELECT grantee, owner, table_name, privilege 
    FROM DBA_TAB_PRIVS WHERE owner='HR'; 

    七、23ai新增视图

    • 向量引擎​:VECSYS.VECTOR$INDEX管理向量索引
    -- 监控向量索引参数
    SELECT IDX_name,IDX_OWNER#,IDX_BASE_TABLE_OWNER# FROM VECSYS.VECTOR$INDEX;
    •  JSON二元性​:DBA_JSON_DUALITY_VIEWS管理关系-JSON映射
    SYS@CDB$ROOT> desc DBA_JSON_DUALITY_VIEWS;
    
    Name                   Null?       Type
    ______________________ ___________ ________________
    VIEW_OWNER             NOT NULL    VARCHAR2(128)
    VIEW_NAME              NOT NULL    VARCHAR2(128)
    JSON_COLUMN_NAME                   CHAR(4)
    ROOT_TABLE_NAME                    VARCHAR2(128)
    ROOT_TABLE_OWNER                   VARCHAR2(128)
    ALLOW_INSERT                       BOOLEAN
    ALLOW_UPDATE                       BOOLEAN
    ALLOW_DELETE                       BOOLEAN
    READ_ONLY                          BOOLEAN
    JSON_SCHEMA                        JSON
    STATUS                             VARCHAR2(7)
    LOGICAL_REPLICATION                VARCHAR2(8)
     --
     SELECT VIEW_OWNER,VIEW_NAME,JSON_COLUMN_NAME,STATUS,LOGICAL_REPLICATION FROM DBA_JSON_DUALITY_VIEWS;
    • 向量内存池视图
    SYS@CDB$ROOT> SELECT * FROM V$VECTOR_MEMORY_POOL;
    
    no rows selected
    SYS@CDB$ROOT> desc V$VECTOR_MEMORY_POOL;
    
    Name               Null?    Type
    __________________ ________ _______________
    POOL                        VARCHAR2(26)
    ALLOC_BYTES                 NUMBER
    USED_BYTES                  NUMBER
    POPULATE_STATUS             VARCHAR2(26)
    CON_ID                      NUMBER
    SYS@CDB$ROOT>

    八、Oralce系统视图工程视角

    Oracle视图的本质是数据库的自我元数据管理—通过DBA_视图实现自描述,通过V$视图实现自监控,通过安全视图实现自防护,通过23ai新视图实现自进化。一线使用的视角:
    1. 像使用API一样使用视图​:封装底层复杂性,提供标准化接口;
    2. 像治理代码一样治理视图​:版本控制、依赖分析、回归测试;
    3. 像设计架构一样设计视图​:平衡实时性(动态视图)与性能(物化视图)。

    网站公告

    今日签到

    点亮在社区的每一天
    去签到