- About MogDB
- Quick Start
- MogDB Playground
- Container-based MogDB Installation
- Installation on a Single Node
- MogDB Access
- Use CLI to Access MogDB
- Use GUI to Access MogDB
- Use Middleware to Access MogDB
- Use Programming Language to Access MogDB
- Using Sample Dataset Mogila
- Characteristic Description
- Overview
- High Performance
- High Availability (HA)
- Primary/Standby
- Logical Replication
- Online Node Replacement
- Logical Backup
- Physical Backup
- Automatic Job Retry upon Failure
- Ultimate RTO
- Cascaded Standby Server
- Delayed Replay
- Adding or Deleting a Standby Server
- Delaying Entering the Maximum Availability Mode
- Parallel Logical Decoding
- DCF
- CM
- Global SysCache
- Using a Standby Node to Build a Standby Node
- Maintainability
- 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
- Application Development Interfaces
- AI Capabilities
- Middleware
- Installation Guide
- Installation Preparation
- Container Installation
- PTK-based Installation
- OM-based Installation
- Manual Installation
- Recommended Parameter Settings
- 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
- Data Security Maintenance Suggestions
- Slow SQL Diagnosis
- Log Reference
- Primary and Standby Management
- MOT Engine
- Introducing MOT
- Using MOT
- Concepts of MOT
- Appendix
- Column-store Tables Management
- Backup and Restoration
- Importing and Exporting Data
- Importing Data
- Exporting Data
- Upgrade Guide
- AI Features Guide
- AI Features Overview
- AI4DB: Autonomous Database O&M
- DBMind Mode
- Components that Support DBMind
- AI Sub-functions of the DBMind
- X-Tuner: Parameter Tuning and Diagnosis
- Index-advisor: Index Recommendation
- AI4DB: Root Cause Analysis for Slow SQL Statements
- AI4DB: Trend Prediction
- SQLdiag: Slow SQL Discovery
- DB4AI: Database-driven AI
- AI in DB
- Intelligence Explain: SQL Statement Query Time Prediction
- Security Guide
- Developer Guide
- Application Development Guide
- Development Specifications
- Development Based on JDBC
- Overview
- JDBC Package, Driver Class, and Environment Class
- Development Process
- Loading the Driver
- Connecting to a Database
- Connecting to the Database (Using SSL)
- 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
- 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
- Development Based on ODBC
- Development Based on libpq
- Dependent Header Files of libpq
- Development Process
- Example
- Link Parameters
- libpq API Reference
- Database Connection Control Functions
- Database Statement Execution Functions
- Functions for Asynchronous Command Processing
- Functions for Canceling Queries in Progress
- Psycopg-Based Development
- Commissioning
- Stored Procedure
- User Defined Functions
- PL/pgSQL-SQL Procedural Language
- Scheduled Jobs
- Autonomous Transaction
- Logical Replication
- Foreign Data Wrapper
- Materialized View
- Materialized View Overview
- Full Materialized View
- Incremental Materialized View
- Partition Management
- Partition Pruning
- Recommendations For Choosing A Partitioning Strategy
- Application Development Guide
- Performance Tuning Guide
- System Optimization
- SQL Optimization
- WDR Snapshot
- Using the Vectorized Executor for Tuning
- TPC-C Performance Tunning Guide
- Reference Guide
- System Catalogs and System Views
- Overview of System Catalogs and System Views
- 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_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_SHDEPEND
- PG_SHDESCRIPTION
- PG_SHSECLABEL
- PG_STATISTIC
- PG_STATISTIC_EXT
- PG_SUBSCRIPTION
- 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
- DV_SESSION_LONGOPS
- DV_SESSIONS
- GET_GLOBAL_PREPARED_XACTS(Discarded)
- GS_AUDITING
- GS_AUDITING_ACCESS
- GS_AUDITING_PRIVILEGE
- GS_ASYNC_SUBMIT_SESSIONS_STATUS
- GS_CLUSTER_RESOURCE_INFO
- 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_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
- GS_WRITE_TERM_LOG
- 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
- 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
- Statistics Information Functions
- 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
- Obsolete Functions
- Supported Data Types
- Numeric Types
- Monetary Types
- Boolean Types
- Enumerated Types
- Character Types
- Binary Types
- Date/Time Types
- Geometric
- Network Address Types
- Bit String Types
- Text Search Types
- UUID
- JSON/JSONB Types
- HLL
- Array Types
- Range
- OID Types
- Pseudo-Types
- Data Types Supported by Column-store Tables
- XML Types
- Data Type Used by the Ledger Database
- SQL Syntax
- ABORT
- ALTER AGGREGATE
- ALTER AUDIT POLICY
- ALTER DATABASE
- ALTER DATA SOURCE
- ALTER DEFAULT PRIVILEGES
- ALTER DIRECTORY
- ALTER EXTENSION
- ALTER FOREIGN TABLE
- ALTER FUNCTION
- ALTER GLOBAL CONFIGURATION
- ALTER GROUP
- ALTER INDEX
- ALTER LANGUAGE
- ALTER LARGE OBJECT
- ALTER MASKING POLICY
- ALTER MATERIALIZED VIEW
- 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 EXTENSION
- CREATE FOREIGN TABLE
- CREATE FUNCTION
- CREATE GROUP
- CREATE INCREMENTAL MATERIALIZED VIEW
- CREATE INDEX
- CREATE LANGUAGE
- CREATE MASKING POLICY
- CREATE MATERIALIZED VIEW
- CREATE MODEL
- CREATE OPERATOR
- CREATE PACKAGE
- CREATE 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 TABLE SUBPARTITION
- CREATE TABLESPACE
- CREATE TEXT SEARCH CONFIGURATION
- CREATE TEXT SEARCH DICTIONARY
- CREATE TRIGGER
- CREATE TYPE
- CREATE USER
- CREATE USER MAPPING
- CREATE VIEW
- CREATE WEAK PASSWORD DICTIONARY
- CURSOR
- DEALLOCATE
- DECLARE
- DELETE
- DO
- DROP AGGREGATE
- DROP AUDIT POLICY
- DROP CAST
- DROP CLIENT MASTER KEY
- DROP COLUMN ENCRYPTION KEY
- DROP DATABASE
- DROP DATA SOURCE
- DROP DIRECTORY
- DROP EXTENSION
- DROP FOREIGN TABLE
- DROP FUNCTION
- DROP 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
- SHUTDOWN
- SNAPSHOT
- START TRANSACTION
- TIMECAPSULE TABLE
- TRUNCATE
- UPDATE
- VACUUM
- VALUES
- SQL Reference
- MogDB SQL
- Keywords
- Constant and Macro
- Expressions
- Type Conversion
- Full Text Search
- Introduction
- Tables and Indexes
- Controlling Text Search
- Additional Features
- Parser
- Dictionaries
- Configuration Examples
- Testing and Debugging Text Search
- Limitations
- System Operation
- Controlling Transactions
- DDL Syntax Overview
- DML Syntax Overview
- DCL Syntax Overview
- Appendix
- GUC Parameters
- GUC Parameter Usage
- GUC Parameter List
- File Location
- Connection and Authentication
- Resource Consumption
- Write Ahead Log
- HA Replication
- Memory Table
- 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
- Developer Options
- Auditing
- SQL Mode
- 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
- Appendix
- Schema
- Information Schema
- DBE_PERF
- Overview
- OS
- Instance
- Memory
- File
- Object
- STAT_USER_TABLES
- SUMMARY_STAT_USER_TABLES
- GLOBAL_STAT_USER_TABLES
- STAT_USER_INDEXES
- SUMMARY_STAT_USER_INDEXES
- GLOBAL_STAT_USER_INDEXES
- STAT_SYS_TABLES
- SUMMARY_STAT_SYS_TABLES
- GLOBAL_STAT_SYS_TABLES
- STAT_SYS_INDEXES
- SUMMARY_STAT_SYS_INDEXES
- GLOBAL_STAT_SYS_INDEXES
- STAT_ALL_TABLES
- SUMMARY_STAT_ALL_TABLES
- GLOBAL_STAT_ALL_TABLES
- STAT_ALL_INDEXES
- SUMMARY_STAT_ALL_INDEXES
- GLOBAL_STAT_ALL_INDEXES
- STAT_DATABASE
- SUMMARY_STAT_DATABASE
- GLOBAL_STAT_DATABASE
- STAT_DATABASE_CONFLICTS
- SUMMARY_STAT_DATABASE_CONFLICTS
- GLOBAL_STAT_DATABASE_CONFLICTS
- STAT_XACT_ALL_TABLES
- SUMMARY_STAT_XACT_ALL_TABLES
- GLOBAL_STAT_XACT_ALL_TABLES
- STAT_XACT_SYS_TABLES
- SUMMARY_STAT_XACT_SYS_TABLES
- GLOBAL_STAT_XACT_SYS_TABLES
- STAT_XACT_USER_TABLES
- SUMMARY_STAT_XACT_USER_TABLES
- GLOBAL_STAT_XACT_USER_TABLES
- STAT_XACT_USER_FUNCTIONS
- SUMMARY_STAT_XACT_USER_FUNCTIONS
- GLOBAL_STAT_XACT_USER_FUNCTIONS
- STAT_BAD_BLOCK
- SUMMARY_STAT_BAD_BLOCK
- GLOBAL_STAT_BAD_BLOCK
- STAT_USER_FUNCTIONS
- SUMMARY_STAT_USER_FUNCTIONS
- GLOBAL_STAT_USER_FUNCTIONS
- Workload
- Session/Thread
- SESSION_STAT
- GLOBAL_SESSION_STAT
- SESSION_TIME
- GLOBAL_SESSION_TIME
- SESSION_MEMORY
- GLOBAL_SESSION_MEMORY
- SESSION_MEMORY_DETAIL
- GLOBAL_SESSION_MEMORY_DETAIL
- SESSION_STAT_ACTIVITY
- GLOBAL_SESSION_STAT_ACTIVITY
- THREAD_WAIT_STATUS
- GLOBAL_THREAD_WAIT_STATUS
- LOCAL_THREADPOOL_STATUS
- GLOBAL_THREADPOOL_STATUS
- SESSION_CPU_RUNTIME
- SESSION_MEMORY_RUNTIME
- STATEMENT_IOSTAT_COMPLEX_RUNTIME
- LOCAL_ACTIVE_SESSION
- Transaction
- Query
- STATEMENT
- SUMMARY_STATEMENT
- STATEMENT_COUNT
- GLOBAL_STATEMENT_COUNT
- SUMMARY_STATEMENT_COUNT
- GLOBAL_STATEMENT_COMPLEX_HISTORY
- GLOBAL_STATEMENT_COMPLEX_HISTORY_TABLE
- GLOBAL_STATEMENT_COMPLEX_RUNTIME
- STATEMENT_RESPONSETIME_PERCENTILE
- STATEMENT_USER_COMPLEX_HISTORY
- STATEMENT_COMPLEX_RUNTIME
- STATEMENT_COMPLEX_HISTORY_TABLE
- STATEMENT_COMPLEX_HISTORY
- STATEMENT_WLMSTAT_COMPLEX_RUNTIME
- STATEMENT_HISTORY
- Cache/IO
- STATIO_USER_TABLES
- SUMMARY_STATIO_USER_TABLES
- GLOBAL_STATIO_USER_TABLES
- STATIO_USER_INDEXES
- SUMMARY_STATIO_USER_INDEXES
- GLOBAL_STATIO_USER_INDEXES
- STATIO_USER_SEQUENCES
- SUMMARY_STATIO_USER_SEQUENCES
- GLOBAL_STATIO_USER_SEQUENCES
- STATIO_SYS_TABLES
- SUMMARY_STATIO_SYS_TABLES
- GLOBAL_STATIO_SYS_TABLES
- STATIO_SYS_INDEXES
- SUMMARY_STATIO_SYS_INDEXES
- GLOBAL_STATIO_SYS_INDEXES
- STATIO_SYS_SEQUENCES
- SUMMARY_STATIO_SYS_SEQUENCES
- GLOBAL_STATIO_SYS_SEQUENCES
- STATIO_ALL_TABLES
- SUMMARY_STATIO_ALL_TABLES
- GLOBAL_STATIO_ALL_TABLES
- STATIO_ALL_INDEXES
- SUMMARY_STATIO_ALL_INDEXES
- GLOBAL_STATIO_ALL_INDEXES
- STATIO_ALL_SEQUENCES
- SUMMARY_STATIO_ALL_SEQUENCES
- GLOBAL_STATIO_ALL_SEQUENCES
- GLOBAL_STAT_DB_CU
- GLOBAL_STAT_SESSION_CU
- Utility
- REPLICATION_STAT
- GLOBAL_REPLICATION_STAT
- REPLICATION_SLOTS
- GLOBAL_REPLICATION_SLOTS
- BGWRITER_STAT
- GLOBAL_BGWRITER_STAT
- GLOBAL_CKPT_STATUS
- GLOBAL_DOUBLE_WRITE_STATUS
- GLOBAL_PAGEWRITER_STATUS
- GLOBAL_RECORD_RESET_TIME
- GLOBAL_REDO_STATUS
- GLOBAL_RECOVERY_STATUS
- CLASS_VITAL_INFO
- USER_LOGIN
- SUMMARY_USER_LOGIN
- GLOBAL_GET_BGWRITER_STATUS
- GLOBAL_SINGLE_FLUSH_DW_STATUS
- GLOBAL_CANDIDATE_STATUS
- Lock
- Wait Events
- Configuration
- Operator
- Workload Manager
- Global Plancache
- RTO
- DBE_PLDEBUGGER Schema
- Overview
- 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
- Tool Reference
- Tool Overview
- Client Tool
- Server Tools
- Tools Used in the Internal System
- mogdb
- gs_backup
- gs_basebackup
- gs_ctl
- gs_initdb
- gs_install
- gs_install_plugin
- gs_install_plugin_local
- gs_preinstall
- gs_sshexkey
- gs_tar
- gs_uninstall
- gs_upgradectl
- gs_expansion
- gs_dropnode
- gs_probackup
- gstrace
- kdb5_util
- kadmin.local
- kinit
- klist
- krb5kdc
- kdestroy
- pg_config
- pg_controldata
- pg_recvlogical
- pg_resetxlog
- pg_archivecleanup
- pssh
- pscp
- transfer.py
- Unified Database Management Tool
- FAQ
- Functions of MogDB Executable Scripts
- System Catalogs and Views Supported by gs_collector
- Extension Reference
- 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 07480
- 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
- 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
- SQL Fault Location
- Index Fault Location
- Source Code Parsing
- FAQs
- Glossary
- Mogeaver
CREATE TABLE SUBPARTITION
Function
CREATE TABLE SUBPARTITION creates a level-2 partitioned table. A partitioned table is a logical table that is divided into several physical partitions for storage based on a specific plan. A partitioned table is a logical table and does not store data. Data is stored in physical partitions. For a level-2 partitioned table, the top-level node table and level-1 partitioned table are logical tables and do not store data. Only the level-2 partitioned (leaf node) stores data.
The partitioning solution of a level-2 partitioned table is a combination of the partitioning solutions of two level-1 partitions. For details about the partitioning solution of a level-1 partitioned table, see CREATE TABLE PARTITION.
Common combination solutions for level-2 partitioned tables include range-range partitioning, range-list partitioning, range-hash partitioning, list-range partitioning, list-list partitioning, list-hash partitioning. Currently, level-2 partitioned tables can only be row-store tables.
Precautions
- A level-2 partitioned table has two partition keys, and each partition key supports only one column. The two partition keys cannot be the same column.
- If the constraint key of the unique constraint and primary key constraint contains all partition keys, a local index is created for the constraints. Otherwise, a global index is created. If a local unique index is created, all partition keys must be included.
- When a level-2 partitioned table is created, if the specified level-2 partition is not displayed under the level-1 partition, a level-2 partition with the same range is automatically created.
- The number of level-2 partitions (leaf nodes) in a level-2 partitioned table cannot exceed 1048575. There is no limit on the number of level-1 partitions, but there must be at least one level-2 partition under a level-1 partition.
- The maximum number of level-2 partitions is 1048575. Generally, it is impossible to create so many partitions, because too many partitions may cause insufficient memory. Create partitions based on the value of local_syscache_threshold. The memory used by the level-2 partitioned tables is about (number of level-2 partitions x 3/1024) MB. Theoretically, the memory occupied by the partitions cannot be greater than the value of local_syscache_threshold. In addition, some space must be reserved for other functions.
- Level-2 partitioned tables support only row store and do not support column-store and hash bucket.
- Clusters are not supported.
- When specifying a partition for query, for example, select * from tablename partition/subpartition (partitionname), ensure that the keywords partition and subpartition are correct. If they are incorrect, no error is reported during the query. In this case, the query is performed based on the table alias.
- Encrypted databases, ledger databases, and row-level security are not supported.
- In the PARTITION FOR (values) syntax for level-2 partitioned tables, values can only be constants.
- In the PARTITION/SUBPARTITION FOR (values) syntax for level-2 partitioned tables, if data type conversion is required for values, you are advised to use forcible type conversion to prevent the implicit type conversion result from being inconsistent with the expected result.
- Currently, the statement specifying a partition cannot perform global index scan.
Syntax
CreateTableSubpartition ::= CREATE TABLE [ IF NOT EXISTS ] subpartition_table_name
(
{ column_name data_type [ COLLATE collation ] [ column_constraint [ ... ] ]
| table_constraint
| LIKE source_table [ like_option [...] ] }[,... ]
)
[ AUTO_INCREMENT [ = ] value ]
[ WITH ( {storage_parameter = value} [,... ] ) ]
[ COMPRESS | NOCOMPRESS ]
[ TABLESPACE tablespace_name ]
PARTITION BY {RANGE [ COLUMNS ] | LIST [ COLUMNS ] | HASH | KEY} ( partition_key ) [ PARTITIONS integer ] SUBPARTITION BY {RANGE | LIST | HASH | KEY} ( subpartition_key ) [ SUBPARTITIONS integer ]
(
{ PARTITION partition_name1 [ VALUES LESS THAN { ( val1 ) | MAXVALUE} | VALUES [ IN ] ( val1 [,...]) ] [ TABLESPACE [=] tablespace ]
(
{ SUBPARTITION subpartition_name1 [ VALUES LESS THAN ( val1_1 ) | VALUES ( val1_1 [,...])] [ TABLESPACE [=] tablespace ] [COMMENT =? 'text' ] } [,...]
) } [,...]
)[ { ENABLE | DISABLE } ROW MOVEMENT ]
-
Column constraint:
column_constraint ::= [ CONSTRAINT constraint_name ] { NOT NULL | NULL | CHECK ( expression ) | DEFAULT default_e xpr | GENERATED ALWAYS AS ( generation_expr ) STORED | UNIQUE index_parameters | PRIMARY KEY index_parameters | REFERENCES reftable [ ( refcolumn ) ] [ MATCH FULL | MATCH PARTIAL | MATCH SIMPLE ] [ ON DELETE action ] [ ON UPDATE action ] } [ DEFERRABLE | NOT DEFERRABLE | INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
-
Table constraint:
table_constraint ::= [ CONSTRAINT constraint_name ] { CHECK ( expression ) | UNIQUE ( column_name [, ... ] ) index_parameters | PRIMARY KEY ( column_name [, ... ] ) index_parameters | FOREIGN KEY ( column_name [, ... ] ) REFERENCES reftable [ ( refcolumn [, ... ] ) ] [ MATCH FULL | MATCH PARTIAL | MATCH SIMPLE ] [ ON DELETE action ] [ ON UPDATE action ] } [ DEFERRABLE | NOT DEFERRABLE | INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
-
LIKE options:
like_option ::= { INCLUDING | EXCLUDING } { DEFAULTS | GENERATED | CONSTRAINTS | INDEXES | STORAGE | COMMENTS | RELOPTIONS| ALL }
-
Index parameters:
index_parameters ::= [ WITH ( {storage_parameter = value} [, ... ] ) ] [ USING INDEX TABLESPACE tablespace_name ]
Parameter Description
-
IF NOT EXISTS
Does not throw an error if a relationship with the same name existed. A notice is issued in this case.
-
subpartition_table_name
Specifies the name of a level-2 partitioned table.
Value range: a string. It must comply with the identifier naming convention.
-
column_name
Specifies the name of a column to be created in the new table.
Value range: a string. It must comply with the identifier naming convention.
-
data_type
Specifies the data type of the column.
-
COLLATE collation
Assigns a collation to the column (which must be of a collatable data type). If no collation is specified, the default collation is used. You can run the select * from pg_collation; command to query collation rules from the pg_collation system catalog. The default collation rule is the row starting with default in the query result.
-
CONSTRAINT constraint_name
Specifies the name of a column or table constraint. The optional constraint clauses specify constraints that new or updated rows must satisfy for an INSERT or UPDATE operation to succeed.
There are two ways to define constraints:
- A column constraint is defined as part of a column definition, and it is bound to a particular column.
- A table constraint is not bound to a particular column but can apply to more than one column.
-
LIKE source_table [ like_option … ]
Level-2 partitioned tables do not support this function.
-
WITH ( storage_parameter [= value] [, … ] )
Specifies an optional storage parameter for a table or an index. Optional parameters are as follows:
-
FILLFACTOR
The fill factor of a table is a percentage from 10 to 100. 100 (complete filling) is the default value. When a smaller fill factor is specified, INSERT operations fill table pages only to the indicated percentage. The remaining space on each page is reserved for updating rows on that page. This gives UPDATE a chance to place the updated copy of a row on the same page, which is more efficient than placing it on a different page. For a table whose entries are never updated, setting the fill factor to 100 (complete filling) is the best choice, but in heavily updated tables a smaller fill factor would be appropriate. The parameter has no meaning for column-store tables.
Value range: 10-100
-
ORIENTATION
Determines the data storage mode of the table.
Value range:
-
COLUMN: The data will be stored in columns.
-
ROW (default value): The data will be stored in rows.
NOTICE: ORIENTATION cannot be modified.
-
-
STORAGE_TYPE
Specifies the storage engine type. This parameter cannot be modified once it is set.
Value range:
-
USTORE indicates that tables support the inplace-update storage engine. Note that the track_counts and track_activities parameters must be enabled when the Ustore table is used. Otherwise, space expansion may occur.
-
ASTORE indicates that tables support the append-only storage engine.
Default value:
If no table is specified, data is stored in append-only mode by default.
-
-
COMPRESSION
- Value range: LOW, MIDDLE, HIGH, YES, and NO for column-store tables, with compression level increasing in ascending order. The default value is LOW.
- Row-store tables do not support compression.
-
MAX_BATCHROW
Specifies the maximum number of records in a storage unit during data loading. The parameter is only valid for column-store tables.
Value range: 10000 to 60000. The default value is 60000.
-
PARTIAL_CLUSTER_ROWS
Specifies the number of records to be partially clustered for storage during data loading. The parameter is only valid for column-store tables.
Value range: greater than or equal to MAX_BATCHROW. You are advised to set this parameter to an integer multiple of MAX_BATCHROW.
-
DELTAROW_THRESHOLD
A reserved parameter. The parameter is only valid for column-store tables.
Value range: 0 to 9999
-
segment
The data is stored in segment-page mode. This parameter supports only row-store tables. Column-store tables, temporary tables, and unlogged tables are not supported. The Ustore storage engine is not supported.
Value range: on and off
Default value: off
-
-
COMPRESS / NOCOMPRESS
Specifies keyword COMPRESS during the creation of a table, so that the compression feature is triggered in case of BULK INSERT operations. If this feature is enabled, a scan is performed for all tuple data within the page to generate a dictionary and then the tuple data is compressed and stored. If NOCOMPRESS is specified, the table is not compressed. Row-store tables do not support compression.
Default value: NOCOMPRESS, that is, tuple data is not compressed before storage.
-
TABLESPACE tablespace_name
Specifies that the new table will be created in the tablespace_name tablespace. If the tablespace is not specified, the default tablespace is used.
-
PARTITION BY {RANGE | LIST | HASH} (partition_key)
- For partition_key, the partitioning policy supports only one column of partition keys.
- The data types supported by the partition key are the same as those supported by the level-1 partitioned table.
-
SUBPARTITION BY {RANGE | LIST | HASH} ( subpartition_key )
- For subpartition_key, the partitioning policy supports only one column of partition keys.
- The data types supported by the partition key are the same as those supported by the level-1 partitioned table.
-
{ ENABLE | DISABLE } ROW MOVEMENT
Specifies whether to enable row movement.
If the tuple value is updated on the partition key during the UPDATE operation, the partition where the tuple is located is altered. Setting this parameter enables error messages to be reported or movement of the tuple between partitions.
Value range:
- ENABLE (default value): Row movement is enabled.
- DISABLE: Row movement is disabled.
-
NOT NULL
The column is not allowed to contain null values. ENABLE can be omitted.
-
NULL
Indicates that the column is allowed to contain NULL values. This is the default setting.
This clause is only provided for compatibility with non-standard SQL databases. It is not recommended.
-
CHECK (condition) [ NO INHERIT ]
Specifies an expression producing a Boolean result where the INSERT or UPDATE operation of new or updated rows can succeed only when the expression result is TRUE or UNKNOWN; otherwise, an error is thrown and the database is not altered.
A check constraint specified as a column constraint should reference only the column's values, while an expression in a table constraint can reference multiple columns.
A constraint marked with NO INHERIT will not propagate to child tables.
ENABLE can be omitted.
-
DEFAULT default_expr
Assigns a default data value to a column. The value can be any variable-free expressions. (Subqueries and cross-references to other columns in the current table are not allowed.) The data type of the default expression must match that of the column.
The default expression will be used in any INSERT operation that does not specify a value for the column. If there is no default value for a column, then the default value is NULL.
-
GENERATED ALWAYS AS ( generation_expr ) STORED
This clause creates a column as a generated column. The value of the generated column is calculated by generation_expr when data is written (inserted or updated). STORED indicates that the value of the generated column is stored as a common column.
NOTE:
- The generation expression cannot refer to data other than the current row in any way. The generation expression cannot reference other generation columns or system columns. The generation expression cannot return a result set. No subquery, aggregate function, or window function can be used. The function called by the generation expression can only be an immutable function.
- Default values cannot be specified for generated columns.
- The generated column cannot be used as a part of the partition key.
- Do not specify the generated column and the CASCADE, SET NULL, and SET DEFAULT actions of the ON UPDATE constraint at the same time. Do not specify the generated column and the SET NULL, and SET DEFAULT actions of the ON DELETE constraint at the same time.
- The method of modifying and deleting generated columns is the same as that of common columns. Delete the common column that the generated column depends on. The generated column is automatically deleted. The type of the column on which the generated column depends cannot be changed.
- The generated column cannot be directly written. In the INSERT or UPDATE statement, values cannot be specified for generated columns, but the keyword DEFAULT can be specified.
- The permission control for generated columns is the same as that for common columns.
- Columns cannot be generated for column-store tables and MOTs. In foreign tables, only postgres_fdw supports generated columns.
-
UNIQUE index_parameters
UNIQUE ( column_name [, … ] ) index_parameters
Specifies that a group of one or more columns of a table can contain only unique values.
For the purpose of a unique constraint, null is not considered equal.
-
PRIMARY KEY index_parameters
PRIMARY KEY ( column_name [, … ] ) index_parameters
Specifies that a column or columns of a table can contain only unique (non-duplicate) and non-null values.
Only one primary key can be specified for a table.
-
DEFERRABLE | NOT DEFERRABLE
They determine whether the constraint is deferrable. A constraint that is not deferrable will be checked immediately after every command. Checking of constraints that are deferrable can be postponed until the end of the transaction using the SET CONSTRAINTS command. NOT DEFERRABLE is the default value. Currently, only UNIQUE constraints, primary key constraints, and foreign key constraints accept this clause. All the other constraints are not deferrable.
-
INITIALLY IMMEDIATE | INITIALLY DEFERRED
If a constraint is deferrable, this clause specifies the default time to check the constraint.
-
If the constraint is INITIALLY IMMEDIATE (default value), it is checked after each statement.
-
If the constraint is INITIALLY DEFERRED, it is checked only at the end of the transaction.
The constraint check time can be altered using the SET CONSTRAINTS statement.
-
-
USING INDEX TABLESPACE tablespace_name
Allows selection of the tablespace in which the index associated with a UNIQUE or PRIMARY KEY constraint will be created. If not specified, the index is created in default_tablespace. If default_tablespace is empty, the default tablespace of the database is used.
Examples
-
Example 1: Create level-2 partitioned tables of various combination types.
CREATE TABLE list_list ( month_code VARCHAR2 ( 30 ) NOT NULL , dept_code VARCHAR2 ( 30 ) NOT NULL , user_no VARCHAR2 ( 30 ) NOT NULL , sales_amt int ) PARTITION BY LIST (month_code) SUBPARTITION BY LIST (dept_code) ( PARTITION p_201901 VALUES ( '201902' ) ( SUBPARTITION p_201901_a VALUES ( '1' ), SUBPARTITION p_201901_b VALUES ( '2' ) ), PARTITION p_201902 VALUES ( '201903' ) ( SUBPARTITION p_201902_a VALUES ( '1' ), SUBPARTITION p_201902_b VALUES ( '2' ) ) ); insert into list_list values('201902', '1', '1', 1); insert into list_list values('201902', '2', '1', 1); insert into list_list values('201902', '1', '1', 1); insert into list_list values('201903', '2', '1', 1); insert into list_list values('201903', '1', '1', 1); insert into list_list values('201903', '2', '1', 1); select * from list_list; month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201903 | 2 | 1 | 1 201903 | 2 | 1 | 1 201903 | 1 | 1 | 1 201902 | 2 | 1 | 1 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 (6 rows) drop table list_list; CREATE TABLE list_hash ( month_code VARCHAR2 ( 30 ) NOT NULL , dept_code VARCHAR2 ( 30 ) NOT NULL , user_no VARCHAR2 ( 30 ) NOT NULL , sales_amt int ) PARTITION BY LIST (month_code) SUBPARTITION BY HASH (dept_code) ( PARTITION p_201901 VALUES ( '201902' ) ( SUBPARTITION p_201901_a, SUBPARTITION p_201901_b ), PARTITION p_201902 VALUES ( '201903' ) ( SUBPARTITION p_201902_a, SUBPARTITION p_201902_b ) ); insert into list_hash values('201902', '1', '1', 1); insert into list_hash values('201902', '2', '1', 1); insert into list_hash values('201902', '3', '1', 1); insert into list_hash values('201903', '4', '1', 1); insert into list_hash values('201903', '5', '1', 1); insert into list_hash values('201903', '6', '1', 1); select * from list_hash; month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201903 | 4 | 1 | 1 201903 | 5 | 1 | 1 201903 | 6 | 1 | 1 201902 | 2 | 1 | 1 201902 | 3 | 1 | 1 201902 | 1 | 1 | 1 (6 rows) drop table list_hash; CREATE TABLE list_range ( month_code VARCHAR2 ( 30 ) NOT NULL , dept_code VARCHAR2 ( 30 ) NOT NULL , user_no VARCHAR2 ( 30 ) NOT NULL , sales_amt int ) PARTITION BY LIST (month_code) SUBPARTITION BY RANGE (dept_code) ( PARTITION p_201901 VALUES ( '201902' ) ( SUBPARTITION p_201901_a values less than ('4'), SUBPARTITION p_201901_b values less than ('6') ), PARTITION p_201902 VALUES ( '201903' ) ( SUBPARTITION p_201902_a values less than ('3'), SUBPARTITION p_201902_b values less than ('6') ) ); insert into list_range values('201902', '1', '1', 1); insert into list_range values('201902', '2', '1', 1); insert into list_range values('201902', '3', '1', 1); insert into list_range values('201903', '4', '1', 1); insert into list_range values('201903', '5', '1', 1); insert into list_range values('201903', '6', '1', 1); ERROR: inserted partition key does not map to any table partition select * from list_range; month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201903 | 4 | 1 | 1 201903 | 5 | 1 | 1 201902 | 1 | 1 | 1 201902 | 2 | 1 | 1 201902 | 3 | 1 | 1 (5 rows) drop table list_range; CREATE TABLE range_list ( month_code VARCHAR2 ( 30 ) NOT NULL , dept_code VARCHAR2 ( 30 ) NOT NULL , user_no VARCHAR2 ( 30 ) NOT NULL , sales_amt int ) PARTITION BY RANGE (month_code) SUBPARTITION BY LIST (dept_code) ( PARTITION p_201901 VALUES LESS THAN( '201903' ) ( SUBPARTITION p_201901_a values ('1'), SUBPARTITION p_201901_b values ('2') ), PARTITION p_201902 VALUES LESS THAN( '201904' ) ( SUBPARTITION p_201902_a values ('1'), SUBPARTITION p_201902_b values ('2') ) ); insert into range_list values('201902', '1', '1', 1); insert into range_list values('201902', '2', '1', 1); insert into range_list values('201902', '1', '1', 1); insert into range_list values('201903', '2', '1', 1); insert into range_list values('201903', '1', '1', 1); insert into range_list values('201903', '2', '1', 1); select * from range_list; month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201902 | 2 | 1 | 1 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 201903 | 2 | 1 | 1 201903 | 2 | 1 | 1 201903 | 1 | 1 | 1 (6 rows) drop table range_list; CREATE TABLE range_hash ( month_code VARCHAR2 ( 30 ) NOT NULL , dept_code VARCHAR2 ( 30 ) NOT NULL , user_no VARCHAR2 ( 30 ) NOT NULL , sales_amt int ) PARTITION BY RANGE (month_code) SUBPARTITION BY HASH (dept_code) ( PARTITION p_201901 VALUES LESS THAN( '201903' ) ( SUBPARTITION p_201901_a, SUBPARTITION p_201901_b ), PARTITION p_201902 VALUES LESS THAN( '201904' ) ( SUBPARTITION p_201902_a, SUBPARTITION p_201902_b ) ); insert into range_hash values('201902', '1', '1', 1); insert into range_hash values('201902', '2', '1', 1); insert into range_hash values('201902', '1', '1', 1); insert into range_hash values('201903', '2', '1', 1); insert into range_hash values('201903', '1', '1', 1); insert into range_hash values('201903', '2', '1', 1); select * from range_hash; month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201902 | 2 | 1 | 1 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 201903 | 2 | 1 | 1 201903 | 2 | 1 | 1 201903 | 1 | 1 | 1 (6 rows) drop table range_hash; CREATE TABLE range_range ( month_code VARCHAR2 ( 30 ) NOT NULL , dept_code VARCHAR2 ( 30 ) NOT NULL , user_no VARCHAR2 ( 30 ) NOT NULL , sales_amt int ) PARTITION BY RANGE (month_code) SUBPARTITION BY RANGE (dept_code) ( PARTITION p_201901 VALUES LESS THAN( '201903' ) ( SUBPARTITION p_201901_a VALUES LESS THAN( '2' ), SUBPARTITION p_201901_b VALUES LESS THAN( '3' ) ), PARTITION p_201902 VALUES LESS THAN( '201904' ) ( SUBPARTITION p_201902_a VALUES LESS THAN( '2' ), SUBPARTITION p_201902_b VALUES LESS THAN( '3' ) ) ); insert into range_range values('201902', '1', '1', 1); insert into range_range values('201902', '2', '1', 1); insert into range_range values('201902', '1', '1', 1); insert into range_range values('201903', '2', '1', 1); insert into range_range values('201903', '1', '1', 1); insert into range_range values('201903', '2', '1', 1); select * from range_range; month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 201902 | 2 | 1 | 1 201903 | 1 | 1 | 1 201903 | 2 | 1 | 1 201903 | 2 | 1 | 1 (6 rows) drop table range_range;
-
Example 2: Specify partitions in a level-2 partitioned table using DML.
CREATE TABLE range_list ( month_code VARCHAR2 ( 30 ) NOT NULL , dept_code VARCHAR2 ( 30 ) NOT NULL , user_no VARCHAR2 ( 30 ) NOT NULL , sales_amt int ) PARTITION BY RANGE (month_code) SUBPARTITION BY LIST (dept_code) ( PARTITION p_201901 VALUES LESS THAN( '201903' ) ( SUBPARTITION p_201901_a values ('1'), SUBPARTITION p_201901_b values ('2') ), PARTITION p_201902 VALUES LESS THAN( '201910' ) ( SUBPARTITION p_201902_a values ('1'), SUBPARTITION p_201902_b values ('2') ) ); -- Insert data to a specified level-1 partition. insert into range_list partition (p_201901) values('201902', '1', '1', 1); -- The actual partition is inconsistent with the specified partition. An error is reported. insert into range_list partition (p_201902) values('201902', '1', '1', 1); ERROR: inserted partition key does not map to the table partition DETAIL: N/A. -- Insert data to a specified level-2 partition. insert into range_list subpartition (p_201901_a) values('201902', '1', '1', 1); -- The actual partition is inconsistent with the specified partition. An error is reported. insert into range_list subpartition (p_201901_b) values('201902', '1', '1', 1); ERROR: inserted subpartition key does not map to the table subpartition DETAIL: N/A. insert into range_list partition for ('201902') values('201902', '1', '1', 1); insert into range_list subpartition for ('201902','1') values('201902', '1', '1', 1); -- Query data in a specified partition. select * from range_list partition (p_201901); month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 (4 rows) select * from range_list subpartition (p_201901_a); month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 (4 rows) select * from range_list partition for ('201902'); month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 (4 rows) select * from range_list subpartition for ('201902','1'); month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 (4 rows) -- Update data in a specified partition. update range_list partition (p_201901) set user_no = '2'; select * from range_list; select *from range_list; month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201902 | 1 | 2 | 1 201902 | 1 | 2 | 1 201902 | 1 | 2 | 1 201902 | 1 | 2 | 1 (4 rows) update range_list subpartition (p_201901_a) set user_no = '3'; select * from range_list; month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201902 | 1 | 3 | 1 201902 | 1 | 3 | 1 201902 | 1 | 3 | 1 201902 | 1 | 3 | 1 (4 rows) update range_list partition for ('201902') set user_no = '4'; select * from range_list; month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201902 | 1 | 4 | 1 201902 | 1 | 4 | 1 201902 | 1 | 4 | 1 201902 | 1 | 4 | 1 (4 rows) update range_list subpartition for ('201902','2') set user_no = '5'; openGauss=# select *from range_list; month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201902 | 1 | 4 | 1 201902 | 1 | 4 | 1 201902 | 1 | 4 | 1 201902 | 1 | 4 | 1 (4 rows) select * from range_list; -- Delete data from a specified partition. delete from range_list partition (p_201901); DELETE 4 delete from range_list partition for ('201903'); DELETE 0 delete from range_list subpartition (p_201901_a); DELETE 0 delete from range_list subpartition for ('201903','2'); DELETE 0 -- Insert data into a specified partition. insert into range_list partition (p_201901) values('201902', '1', '1', 1) ON DUPLICATE KEY UPDATE sales_amt = 5; insert into range_list subpartition (p_201901_a) values('201902', '1', '1', 1) ON DUPLICATE KEY UPDATE sales_amt = 10; insert into range_list partition for ('201902') values('201902', '1', '1', 1) ON DUPLICATE KEY UPDATE sales_amt = 30; insert into range_list subpartition for ('201902','1') values('201902', '1', '1', 1) ON DUPLICATE KEY UPDATE sales_amt = 40; select * from range_list; month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 (4 rows) -- Merge data into a specified partition. CREATE TABLE newrange_list ( month_code VARCHAR2 ( 30 ) NOT NULL , dept_code VARCHAR2 ( 30 ) NOT NULL , user_no VARCHAR2 ( 30 ) NOT NULL , sales_amt int ) PARTITION BY RANGE (month_code) SUBPARTITION BY LIST (dept_code) ( PARTITION p_201901 VALUES LESS THAN( '201903' ) ( SUBPARTITION p_201901_a values ('1'), SUBPARTITION p_201901_b values ('2') ), PARTITION p_201902 VALUES LESS THAN( '201910' ) ( SUBPARTITION p_201902_a values ('1'), SUBPARTITION p_201902_b values ('2') ) ); insert into newrange_list values('201902', '1', '1', 1); insert into newrange_list values('201903', '1', '1', 2); MERGE INTO range_list partition (p_201901) p USING newrange_list partition (p_201901) np ON p.month_code= np.month_code WHEN MATCHED THEN UPDATE SET dept_code = np.dept_code, user_no = np.user_no, sales_amt = np.sales_amt WHEN NOT MATCHED THEN INSERT VALUES (np.month_code, np.dept_code, np.user_no, np.sales_amt); select * from range_list; month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 (4 rows) MERGE INTO range_list partition for ('201901') p USING newrange_list partition for ('201901') np ON p.month_code= np.month_code WHEN MATCHED THEN UPDATE SET dept_code = np.dept_code, user_no = np.user_no, sales_amt = np.sales_amt WHEN NOT MATCHED THEN INSERT VALUES (np.month_code, np.dept_code, np.user_no, np.sales_amt); select * from range_list; month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 (4 rows) MERGE INTO range_list subpartition (p_201901_a) p USING newrange_list subpartition (p_201901_a) np ON p.month_code= np.month_code WHEN MATCHED THEN UPDATE SET dept_code = np.dept_code, user_no = np.user_no, sales_amt = np.sales_amt WHEN NOT MATCHED THEN INSERT VALUES (np.month_code, np.dept_code, np.user_no, np.sales_amt); select * from range_list; month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 (4 rows) MERGE INTO range_list subpartition for ('201901', '1') p USING newrange_list subpartition for ('201901', '1') np ON p.month_code= np.month_code WHEN MATCHED THEN UPDATE SET dept_code = np.dept_code, user_no = np.user_no, sales_amt = np.sales_amt WHEN NOT MATCHED THEN INSERT VALUES (np.month_code, np.dept_code, np.user_no, np.sales_amt); select * from range_list; month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 (4 rows)
-
Example 3: Truncate a level-2 partitioned table.
CREATE TABLE list_list ( month_code VARCHAR2 ( 30 ) NOT NULL , dept_code VARCHAR2 ( 30 ) NOT NULL , user_no VARCHAR2 ( 30 ) NOT NULL , sales_amt int ) PARTITION BY LIST (month_code) SUBPARTITION BY LIST (dept_code) ( PARTITION p_201901 VALUES ( '201902' ) ( SUBPARTITION p_201901_a VALUES ( '1' ), SUBPARTITION p_201901_b VALUES ( default ) ), PARTITION p_201902 VALUES ( '201903' ) ( SUBPARTITION p_201902_a VALUES ( '1' ), SUBPARTITION p_201902_b VALUES ( '2' ) ) ); insert into list_list values('201902', '1', '1', 1); insert into list_list values('201902', '2', '1', 1); insert into list_list values('201902', '1', '1', 1); insert into list_list values('201903', '2', '1', 1); insert into list_list values('201903', '1', '1', 1); insert into list_list values('201903', '2', '1', 1); select * from list_list; month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201903 | 2 | 1 | 1 201903 | 2 | 1 | 1 201903 | 1 | 1 | 1 201902 | 2 | 1 | 1 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 (6 rows) select * from list_list partition (p_201901); month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201902 | 2 | 1 | 1 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 (3 rows) alter table list_list truncate partition p_201901; select * from list_list partition (p_201901); month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- (0 rows) select * from list_list partition (p_201902); month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201903 | 2 | 1 | 1 201903 | 2 | 1 | 1 201903 | 1 | 1 | 1 (3 rows) alter table list_list truncate partition p_201902; select * from list_list partition (p_201902); month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- (0 rows) select * from list_list; month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- (0 rows) insert into list_list values('201902', '1', '1', 1); insert into list_list values('201902', '2', '1', 1); insert into list_list values('201902', '1', '1', 1); insert into list_list values('201903', '2', '1', 1); insert into list_list values('201903', '1', '1', 1); insert into list_list values('201903', '2', '1', 1); select * from list_list subpartition (p_201901_a); month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 (2 rows) alter table list_list truncate subpartition p_201901_a; select * from list_list subpartition (p_201901_a); month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- (0 rows) select * from list_list subpartition (p_201901_b); month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201902 | 2 | 1 | 1 (1 row) alter table list_list truncate subpartition p_201901_b; select * from list_list subpartition (p_201901_b); month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- (0 rows) select * from list_list subpartition (p_201902_a); month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201903 | 1 | 1 | 1 (1 row) alter table list_list truncate subpartition p_201902_a; select * from list_list subpartition (p_201902_a); month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- (0 rows) select * from list_list subpartition (p_201902_b); month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201903 | 2 | 1 | 1 201903 | 2 | 1 | 1 (2 rows) alter table list_list truncate subpartition p_201902_b; select * from list_list subpartition (p_201902_b); month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- (0 rows) select * from list_list; month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- (0 rows) drop table list_list;
-
Example 4: Split a level-2 partitioned table.
CREATE TABLE list_list ( month_code VARCHAR2 ( 30 ) NOT NULL , dept_code VARCHAR2 ( 30 ) NOT NULL , user_no VARCHAR2 ( 30 ) NOT NULL , sales_amt int ) PARTITION BY LIST (month_code) SUBPARTITION BY LIST (dept_code) ( PARTITION p_201901 VALUES ( '201902' ) ( SUBPARTITION p_201901_a VALUES ( '1' ), SUBPARTITION p_201901_b VALUES ( default ) ), PARTITION p_201902 VALUES ( '201903' ) ( SUBPARTITION p_201902_a VALUES ( '1' ), SUBPARTITION p_201902_b VALUES ( default ) ) ); insert into list_list values('201902', '1', '1', 1); insert into list_list values('201902', '2', '1', 1); insert into list_list values('201902', '1', '1', 1); insert into list_list values('201903', '2', '1', 1); insert into list_list values('201903', '1', '1', 1); insert into list_list values('201903', '2', '1', 1); select * from list_list; month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201903 | 2 | 1 | 1 201903 | 2 | 1 | 1 201903 | 1 | 1 | 1 201902 | 2 | 1 | 1 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 (6 rows) select * from list_list subpartition (p_201901_a); month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 (2 rows) select * from list_list subpartition (p_201901_b); month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201902 | 2 | 1 | 1 (1 row) alter table list_list split subpartition p_201901_b values (2) into ( subpartition p_201901_b, subpartition p_201901_c ); select * from list_list subpartition (p_201901_a); month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 (2 rows) select * from list_list subpartition (p_201901_b); month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201902 | 2 | 1 | 1 (1 row) select * from list_list subpartition (p_201901_c); month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- (0 rows) select * from list_list partition (p_201901); month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201902 | 2 | 1 | 1 201902 | 1 | 1 | 1 201902 | 1 | 1 | 1 (3 rows) select * from list_list subpartition (p_201902_a); month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201903 | 1 | 1 | 1 (1 row) select * from list_list subpartition (p_201902_b); month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201903 | 2 | 1 | 1 201903 | 2 | 1 | 1 (2 rows) alter table list_list split subpartition p_201902_b values (3) into ( subpartition p_201902_b, subpartition p_201902_c ); select * from list_list subpartition (p_201902_a); month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201903 | 1 | 1 | 1 (1 row) select * from list_list subpartition (p_201902_b); month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- (0 rows) select * from list_list subpartition (p_201902_c); month_code | dept_code | user_no | sales_amt ------------+-----------+---------+----------- 201903 | 2 | 1 | 1 201903 | 2 | 1 | 1 (2 rows) drop table list_list;