- 关于MogDB
- 快速入门
- 特性描述
- 概览
- 高性能
- 高可用
- 维护性
- 兼容性
- 视图增加%rowtype属性
- 聚合函数distinct性能优化
- 聚合函数支持KEEP子句
- 聚合函数支持场景扩展
- 兼容支持MySQL别名支持单引号
- 支持current_date/current_time关键字作为字段名
- 自定义type数组
- For Update支持外连接
- MogDB支持Insert All特性
- Oracle DBLink语法兼容
- 创建PACKAGE/FUNCTION/PROCEDURE时去除TYPE类型转换提示
- 支持MERGE INTO命中索引时使用Bypass方法
- 支持增加存储过程及函数参数的nocopy属性
- 支持在数组extend的参数中传入数组的count属性
- 支持q quote转义字符
- 支持两个date类型的数据相减返回numeric类型
- 支持表函数table()
- 支持PROCEDURE/FUNCTION/PACKAGE的end后的name和Oracle保持一致
- 支持WHERE CURRENT OF写法
- 支持包内常量作为函数或者过程入参的默认值
- 支持PLPGSQL subtype
- 支持无参数FUNCTION的同义词调用不加括号
- 支持dbms_utility.format_error_backtrace
- 支持PIVOT和UNPIVOT语法
- mod函数兼容
- 支持聚集函数嵌套
- ORDER BY/GROUP BY场景兼容
- 支持在建表后修改表日志属性
- INSERT支持ON CONFLICT子句
- 支持AUTHID CURRENT_USER
- PBE模式支持存储过程out出参
- 数据库安全
- 企业级特性
- 应用开发接口
- AI能力
- 中间件
- 负载管理
- 安装指南
- 升级指南
- 管理指南
- 高可用指南
- AI特性指南
- 安全指南
- 开发者指南
- 应用程序开发教程
- 开发规范
- 基于JDBC开发
- JDBC包、驱动类和环境类
- 开发流程
- 加载驱动
- 连接数据库
- 连接数据库(以SSL方式)
- 连接数据库(UDS方式)
- 执行SQL语句
- 处理结果集
- 关闭连接
- 日志管理
- 示例:常用操作
- 示例:重新执行应用SQL
- 示例:通过本地文件导入导出数据
- 示例:从MY向MogDB进行数据迁移
- 示例:逻辑复制代码示例
- 示例:不同场景下连接数据库参数配置
- 示例:jdbc主备集群负载均衡
- 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
- JDBC常用参数参考
- JDBC发布记录
- 基于ODBC开发
- 基于libpq开发
- 基于Psycopg2开发
- 调试
- 存储过程
- 用户自定义函数
- PL/pgSQL-SQL过程语言
- 定时任务
- 自治事务
- 逻辑复制
- Extension
- MySQL兼容性说明
- Dolphin Extension
- Dolphin概述
- Dolphin安装
- Dolphin限制
- Dolphin语法介绍
- SQL参考
- 关键字
- 数据类型
- 函数和操作符
- 表达式
- DDL语法一览表
- DML语法一览表
- DCL语法一览表
- SQL语法
- ALTER DATABASE
- ALTER FUNCTION
- ALTER PROCEDURE
- ALTER SERVER
- ALTER TABLE
- ALTER TABLE PARTITION
- ALTER TABLESPACE
- ALTER VIEW
- ANALYZE | ANALYSE
- AST
- CHECKSUM TABLE
- CREATE DATABASE
- CREATE FUNCTION
- CREATE INDEX
- CREATE PROCEDURE
- CREATE SERVER
- CREATE TABLE
- CREATE TABLE AS
- CREATE TABLE PARTITION
- CREATE TABLESPACE
- CREATE TRIGGER
- CREATE VIEW
- DESCRIBE TABLE
- DO
- DROP DATABASE
- DROP INDEX
- DROP TABLESPACE
- EXECUTE
- EXPLAIN
- FLUSH BINARY LOGS
- GRANT
- GRANT/REVOKE PROXY
- INSERT
- KILL
- LOAD DATA
- OPTIMIZE TABLE
- PREPARE
- RENAME TABLE
- RENAME USER
- REVOKE
- SELECT
- SELECT HINT
- SET CHARSET
- SET PASSWORD
- SHOW CHARACTER SET
- SHOW COLLATION
- SHOW COLUMNS
- SHOW CREATE DATABASE
- SHOW CREATE FUNCTION
- SHOW CREATE PROCEDURE
- SHOW CREATE TABLE
- SHOW CREATE TRIGGER
- SHOW CREATE VIEW
- SHOW DATABASES
- SHOW FUNCTION STATUS
- SHOW GRANTS
- SHOW INDEX
- SHOW MASTER STATUS
- SHOW PLUGINS
- SHOW PRIVILEGES
- SHOW PROCEDURE STATUS
- SHOW PROCESSLIST
- SHOW SLAVE HOSTS
- SHOW STATUS
- SHOW TABLES
- SHOW TABLE STATUS
- SHOW TRIGGERS
- SHOW VARIABLES
- SHOW WARNINGS/ERRORS
- UPDATE
- USE db_name
- 系统视图
- GUC参数说明
- 重设参数
- 存储过程
- 标识符说明
- SQL参考
- MySQL语法兼容性评估工具
- Dolphin Extension
- 物化视图
- 分区管理
- 应用程序开发教程
- 性能优化指南
- 参考指南
- 系统表及系统视图
- 系统表和系统视图概述
- 查看系统表
- 系统表
- GS_ASP
- 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_DB_PRIVILEGE
- GS_ENCRYPTED_COLUMNS
- GS_ENCRYPTED_PROC
- GS_GLOBAL_CHAIN
- GS_GLOBAL_CONFIG
- GS_MASKING_POLICY
- GS_MASKING_POLICY_ACTIONS
- GS_MASKING_POLICY_FILTERS
- GS_MATVIEW
- GS_MATVIEW_DEPENDENCY
- GS_MODEL_WAREHOUSE
- GS_OPT_MODEL
- GS_PACKAGE
- GS_POLICY_LABEL
- GS_RECYCLEBIN
- GS_TXN_SNAPSHOT
- GS_UID
- GS_WLM_EC_OPERATOR_INFO
- GS_WLM_INSTANCE_HISTORY
- GS_WLM_OPERATOR_INFO
- GS_WLM_PLAN_ENCODING_TABLE
- GS_WLM_PLAN_OPERATOR_INFO
- GS_WLM_SESSION_QUERY_INFO_ALL
- GS_WLM_USER_RESOURCE_HISTORY
- PG_AGGREGATE
- PG_AM
- PG_AMOP
- PG_AMPROC
- PG_APP_WORKLOADGROUP_MAPPING
- PG_ATTRDEF
- PG_ATTRIBUTE
- PG_AUTH_HISTORY
- PG_AUTH_MEMBERS
- PG_AUTHID
- 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_EVENT_TRIGGER
- PG_EXTENSION
- PG_EXTENSION_DATA_SOURCE
- PG_FOREIGN_DATA_WRAPPER
- PG_FOREIGN_SERVER
- PG_FOREIGN_TABLE
- PG_HASHBUCKET
- 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_PUBLICATION
- PG_PUBLICATION_REL
- PG_RANGE
- PG_REPLICATION_ORIGIN
- PG_RESOURCE_POOL
- PG_REWRITE
- PG_RLSPOLICY
- PG_SECLABEL
- PG_SET
- PG_SHDEPEND
- PG_SHDESCRIPTION
- PG_SHSECLABEL
- PG_STATISTIC
- PG_STATISTIC_EXT
- PG_SUBSCRIPTION
- PG_SUBSCRIPTION_REL
- 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
- PGXC_CLASS
- PGXC_GROUP
- PGXC_NODE
- PGXC_SLICE
- PLAN_TABLE_DATA
- STATEMENT_HISTORY
- 系统视图
- GET_GLOBAL_PREPARED_XACTS(废弃)
- GS_ASYNC_SUBMIT_SESSIONS_STATUS
- GS_AUDITING
- GS_AUDITING_ACCESS
- GS_AUDITING_PRIVILEGE
- GS_CLUSTER_RESOURCE_INFO
- GS_COMPRESSION
- GS_DB_PRIVILEGES
- GS_FILE_STAT
- GS_GSC_MEMORY_DETAIL
- GS_INSTANCE_TIME
- GS_LABELS
- GS_LSC_MEMORY_DETAIL
- GS_MASKING
- GS_MATVIEWS
- GS_OS_RUN_INFO
- GS_REDO_STAT
- GS_SESSION_CPU_STATISTICS
- GS_SESSION_MEMORY
- GS_SESSION_MEMORY_CONTEXT
- GS_SESSION_MEMORY_DETAIL
- GS_SESSION_MEMORY_STATISTICS
- GS_SESSION_STAT
- GS_SESSION_TIME
- GS_SHARED_MEMORY_DETAIL
- GS_SQL_COUNT
- GS_STAT_SESSION_CU
- GS_THREAD_MEMORY_CONTEXT
- GS_TOTAL_MEMORY_DETAIL
- GS_WLM_CGROUP_INFO
- GS_WLM_EC_OPERATOR_STATISTICS
- GS_WLM_OPERATOR_HISTORY
- GS_WLM_OPERATOR_STATISTICS
- GS_WLM_PLAN_OPERATOR_HISTORY
- GS_WLM_REBUILD_USER_RESOURCE_POOL
- GS_WLM_RESOURCE_POOL
- GS_WLM_SESSION_HISTORY
- GS_WLM_SESSION_INFO
- GS_WLM_SESSION_INFO_ALL
- GS_WLM_SESSION_STATISTICS
- GS_WLM_USER_INFO
- IOS_STATUS
- 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_ATTACHED_PIDS
- PG_GTT_RELSTATS
- PG_GTT_STATS
- PG_INDEXES
- PG_LOCKS
- PG_NODE_ENV
- PG_OS_THREADS
- PG_PREPARED_STATEMENTS
- PG_PREPARED_XACTS
- PG_PUBLICATION_TABLES
- PG_REPLICATION_ORIGIN_STATUS
- PG_REPLICATION_SLOTS
- PG_RLSPOLICIES
- PG_ROLES
- PG_RULES
- PG_RUNNING_XACTS
- PG_SECLABELS
- PG_SESSION_IOSTAT
- PG_SESSION_WLMSTAT
- PG_SETTINGS
- PG_SHADOW
- PG_STAT_ACTIVITY
- PG_STAT_ACTIVITY_NG
- PG_STAT_ALL_INDEXES
- PG_STAT_ALL_TABLES
- PG_STAT_BAD_BLOCK
- PG_STAT_BGWRITER
- PG_STAT_DATABASE
- PG_STAT_DATABASE_CONFLICTS
- PG_STAT_REPLICATION
- PG_STAT_SUBSCRIPTION
- PG_STAT_SYS_INDEXES
- PG_STAT_SYS_TABLES
- PG_STAT_USER_FUNCTIONS
- PG_STAT_USER_INDEXES
- PG_STAT_USER_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_STATS
- 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
- PG_WLM_STATISTICS
- PGXC_PREPARED_XACTS
- PLAN_TABLE
- PATCH_INFORMATION_TABLE
- 系统函数
- 逻辑操作符
- 比较操作符
- 字符处理函数和操作符
- 二进制字符串函数和操作符
- 位串函数和操作符
- 模式匹配操作符
- 数字操作函数和操作符
- 时间和日期处理函数和操作符
- 类型转换函数
- 几何函数和操作符
- 网络地址函数和操作符
- 文本检索函数和操作符
- JSON/JSONB函数和操作符
- HLL函数和操作符
- SEQUENCE函数
- 数组函数和操作符
- 范围函数和操作符
- 聚集函数
- 窗口函数(分析函数)
- 安全函数
- 账本数据库的函数
- 密态等值的函数
- 返回集合的函数
- 条件表达式函数
- 系统信息函数
- 系统管理函数
- 统计信息函数
- 触发器函数
- 事件触发器函数
- HashFunc函数
- 提示信息函数
- 全局临时表函数
- 故障注入系统函数
- AI特性函数
- 动态数据脱敏函数
- 其他系统函数
- 内部函数
- Global SysCache特性函数
- 数据损坏检测修复函数
- XML类型函数
- 废弃函数
- 支持的数据类型
- SQL语法
- ABORT
- ALTER AGGREGATE
- ALTER AUDIT POLICY
- ALTER DATABASE
- ALTER DATA SOURCE
- ALTER DEFAULT PRIVILEGES
- ALTER DIRECTORY
- ALTER EVENT
- ALTER EVENT TRIGGER
- ALTER EXTENSION
- ALTER FOREIGN DATA WRAPPER
- ALTER FOREIGN TABLE
- ALTER FUNCTION
- ALTER GLOBAL CONFIGURATION
- ALTER GROUP
- ALTER INDEX
- ALTER LANGUAGE
- ALTER LARGE OBJECT
- ALTER MASKING POLICY
- ALTER MATERIALIZED VIEW
- ALTER OPERATOR
- ALTER PACKAGE
- ALTER PROCEDURE
- ALTER PUBLICATION
- ALTER RESOURCE LABEL
- ALTER RESOURCE POOL
- ALTER ROLE
- ALTER ROW LEVEL SECURITY POLICY
- ALTER RULE
- ALTER SCHEMA
- ALTER SEQUENCE
- ALTER SERVER
- ALTER SESSION
- ALTER SUBSCRIPTION
- 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 EVENT
- CREATE EVENT TRIGGER
- CREATE EXTENSION
- CREATE FOREIGN DATA WRAPPER
- 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 PROCEDURE
- CREATE PUBLICATION
- CREATE RESOURCE LABEL
- CREATE RESOURCE POOL
- CREATE ROLE
- CREATE ROW LEVEL SECURITY POLICY
- CREATE RULE
- CREATE SCHEMA
- CREATE SEQUENCE
- CREATE SERVER
- CREATE SUBSCRIPTION
- CREATE SYNONYM
- CREATE TABLE
- CREATE TABLE AS
- CREATE TABLE PARTITION
- CREATE TABLESPACE
- CREATE TABLE SUBPARTITION
- 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
- DELIMITER
- DO
- DROP AGGREGATE
- DROP AUDIT POLICY
- DROP CAST
- DROP CLIENT MASTER KEY
- DROP COLUMN ENCRYPTION KEY
- DROP DATABASE
- DROP DATA SOURCE
- DROP DIRECTORY
- DROP EVENT
- DROP EVENT TRIGGER
- DROP EXTENSION
- DROP FOREIGN DATA WRAPPER
- DROP FOREIGN TABLE
- DROP FUNCTION
- DROP GLOBAL CONFIGURATION
- DROP GROUP
- DROP INDEX
- DROP LANGUAGE
- DROP MASKING POLICY
- DROP MATERIALIZED VIEW
- DROP MODEL
- DROP OPERATOR
- DROP OWNED
- DROP PACKAGE
- DROP PROCEDURE
- DROP PUBLICATION
- DROP RESOURCE LABEL
- DROP RESOURCE POOL
- DROP ROLE
- DROP ROW LEVEL SECURITY POLICY
- DROP RULE
- DROP SCHEMA
- DROP SEQUENCE
- DROP SERVER
- DROP SUBSCRIPTION
- 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
- MERGE INTO
- MOVE
- 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
- SHOW EVENTS
- SHRINK
- 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_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.turn_on
- DBE_PLDEBUGGER.turn_off
- DBE_PLDEBUGGER.local_debug_server_info
- DBE_PLDEBUGGER.attach
- DBE_PLDEBUGGER.info_locals
- 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.disable_breakpoint
- DBE_PLDEBUGGER.enable_breakpoint
- DBE_PLDEBUGGER.finish
- DBE_PLDEBUGGER.set_var
- DB4AI Schema
- DBE_PLDEVELOPER
- DBE_SQL_UTIL Schema
- 工具参考
- 工具一览表
- 客户端工具
- 服务端工具
- 系统内部使用的工具
- dsscmd
- dssserver
- mogdb
- gs_backup
- gs_basebackup
- gs_ctl
- gs_initdb
- gs_install
- gs_postuninstall
- 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
- MogDB可运行脚本功能说明
- 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 07500
- GAUSS 50000 - GAUSS 50999
- GAUSS 51000 - GAUSS 51999
- GAUSS 52000 - GAUSS 52999
- GAUSS 53000 - GAUSS 53699
- 错误日志信息参考
- 系统表及系统视图
- 故障诊断指南
- 源码解析
- 常见问题解答 (FAQs)
- 术语表
- 通信矩阵
- Mogeaver
分区表
一张表内的数据过多时,就会严重影响到数据的查询和操作效率。MogDB支持把一张表从逻辑上分成多个小的分片,从而避免一次处理大量数据,提高处理效率。
MogDB数据库支持这些划分类型:
- 范围分区表:指定一个或多个列划分为多个范围,每个范围创建一个分区,用来存储相应的数据。例如可以采用日期划分范围,将销售数据按照月份进行分区。
- 列表分区表:直接按照一个列上的值来划分出分区。例如可以采用销售门店划分销售数据。
- 间隔分区表:是一种特殊的范围分区,新增了间隔值定义。当插入记录找不到匹配的分区时可以根据间隔值自动创建分区。
- 哈希分区表:根据表的一列,为每个分区指定模数和余数,将要插入表的记录划分到对应的分区中。
分区表的操作除了创建之外还有:
- 查询分区表:按照分区名或者分区中的值查询数据。
- 导入数据:直接导入数据或从现有表格中导入。
- 修改分区表:包括增加分区、删除分区、切割分区、合并分区,以及修改分区名称等。
- 删除分区表:与删除普通表格相同。
范围分区表的分类
范围分区表按照划分范围的方式,分为以下类别:
- VALUES LESS THAN:通过给出每个分区的上限来确定分区范围。上个分区的上限<=分区的范围<本分区的上限。
- START END:通过以下方式划分:
- 分区的起点和终点;
- 仅给出分区起点;
- 仅给出分区终点;
- 给出分区起点和终点后,再给出该范围内的间隔值
- 以上这些方式的综合应用。
创建VALUES LESS THAN范围分区表语法格式
CREATE TABLE partition_table_name
( [column_name data_type ]
[, ... ]
)
PARTITION BY RANGE (partition_key)
(
PARTITION partition_name VALUES LESS THAN (partition_value | MAXVALUE)
[, ... ]
);
创建VALUES LESS THAN范围分区表参数说明
-
partition_table_name
分区表的名称。
-
column_name
新表中要创建的字段名。
-
data_type
字段的数据类型。
-
partition_key
partition_key为分区键的名称。
对于从句是VALUE LESS THAN的语法格式,范围分区策略的分区键最多支持4列。
-
partition_name
partition_name为范围分区的名称。
-
VALUES LESS THAN
分区中的数值必须小于上边界值。
-
partition_value
partition_value为范围分区的上边界,取值依赖于partition_key的类型。
-
MAXVALUE
MAXVALUE表示分区的上边界,它通常用于设置最后一个范围分区的上边界。
创建VALUES LESS THAN范围分区表示例
示例1:创建范围分区表sales_table,含有4个分区,分区键为DATE类型。分区的范围分别为:sales_date<2021-04-01,2021-04-01<= sales_date<2021-07-01,2021-07-01<=sales_date< 2021-10-01,2021-10-01 <= sales_date< MAXVALUE。
--创建分区表sales_table。
MogDB=# CREATE TABLE sales_table
(
order_no INTEGER NOT NULL,
goods_name CHAR(20) NOT NULL,
sales_date DATE NOT NULL,
sales_volume INTEGER,
sales_store CHAR(20)
)
PARTITION BY RANGE(sales_date)
(
PARTITION season1 VALUES LESS THAN('2021-04-01 00:00:00'),
PARTITION season2 VALUES LESS THAN('2021-07-01 00:00:00'),
PARTITION season3 VALUES LESS THAN('2021-10-01 00:00:00'),
PARTITION season4 VALUES LESS THAN(MAXVALUE)
);
-- 数据插入分区season1
MogDB=# INSERT INTO sales_table VALUES(1, 'jacket', '2021-01-10 00:00:00', 3,'Alaska');
-- 数据插入分区season2
MogDB=# INSERT INTO sales_table VALUES(2, 'hat', '2021-05-06 00:00:00', 5,'Clolorado');
-- 数据插入分区season3
MogDB=# INSERT INTO sales_table VALUES(3, 'shirt', '2021-09-17 00:00:00', 7,'Florida');
-- 数据插入分区season4
MogDB=# INSERT INTO sales_table VALUES(4, 'coat', '2021-10-21 00:00:00', 9,'Hawaii');
查询分区表语法格式
SELECT * FROM partition_table_name PARTITION { ( partition_name ) | FOR ( partition_value [, ...] ) }
查询分区表参数说明
-
partition_table_name
分区表的名称。
-
partition_name
partition_name为分区的名称。
-
partition_value
用于指定分区的值。PARTITION FOR子句指定的值所在的分区,就是进行查询的分区。
查询分区表语法示例
示例2:查询示例1中建立的分区表sales_table。
--查询sales_table的数据。
MogDB=# SELECT * FROM sales_table;
order_no | goods_name | sales_date | sales_volume | sale
s_store
----------+----------------------+---------------------+--------------+---------
-------------
1 | jacket | 2021-01-10 00:00:00 | 3 | Alaska
2 | hat | 2021-05-06 00:00:00 | 5 | Clolorado
3 | shirt | 2021-09-17 00:00:00 | 7 | Florida
4 | coat | 2021-10-21 00:00:00 | 9 | Hawaii
(4 rows)
--查询sales_table的4季度数据。这里采用“sales_table PARTITION (season4);”来引用第4季度数据所在分区。
MogDB=# SELECT * FROM sales_table PARTITION (season4);
order_no | goods_name | sales_date | sales_volume | sales_store
----------+----------------------+---------------------+--------------+----------------------
4 | coat | 2021-10-21 00:00:00 | 9 | Hawaii
(1 row)
--查询sales_table的1季度数据。这里采用“sales_table PARTITION FOR ('2021-3-21 00:00:00')”来引用第1季度数据所在分区。其中的'2021-3-21 00:00:00'处于第1季度所在分区。
MogDB=# SELECT * FROM sales_table PARTITION FOR ('2021-3-21 00:00:00');
order_no | goods_name | sales_date | sales_volume | sales_store
----------+----------------------+---------------------+--------------+----------------------
1 | jacket | 2021-01-10 00:00:00 | 3 | Alaska
(1 row)
创建START END范围分区表语法格式
START END范围分区表有多种表达方式,而且这些方式可以在一个分区表内组合使用。
-
方式一:START(partition_value) END (partition_value | MAXVALUE)方式
CREATE TABLE partition_table_name ( [column_name data_type ] [, ... ] ) PARTITION BY RANGE (partition_key) ( PARTITION partition_name START(partition_value) END (partition_value | MAXVALUE) [, ... ] );
-
CREATE TABLE partition_table_name ( [column_name data_type ] [, ... ] ) PARTITION BY RANGE (partition_key) ( PARTITION partition_name START(partition_value) [, ... ] );
-
方式三:END(partition_value | MAXVALUE)方式
CREATE TABLE partition_table_name ( [column_name data_type ] [, ... ] ) PARTITION BY RANGE (partition_key) ( PARTITION partition_name END(partition_value | MAXVALUE) [, ... ] );
-
方式四:START(partition_value) END (partition_value) EVERY (interval_value)方式
CREATE TABLE partition_table_name ( [column_name data_type ] [, ... ] ) PARTITION BY RANGE (partition_key) ( PARTITION partition_name START(partition_value) END (partition_value) EVERY (interval_value) [, ... ] );
创建START END范围分区表参数说明
-
partition_table_name
分区表的名称。
-
column_name
新表中要创建的字段名。
-
data_type
字段的数据类型。
-
partition_key
partition_key为分区键的名称。
对于从句是START END的语法格式,范围分区策略的分区键仅支持1列。
-
partition_name
partition_name为范围分区的名称或者范围分区的名称前缀。
-
若该定义是“START(partition_value) END (partition_value) EVERY (interval_value)”从句,假定其中的partition_name是p1,则分区的名称依次为p1_1, p1_2, …。
例如对于定义“PARTITION p1 START(1) END(4) EVERY(1)”,则生成的分区是:[1, 2), [2, 3) 和 [3, 4),名称依次为p1_1, p1_2和p1_3,即此处的p1是名称前缀。
-
若该定义是第一个分区定义,且该定义有START值,则范围(MINVALUE, START)将自动作为第一个实际分区,其名称为p1_0,然后该定义语义描述的分区名称依次为p1_1, p1_2, …。
例如对于完整定义“PARTITION p1 START(1), PARTITION p2 START(2)”,生成的分区是:(MINVALUE, 1), [1, 2) 和 [2, MAXVALUE),其名称依次为p1_0, p1_1和p2,即此处p1是名称前缀,p2是分区名称。这里MINVALUE表示最小值。
-
其余的情况都是范围分区名称。
-
-
VALUES LESS THAN
分区中的数值必须小于上边界值。
-
partition_value
partition_value为范围分区的端点值(起始或终点),取值依赖于partition_key的类型。
-
interval_value:
对[START,END) 表示的范围进行切分,interval_value是指定切分后每个分区的宽度。如果(END-START)值不能整除以EVERY值,则仅最后一个分区的宽度小于EVERY值。
-
MAXVALUE
MAXVALUE表示分区的上边界,它通常用于设置最后一个范围分区的上边界。
创建START END范围分区表示例
示例3:以“START(partition_value) END (partition_value | MAXVALUE)”方式创建START END范围分区表graderecord。含有3个分区,分区键为INTEGER类型。分区的范围分别为:0<= grade<60,60<= grade<90,90<=grade< MAXVALUE。
--创建分区表graderecord。
MogDB=# CREATE TABLE graderecord
(
number INTEGER,
name CHAR(20),
class CHAR(20),
grade INTEGER
)
PARTITION BY RANGE(grade)
(
PARTITION pass START(60) END(90),
PARTITION excellent START(90) END(MAXVALUE)
);
-- 数据插入分区。
MogDB=# insert into graderecord values('210101','Alan','21.01',92);
MogDB=# insert into graderecord values('210102','Ben','21.01',62);
MogDB=# insert into graderecord values('210103','Brain','21.01',26);
MogDB=# insert into graderecord values('210204','Carl','21.02',77);
MogDB=# insert into graderecord values('210205','David','21.02',47);
MogDB=# insert into graderecord values('210206','Eric','21.02',97);
MogDB=# insert into graderecord values('210307','Frank','21.03',90);
MogDB=# insert into graderecord values('210308','Gavin','21.03',100);
MogDB=# insert into graderecord values('210309','Henry','21.03',67);
MogDB=# insert into graderecord values('210410','Jack','21.04',75);
MogDB=# insert into graderecord values('210311','Jerry','21.04',60);
--查询graderecord的数据。
MogDB=# SELECT * FROM graderecord;
number | name | class | grade
--------+----------------------+----------------------+-------
210103 | Brain | 21.01 | 26
210205 | David | 21.02 | 47
210102 | Ben | 21.01 | 62
210204 | Carl | 21.02 | 77
210309 | Henry | 21.03 | 67
210410 | Jack | 21.04 | 75
210311 | Jerry | 21.04 | 60
210101 | Alan | 21.01 | 92
210206 | Eric | 21.02 | 97
210307 | Frank | 21.03 | 90
210308 | Gavin | 21.03 | 100
(11 rows)
--查询graderecord的pass分区数据。
MogDB=# SELECT * FROM graderecord PARTITION (pass);
ERROR: partition "pass" of relation "graderecord" does not exist
查询失败。
原因是“PARTITION pass START(60) END(90),”是第一个分区定义,且该定义有START值,则范围(MINVALUE, 60)将自动作为第一个实际分区,其名称为“pass_0”。
而该定义语义描述的“60<= grade<90”分区的名称为“pass_1”。
--查询graderecord的pass_0分区数据。
MogDB=# SELECT * FROM graderecord PARTITION (pass_0);
number | name | class | grade
--------+----------------------+----------------------+-------
210103 | Brain | 21.01 | 26
210205 | David | 21.02 | 47
(2 rows)
--查询graderecord的pass_1分区数据。
MogDB=# SELECT * FROM graderecord PARTITION (pass_1);
number | name | class | grade
--------+----------------------+----------------------+-------
210102 | Ben | 21.01 | 62
210204 | Carl | 21.02 | 77
210309 | Henry | 21.03 | 67
210410 | Jack | 21.04 | 75
210311 | Jerry | 21.04 | 60
(5 rows)
--查询graderecord的execllent分区数据。
MogDB=# SELECT * FROM graderecord PARTITION (excellent);
number | name | class | grade
--------+----------------------+----------------------+-------
210101 | Alan | 21.01 | 92
210206 | Eric | 21.02 | 97
210307 | Frank | 21.03 | 90
210308 | Gavin | 21.03 | 100
(4 rows)
示例4:以“START(partition_value) END (partition_value) EVERY (interval_value)”方式创建START END范围分区表metro_ride_record。含有7个分区,分区键为INTEGER类型。总范围是ride_stations_number<21, 每3站为一个分区。
--创建分区表metro_ride_record。记录乘车人、上下车站点、乘坐站点数量。并按照乘坐站点数量,每3站建立一个分区。
MogDB=# CREATE TABLE metro_ride_record
(
record_number INTEGER,
name CHAR(20),
enter_station CHAR(20),
leave_station CHAR(20),
ride_stations_number INTEGER
)
PARTITION BY RANGE(ride_stations_number)
(
PARTITION cost START(3) END(21) EVERY (3)
);
-- 数据插入分区。
MogDB=# insert into metro_ride_record values('120101','Brain','Tung Chung','Tsing Yi',2);
MogDB=# insert into metro_ride_record values('120102','David','Po Lam','Yau Tong',4);
MogDB=# insert into metro_ride_record values('120103','Ben','Yau Ma Tei','Wong Tai Sin',6);
MogDB=# insert into metro_ride_record values('120104','Carl','Tai Wo Hau','Prince Edward',8);
MogDB=# insert into metro_ride_record values('120105','Henry','Admiralty','Lai King',10);
MogDB=# insert into metro_ride_record values('120106','Jack','Chai Wan','Central',12);
MogDB=# insert into metro_ride_record values('120107','Jerry','Central','Tai Wo Hau',14);
MogDB=# insert into metro_ride_record values('120108','Alan','Diamond Hill','Kwai Hing',16);
MogDB=# insert into metro_ride_record values('120109','Eric','Jordan','Shek Kip Mei',18);
MogDB=# insert into metro_ride_record values('120110','Frank','Lok Fu','Sunny Bay',20);
--查询metro_ride_record的数据。
MogDB=# SELECT * FROM metro_ride_record;
record_number | name | enter_station | leave_station | ride_stations_number
---------------+----------------------+----------------------+----------------------+----------------------
120101 | Brain | Tung Chung | Tsing Yi | 2
120102 | David | Po Lam | Yau Tong | 4
120103 | Ben | Yau Ma Tei | Wong Tai Sin | 6
120104 | Carl | Tai Wo Hau | Prince Edward | 8
120105 | Henry | Admiralty | Lai King | 10
120106 | Jack | Chai Wan | Central | 12
120107 | Jerry | Central | Tai Wo Hau | 14
120108 | Alan | Diamond Hill | Kwai Hing | 16
120109 | Eric | Jordan | Shek Kip Mei | 18
120110 | Frank | Lok Fu | Sunny Bay | 20
(10 rows)
“PARTITION cost START(3) END(21) EVERY (3)”是第一个分区定义,且该定义有START值,则范围(MINVALUE, 3)将自动作为第一个实际分区,其名称为“cost_0”。
其余分区依次为“cost_1”、...、“cost_6”.
--查询metro_ride_record的cost_0分区数据。
MogDB=# SELECT * FROM metro_ride_record PARTITION (cost_0);
record_number | name | enter_station | leave_station | ride_stations_number
---------------+----------------------+----------------------+----------------------+----------------------
120101 | Brain | Tung Chung | Tsing Yi | 2
(1 row)
--查询metro_ride_record的cost_1分区数据。
MogDB=# SELECT * FROM metro_ride_record PARTITION (cost_1);
record_number | name | enter_station | leave_station | ride_stations_number
---------------+----------------------+----------------------+----------------------+----------------------
120102 | David | Po Lam | Yau Tong | 4
(1 row)
--查询metro_ride_record的cost_6分区数据。
MogDB=# SELECT * FROM metro_ride_record PARTITION (cost_6);
record_number | name | enter_station | leave_station | ride_stations_number
---------------+----------------------+----------------------+----------------------+----------------------
120109 | Eric | Jordan | Shek Kip Mei | 18
120110 | Frank | Lok Fu | Sunny Bay | 20
(2 rows)
示例5:以“START(partition_value) ”方式创建START END范围分区表graderecord。含有3个分区,分区键为INTEGER类型。分区的范围分别为:0<= grade<60,60<= grade<90,90<=grade< MAXVALUE。
--创建分区表graderecord。
MogDB=# CREATE TABLE graderecord
(
number INTEGER,
name CHAR(20),
class CHAR(20),
grade INTEGER
)
PARTITION BY RANGE(grade)
(
PARTITION pass START(60),
PARTITION excellent START(90)
);
-- 数据插入分区。
MogDB=# insert into graderecord values('210101','Alan','21.01',92);
MogDB=# insert into graderecord values('210102','Ben','21.01',62);
MogDB=# insert into graderecord values('210103','Brain','21.01',26);
MogDB=# insert into graderecord values('210204','Carl','21.02',77);
MogDB=# insert into graderecord values('210205','David','21.02',47);
MogDB=# insert into graderecord values('210206','Eric','21.02',97);
MogDB=# insert into graderecord values('210307','Frank','21.03',90);
MogDB=# insert into graderecord values('210308','Gavin','21.03',100);
MogDB=# insert into graderecord values('210309','Henry','21.03',67);
MogDB=# insert into graderecord values('210410','Jack','21.04',75);
MogDB=# insert into graderecord values('210311','Jerry','21.04',60);
--查询graderecord的数据。
MogDB=# SELECT * FROM graderecord;
number | name | class | grade
--------+----------------------+----------------------+-------
210103 | Brain | 21.01 | 26
210205 | David | 21.02 | 47
210102 | Ben | 21.01 | 62
210204 | Carl | 21.02 | 77
210309 | Henry | 21.03 | 67
210410 | Jack | 21.04 | 75
210311 | Jerry | 21.04 | 60
210101 | Alan | 21.01 | 92
210206 | Eric | 21.02 | 97
210307 | Frank | 21.03 | 90
210308 | Gavin | 21.03 | 100
(11 rows)
--查询graderecord的pass分区数据。
MogDB=# SELECT * FROM graderecord PARTITION (pass);
ERROR: partition "pass" of relation "graderecord" does not exist
查询失败。
原因是“PARTITION pass START(60),”是第一个分区定义,且该定义有START值,则范围(MINVALUE, 60)将自动作为第一个实际分区,其名称为“pass_0”。
而该定义语义描述的“60<= grade<90”分区的名称为“pass_1”。
--查询graderecord的pass_0分区数据。
MogDB=# SELECT * FROM graderecord PARTITION (pass_0);
number | name | class | grade
--------+----------------------+----------------------+-------
210103 | Brain | 21.01 | 26
210205 | David | 21.02 | 47
(2 rows)
--查询graderecord的pass_1分区数据。
MogDB=# SELECT * FROM graderecord PARTITION (pass_1);
number | name | class | grade
--------+----------------------+----------------------+-------
210102 | Ben | 21.01 | 62
210204 | Carl | 21.02 | 77
210309 | Henry | 21.03 | 67
210410 | Jack | 21.04 | 75
210311 | Jerry | 21.04 | 60
(5 rows)
--查询graderecord的execllent分区数据。
MogDB=# SELECT * FROM graderecord PARTITION (excellent);
number | name | class | grade
--------+----------------------+----------------------+-------
210101 | Alan | 21.01 | 92
210206 | Eric | 21.02 | 97
210307 | Frank | 21.03 | 90
210308 | Gavin | 21.03 | 100
(4 rows)
示例6:以“END(partition_value | MAXVALUE) ”方式创建START END范围分区表graderecord。含有3个分区,分区键为INTEGER类型。分区的范围分别为:0<= grade<60,60<= grade<90,90<=grade< MAXVALUE。。
--创建分区表graderecord。
MogDB=# CREATE TABLE graderecord
(
number INTEGER,
name CHAR(20),
class CHAR(20),
grade INTEGER
)
PARTITION BY RANGE(grade)
(
PARTITION no_pass END(60),
PARTITION pass END(90),
PARTITION excellent END(MAXVALUE)
);
-- 数据插入分区。
MogDB=# insert into graderecord values('210101','Alan','21.01',92);
MogDB=# insert into graderecord values('210102','Ben','21.01',62);
MogDB=# insert into graderecord values('210103','Brain','21.01',26);
MogDB=# insert into graderecord values('210204','Carl','21.02',77);
MogDB=# insert into graderecord values('210205','David','21.02',47);
MogDB=# insert into graderecord values('210206','Eric','21.02',97);
MogDB=# insert into graderecord values('210307','Frank','21.03',90);
MogDB=# insert into graderecord values('210308','Gavin','21.03',100);
MogDB=# insert into graderecord values('210309','Henry','21.03',67);
MogDB=# insert into graderecord values('210410','Jack','21.04',75);
MogDB=# insert into graderecord values('210311','Jerry','21.04',60);
--查询graderecord的数据。
MogDB=# SELECT * FROM graderecord;
number | name | class | grade
--------+----------------------+----------------------+-------
210103 | Brain | 21.01 | 26
210205 | David | 21.02 | 47
210102 | Ben | 21.01 | 62
210204 | Carl | 21.02 | 77
210309 | Henry | 21.03 | 67
210410 | Jack | 21.04 | 75
210311 | Jerry | 21.04 | 60
210101 | Alan | 21.01 | 92
210206 | Eric | 21.02 | 97
210307 | Frank | 21.03 | 90
210308 | Gavin | 21.03 | 100
(11 rows)
--查询graderecord的no_pass分区数据。
MogDB=# SELECT * FROM graderecord PARTITION (no_pass);
number | name | class | grade
--------+----------------------+----------------------+-------
210103 | Brain | 21.01 | 26
210205 | David | 21.02 | 47
(2 rows)
--查询graderecord的pass分区数据。
MogDB=# SELECT * FROM graderecord PARTITION (pass);
number | name | class | grade
--------+----------------------+----------------------+-------
210102 | Ben | 21.01 | 62
210204 | Carl | 21.02 | 77
210309 | Henry | 21.03 | 67
210410 | Jack | 21.04 | 75
210311 | Jerry | 21.04 | 60
(5 rows)
--查询graderecord的execllent分区数据。
MogDB=# SELECT * FROM graderecord PARTITION (excellent);
number | name | class | grade
--------+----------------------+----------------------+-------
210101 | Alan | 21.01 | 92
210206 | Eric | 21.02 | 97
210307 | Frank | 21.03 | 90
210308 | Gavin | 21.03 | 100
(4 rows)
创建列表分区表语法格式
CREATE TABLE partition_table_name
( [column_name data_type ]
[, ... ]
)
PARTITION BY LIST (partition_key)
(
PARTITION partition_name VALUES (list_values_clause)
[, ... ]
);
创建列表分区表参数说明
-
partition_table_name
分区表的名称。
-
column_name
新表中要创建的字段名。
-
data_type
字段的数据类型。
-
partition_key
partition_key为分区键的名称。
列表分区策略的分区键仅支持1列。
-
partition_name
partition_name为范围分区的名称。
-
list_values_clause
对应分区存在的一个或者多个键值。多个键值之间以逗号分隔。
-
VALUES (DEFAULT)
加入的数据如有“list_values_clause”中未列出的键值,存放在VALUES (DEFAULT)对应的分区。
-
MAXVALUE
MAXVALUE表示分区的上边界,它通常用于设置最后一个范围分区的上边界。
创建列表分区表示例
示例7:创建列表分区表graderecord。含有4个分区,分区键为CHAR类型。分区的范围分别为:21.01,21.02,21.03,21.04。
--创建分区表graderecord。
MogDB=# CREATE TABLE graderecord
(
number INTEGER,
name CHAR(20),
class CHAR(20),
grade INTEGER
)
PARTITION BY LIST(class)
(
PARTITION class_01 VALUES ('21.01'),
PARTITION class_02 VALUES ('21.02'),
PARTITION class_03 VALUES ('21.03'),
PARTITION class_04 VALUES ('21.04')
);
-- 数据插入分区。
MogDB=# insert into graderecord values('210101','Alan','21.01',92);
MogDB=# insert into graderecord values('210102','Ben','21.01',62);
MogDB=# insert into graderecord values('210103','Brain','21.01',26);
MogDB=# insert into graderecord values('210204','Carl','21.02',77);
MogDB=# insert into graderecord values('210205','David','21.02',47);
MogDB=# insert into graderecord values('210206','Eric','21.02',97);
MogDB=# insert into graderecord values('210307','Frank','21.03',90);
MogDB=# insert into graderecord values('210308','Gavin','21.03',100);
MogDB=# insert into graderecord values('210309','Henry','21.03',67);
MogDB=# insert into graderecord values('210410','Jack','21.04',75);
MogDB=# insert into graderecord values('210311','Jerry','21.04',60);
--查询graderecord的数据。
MogDB=# SELECT * FROM graderecord;
number | name | class | grade
--------+----------------------+----------------------+-------
210410 | Jack | 21.04 | 75
210311 | Jerry | 21.04 | 60
210307 | Frank | 21.03 | 90
210308 | Gavin | 21.03 | 100
210309 | Henry | 21.03 | 67
210204 | Carl | 21.02 | 77
210205 | David | 21.02 | 47
210206 | Eric | 21.02 | 97
210101 | Alan | 21.01 | 92
210102 | Ben | 21.01 | 62
210103 | Brain | 21.01 | 26
(11 rows)
--查询graderecord的class_01分区数据。
MogDB=# SELECT * FROM graderecord PARTITION (class_01);
number | name | class | grade
--------+----------------------+----------------------+-------
210101 | Alan | 21.01 | 92
210102 | Ben | 21.01 | 62
210103 | Brain | 21.01 | 26
(3 rows)
--查询graderecord的class_04分区数据。
MogDB=# SELECT * FROM graderecord PARTITION (class_04);
number | name | class | grade
--------+----------------------+----------------------+-------
210410 | Jack | 21.04 | 75
210311 | Jerry | 21.04 | 60
(2 rows)
创建间隔分区表语法格式
间隔分区是在范围分区的基础上,增加了间隔值“PARTITION BY RANGE (partition_key)”的定义。
VALUES LESS THAN间隔分区语法格式:
CREATE TABLE partition_table_name
( [column_name data_type ]
[, ... ]
)
PARTITION BY RANGE (partition_key)
(
INTERVAL ('interval_expr')
PARTITION partition_name VALUES LESS THAN (partition_value | MAXVALUE)
[, ... ]
);
START END间隔分区表语法格式:
方式一:START(partition_value) END (partition_value | MAXVALUE)方式
CREATE TABLE partition_table_name
( [column_name data_type ]
[, ... ]
)
PARTITION BY RANGE (partition_key)
(
INTERVAL ('interval_expr')
PARTITION partition_name START(partition_value) END (partition_value | MAXVALUE)
[, ... ]
);
方式二:START(partition_value) END (partition_value) EVERY (interval_value)方式
CREATE TABLE partition_table_name
( [column_name data_type ]
[, ... ]
)
PARTITION BY RANGE (partition_key)
(
PARTITION partition_name START(partition_value) END (partition_value) EVERY (interval_value)
[, ... ]
);
方式三:START(partition_value)方式
CREATE TABLE partition_table_name
( [column_name data_type ]
[, ... ]
)
PARTITION BY RANGE (partition_key)
(
INTERVAL ('interval_expr')
PARTITION partition_name START(partition_value)
[, ... ]
);
方式四:END(partition_value | MAXVALUE)方式
CREATE TABLE partition_table_name
( [column_name data_type ]
[, ... ]
)
PARTITION BY RANGE (partition_key)
INTERVAL ('interval_expr')
(
PARTITION partition_name END(partition_value | MAXVALUE)
[, ... ]
);
间隔分区表参数说明
-
INTERVAL ('interval_expr')
间隔分区定义信息。只支持TIMESTAMP[(p)] [WITHOUT TIME ZONE]、TIMESTAMP[(p)] [WITH TIME ZONE]、DATE数据类型。
-
interval_expr自动创建分区的间隔,例如:
自动创建分区的间隔,例如:1 day、1 month。
-
partition_name
partition_name为范围分区的名称。
系统自动建立的分区按照建立的先后顺序,依次命名为:sys_p1、sys_p2、sys_p3…
间隔分区表语法示例
示例8:间隔分区表sales_table。
--创建分区表sales_table。
MogDB=# CREATE TABLE sales_table
(
order_no INTEGER NOT NULL,
goods_name CHAR(20) NOT NULL,
sales_date DATE NOT NULL,
sales_volume INTEGER,
sales_store CHAR(20)
)
PARTITION BY RANGE(sales_date)
INTERVAL ('1 month')
(
PARTITION start VALUES LESS THAN('2021-01-01 00:00:00'),
PARTITION later VALUES LESS THAN('2021-01-10 00:00:00')
);
-- 数据插入分区later
MogDB=# INSERT INTO sales_table VALUES(1, 'jacket', '2021-01-8 00:00:00', 3,'Alaska');
-- 不在已有分区的数据插入,系统会新建分区sys_p1。
MogDB=# INSERT INTO sales_table VALUES(2, 'hat', '2021-04-06 00:00:00', 255,'Clolorado');
-- 不在已有分区的数据插入,系统会新建分区sys_p2。
MogDB=# INSERT INTO sales_table VALUES(3, 'shirt', '2021-11-17 00:00:00', 7000,'Florida');
-- 数据插入分区start
MogDB=# INSERT INTO sales_table VALUES(4, 'coat', '2020-10-21 00:00:00', 9000,'Hawaii');
--查询sales_table的数据。
MogDB=# SELECT * FROM sales_table;
order_no | goods_name | sales_date | sales_volume | sales_store
----------+----------------------+---------------------+--------------+----------------------
4 | coat | 2020-10-21 00:00:00 | 9000 | Hawaii
1 | jacket | 2021-01-08 00:00:00 | 3 | Alaska
2 | hat | 2021-04-06 00:00:00 | 255 | Clolorado
3 | shirt | 2021-11-17 00:00:00 | 7000 | Florida
(4 rows)
--查询sales_table的start分区数据。这里采用“sales_table PARTITION (start);”来引用分区。
MogDB=# SELECT * FROM sales_table PARTITION (start);
order_no | goods_name | sales_date | sales_volume | sales_store
----------+----------------------+---------------------+--------------+----------------------
4 | coat | 2020-10-21 00:00:00 | 9000 | Hawaii
(1 row)
--查询sales_table的later分区数据。这里采用“sales_table PARTITION (later);”来引用分区。
MogDB=# SELECT * FROM sales_table PARTITION (later);
order_no | goods_name | sales_date | sales_volume | sales_store
----------+----------------------+---------------------+--------------+----------------------
1 | jacket | 2021-01-08 00:00:00 | 3 | Alaska
(1 row)
--查询sales_table的sys_p1分区数据。这里采用“sales_table PARTITION (sys_p1);”来引用分区。
MogDB=# SELECT * FROM sales_table PARTITION (sys_p1);
order_no | goods_name | sales_date | sales_volume | sales_store
----------+----------------------+---------------------+--------------+----------------------
2 | hat | 2021-04-06 00:00:00 | 255 | Clolorado
(1 row)
--查询sales_table的sys_p2分区数据。这里采用“sales_table PARTITION (sys_p2);”来引用分区。
MogDB=# SELECT * FROM sales_table PARTITION (sys_p2);
order_no | goods_name | sales_date | sales_volume | sales_store
----------+----------------------+---------------------+--------------+----------------------
3 | shirt | 2021-11-17 00:00:00 | 7000 | Florida
(1 row)
哈希分区表语法格式
CREATE TABLE partition_table_name
( [column_name data_type ]
[, ... ]
)
PARTITION BY HASH (partition_key)
(PARTITION partition_name )
[, ... ]
;
哈希分区表参数说明
-
partition_table_name
分区表的名称。
-
column_name
新表中要创建的字段名。
-
data_type
字段的数据类型。
-
partition_key
partition_key为分区键的名称。哈希分区策略的分区键仅支持1列。
-
partition_name
partition_name为哈希分区的名称。希望创建几个哈希分区就给出几个分区名。
哈希分区表示例
示例9:哈希分区表hash_partition_table。
--创建哈希分区表hash_partition_table
MogDB=# create table hash_partition_table (
col1 int,
col2 int)
partition by hash(col1)
(
partition p1,
partition p2
);
-- 数据插入
MogDB=# INSERT INTO hash_partition_table VALUES(1, 1);
INSERT 0 1
MogDB=# INSERT INTO hash_partition_table VALUES(2, 2);
INSERT 0 1
MogDB=# INSERT INTO hash_partition_table VALUES(3, 3);
INSERT 0 1
MogDB=# INSERT INTO hash_partition_table VALUES(4, 4);
INSERT 0 1
-- 查看数据
MogDB=# select * from hash_partition_table partition (p1);
col1 | col2
------+------
3 | 3
4 | 4
(2 rows)
MogDB=# select * from hash_partition_table partition (p2);
col1 | col2
------+------
1 | 1
2 | 2
(2 rows)
导入数据语法格式
导入单行数据:
INSERT INTO partition_table_name [ ( column_name [, ...] ) ] VALUES [ ( value )[, ...] ];
导入结构相同的现有表格数据:
INSERT INTO partition_table_name SELECT * FROM source_table_name
导入数据参数说明
-
partition_table_name
分区表的名称。
-
column_name
分区表中的字段名。可省略。
-
value
字段对应的值:
- 提供了column_name值时:value子句提供的值从左到右关联到对应列。
- 没提供column_name值时:value子句提供的值从左到右关联到partition_table_name对应列。
导入数据示例
示例10:
--创建分区表employees_table。
MogDB=# CREATE TABLE employees_table
(
employee_id INTEGER NOT NULL,
employee_name CHAR(20) NOT NULL,
onboarding_date DATE NOT NULL,
position CHAR(20)
)
PARTITION BY RANGE(onboarding_date)
(
PARTITION founders VALUES LESS THAN('2000-01-01 00:00:00'),
PARTITION senate VALUES LESS THAN('2010-01-01 00:00:00'),
PARTITION seniors VALUES LESS THAN('2020-01-01 00:00:00'),
PARTITION newcomer VALUES LESS THAN(MAXVALUE)
);
-- 数据插入分区founders
MogDB=# INSERT INTO employees_table VALUES(1, 'SMITH', '1997-01-10 00:00:00','Manager');
-- 查看founders分区数据
MogDB=# select * from employees_table partition (founders);
-- 创建表格employees_data_table
MogDB=# CREATE TABLE employees_data_table
(
employee_id INTEGER NOT NULL,
employee_name CHAR(20) NOT NULL,
onboarding_date DATE NOT NULL,
position CHAR(20)
);
-- 插入数据
MogDB=# insert into employees_data_table (employee_id, employee_name, onboarding_date, position) VALUES
(2, 'JONES', '2001-05-06 00:00:00', 'Supervisor'),
(3, 'WILLIAMS', '2011-09-17 00:00:00', 'Engineer'),
(4, 'TAYLOR', '2021-10-21 00:00:00', 'Clerk');
-- 查看表格数据
MogDB=# select * from employees_data_table;
--数据导入employees_table
MogDB=# INSERT INTO employees_table SELECT * FROM employees_data_table;
-- 查看senate分区数据
MogDB=# select * from employees_table partition (senate);
employee_id | employee_name | onboarding_date | position
-------------+----------------------+---------------------+----------------------
2 | JONES | 2001-05-06 00:00:00 | Supervisor
(1 row)
-- 查看seniors分区数据
MogDB=# select * from employees_table partition (seniors);
employee_id | employee_name | onboarding_date | position
-------------+----------------------+---------------------+----------------------
3 | WILLIAMS | 2011-09-17 00:00:00 | Engineer
(1 row)
-- 查看newcomer分区数据
MogDB=# select * from employees_table partition (newcomer);
employee_id | employee_name | onboarding_date | position
-------------+----------------------+---------------------+----------------------
4 | TAYLOR | 2021-10-21 00:00:00 | Clerk
(1 row)
修改分区表语法格式
-
删除分区:
ALTER TABLE partition_table_name DROP PARTITION partition_name;
-
增加分区:
ALTER TABLE partition_table_name ADD {partition_less_than_item | partition_start_end_item| partition_list_item };
-
重命名分区:
ALTER TABLE partition_table_name RENAME PARTITION partition_name TO partition_new_name;
-
分裂分区(指定切割点split_partition_value的语法):
ALTER TABLE partition_table_name SPLIT PARTITION partition_name AT ( split_partition_value ) INTO ( PARTITION partition_new_name1, PARTITION partition_new_name2);
-
分裂分区(指定分区范围的语法):
ALTER TABLE partition_table_name SPLIT PARTITION partition_name INTO { ( partition_less_than_item [, ...] ) | ( partition_start_end_item [, ...] ) };
-
合并分区:
ALTER TABLE partition_table_name MERGE PARTITIONS { partition_name } [, ...] INTO PARTITION partition_name;
修改分区表参数说明
-
partition_table_name
分区表的名称。
-
partition_name
partition_name为分区的名称。
-
split_partition_value
切割点。
-
PARTITION partition_new_name1, PARTITION partition_new_name2
按照切割点分裂出的两个分区。
-
partition_less_than_item
分区项的描述语句,语法为:
PARTITION partition_name VALUES LESS THAN ( { partition_value | MAXVALUE } [, ...] )
用法与创建VALUES LESS THAN范围分区表语法格式中相同。
-
partition_start_end_item
分区项的描述语句,语法为:
PARTITION partition_name {START(partition_value) END (partition_value) EVERY (interval_value)} | {START(partition_value) END ({partition_value | MAXVALUE})} | {START(partition_value)} | {END({partition_value | MAXVALUE})}
用法与创建START END范围分区表语法格式中相同。
-
partition_list_item
分区项的描述语句,语法为:
PARTITION partition_name VALUES (list_values_clause)
用法与创建列表分区表语法格式中相同。
-
split_point_clause
分裂分区时,指定的切割点。
-
partition_value
分区键值。
修改分区表示例
示例11:
--创建分区表employees_table。
MogDB=# CREATE TABLE employees_table
(
employee_id INTEGER NOT NULL,
employee_name CHAR(20) NOT NULL,
onboarding_date DATE NOT NULL,
position CHAR(20)
)
PARTITION BY RANGE(onboarding_date)
(
PARTITION founders VALUES LESS THAN('2000-01-01 00:00:00'),
PARTITION senate VALUES LESS THAN('2010-01-01 00:00:00'),
PARTITION seniors VALUES LESS THAN('2020-01-01 00:00:00'),
PARTITION newcomer VALUES LESS THAN(MAXVALUE)
);
-- 插入数据
MogDB=# INSERT INTO employees_table VALUES
(1, 'SMITH', '1997-01-10 00:00:00','Manager'),
(2, 'JONES', '2001-05-06 00:00:00', 'Supervisor'),
(3, 'WILLIAMS', '2011-09-17 00:00:00', 'Engineer'),
(4, 'TAYLOR', '2021-10-21 00:00:00', 'Clerk');
查看newcomer分区
MogDB=# SELECT * FROM employees_table PARTITION (newcomer);
employee_id | employee_name | onboarding_date | position
-------------+----------------------+---------------------+----------------------
4 | TAYLOR | 2021-10-21 00:00:00 | Clerk
(1 row)
--删除newcomer分区。
MogDB=# ALTER TABLE employees_table DROP PARTITION newcomer;
ALTER TABLE
-- 查看newcomer分区数据
MogDB=# select * from employees_table partition (newcomer);
ERROR: partition "newcomer" of relation "employees_table" does not exist
--增加fresh分区。
MogDB=# ALTER TABLE employees_table ADD PARTITION fresh VALUES LESS THAN ('2040-01-01 00:00:00');
ALTER TABLE
--以2030-01-01 00:00:00为分割点,分裂fresh分区为current、future两个分区
MogDB=# ALTER TABLE employees_table SPLIT PARTITION fresh AT ('2030-01-01 00:00:00') INTO (PARTITION current, PARTITION future);
ALTER TABLE
--将分区current改名为now
MogDB=# ALTER TABLE employees_table RENAME PARTITION current TO now;
ALTER TABLE
--将founders,senate合并为一个分区original。
MogDB=# ALTER TABLE employees_table MERGE PARTITIONS founders, senate INTO PARTITION original;
删除分区表语法格式
DROP TABLE partition_table_name;
删除分区表参数说明
-
partition_table_name
分区表的名称。
删除分区表示例
示例12:
--删除分区表employees_table。
MogDB=# DROP TABLE employees_table;
DROP TABLE