- 关于MogDB
- 快速入门
- MogDB实训平台
- 容器化安装
- 单节点安装
- 访问数据库
- 使用命令行访问MogDB
- 使用图形工具访问MogDB
- 使用中间件访问MogDB
- 使用编程语言访问MogDB
- 使用样本数据集Mogila
- 特性描述
- 高性能
- 高可用
- 维护性
- 数据库安全
- 企业级特性
- 应用开发接口
- AI能力
- 安装指南
- 管理指南
- AI特性指南
- 概述
- Predictor:AI查询时间预测
- X-Tuner:参数调优与诊断
- SQLdiag:慢SQL发现
- Anomaly-detection:数据库指标采集、预测与异常监控
- Index-advisor:索引推荐
- DeepSQL:库内AI算法
- DB4AI:数据库原生AI引擎
- 安全指南
- 开发者指南
- 应用程序开发教程
- 开发规范
- 基于JDBC开发
- 概述
- JDBC包、驱动类和环境类
- 开发流程
- 加载驱动
- 连接数据库
- 连接数据库(以SSL方式)
- 执行SQL语句
- 处理结果集
- 关闭连接
- 日志管理
- 示例:常用操作
- 示例:重新执行应用SQL
- 示例:通过本地文件导入导出数据
- 示例:从MY向MogDB进行数据迁移
- 示例:逻辑复制代码示例
- 示例:不同场景下连接数据库参数配置
- JDBC接口参考
- java.sql.Connection
- java.sql.CallableStatement
- java.sql.DatabaseMetaData
- java.sql.Driver
- java.sql.PreparedStatement
- java.sql.ResultSet
- java.sql.ResultSetMetaData
- java.sql.Statement
- javax.sql.ConnectionPoolDataSource
- javax.sql.DataSource
- javax.sql.PooledConnection
- javax.naming.Context
- javax.naming.spi.InitialContextFactory
- CopyManager
- 基于ODBC开发
- 基于libpq开发
- 基于Psycopg开发
- 调试
- 附录
- 存储过程
- 用户自定义函数
- PL/pgSQL-SQL过程语言
- 定时任务
- 自治事务
- 逻辑复制
- Foreign Data Wrapper
- 物化视图
- 资源负载管理
- 应用程序开发教程
- 性能优化指南
- 参考指南
- 系统表及系统视图
- 系统表和系统视图概述
- 系统表
- GS_AUDITING_POLICY
- GS_AUDITING_POLICY_ACCESS
- GS_AUDITING_POLICY_FILTERS
- GS_AUDITING_POLICY_PRIVILEGES
- GS_CLIENT_GLOBAL_KEYS
- GS_CLIENT_GLOBAL_KEYS_ARGS
- GS_COLUMN_KEYS
- GS_COLUMN_KEYS_ARGS
- GS_ENCRYPTED_COLUMNS
- GS_ENCRYPTED_PROC
- GS_GLOBAL_CHAIN
- GS_MASKING_POLICY
- GS_MASKING_POLICY_ACTIONS
- GS_MASKING_POLICY_FILTERS
- GS_MATVIEW
- GS_MATVIEW_DEPENDENCY
- GS_OPT_MODEL
- GS_POLICY_LABEL
- GS_RECYCLEBIN
- GS_TXN_SNAPSHOT
- GS_WLM_INSTANCE_HISTORY
- GS_WLM_OPERATOR_INFO
- GS_WLM_PLAN_ENCODING_TABLE
- GS_WLM_PLAN_OPERATOR_INFO
- GS_WLM_EC_OPERATOR_INFO
- PG_AGGREGATE
- PG_AM
- PG_AMOP
- PG_AMPROC
- PG_APP_WORKLOADGROUP_MAPPING
- PG_ATTRDEF
- PG_ATTRIBUTE
- PG_AUTHID
- PG_AUTH_HISTORY
- PG_AUTH_MEMBERS
- PG_CAST
- PG_CLASS
- PG_COLLATION
- PG_CONSTRAINT
- PG_CONVERSION
- PG_DATABASE
- PG_DB_ROLE_SETTING
- PG_DEFAULT_ACL
- PG_DEPEND
- PG_DESCRIPTION
- PG_DIRECTORY
- PG_ENUM
- PG_EXTENSION
- PG_EXTENSION_DATA_SOURCE
- PG_FOREIGN_DATA_WRAPPER
- PG_FOREIGN_SERVER
- PG_FOREIGN_TABLE
- PG_INDEX
- PG_INHERITS
- PG_JOB
- PG_JOB_PROC
- PG_LANGUAGE
- PG_LARGEOBJECT
- PG_LARGEOBJECT_METADATA
- PG_NAMESPACE
- PG_OBJECT
- PG_OPCLASS
- PG_OPERATOR
- PG_OPFAMILY
- PG_PARTITION
- PG_PLTEMPLATE
- PG_PROC
- PG_RANGE
- PG_RESOURCE_POOL
- PG_REWRITE
- PG_RLSPOLICY
- PG_SECLABEL
- PG_SHDEPEND
- PG_SHDESCRIPTION
- PG_SHSECLABEL
- PG_STATISTIC
- PG_STATISTIC_EXT
- PG_SYNONYM
- PG_TABLESPACE
- PG_TRIGGER
- PG_TS_CONFIG
- PG_TS_CONFIG_MAP
- PG_TS_DICT
- PG_TS_PARSER
- PG_TS_TEMPLATE
- PG_TYPE
- PG_USER_MAPPING
- PG_USER_STATUS
- PG_WORKLOAD_GROUP
- PLAN_TABLE_DATA
- STATEMENT_HISTORY
- 系统视图
- GET_GLOBAL_PREPARED_XACTS(废弃)
- GS_AUDITING
- GS_AUDITING_ACCESS
- GS_AUDITING_PRIVILEGE
- GS_CLUSTER_RESOURCE_INFO
- GS_INSTANCE_TIME
- GS_LABELS
- GS_MASKING
- GS_MATVIEWS
- GS_SESSION_MEMORY
- GS_SESSION_CPU_STATISTICS
- GS_SESSION_MEMORY_CONTEXT
- GS_SESSION_MEMORY_DETAIL
- GS_SESSION_MEMORY_STATISTICS
- GS_SQL_COUNT
- GS_WLM_CGROUP_INFO
- GS_WLM_PLAN_OPERATOR_HISTORY
- GS_WLM_REBUILD_USER_RESOURCE_POOL
- GS_WLM_RESOURCE_POOL
- GS_WLM_USER_INFO
- GS_STAT_SESSION_CU
- GS_TOTAL_MEMORY_DETAIL
- MPP_TABLES
- PG_AVAILABLE_EXTENSION_VERSIONS
- PG_AVAILABLE_EXTENSIONS
- PG_COMM_DELAY
- PG_COMM_RECV_STREAM
- PG_COMM_SEND_STREAM
- PG_COMM_STATUS
- PG_CONTROL_GROUP_CONFIG
- PG_CURSORS
- PG_EXT_STATS
- PG_GET_INVALID_BACKENDS
- PG_GET_SENDERS_CATCHUP_TIME
- PG_GROUP
- PG_GTT_RELSTATS
- PG_GTT_STATS
- PG_GTT_ATTACHED_PIDS
- PG_INDEXES
- PG_LOCKS
- PG_NODE_ENV
- PG_OS_THREADS
- PG_PREPARED_STATEMENTS
- PG_PREPARED_XACTS
- PG_REPLICATION_SLOTS
- PG_RLSPOLICIES
- PG_ROLES
- PG_RULES
- PG_SECLABELS
- PG_SETTINGS
- PG_SHADOW
- PG_STATS
- PG_STAT_ACTIVITY
- PG_STAT_ALL_INDEXES
- PG_STAT_ALL_TABLES
- PG_STAT_BAD_BLOCK
- PG_STAT_BGWRITER
- PG_STAT_DATABASE
- PG_STAT_DATABASE_CONFLICTS
- PG_STAT_USER_FUNCTIONS
- PG_STAT_USER_INDEXES
- PG_STAT_USER_TABLES
- PG_STAT_REPLICATION
- PG_STAT_SYS_INDEXES
- PG_STAT_SYS_TABLES
- PG_STAT_XACT_ALL_TABLES
- PG_STAT_XACT_SYS_TABLES
- PG_STAT_XACT_USER_FUNCTIONS
- PG_STAT_XACT_USER_TABLES
- PG_STATIO_ALL_INDEXES
- PG_STATIO_ALL_SEQUENCES
- PG_STATIO_ALL_TABLES
- PG_STATIO_SYS_INDEXES
- PG_STATIO_SYS_SEQUENCES
- PG_STATIO_SYS_TABLES
- PG_STATIO_USER_INDEXES
- PG_STATIO_USER_SEQUENCES
- PG_STATIO_USER_TABLES
- PG_TABLES
- PG_TDE_INFO
- PG_THREAD_WAIT_STATUS
- PG_TIMEZONE_ABBREVS
- PG_TIMEZONE_NAMES
- PG_TOTAL_MEMORY_DETAIL
- PG_TOTAL_USER_RESOURCE_INFO
- PG_TOTAL_USER_RESOURCE_INFO_OID
- PG_USER
- PG_USER_MAPPINGS
- PG_VARIABLE_INFO
- PG_VIEWS
- PLAN_TABLE
- GS_FILE_STAT
- GS_OS_RUN_INFO
- GS_REDO_STAT
- GS_SESSION_STAT
- GS_SESSION_TIME
- GS_THREAD_MEMORY_CONTEXT
- 系统函数
- 支持的数据类型
- SQL语法
- ABORT
- ALTER AGGREGATE
- ALTER AUDIT POLICY
- ALTER DATABASE
- ALTER DATA SOURCE
- ALTER DEFAULT PRIVILEGES
- ALTER DIRECTORY
- ALTER EXTENSION
- ALTER FOREIGN TABLE
- ALTER FUNCTION
- ALTER GROUP
- ALTER INDEX
- ALTER LANGUAGE
- ALTER LARGE OBJECT
- ALTER MASKING POLICY
- ALTER MATERIALIZED VIEW
- ALTER OPERATOR
- ALTER RESOURCE LABEL
- ALTER RESOURCE POOL
- ALTER ROLE
- ALTER ROW LEVEL SECURITY POLICY
- ALTER RULE
- ALTER SCHEMA
- ALTER SEQUENCE
- ALTER SERVER
- ALTER SESSION
- ALTER SYNONYM
- ALTER SYSTEM KILL SESSION
- ALTER SYSTEM SET
- ALTER TABLE
- ALTER TABLE PARTITION
- ALTER TABLE SUBPARTITION
- ALTER TABLESPACE
- ALTER TEXT SEARCH CONFIGURATION
- ALTER TEXT SEARCH DICTIONARY
- ALTER TRIGGER
- ALTER TYPE
- ALTER USER
- ALTER USER MAPPING
- ALTER VIEW
- ANALYZE | ANALYSE
- BEGIN
- CALL
- CHECKPOINT
- CLEAN CONNECTION
- CLOSE
- CLUSTER
- COMMENT
- COMMIT | END
- COMMIT PREPARED
- CONNECT BY
- COPY
- CREATE AGGREGATE
- CREATE AUDIT POLICY
- CREATE CAST
- CREATE CLIENT MASTER KEY
- CREATE COLUMN ENCRYPTION KEY
- CREATE DATABASE
- CREATE DATA SOURCE
- CREATE DIRECTORY
- CREATE EXTENSION
- CREATE FOREIGN TABLE
- CREATE FUNCTION
- CREATE GROUP
- CREATE INCREMENTAL MATERIALIZED VIEW
- CREATE INDEX
- CREATE LANGUAGE
- CREATE MASKING POLICY
- CREATE MATERIALIZED VIEW
- CREATE MODEL
- CREATE OPERATOR
- CREATE PACKAGE
- CREATE ROW LEVEL SECURITY POLICY
- CREATE PROCEDURE
- CREATE RESOURCE LABEL
- CREATE RESOURCE POOL
- CREATE ROLE
- CREATE RULE
- CREATE SCHEMA
- CREATE SEQUENCE
- CREATE SERVER
- CREATE SYNONYM
- CREATE TABLE
- CREATE TABLE AS
- CREATE TABLE PARTITION
- CREATE TABLE SUBPARTITION
- CREATE TABLESPACE
- CREATE TEXT SEARCH CONFIGURATION
- CREATE TEXT SEARCH DICTIONARY
- CREATE TRIGGER
- CREATE TYPE
- CREATE USER
- CREATE USER MAPPING
- CREATE VIEW
- CREATE WEAK PASSWORD DICTIONARY
- CURSOR
- DEALLOCATE
- DECLARE
- DELETE
- DO
- DROP AGGREGATE
- DROP AUDIT POLICY
- DROP CAST
- DROP CLIENT MASTER KEY
- DROP COLUMN ENCRYPTION KEY
- DROP DATABASE
- DROP DATA SOURCE
- DROP DIRECTORY
- DROP EXTENSION
- DROP FOREIGN TABLE
- DROP FUNCTION
- DROP GROUP
- DROP INDEX
- DROP LANGUAGE
- DROP MASKING POLICY
- DROP MATERIALIZED VIEW
- DROP MODEL
- DROP OPERATOR
- DROP OWNED
- DROP PACKAGE
- DROP PROCEDURE
- DROP RESOURCE LABEL
- DROP RESOURCE POOL
- DROP ROW LEVEL SECURITY POLICY
- DROP ROLE
- DROP RULE
- DROP SCHEMA
- DROP SEQUENCE
- DROP SERVER
- DROP SYNONYM
- DROP TABLE
- DROP TABLESPACE
- DROP TEXT SEARCH CONFIGURATION
- DROP TEXT SEARCH DICTIONARY
- DROP TRIGGER
- DROP TYPE
- DROP USER
- DROP USER MAPPING
- DROP VIEW
- DROP WEAK PASSWORD DICTIONARY
- EXECUTE
- EXECUTE DIRECT
- EXPLAIN
- EXPLAIN PLAN
- FETCH
- GRANT
- INSERT
- LOCK
- MOVE
- MERGE INTO
- PREDICT BY
- PREPARE
- PREPARE TRANSACTION
- PURGE
- REASSIGN OWNED
- REFRESH INCREMENTAL MATERIALIZED VIEW
- REFRESH MATERIALIZED VIEW
- REINDEX
- RELEASE SAVEPOINT
- RESET
- REVOKE
- ROLLBACK
- ROLLBACK PREPARED
- ROLLBACK TO SAVEPOINT
- SAVEPOINT
- SELECT
- SELECT INTO
- SET
- SET CONSTRAINTS
- SET ROLE
- SET SESSION AUTHORIZATION
- SET TRANSACTION
- SHOW
- SHUTDOWN
- SNAPSHOT
- START TRANSACTION
- TIMECAPSULE TABLE
- TRUNCATE
- UPDATE
- VACUUM
- VALUES
- SQL参考
- GUC参数说明
- Schema
- Information Schema
- DBE_PERF
- 概述
- OS
- Instance
- Memory
- File
- Object
- STAT_USER_TABLES
- SUMMARY_STAT_USER_TABLES
- GLOBAL_STAT_USER_TABLES
- STAT_USER_INDEXES
- SUMMARY_STAT_USER_INDEXES
- GLOBAL_STAT_USER_INDEXES
- STAT_SYS_TABLES
- SUMMARY_STAT_SYS_TABLES
- GLOBAL_STAT_SYS_TABLES
- STAT_SYS_INDEXES
- SUMMARY_STAT_SYS_INDEXES
- GLOBAL_STAT_SYS_INDEXES
- STAT_ALL_TABLES
- SUMMARY_STAT_ALL_TABLES
- GLOBAL_STAT_ALL_TABLES
- STAT_ALL_INDEXES
- SUMMARY_STAT_ALL_INDEXES
- GLOBAL_STAT_ALL_INDEXES
- STAT_DATABASE
- SUMMARY_STAT_DATABASE
- GLOBAL_STAT_DATABASE
- STAT_DATABASE_CONFLICTS
- SUMMARY_STAT_DATABASE_CONFLICTS
- GLOBAL_STAT_DATABASE_CONFLICTS
- STAT_XACT_ALL_TABLES
- SUMMARY_STAT_XACT_ALL_TABLES
- GLOBAL_STAT_XACT_ALL_TABLES
- STAT_XACT_SYS_TABLES
- SUMMARY_STAT_XACT_SYS_TABLES
- GLOBAL_STAT_XACT_SYS_TABLES
- STAT_XACT_USER_TABLES
- SUMMARY_STAT_XACT_USER_TABLES
- GLOBAL_STAT_XACT_USER_TABLES
- STAT_XACT_USER_FUNCTIONS
- SUMMARY_STAT_XACT_USER_FUNCTIONS
- GLOBAL_STAT_XACT_USER_FUNCTIONS
- STAT_BAD_BLOCK
- SUMMARY_STAT_BAD_BLOCK
- GLOBAL_STAT_BAD_BLOCK
- STAT_USER_FUNCTIONS
- SUMMARY_STAT_USER_FUNCTIONS
- GLOBAL_STAT_USER_FUNCTIONS
- Workload
- Session/Thread
- SESSION_STAT
- GLOBAL_SESSION_STAT
- SESSION_TIME
- GLOBAL_SESSION_TIME
- SESSION_MEMORY
- GLOBAL_SESSION_MEMORY
- SESSION_MEMORY_DETAIL
- GLOBAL_SESSION_MEMORY_DETAIL
- SESSION_STAT_ACTIVITY
- GLOBAL_SESSION_STAT_ACTIVITY
- THREAD_WAIT_STATUS
- GLOBAL_THREAD_WAIT_STATUS
- LOCAL_THREADPOOL_STATUS
- GLOBAL_THREADPOOL_STATUS
- SESSION_CPU_RUNTIME
- SESSION_MEMORY_RUNTIME
- STATEMENT_IOSTAT_COMPLEX_RUNTIME
- LOCAL_ACTIVE_SESSION
- Transaction
- Query
- STATEMENT
- SUMMARY_STATEMENT
- STATEMENT_COUNT
- GLOBAL_STATEMENT_COUNT
- SUMMARY_STATEMENT_COUNT
- GLOBAL_STATEMENT_COMPLEX_HISTORY
- GLOBAL_STATEMENT_COMPLEX_HISTORY_TABLE
- GLOBAL_STATEMENT_COMPLEX_RUNTIME
- STATEMENT_RESPONSETIME_PERCENTILE
- STATEMENT_USER_COMPLEX_HISTORY
- STATEMENT_COMPLEX_RUNTIME
- STATEMENT_COMPLEX_HISTORY_TABLE
- STATEMENT_COMPLEX_HISTORY
- STATEMENT_WLMSTAT_COMPLEX_RUNTIME
- STATEMENT_HISTORY
- Cache/IO
- STATIO_USER_TABLES
- SUMMARY_STATIO_USER_TABLES
- GLOBAL_STATIO_USER_TABLES
- STATIO_USER_INDEXES
- SUMMARY_STATIO_USER_INDEXES
- GLOBAL_STATIO_USER_INDEXES
- STATIO_USER_SEQUENCES
- SUMMARY_STATIO_USER_SEQUENCES
- GLOBAL_STATIO_USER_SEQUENCES
- STATIO_SYS_TABLES
- SUMMARY_STATIO_SYS_TABLES
- GLOBAL_STATIO_SYS_TABLES
- STATIO_SYS_INDEXES
- SUMMARY_STATIO_SYS_INDEXES
- GLOBAL_STATIO_SYS_INDEXES
- STATIO_SYS_SEQUENCES
- SUMMARY_STATIO_SYS_SEQUENCES
- GLOBAL_STATIO_SYS_SEQUENCES
- STATIO_ALL_TABLES
- SUMMARY_STATIO_ALL_TABLES
- GLOBAL_STATIO_ALL_TABLES
- STATIO_ALL_INDEXES
- SUMMARY_STATIO_ALL_INDEXES
- GLOBAL_STATIO_ALL_INDEXES
- STATIO_ALL_SEQUENCES
- SUMMARY_STATIO_ALL_SEQUENCES
- GLOBAL_STATIO_ALL_SEQUENCES
- GLOBAL_STAT_DB_CU
- GLOBAL_STAT_SESSION_CU
- Utility
- REPLICATION_STAT
- GLOBAL_REPLICATION_STAT
- REPLICATION_SLOTS
- GLOBAL_REPLICATION_SLOTS
- BGWRITER_STAT
- GLOBAL_BGWRITER_STAT
- GLOBAL_CKPT_STATUS
- GLOBAL_DOUBLE_WRITE_STATUS
- GLOBAL_PAGEWRITER_STATUS
- GLOBAL_RECORD_RESET_TIME
- GLOBAL_REDO_STATUS
- GLOBAL_RECOVERY_STATUS
- CLASS_VITAL_INFO
- USER_LOGIN
- SUMMARY_USER_LOGIN
- GLOBAL_GET_BGWRITER_STATUS
- GLOBAL_SINGLE_FLUSH_DW_STATUS
- GLOBAL_CANDIDATE_STATUS
- Lock
- Wait Events
- Configuration
- Operator
- Workload Manager
- Global Plancache
- RTO
- 附录
- DBE_PLDEBUGGER Schema
- DBE_PLDEBUGGER Schema概述
- DBE_PLDEBUGGER.turn_on
- DBE_PLDEBUGGER.turn_off
- DBE_PLDEBUGGER.local_debug_server_info
- DBE_PLDEBUGGER.attach
- DBE_PLDEBUGGER.next
- DBE_PLDEBUGGER.continue
- DBE_PLDEBUGGER.abort
- DBE_PLDEBUGGER.print_var
- DBE_PLDEBUGGER.info_code
- DBE_PLDEBUGGER.step
- DBE_PLDEBUGGER.add_breakpoint
- DBE_PLDEBUGGER.delete_breakpoint
- DBE_PLDEBUGGER.info_breakpoints
- DBE_PLDEBUGGER.backtrace
- DBE_PLDEBUGGER.finish
- DBE_PLDEBUGGER.set_var
- DB4AI Schema
- 工具参考
- 工具一览表
- 客户端工具
- 服务端工具
- 系统内部使用的工具
- mogdb
- gs_backup
- gs_basebackup
- gs_ctl
- gs_initdb
- gs_install
- gs_install_plugin
- gs_install_plugin_local
- gs_preinstall
- gs_sshexkey
- gs_tar
- gs_uninstall
- gs_upgradectl
- gs_expansion
- gs_dropnode
- gs_probackup
- gstrace
- kdb5_util
- kadmin.local
- kinit
- klist
- krb5kdc
- kdestroy
- pg_config
- pg_controldata
- pg_recvlogical
- pg_resetxlog
- pg_archivecleanup
- pssh
- pscp
- transfer.py
- FAQ
- gs_collector工具支持收集的系统表和视图列表
- 插件
- 数据库报错信息
- SQL标准错误码说明
- 第三方库错误码说明
- GAUSS-00001 - GAUSS-00100
- GAUSS-00101 - GAUSS-00200
- GAUSS 00201 - GAUSS 00300
- GAUSS 00301 - GAUSS 00400
- GAUSS 00401 - GAUSS 00500
- GAUSS 00501 - GAUSS 00600
- GAUSS 00601 - GAUSS 00700
- GAUSS 00701 - GAUSS 00800
- GAUSS 00801 - GAUSS 00900
- GAUSS 00901 - GAUSS 01000
- GAUSS 01001 - GAUSS 01100
- GAUSS 01101 - GAUSS 01200
- GAUSS 01201 - GAUSS 01300
- GAUSS 01301 - GAUSS 01400
- GAUSS 01401 - GAUSS 01500
- GAUSS 01501 - GAUSS 01600
- GAUSS 01601 - GAUSS 01700
- GAUSS 01701 - GAUSS 01800
- GAUSS 01801 - GAUSS 01900
- GAUSS 01901 - GAUSS 02000
- GAUSS 02001 - GAUSS 02100
- GAUSS 02101 - GAUSS 02200
- GAUSS 02201 - GAUSS 02300
- GAUSS 02301 - GAUSS 02400
- GAUSS 02401 - GAUSS 02500
- GAUSS 02501 - GAUSS 02600
- GAUSS 02601 - GAUSS 02700
- GAUSS 02701 - GAUSS 02800
- GAUSS 02801 - GAUSS 02900
- GAUSS 02901 - GAUSS 03000
- GAUSS 03001 - GAUSS 03100
- GAUSS 03101 - GAUSS 03200
- GAUSS 03201 - GAUSS 03300
- GAUSS 03301 - GAUSS 03400
- GAUSS 03401 - GAUSS 03500
- GAUSS 03501 - GAUSS 03600
- GAUSS 03601 - GAUSS 03700
- GAUSS 03701 - GAUSS 03800
- GAUSS 03801 - GAUSS 03900
- GAUSS 03901 - GAUSS 04000
- GAUSS 04001 - GAUSS 04100
- GAUSS 04101 - GAUSS 04200
- GAUSS 04201 - GAUSS 04300
- GAUSS 04301 - GAUSS 04400
- GAUSS 04401 - GAUSS 04500
- GAUSS 04501 - GAUSS 04600
- GAUSS 04601 - GAUSS 04700
- GAUSS 04701 - GAUSS 04800
- GAUSS 04801 - GAUSS 04900
- GAUSS 04901 - GAUSS 05000
- GAUSS 05001 - GAUSS 05100
- GAUSS 05101 - GAUSS 05200
- GAUSS 05201 - GAUSS 05300
- GAUSS 05301 - GAUSS 05400
- GAUSS 05401 - GAUSS 05500
- GAUSS 05501 - GAUSS 05600
- GAUSS 05601 - GAUSS 05700
- GAUSS 05701 - GAUSS 05800
- GAUSS 05801 - GAUSS 05900
- GAUSS 05901 - GAUSS 06000
- GAUSS 06001 - GAUSS 06100
- GAUSS 06101 - GAUSS 06200
- GAUSS 06201 - GAUSS 06300
- GAUSS 06301 - GAUSS 06400
- GAUSS 06401 - GAUSS 06500
- GAUSS 06501 - GAUSS 06600
- GAUSS 06601 - GAUSS 06700
- GAUSS 06701 - GAUSS 06800
- GAUSS 06801 - GAUSS 06900
- GAUSS 06901 - GAUSS 07000
- GAUSS 07001 - GAUSS 07100
- GAUSS 07101 - GAUSS 07200
- GAUSS 07201 - GAUSS 07300
- GAUSS 07301 - GAUSS 07400
- GAUSS 07401 - GAUSS 07480
- GAUSS 50000 - GAUSS 50999
- GAUSS 51000 - GAUSS 51999
- GAUSS 52000 - GAUSS 52999
- GAUSS 53000 - GAUSS 53699
- 错误日志信息参考
- 系统表及系统视图
- 故障诊断指南
- 常见故障定位手段
- 常见故障定位案例
- core问题定位
- 权限/会话/数据类型问题定位
- 服务/高可用/并发问题定位
- 表/分区表问题定位
- 文件系统/磁盘/内存问题定位
- SQL问题定位
- 索引问题定位
- 源码解析
- 常见问题解答 (FAQs)
- 术语表
聚集函数
-
sum(expression)
描述:所有输入行的expression总和。
返回类型:
通常情况下输入数据类型和输出数据类型是相同的,但以下情况会发生类型转换:
- 对于SMALLINT或INT输入,输出类型为BIGINT。
- 对于BIGINT输入,输出类型为NUMBER 。
- 对于浮点数输入,输出类型为DOUBLE PRECISION。
示例:
mogdb=# SELECT SUM(ss_ext_tax) FROM tpcds.STORE_SALES; sum -------------- 213267594.69 (1 row)
-
max(expression)
描述:所有输入行中expression的最大值。
参数类型:任意数组、数值、字符串、日期/时间类型、IPV4和IPV6地址(INET型和CIDR型)。
返回类型:与参数数据类型相同
示例:
mogdb=# SELECT MAX(inv_quantity_on_hand) FROM tpcds.inventory;
-
min(expression)
描述:所有输入行中expression的最小值。
参数类型:任意数组、数值、字符串、日期/时间类型、IPV4和IPV6地址(INET型和CIDR型)。
返回类型:与参数数据类型相同
示例:
mogdb=# SELECT MIN(inv_quantity_on_hand) FROM tpcds.inventory; min ----- 0 (1 row)
-
avg(expression)
描述:所有输入值的均值(算术平均)。
返回类型:
对于任何整数类型输入,结果都是NUMBER类型。
对于任何浮点输入,结果都是DOUBLE PRECISION类型。
否则和输入数据类型相同。
示例:
mogdb=# SELECT AVG(inv_quantity_on_hand) FROM tpcds.inventory; avg ---------------------- 500.0387129084044604 (1 row)
-
count(expression)
描述:返回表中满足expression不为NULL的行数。
返回类型:BIGINT
示例:
mogdb=# SELECT COUNT(inv_quantity_on_hand) FROM tpcds.inventory; count ---------- 11158087 (1 row)
-
count(*)
描述:返回表中的记录行数。
返回类型:BIGINT
示例:
mogdb=# SELECT COUNT(*) FROM tpcds.inventory; count ---------- 11745000 (1 row)
-
median(expression) [over (query partition clause)]
描述:返回表达式的中位数,计算时NULL将会被median函数忽略。可以使用distinct关键字排除表达式中的重复记录。输入expression的数据类型可以是数值类型(包括integer, double,bigint等), 也可以是interval类型。其他数据类型不支持求取中位数。
返回类型:double或interval类型
示例:
select median(id) from (values(1), (2), (3), (4), (null)) test(id); median -------- 2.5 (1 row)
-
array_agg(expression)
描述:将所有输入值(包括空)连接成一个数组。
返回类型:参数类型的数组
示例:
mogdb=# SELECT ARRAY_AGG(sr_fee) FROM tpcds.store_returns WHERE sr_customer_sk = 2; array_agg --------------- {22.18,63.21} (1 row)
-
string_agg(expression, delimiter)
描述:将输入值连接成为一个字符串,用分隔符分开。
返回类型:和参数数据类型相同。
示例:
mogdb=# SELECT string_agg(sr_item_sk, ',') FROM tpcds.store_returns where sr_item_sk < 3; string_agg --------------------------------------------------------------------------------- ------------------------------ 1,2,1,2,2,1,1,2,2,1,2,1,2,1,1,1,2,1,1,1,1,1,2,1,1,1,1,1,2,2,1,1,1,1,1,1,1,1,1,2, 2,1,1,1,1,1,1,2,2,1,1,2,1,1,1 (1 row)
-
listagg(expression [, delimiter]) WITHIN GROUP(ORDER BY order-list)
描述:将聚集列数据按WITHIN GROUP指定的排序方式排列,并用delimiter指定的分隔符拼接成一个字符串。
- expression:必选。指定聚集列名或基于列的有效表达式,不支持DISTINCT关键字和VARIADIC参数。
- delimiter:可选。指定分隔符,可以是字符串常数或基于分组列的确定性表达式,缺省时表示分隔符为空。
- order-list:必选。指定分组内的排序方式。
返回类型:text
示例:
聚集列是文本字符集类型。
mogdb=# SELECT deptno, listagg(ename, ',') WITHIN GROUP(ORDER BY ename) AS employees FROM emp GROUP BY deptno; deptno | employees --------+-------------------------------------- 10 | CLARK,KING,MILLER 20 | ADAMS,FORD,JONES,SCOTT,SMITH 30 | ALLEN,BLAKE,JAMES,MARTIN,TURNER,WARD (3 rows)
聚集列是整型。
mogdb=# SELECT deptno, listagg(mgrno, ',') WITHIN GROUP(ORDER BY mgrno NULLS FIRST) AS mgrnos FROM emp GROUP BY deptno; deptno | mgrnos --------+------------------------------- 10 | 7782,7839 20 | 7566,7566,7788,7839,7902 30 | 7698,7698,7698,7698,7698,7839 (3 rows)
聚集列是浮点类型。
mogdb=# SELECT job, listagg(bonus, '($); ') WITHIN GROUP(ORDER BY bonus DESC) || '($)' AS bonus FROM emp GROUP BY job; job | bonus ------------+------------------------------------------------- CLERK | 10234.21($); 2000.80($); 1100.00($); 1000.22($) PRESIDENT | 23011.88($) ANALYST | 2002.12($); 1001.01($) MANAGER | 10000.01($); 2399.50($); 999.10($) SALESMAN | 1000.01($); 899.00($); 99.99($); 9.00($) (5 rows)
聚集列是时间类型。
mogdb=# SELECT deptno, listagg(hiredate, ', ') WITHIN GROUP(ORDER BY hiredate DESC) AS hiredates FROM emp GROUP BY deptno; deptno | hiredates --------+------------------------------------------------------------------------------------------------------------------------------ 10 | 1982-01-23 00:00:00, 1981-11-17 00:00:00, 1981-06-09 00:00:00 20 | 2001-04-02 00:00:00, 1999-12-17 00:00:00, 1987-05-23 00:00:00, 1987-04-19 00:00:00, 1981-12-03 00:00:00 30 | 2015-02-20 00:00:00, 2010-02-22 00:00:00, 1997-09-28 00:00:00, 1981-12-03 00:00:00, 1981-09-08 00:00:00, 1981-05-01 00:00:00 (3 rows)
聚集列是时间间隔类型。
mogdb=# SELECT deptno, listagg(vacationTime, '; ') WITHIN GROUP(ORDER BY vacationTime DESC) AS vacationTime FROM emp GROUP BY deptno; deptno | vacationtime --------+------------------------------------------------------------------------------------ 10 | 1 year 30 days; 40 days; 10 days 20 | 70 days; 36 days; 9 days; 5 days 30 | 1 year 1 mon; 2 mons 10 days; 30 days; 12 days 12:00:00; 4 days 06:00:00; 24:00:00 (3 rows)
分隔符缺省时,默认为空。
mogdb=# SELECT deptno, listagg(job) WITHIN GROUP(ORDER BY job) AS jobs FROM emp GROUP BY deptno; deptno | jobs --------+---------------------------------------------- 10 | CLERKMANAGERPRESIDENT 20 | ANALYSTANALYSTCLERKCLERKMANAGER 30 | CLERKMANAGERSALESMANSALESMANSALESMANSALESMAN (3 rows)
listagg作为窗口函数时,OVER子句不支持ORDER BY的窗口排序,listagg列为对应分组的有序聚集。
mogdb=# SELECT deptno, mgrno, bonus, listagg(ename,'; ') WITHIN GROUP(ORDER BY hiredate) OVER(PARTITION BY deptno) AS employees FROM emp; deptno | mgrno | bonus | employees --------+-------+----------+------------------------------------------- 10 | 7839 | 10000.01 | CLARK; KING; MILLER 10 | | 23011.88 | CLARK; KING; MILLER 10 | 7782 | 10234.21 | CLARK; KING; MILLER 20 | 7566 | 2002.12 | FORD; SCOTT; ADAMS; SMITH; JONES 20 | 7566 | 1001.01 | FORD; SCOTT; ADAMS; SMITH; JONES 20 | 7788 | 1100.00 | FORD; SCOTT; ADAMS; SMITH; JONES 20 | 7902 | 2000.80 | FORD; SCOTT; ADAMS; SMITH; JONES 20 | 7839 | 999.10 | FORD; SCOTT; ADAMS; SMITH; JONES 30 | 7839 | 2399.50 | BLAKE; TURNER; JAMES; MARTIN; WARD; ALLEN 30 | 7698 | 9.00 | BLAKE; TURNER; JAMES; MARTIN; WARD; ALLEN 30 | 7698 | 1000.22 | BLAKE; TURNER; JAMES; MARTIN; WARD; ALLEN 30 | 7698 | 99.99 | BLAKE; TURNER; JAMES; MARTIN; WARD; ALLEN 30 | 7698 | 1000.01 | BLAKE; TURNER; JAMES; MARTIN; WARD; ALLEN 30 | 7698 | 899.00 | BLAKE; TURNER; JAMES; MARTIN; WARD; ALLEN (14 rows)
-
covar_pop(Y, X)
描述:总体协方差。
返回类型:double precision
示例:
mogdb=# SELECT COVAR_POP(sr_fee, sr_net_loss) FROM tpcds.store_returns WHERE sr_customer_sk < 1000; covar_pop ------------------ 829.749627587403 (1 row)
-
covar_samp(Y, X)
描述:样本协方差。
返回类型:double precision
示例:
mogdb=# SELECT COVAR_SAMP(sr_fee, sr_net_loss) FROM tpcds.store_returns WHERE sr_customer_sk < 1000; covar_samp ------------------ 830.052235037289 (1 row)
-
stddev_pop(expression)
描述:总体标准差。
返回类型:对于浮点类型的输入返回double precision,其他输入返回numeric。
示例:
mogdb=# SELECT STDDEV_POP(inv_quantity_on_hand) FROM tpcds.inventory WHERE inv_warehouse_sk = 1; stddev_pop ------------------ 289.224294957556 (1 row)
-
stddev_samp(expression)
描述:样本标准差。
返回类型:对于浮点类型的输入返回double precision,其他输入返回numeric。
示例:
mogdb=# SELECT STDDEV_SAMP(inv_quantity_on_hand) FROM tpcds.inventory WHERE inv_warehouse_sk = 1; stddev_samp ------------------ 289.224359757315 (1 row)
-
var_pop(expression)
描述:总体方差(总体标准差的平方)
返回类型:对于浮点类型的输入返回double precision类型,其他输入返回numeric类型。
示例:
mogdb=# SELECT VAR_POP(inv_quantity_on_hand) FROM tpcds.inventory WHERE inv_warehouse_sk = 1; var_pop -------------------- 83650.692793695475 (1 row)
-
var_samp(expression)
描述:样本方差(样本标准差的平方)
返回类型:对于浮点类型的输入返回double precision类型,其他输入返回numeric类型。
示例:
mogdb=# SELECT VAR_SAMP(inv_quantity_on_hand) FROM tpcds.inventory WHERE inv_warehouse_sk = 1; var_samp -------------------- 83650.730277028768 (1 row)
-
bit_and(expression)
描述:所有非NULL输入值的按位与(AND),如果全部输入值皆为NULL,那么结果也为NULL 。
返回类型:和参数数据类型相同。
示例:
mogdb=# SELECT BIT_AND(inv_quantity_on_hand) FROM tpcds.inventory WHERE inv_warehouse_sk = 1; bit_and --------- 0 (1 row)
-
bit_or(expression)
描述:所有非NULL输入值的按位或(OR),如果全部输入值皆为NULL,那么结果也为NULL。
返回类型:和参数数据类型相同
示例:
mogdb=# SELECT BIT_OR(inv_quantity_on_hand) FROM tpcds.inventory WHERE inv_warehouse_sk = 1; bit_or -------- 1023 (1 row)
-
bool_and(expression)
描述:如果所有输入值都是真,则为真,否则为假。
返回类型:bool
示例:
mogdb=# SELECT bool_and(100 <2500); bool_and ---------- t (1 row)
-
bool_or(expression)
描述:如果所有输入值只要有一个为真,则为真,否则为假。
返回类型:bool
示例:
mogdb=# SELECT bool_or(100 <2500); bool_or ---------- t (1 row)
-
corr(Y, X)
描述:相关系数
返回类型:double precision
示例:
mogdb=# SELECT CORR(sr_fee, sr_net_loss) FROM tpcds.store_returns WHERE sr_customer_sk < 1000; corr ------------------- .0381383624904186 (1 row)
-
every(expression)
描述:等效于bool_and。
返回类型:bool
示例:
mogdb=# SELECT every(100 <2500); every ------- t (1 row)
-
regr_avgx(Y, X)
描述:自变量的平均值 (sum(X)/N)
返回类型:double precision
示例:
mogdb=# SELECT REGR_AVGX(sr_fee, sr_net_loss) FROM tpcds.store_returns WHERE sr_customer_sk < 1000; regr_avgx ------------------ 578.606576740795 (1 row)
-
regr_avgy(Y, X)
描述:因变量的平均值 (sum(Y)/N)
返回类型:double precision
示例:
mogdb=# SELECT REGR_AVGY(sr_fee, sr_net_loss) FROM tpcds.store_returns WHERE sr_customer_sk < 1000; regr_avgy ------------------ 50.0136711629602 (1 row)
-
regr_count(Y, X)
描述:两个表达式都不为NULL的输入行数。
返回类型:bigint
示例:
mogdb=# SELECT REGR_COUNT(sr_fee, sr_net_loss) FROM tpcds.store_returns WHERE sr_customer_sk < 1000; regr_count ------------ 2743 (1 row)
-
regr_intercept(Y, X)
描述:根据所有输入的点(X, Y)按照最小二乘法拟合成一个线性方程,然后返回该直线的Y轴截距。
返回类型:double precision
示例:
mogdb=# SELECT REGR_INTERCEPT(sr_fee, sr_net_loss) FROM tpcds.store_returns WHERE sr_customer_sk < 1000; regr_intercept ------------------ 49.2040847848607 (1 row)
-
regr_r2(Y, X)
描述:相关系数的平方
返回类型:double precision
示例:
mogdb=# SELECT REGR_R2(sr_fee, sr_net_loss) FROM tpcds.store_returns WHERE sr_customer_sk < 1000; regr_r2 -------------------- .00145453469345058 (1 row)
-
regr_slope(Y, X)
描述:根据所有输入的点(X, Y)按照最小二乘法拟合成一个线性方程, 然后返回该直线的斜率。
返回类型:double precision
示例:
mogdb=# SELECT REGR_SLOPE(sr_fee, sr_net_loss) FROM tpcds.store_returns WHERE sr_customer_sk < 1000; regr_slope -------------------- .00139920009665259 (1 row)
-
regr_sxx(Y, X)
描述:sum(X^2) - sum(X)^2/N (自变量的"平方和")
返回类型:double precision
示例:
mogdb=# SELECT REGR_SXX(sr_fee, sr_net_loss) FROM tpcds.store_returns WHERE sr_customer_sk < 1000; regr_sxx ------------------ 1626645991.46135 (1 row)
-
regr_sxy(Y, X)
描述:sum(XY) - sum(X) sum(Y)/N (自变量和因变量的"乘方积")
返回类型:double precision
示例:
mogdb=# SELECT REGR_SXY(sr_fee, sr_net_loss) FROM tpcds.store_returns WHERE sr_customer_sk < 1000; regr_sxy ------------------ 2276003.22847225 (1 row)
-
regr_syy(Y, X)
描述:sum(Y^2) - sum(Y)^2/N(因变量的"平方和")
返回类型:double precision
示例:
mogdb=# SELECT REGR_SYY(sr_fee, sr_net_loss) FROM tpcds.store_returns WHERE sr_customer_sk < 1000; regr_syy ----------------- 2189417.6547314 (1 row)
-
stddev(expression)
描述:stddev_samp的别名。
返回类型:对于浮点类型的输入返回double precision,其他输入返回numeric。
示例:
mogdb=# SELECT STDDEV(inv_quantity_on_hand) FROM tpcds.inventory WHERE inv_warehouse_sk = 1; stddev ------------------ 289.224359757315 (1 row)
-
variance(expexpression,ression)
描述:var_samp的别名。
返回类型:对于浮点类型的输入返回double precision类型,其他输入返回numeric类型。
示例:
mogdb=# SELECT VARIANCE(inv_quantity_on_hand) FROM tpcds.inventory WHERE inv_warehouse_sk = 1; variance -------------------- 83650.730277028768 (1 row)
-
delta
描述:返回当前行和前一行的差值。
参数:numeric
返回值类型:numeric
-
checksum(expression)
描述:返回所有输入值的CHECKSUM值。使用该函数可以用来验证MogDB数据库(不支持MogDB之外的其他数据库)的备份恢复或者数据迁移操作前后表中的数据是否相同。在备份恢复或者数据迁移操作前后都需要用户通过手工执行SQL命令的方式获取执行结果,通过对比获取的执行结果判断操作前后表中的数据是否相同。
说明:
- 对于大表,CHECKSUM函数可能会需要很长时间。
- 如果某两表的CHECKSUM值不同,则表明两表的内容是不同的。由于CHECKSUM函数中使用散列函数不能保证无冲突,因此两个不同内容的表可能会得到相同的CHECKSUM值,存在这种情况的可能性较小。对于列进行的CHECKSUM也存在相同的情况。
- 对于时间类型timestamp, timestamptz和smalldatetime,计算CHECKSUM值时请确保时区设置一致。
- 若计算某列的CHECKSUM值,且该列类型可以默认转为TEXT类型,则expression为列名。
- 若计算某列的CHECKSUM值,且该列类型不能默认转为TEXT类型,则expression为列名::TEXT。
- 若计算所有列的CHECKSUM值,则expression为表名::TEXT。
可以默认转换为TEXT类型的类型包括:char, name, int8, int2, int1, int4, raw, pg_node_tree, float4, float8, bpchar, varchar, nvarchar2, date, timestamp, timestamptz, numeric, smalldatetime,其他类型需要强制转换为TEXT。
返回类型:numeric。
示例:
表中可以默认转为TEXT类型的某列的CHECKSUM值。
mogdb=# SELECT CHECKSUM(inv_quantity_on_hand) FROM tpcds.inventory; checksum ------------------- 24417258945265247 (1 row)
表中不能默认转为TEXT类型的某列的CHECKSUM值。注意此时CHECKSUM参数是列名::TEXT。
mogdb=# SELECT CHECKSUM(inv_quantity_on_hand::TEXT) FROM tpcds.inventory; checksum ------------------- 24417258945265247 (1 row)
表中所有列的CHECKSUM值。注意此时CHECKSUM参数是表名::TEXT,且表名前不加Schema。
mogdb=# SELECT CHECKSUM(inventory::TEXT) FROM tpcds.inventory; checksum ------------------- 25223696246875800 (1 row)
-
first(anyelement)
描述:返回第一个非NULL输入。
返回类型:anyelement
mogdb=# select * from tba; name ----- A A D (4 rows) mogdb=# select first(name) from tba; first ----- A (1 rows)
-
last(anyelement)
描述:返回最后一个非NULL输入。
返回类型:anyelement
mogdb=# select * from tba; name ----- A A D (4 rows) mogdb=# select last(name) from tba; last ----- D (1 rows)
-
mode() within group (order by value anyelement)
描述:返回某列中出现频率最高的值,如果多个值频率相同,则返回最小的那个值。排序方式和该列类型的默认排序方式相同。其中value为输入参数,可以为任意类型。
返回类型:与输入参数类型相同。
示例:
mogdb=# select mode() within group (order by value) from (values(1, 'a'), (2, 'b'), (2, 'c')) v(value, tag); mode ------ 2 (1 row) mogdb=# select mode() within group (order by tag) from (values(1, 'a'), (2, 'b'), (2, 'c')) v(value, tag); mode ------ a (1 row)
-
json_agg(any)
描述:将值聚集为json数组。
返回类型:array-json
示例:
mogdb=# select * from classes; name | score -----+------- A | 2 A | 3 D | 5 D | (4 rows)
mogdb=# select name, json_agg(score) score from classes group by name order by name; name | score -----+----------------- A | [2, 3] D | [5, null] | [null] (3 rows)
-
json_object_agg(any, any)
描述:将值聚集为json对象。
返回类型:object-json
示例:
mogdb=# select * from classes; name | score -----+------- A | 2 A | 3 D | 5 D | (4 rows)
mogdb=# select json_object_agg(name, score) from classes group by name order by name; json_object_agg ------------------------- { "A" : 2, "A" : 3 } { "D" : 5, "D" : null } (2 rows)