- About MogDB
- Quick Start
- Characteristic Description
- Overview
- High Performance
- CBO Optimizer
- LLVM
- Vectorized Engine
- Hybrid Row-Column Store
- Adaptive Compression
- Adaptive Two-phase Hash Aggregation
- SQL Bypass
- Kunpeng NUMA Architecture Optimization
- High Concurrency of Thread Pools
- SMP for Parallel Execution
- Xlog no Lock Flush
- Parallel Page-based Redo For Ustore
- Row-Store Execution to Vectorized Execution
- Astore Row Level Compression
- BTree Index Compression
- Tracing SQL Function
- Parallel Index Scan
- Parallel Query Optimization
- Enhancement of Tracing Backend Key Thread
- Ordering Operator Optimization
- OCK-accelerated Data Transmission
- OCK SCRLock Accelerate Distributed Lock
- Enhancement of WAL Redo Performance
- Enhancement of Dirty Pages Flushing Performance
- Sequential Scan Prefetch
- Ustore SMP Parallel Scanning
- Statement Level PLSQL Function Cache Support
- High Availability (HA)
- Primary/Standby
- Logical Replication
- Logical Backup
- Physical Backup
- Automatic Job Retry upon Failure
- Ultimate RTO
- High Availability Based on the Paxos Protocol
- Cascaded Standby Server
- Delayed Replay
- Adding or Deleting a Standby Server
- Delaying Entering the Maximum Availability Mode
- Parallel Logical Decoding
- DCF
- CM(Cluster Manager)
- Global SysCache
- Using a Standby Node to Build a Standby Node
- Two City and Three Center DR
- CM Cluster Management Component Supporting Two Node Deployment
- Query of the Original DDL Statement for a View
- MogDB/CM/PTK Dual Network Segment Support
- Enhanced Efficiency of Logical Backup and Restore
- Maintainability
- Workload Diagnosis Report (WDR)
- Slow SQL Diagnosis
- Session Performance Diagnosis
- System KPI-aided Diagnosis
- Fault Diagnosis
- Extension Splitting
- Built-in Stack Tool
- SQL PATCH
- Lightweight Lock Export and Analysis
- DCF Module Tracing
- Error When Writing Illegal Characters
- Support For Pageinspect & Pagehack
- Autonomous Transaction Management View and Termination
- Corrupt Files Handling
- Compatibility
- Add %rowtype Attribute To The View
- Aggregate Functions Distinct Performance Optimization
- Aggregate Functions Support Keep Clause
- Aggregate Functions Support Scenario Extensions
- Compatible With MySQL Alias Support For Single Quotes
- current_date/current_time Keywords As Field Name
- Custom Type Array
- For Update Support Outer Join
- MogDB Supports Insert All
- Oracle DBLink Syntax Compatibility
- Remove Type Conversion Hint When Creating PACKAGE/FUNCTION/PROCEDURE
- Support Bypass Method When Merge Into Hit Index
- Support For Adding Nocopy Attributes To Procedure And Function Parameters
- Support For Passing The Count Attribute Of An Array As A Parameter Of The Array Extend
- Support Q Quote Escape Character
- Support Subtracting Two Date Types To Return Numeric Type
- Support table()
- Support To Keep The Same Name After The End With Oracle
- Support Where Current Of
- Support For Constants In Package As Default Values
- Support PLPGSQL subtype
- Support Synonym Calls Without Parentheses For Function Without Parameters
- Support For dbms_utility.format_error_backtrace
- Support for PIVOT and UNPIVOT Syntax
- Mod Function Compatibility
- Support for Nesting of Aggregate Functions
- ORDER BY/GROUP BY Scenario Expansion
- Support for Modifying Table Log Properties After Table Creation
- Support for INSERT ON CONFLICT Clause
- Support for AUTHID CURRENT_USER
- Support for Stored Procedure OUT Parameters in PBE Mode
- Database Security
- Access Control Model
- Separation of Control and Access Permissions
- Database Encryption Authentication
- Data Encryption and Storage
- Database Audit
- Network Communication Security
- Resource Label
- Unified Audit
- Dynamic Data Anonymization
- Row-Level Access Control
- Password Strength Verification
- Equality Query in a Fully-encrypted Database
- Ledger Database Mechanism
- Transparent Data Encryption
- Enterprise-Level Features
- Support for Functions and Stored Procedures
- SQL Hints
- Full-Text Indexing
- Copy Interface for Error Tolerance
- Partitioning
- Support for Advanced Analysis Functions
- Materialized View
- HyperLogLog
- Creating an Index Online
- Autonomous Transaction
- Global Temporary Table
- Pseudocolumn ROWNUM
- Stored Procedure Debugging
- JDBC Client Load Balancing and Read/Write Isolation
- In-place Update Storage Engine
- Publication-Subscription
- Foreign Key Lock Enhancement
- Data Compression in OLTP Scenarios
- Transaction Async Submit
- Index Creation Parallel Control
- Dynamic Partition Pruning
- COPY Import Optimization
- SQL Running Status Observation
- BRIN Index
- BLOOM Index
- Event Trigger
- Scrollable Cursor Support for Reverse Retrieval
- Support for Pruning Subquery Projection Columns
- Pruning ORDER BY in Subqueries
- Automatic Creation of Indexes Supporting Fuzzy Matching
- Support for Importing and Exporting Specific Objects
- Application Development Interfaces
- AI Capabilities
- Middleware
- Workload Management
- Installation Guide
- Upgrade Guide
- Administrator Guide
- Localization
- Routine Maintenance
- Starting and Stopping MogDB
- Using the gsql Client for Connection
- Routine Maintenance
- Checking OS Parameters
- Checking MogDB Health Status
- Checking Database Performance
- Checking and Deleting Logs
- Checking Time Consistency
- Checking The Number of Application Connections
- Routinely Maintaining Tables
- Routinely Recreating an Index
- Exporting and Viewing the WDR
- Data Security Maintenance Suggestions
- Slow SQL Diagnosis
- Log Reference
- Primary and Standby Management
- Column-store Tables Management
- Backup and Restoration
- Database Deployment Solutions
- Importing and Exporting Data
- High Available Guide
- AI Features Guide
- AI4DB: Autonomous Database O&M
- DBMind Mode
- Components that Support DBMind
- AI Sub-functions of the DBMind
- ABO Optimizer
- DB4AI: Database-driven AI
- AI4DB: Autonomous Database O&M
- Security Guide
- Developer Guide
- Application Development Guide
- Development Specifications
- Development Based on JDBC
- JDBC Package, Driver Class, and Environment Class
- Development Process
- Loading the Driver
- Connecting to a Database
- Connecting to the Database (Using SSL)
- Connecting to the Database (Using UDS)
- Running SQL Statements
- Processing Data in a Result Set
- Closing a Connection
- Managing Logs
- Example: Common Operations
- Example: Retrying SQL Queries for Applications
- Example: Importing and Exporting Data Through Local Files
- Example 2: Migrating Data from a MY Database to MogDB
- Example: Logic Replication Code
- Example: Parameters for Connecting to the Database in Different Scenarios
- Example: JDBC Primary/Standby Cluster Load Balancing
- JDBC API Reference
- 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-based Common Parameter Reference
- JDBC Release Notes
- Development Based on ODBC
- Development Based on libpq
- Psycopg2-Based Development
- Commissioning
- Stored Procedure
- User Defined Functions
- PL/pgSQL-SQL Procedural Language
- Scheduled Jobs
- Autonomous Transaction
- Logical Replication
- Extension
- MySQL Compatibility Description
- Dolphin Extension
- Dolphin Overview
- Dolphin Installation
- Dolphin Restrictions
- Dolphin Syntax
- SQL Reference
- Keywords
- Data Types
- Functions and Operators
- Assignment Operators
- Character Processing Functions and Operators
- Arithmetic Functions and Operators
- Dolphin Lock
- Date and Time Processing Functions and Operators
- Advisory Lock Functions
- Network Address Functions and Operators
- Conditional Expression Functions
- Aggregate Functions
- System Information Functions
- Logical Operators
- Bit String Functions and Operators
- JSON-JSONB Functions and Operators
- Type Conversion Functions
- Compatible Operators and Operations
- Comment Operators
- Expressions
- DDL Syntax
- DML Syntax
- DCL Syntax
- SQL Syntax
- 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
- System Views
- GUC Parameters
- Resetting Parameters
- Stored Procedures
- Identifiers
- SQL Reference
- MySQL Syntax Compatibility Assessment Tool
- Dolphin Extension
- Materialized View
- Partition Management
- Application Development Guide
- Performance Tuning Guide
- Reference Guide
- System Catalogs and System Views
- Overview
- Querying a System Catalog
- System Catalogs
- 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
- System Views
- GET_GLOBAL_PREPARED_XACTS(Discarded)
- 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
- Functions and Operators
- Logical Operators
- Comparison Operators
- Character Processing Functions and Operators
- Binary String Functions and Operators
- Bit String Functions and Operators
- Mode Matching Operators
- Mathematical Functions and Operators
- Date and Time Processing Functions and Operators
- Type Conversion Functions
- Geometric Functions and Operators
- Network Address Functions and Operators
- Text Search Functions and Operators
- JSON/JSONB Functions and Operators
- HLL Functions and Operators
- SEQUENCE Functions
- Array Functions and Operators
- Range Functions and Operators
- Aggregate Functions
- Window Functions(Analysis Functions)
- Security Functions
- Ledger Database Functions
- Encrypted Equality Functions
- Set Returning Functions
- Conditional Expression Functions
- System Information Functions
- System Administration Functions
- Configuration Settings Functions
- Universal File Access Functions
- Server Signal Functions
- Backup and Restoration Control Functions
- Snapshot Synchronization Functions
- Database Object Functions
- Advisory Lock Functions
- Logical Replication Functions
- Segment-Page Storage Functions
- Other Functions
- Undo System Functions
- Row-store Compression System Functions
- Statistics Information Functions
- Trigger Functions
- Event Trigger Functions
- Hash Function
- Prompt Message Function
- Global Temporary Table Functions
- Fault Injection System Function
- AI Feature Functions
- Dynamic Data Masking Functions
- Other System Functions
- Internal Functions
- Global SysCache Feature Functions
- Data Damage Detection and Repair Functions
- XML Functions
- Obsolete Functions
- Supported Data Types
- SQL Syntax
- 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 Reference
- MogDB SQL
- Keywords
- Constant and Macro
- Expressions
- Type Conversion
- Full Text Search
- System Operation
- DDL Syntax Overview
- DML Syntax Overview
- DCL Syntax Overview
- Subquery
- LLVM
- Alias
- Lock
- Transaction
- Ordinary Table
- Partitioned Table
- Index
- Constraints
- Cursors
- Anonymous Block
- Trigger
- INSERT_RIGHT_REF_DEFAULT_VALUE
- Appendix
- GUC Parameters
- GUC Parameter Usage
- GUC Parameter List
- File Location
- Connection and Authentication
- Resource Consumption
- Write Ahead Log
- HA Replication
- Query Planning
- Error Reporting and Logging
- Alarm Detection
- Statistics During the Database Running
- Load Management
- Automatic Vacuuming
- Default Settings of Client Connection
- Lock Management
- Version and Platform Compatibility
- Faut Tolerance
- Connection Pool Parameters
- MogDB Transaction
- Replication Parameters of Two Database Instances
- Developer Options
- Auditing
- CM Parameters
- Backend Compression
- Upgrade Parameters
- Miscellaneous Parameters
- Wait Events
- Query
- System Performance Snapshot
- Security Configuration
- Global Temporary Table
- HyperLogLog
- Scheduled Task
- Thread Pool
- User-defined Functions
- Backup and Restoration
- DCF Parameters Settings
- Flashback
- Rollback Parameters
- Reserved Parameters
- AI Features
- Global SysCache Parameters
- Multi-Level Cache Management Parameters
- Resource Pooling Parameters
- Parameters Related to Efficient Data Compression Algorithms
- Writer Statement Parameters Supported by Standby Servers
- Data Import and Export
- Delimiter
- Appendix
- 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
- Tool Reference
- Tool Overview
- Client Tool
- Server Tools
- Tools Used in the Internal System
- 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
- Functions of MogDB Executable Scripts
- System Catalogs and Views Supported by gs_collector
- Error Code Reference
- Description of SQL Error Codes
- Third-Party Library Error Codes
- 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
- Error Log Reference
- System Catalogs and System Views
- Common Faults and Identification
- Common Fault Locating Methods
- Common Fault Locating Cases
- Core Fault Locating
- Permission/Session/Data Type Fault Location
- Service/High Availability/Concurrency Fault Location
- Standby Node in the Need Repair (WAL) State
- Service Startup Failure
- Primary Node Is Hung in Demoting During a Switchover
- "too many clients already" Is Reported or Threads Failed To Be Created in High Concurrency Scenarios
- Performance Deterioration Caused by Dirty Page Flushing Efficiency During TPCC High Concurrentcy Long Term Stable Running
- A Query Error Is Reported Due to Predicate Pushdown
- Table/Partition Table Fault Location
- File System/Disk/Memory Fault Location
- After You Run the du Command to Query Data File Size In the XFS File System, the Query Result Is Greater than the Actual File Size
- File Is Damaged in the XFS File System
- Insufficient Memory
- "Error:No space left on device" Is Displayed
- When the TPC-C is running and a disk to be injected is full, the TPC-C stops responding
- Disk Space Usage Reaches the Threshold and the Database Becomes Read-only
- Shared Memory Leakage
- SQL Fault Location
- Index Fault Location
- CM Two-Node Fault Location
- Source Code Parsing
- FAQs
- Glossary
- Communication Matrix
- Mogeaver
Partitioned Tables
If a table contains a large amount of data, data query and operation efficiency will be severely affected. MogDB can logically divide a table into multiple shards to avoid processing a large amount of data at a time and then improve the processing efficiency.
MogDB supports the following types of partitioned tables:
- Range partitioned table: One or more columns are divided into multiple ranges. A partition is created for each range to store data. For example, sales data can be partitioned by month.
- List partitioned table: Partitions are created based on values in a column. For example, sales data is divided by sales store.
- Interval partitioned table: It is a special type of range partitions. The interval value definition is added. If no matched partition is found when a record is inserted, partitions can be automatically created based on the interval.
- Hash partitioned table: The modulus and remainder are specified for each partition based on a column of the table, and the records to be inserted into the table are allocated to the corresponding partitions.
In addition to creating a partitioned table, you can perform the following operations:
- Querying a partitioned table: Data is queried by partition name or value in a partition.
- Importing data: Data is imported directly or from an existing table.
- Modifying a partitioned table: Partitions are added, deleted,split, or combined, or partition names are changed.
- Deleting a partitioned table: The operation is the same as that of deleting a common table.
Classification of Range Partitioned Tables
Range partitioned tables are classified into the following types:
- VALUES LESS THAN:specifies the partition range based on the upper limit of each partition. Upper limit of the previous partition ≤ Range of the partition ≤ Upper limit of the current partition.
- START END:Partitioning is performed in the following methods.
- START(partition_value) END (partition_value | MAXVALUE);
- START(partition_value);
- END(partition_value | MAXVALUE)
- START(partition_value) END (partition_value) EVERY (interval_value)
- Comprehensively using the preceding methods
Syntax for Creating a VALUES LESS THAN Range Partitioned Table
CREATE TABLE partition_table_name
( [column_name data_type ]
[, ... ]
)
PARTITION BY RANGE (partition_key)
(
PARTITION partition_name VALUES LESS THAN (partition_value | MAXVALUE)
[, ... ]
);
Parameters for Creating a VALUES LESS THAN Range Partitioned Table
-
partition_table_name
Specifies the name of the partitioned table.
-
column_name
Specifies the name of the column to be created in the new table.
-
data_type
Specifies the data type of the column.
-
partition_key
Specifies the name of the partition key.
In this case, a maximum of four partition keys are supported.
-
partition_name
Specifies the name of a range partition.
-
VALUES LESS THAN
Specifies that the value in the partition must be less than the upper limit value.
-
partition_value
Specifies the upper limit of a range partition, and the value depends on the type specified by partition_key.
-
MAXVALUE
Specifies the upper limit of the last range partition.
Example of Creating a VALUES LESS THAN Range Partitioned Table
Example 1: Create the sales_table range partitioned table. The table has four partitions and the data type of their partition keys is DATE. The range of the partition is as follows: sales_date < 2021-04-01, 2021-04-01 ≤ sales_date < 2021-07-01, 2021-07-01 ≤ sales_date < 2021-10-01, and 2021-10-01 ≤ sales_date < MAXVALUE.
-- Create the sales_table partitioned 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)
);
-- Insert data into the season1 partition.
MogDB=# INSERT INTO sales_table VALUES(1, 'jacket', '2021-01-10 00:00:00', 3,'Alaska');
-- Insert data into the season2 partition.
MogDB=# INSERT INTO sales_table VALUES(2, 'hat', '2021-05-06 00:00:00', 5,'Clolorado');
-- Insert data into the season3 partition.
MogDB=# INSERT INTO sales_table VALUES(3, 'shirt', '2021-09-17 00:00:00', 7,'Florida');
-- Insert data into the season4 partition.
MogDB=# INSERT INTO sales_table VALUES(4, 'coat', '2021-10-21 00:00:00', 9,'Hawaii');
Syntax for Querying a Partitioned Table
SELECT * FROM partition_table_name PARTITION { ( partition_name ) | FOR ( partition_value [, ...] ) }
Parameters for Querying a Partitioned Table
-
partition_table_name
Specifies the name of the partitioned table.
-
partition_name
Specifies the partition name.
-
partition_value
Specifies the value of the partition. The partition where the value specified by the PARTITION FOR clause is located is the partition to be queried.
Example of Querying a Partitioned Table
Example 2: Query the sales_table partitioned table created in example 1.
-- Query data in the sales_table 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)
-- Query the data of the fourth quarter in the sales_table table. sales_table PARTITION (season4) is used to reference the partition where the data of the fourth quarter is located.
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)
-- Query the data of the first quarter in the sales_table table. sales_table PARTITION FOR ('2021-3-21 00:00:00') is used to reference the partition where the data of the first quarter is located. '2021-3-21 00:00:00' is located in the partition where the data of the first quarter is located.
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)
Syntax for Creating a START END Range Partitioned Table
A START END range partitioned table can be created by different methods, and these methods can be combined within a partitioned table.
-
Method 1: By executing 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) [, ... ] );
-
Method 2: By executing START(partition_value)
CREATE TABLE partition_table_name ( [column_name data_type ] [, ... ] ) PARTITION BY RANGE (partition_key) ( PARTITION partition_name START(partition_value) [, ... ] );
-
Method 3: By executing 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) [, ... ] );
-
Method 4: By executing 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) [, ... ] );
Parameters for Creating a START END Range Partitioned Table
-
partition_table_name
Specifies the name of the partitioned table.
-
column_name
Specifies the name of the column to be created in the new table.
-
data_type
Specifies the data type of the column.
-
partition_key
Specifies the name of the partition key.
In this case, only one partition key is supported.
-
partition_name
Specifies the name or prefix of the range partition.
-
If the definition is in the START(partition_value) END (partition_value) EVERY (interval_value) clause and the value of partition_name is p1, the partition names are p1_1, p1_2, and so on.
For example, if PARTITION p1 START(1) END(4) EVERY(1) is defined, the generated partitions are [1, 2), [2, 3), and [3, 4), and their names are p1_1, p1_2, and p1_3. In this case, p1 is a name prefix.
-
If the defined statement is in the first place and has START specified, the range (MINVALUE, START) will be automatically used as the first actual partition, and its name will be p1_0. The other partitions are then named p1_1, p1_2, and so on.
For example, if PARTITION p1 START(1), PARTITION p2 START(2) is defined, generated partitions are (MINVALUE, 1), [1, 2), and [2, MAXVALUE), and their names will be p1_0, p1_1, and p2. In this case, p1 is a name prefix and p2 is a partition name. MINVALUE indicates the minimum value.
-
In other cases, this parameter specifies the range partition name.
-
-
VALUES LESS THAN
Specifies that the value in the partition must be less than the upper limit value.
-
partition_value
Specifies the endpoint value (start or end point) of the range partition. The value depends on the type specified by partition_key.
-
interval_value
Splits the range specified by [START, END) and specifies the width of each partition after splitting. If the value of (END-START) cannot be exactly divided by the value of EVERY, only the width of the last partition is less than the value of EVERY.
-
MAXVALUE
Specifies the upper limit of the last range partition.
Example of Creating a START END Range Partitioned Table
Example 3: Execute START(partition_value) END (partition_value | MAXVALUE) to create a START END partitioned table named graderecord. There are three partitions, and their partition keys are of the INTEGER type. The partition ranges are as follows: 0 ≤ grade < 60, 60 ≤ grade < 90, and 90 ≤ grade < MAXVALUE.
-- Create the graderecord partitioned table.
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)
);
-- Insert data into the partition.
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);
-- Query data in the graderecord table.
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)
-- Query data in the pass partition of the graderecord table.
MogDB=# SELECT * FROM graderecord PARTITION (pass);
ERROR: partition "pass" of relation "graderecord" does not exist
The query fails.
The cause is that the defined PARTITION pass START(60) END(90), statement is in the first place and has START specified. Therefore, the range (MINVALUE, 60) will be automatically used as the first actual partition, and its name will be pass_0.
The name of the partition with the range of 60 ≤ grade < 90 is pass_1.
-- Query data in the pass_0 partition of the graderecord table.
MogDB=# SELECT * FROM graderecord PARTITION (pass_0);
number | name | class | grade
--------+----------------------+----------------------+-------
210103 | Brain | 21.01 | 26
210205 | David | 21.02 | 47
(2 rows)
-- Query data in the pass_1 partition of the graderecord table.
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)
-- Query data in the execllent partition of the graderecord table.
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)
Example 4: Execute START(partition_value) END (partition_value) EVERY (interval_value) to create a START END range partitioned table named metro_ride_record. There are seven partitions and their partition keys are of the INTEGER type. The value of ride_stations_number is less than 21. Every three stations form a partition.
-- Create the metro_ride_record partitioned table. Record the number of passengers, getting-on and getting-off stations, and number of stations. A partition is created for every three stations based on the number of stations.
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)
);
-- Insert data into the partition.
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);
-- Query data in the metro_ride_record table.
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)
The defined PARTITION cost START(3) END(21) EVERY (3) statement is in the first place and has START specified. Therefore, the range (MINVALUE, 3) will be automatically used as the first actual partition, and its name will be cost_0.
Other partitions are cost_1, ..., and cost_6.
-- Query data in the cost_0 partition of the metro_ride_record table.
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)
-- Query data in the cost_1 partition of the metro_ride_record table.
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)
-- Query data in the cost_6 partition of the metro_ride_record table.
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)
Example 5: Execute START(partition_value) to create a START END range partitioned table named graderecord. There are three partitions, and their partition keys are of the INTEGER type. The partition ranges are as follows: 0 ≤ grade < 60, 60 ≤ grade < 90, and 90 ≤ grade < MAXVALUE.
-- Create the graderecord partitioned table.
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)
);
-- Insert data into the partition.
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);
-- Query data in the graderecord table.
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)
-- Query data in the pass partition of the graderecord table.
MogDB=# SELECT * FROM graderecord PARTITION (pass);
ERROR: partition "pass" of relation "graderecord" does not exist
The query fails.
The cause is that the defined PARTITION pass START(60), statement is in the first place and has START specified. Therefore, the range (MINVALUE, 60) will be automatically used as the first actual partition, and its name will be pass_0.
The name of the partition with the range of 60 ≤ grade < 90 is pass_1.
-- Query data in the pass_0 partition of the graderecord table.
MogDB=# SELECT * FROM graderecord PARTITION (pass_0);
number | name | class | grade
--------+----------------------+----------------------+-------
210103 | Brain | 21.01 | 26
210205 | David | 21.02 | 47
(2 rows)
-- Query data in the pass_1 partition of the graderecord table.
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)
-- Query data in the execllent partition of the graderecord table.
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)
Example 6: Execute END(partition_value | MAXVALUE) to create a START END range partitioned table named graderecord. There are three partitions, and their partition keys are of the INTEGER type. The partition ranges are as follows: 0 ≤ grade < 60, 60 ≤ grade < 90, and 90 ≤ grade < MAXVALUE.
-- Create the graderecord partitioned table.
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)
);
-- Insert data into the partition.
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);
-- Query data in the graderecord table.
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)
-- Query data in the no_pass partition of the graderecord table.
MogDB=# SELECT * FROM graderecord PARTITION (no_pass);
number | name | class | grade
--------+----------------------+----------------------+-------
210103 | Brain | 21.01 | 26
210205 | David | 21.02 | 47
(2 rows)
-- Query data in the pass partition of the graderecord table.
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)
-- Query data in the execllent partition of the graderecord table.
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)
Syntax for Creating a List Partitioned Table
CREATE TABLE partition_table_name
( [column_name data_type ]
[, ... ]
)
PARTITION BY LIST (partition_key)
(
PARTITION partition_name VALUES (list_values_clause)
[, ... ]
);
Parameters for Creating a List Partitioned Table
-
partition_table_name
Specifies the name of the partitioned table.
-
column_name
Specifies the name of the column to be created in the new table.
-
data_type
Specifies the data type of the column.
-
partition_key
Specifies the name of the partition key.
The list partitioning policy supports only one column of partition keys.
-
partition_name
Specifies the name of a range partition.
-
list_values_clause
There are one or more key values of the corresponding partition. Use commas (,) to separate multiple key values.
-
VALUES (DEFAULT)
If the added data contains key values that are not listed in list_values_clause, the data is stored in the partition corresponding to VALUES (DEFAULT).
-
MAXVALUE
Specifies the upper limit of the last range partition.
Example of Creating a List Partitioned Table
Example 7: Create the graderecord list partitioned table. There are four partitions, and their partition keys are of the CHAR type. The partition ranges are 21.01, 21.02, 21.03, and 21.04.
-- Create the graderecord partitioned table.
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')
);
-- Insert data into the partition.
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);
-- Query data in the graderecord table.
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)
-- Query data in the class_01 partition of the graderecord table.
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)
-- Query data in the class_04 partition of the graderecord table.
MogDB=# SELECT * FROM graderecord PARTITION (class_04);
number | name | class | grade
--------+----------------------+----------------------+-------
210410 | Jack | 21.04 | 75
210311 | Jerry | 21.04 | 60
(2 rows)
Syntax for Creating an Interval Partitioned Table
Interval partitioning adds the definition of the interval value PARTITION BY RANGE (partition_key) on the basis of range partitioning.
The syntax of the VALUES LESS THAN interval partition is as follows:
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)
[, ... ]
);
The syntax for creating a START END interval partitioned table is as follows:
Method 1: By executing 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)
[, ... ]
);
Method 2: By executing 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)
[, ... ]
);
Method 3: By executing 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)
[, ... ]
);
Method 4: By executing 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)
[, ... ]
);
Parameters for Creating an Interval Partitioned Table
-
INTERVAL ('interval_expr')
Defines interval partitioning. Only the TIMESTAMP[(p)] [WITHOUT TIME ZONE], TIMESTAMP[(p)] [WITH TIME ZONE] and DATE data types are supported.
-
interval_expr
Specifies the interval for automatically creating partitions, for example, 1 day or 1 month.
-
partition_name
Specifies the name of a range partition.
The partitions automatically created by the system are named sys_p1, sys_p2, sys_p3, and the like.
Example of Creating an Interval Partitioned Table
Example 8: Creating the sales_table interval partitioned table.
-- Create the sales_table partitioned 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')
);
-- Insert data into the later partition.
MogDB=# INSERT INTO sales_table VALUES(1, 'jacket', '2021-01-8 00:00:00', 3,'Alaska');
-- If you do not insert data into existing partitions, the system creates the sys_p1 partition.
MogDB=# INSERT INTO sales_table VALUES(2, 'hat', '2021-04-06 00:00:00', 255,'Clolorado');
-- If you do not insert data into existing partitions, the system creates the sys_p2 partition.
MogDB=# INSERT INTO sales_table VALUES(3, 'shirt', '2021-11-17 00:00:00', 7000,'Florida');
-- Insert data into the start partition.
MogDB=# INSERT INTO sales_table VALUES(4, 'coat', '2020-10-21 00:00:00', 9000,'Hawaii');
-- Query data in the sales_table 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)
-- Query data in the start partition of the sales_table table. In this example, sales_table PARTITION (start); is used to reference partitions.
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)
-- Query data in the later partition of the sales_table table. In this example, sales_table PARTITION (later); is used to reference partitions.
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)
-- Query data in the sys_p1 partition of the sales_table table. In this example, sales_table PARTITION (sys_p1); is used to reference partitions.
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)
-- Query data in the sys_p2 partition of the sales_table table. In this example, sales_table PARTITION (sys_p2); is used to reference partitions.
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)
Syntax for Creating a Hash Partitioned Table
CREATE TABLE partition_table_name
( [column_name data_type ]
[, ... ]
)
PARTITION BY HASH (partition_key)
(PARTITION partition_name )
[, ... ]
;
Parameters for Creating a Hash Partitioned Table
-
partition_table_name
Specifies the name of the partitioned table.
-
column_name
Specifies the name of the column to be created in the new table.
-
data_type
Specifies the data type of the column.
-
partition_key
Specifies the name of the partition key. The hash partitioning policy supports only one column of partition keys.
-
partition_name
Specifies the name of a hash partition. The number of hash partitions to be created is the same as the number of partition names.
Example of Creating a Hash Partitioned Table
Example 9: Create the hash_partition_table hash partitioned table.
-- Create the hash_partition_table hash partitioned table.
MogDB=# create table hash_partition_table (
col1 int,
col2 int)
partition by hash(col1)
(
partition p1,
partition p2
);
-- Insert data.
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
-- View the data.
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)
Syntax for Importing Data
Import a single row of data.
INSERT INTO partition_table_name [ ( column_name [, ...] ) ] VALUES [ ( value )[, ...] ];
Import data from an existing table with the same structure.
INSERT INTO partition_table_name SELECT * FROM source_table_name
Parameters for Importing Data
-
partition_table_name
Specifies the name of the partitioned table.
-
column_name
Specifies a column name in the partitioned table. It can be omitted.
-
value
Specifies column values.
- If the value of column_name is provided, the value provided by the value clause is associated with the corresponding column from left to right.
- If the value of column_name is not provided, the value provided by the value clause is associated with the column specified by partition_table_name from left to right.
Example of Importing Data
Example 10:
-- Create the employees_table partitioned 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)
);
-- Insert data into the founders partition.
MogDB=# INSERT INTO employees_table VALUES(1, 'SMITH', '1997-01-10 00:00:00','Manager');
-- View data in the founders partition.
MogDB=# select * from employees_table partition (founders);
-- Create the employees_data_table 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)
);
-- Insert data.
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');
-- View table data.
MogDB=# select * from employees_data_table;
-- Import data to the employees_table table.
MogDB=# INSERT INTO employees_table SELECT * FROM employees_data_table;
-- View data in the senate partition.
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)
-- View data in the seniors partition.
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)
-- View data in the newcomer partition.
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)
Syntax for Modifying a Partitioned Table
-
Delete a partition.
ALTER TABLE partition_table_name DROP PARTITION partition_name;
-
Add a partition.
ALTER TABLE partition_table_name ADD {partition_less_than_item | partition_start_end_item| partition_list_item };
-
Rename a partition.
ALTER TABLE partition_table_name RENAME PARTITION partition_name TO partition_new_name;
-
Split a partition (Specify the syntax of 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);
-
Split a partition (Specify the syntax of the partition range).
ALTER TABLE partition_table_name SPLIT PARTITION partition_name INTO { ( partition_less_than_item [, ...] ) | ( partition_start_end_item [, ...] ) };
-
Combine partitions.
ALTER TABLE partition_table_name MERGE PARTITIONS { partition_name } [, ...] INTO PARTITION partition_name;
Parameters for Modifying a Partitioned Table
-
partition_table_name
Specifies the name of the partitioned table.
-
partition_name
Specifies the partition name.
-
split_partition_value
Specifies the split point.
-
PARTITION partition_new_name1, PARTITION partition_new_name2
Specifies the two partitions that are split based on the split point.
-
partition_less_than_item
Specifies the description statement of a partition item. The syntax is as follows:
PARTITION partition_name VALUES LESS THAN ( { partition_value | MAXVALUE } [, ...] )
The usage is the same as that in Syntax for Creating a VALUES LESS THAN Range Partitioned Table.
-
partition_start_end_item
Specifies the description statement of a partition item. The syntax is as follows:
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})}
The usage is the same as that in Syntax for Creating a START END Range Partitioned Table.
-
partition_list_item
Specifies the description statement of a partition item. The syntax is as follows:
PARTITION partition_name VALUES (list_values_clause)
The usage is the same as that in [Syntax for Creating a List Partitioned Table](#Syntax for Creating a List Partitioned Table).
-
split_point_clause
Specifies the split point when a partition is split.
-
partition_value
Specifies the key value of a partition.
Example of Modifying a Partitioned Table
Example 11:
-- Create the employees_table partitioned 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)
);
-- Insert data.
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');
View the newcomer partition.
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)
-- Delete the newcomer partition.
MogDB=# ALTER TABLE employees_table DROP PARTITION newcomer;
ALTER TABLE
-- View data in the newcomer partition.
MogDB=# select * from employees_table partition (newcomer);
ERROR: partition "newcomer" of relation "employees_table" does not exist
-- Add the fresh partition.
MogDB=# ALTER TABLE employees_table ADD PARTITION fresh VALUES LESS THAN ('2040-01-01 00:00:00');
ALTER TABLE
-- Use 2030-01-01 00:00:00 as the split point to split the fresh partition into the current and future partitions.
MogDB=# ALTER TABLE employees_table SPLIT PARTITION fresh AT ('2030-01-01 00:00:00') INTO (PARTITION current, PARTITION future);
ALTER TABLE
-- Change the name of the current partition to now.
MogDB=# ALTER TABLE employees_table RENAME PARTITION current TO now;
ALTER TABLE
-- Combine the founders and senate partitions into the original partition.
MogDB=# ALTER TABLE employees_table MERGE PARTITIONS founders, senate INTO PARTITION original;
Syntax for Deleting a Partitioned Table
DROP TABLE partition_table_name;
Parameters for Deleting a Partitioned Table
-
partition_table_name
Specifies the name of the partitioned table.
Example of Deleting a Partitioned Table
Example 12:
-- Delete the employees_table partitioned table.
MogDB=# DROP TABLE employees_table;
DROP TABLE