- About MogDB
- MogDB Introduction
- Comparison Between MogDB and openGauss
- MogDB Release Note
- High Availability and Performance
- Open Source Components
- Usage Limitations
- Terms of Use
- Quick Start
- Installation Guide
- Container Installation
- Standard Installation
- Installation Overview
- Preparing for Installation
- Installing the MogDB
- Verifying the Installation
- Uninstalling the MogDB
- Administrator Guide
- Routine Maintenance
- Primary and Standby Management
- MogHA 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
- Common Fault Locating Cases
- Core Fault Locating
- When the TPC-C is running and a disk to be injected is full, the TPC-C stops responding
- Standby Node in the Need Repair (WAL) State
- Insufficient Memory
- Service Startup Failure
- "Error:No space left on device" Is Displayed
- 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
- Primary Node Is Hung in Demoting During a Switchover
- Disk Space Usage Reaches the Threshold and the Database Becomes Read-only
- Slow Response to a Query Statement
- Analyzing the Status of a Query Statement
- Forcibly Terminating a Session
- Analyzing Whether a Query Statement Is Blocked
- Low Query Efficiency
- "Lock wait timeout" Is Displayed When a User Executes an SQL Statement
- Table Size Does not Change After VACUUM FULL Is Executed on the Table
- An Error Is Reported When the Table Partition Is Modified
- Different Data Is Displayed for the Same Table Queried By Multiple Users
- When a User Specifies Only an Index Name to Modify the Index, A Message Indicating That the Index Does Not Exist Is Displayed
- Reindexing Fails
- An Error Occurs During Integer Conversion
- "too many clients already" Is Reported or Threads Failed To Be Created in High Concurrency Scenarios
- B-tree Index Faults
- Security Guide
- Database Security Management
- Performance Tuning
- System Optimization
- SQL Optimization
- WDR Snapshot Schema
- 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
- 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
- JDBC Interface Reference
- Development Based on ODBC
- Development Based on libpq
- Commissioning
- Appendices
- Stored Procedure
- User Defined Functions
- Application Development Guide
- Tool Reference
- System Catalogs and System Views
- Overview of System Catalogs and System Views
- System Catalogs
- GS_CLIENT_GLOBAL_KEYS
- GS_CLIENT_GLOBAL_KEYS_ARGS
- GS_COLUMN_KEYS
- GS_COLUMN_KEYS_ARGS
- GS_ENCRYPTED_COLUMNS
- GS_OPT_MODEL
- GS_WLM_INSTANCE_HISTORY
- GS_WLM_OPERATOR_INFO
- GS_WLM_PLAN_ENCODING_TABLE
- GS_WLM_PLAN_OPERATOR_INFO
- GS_WLM_USER_RESOURCE_HISTORY
- PG_AGGREGATE
- PG_AM
- PG_AMOP
- PG_AMPROC
- PG_APP_WORKLOADGROUP_MAPPING
- PG_ATTRDEF
- PG_ATTRIBUTE
- PG_AUTHID
- PG_AUTH_HISTORY
- PG_AUTH_MEMBERS
- PG_CAST
- PG_CLASS
- PG_COLLATION
- PG_CONSTRAINT
- PG_CONVERSION
- PG_DATABASE
- PG_DB_ROLE_SETTING
- PG_DEFAULT_ACL
- PG_DEPEND
- PG_DESCRIPTION
- PG_DIRECTORY
- PG_ENUM
- PG_EXTENSION
- PG_EXTENSION_DATA_SOURCE
- PG_FOREIGN_DATA_WRAPPER
- PG_FOREIGN_SERVER
- PG_FOREIGN_TABLE
- PG_INDEX
- PG_INHERITS
- PG_JOB
- PG_JOB_PROC
- PG_LANGUAGE
- PG_LARGEOBJECT
- PG_LARGEOBJECT_METADATA
- PG_NAMESPACE
- PG_OBJECT
- PG_OPCLASS
- PG_OPERATOR
- PG_OPFAMILY
- PG_PARTITION
- PG_PLTEMPLATE
- PG_PROC
- PG_RANGE
- PG_RESOURCE_POOL
- PG_REWRITE
- PG_RLSPOLICY
- PG_SECLABEL
- PG_SHDEPEND
- PG_SHDESCRIPTION
- PG_SHSECLABEL
- PG_STATISTIC
- PG_STATISTIC_EXT
- PG_TABLESPACE
- PG_TRIGGER
- PG_TS_CONFIG
- PG_TS_CONFIG_MAP
- PG_TS_DICT
- PG_TS_PARSER
- PG_TS_TEMPLATE
- PG_TYPE
- PG_USER_MAPPING
- PG_USER_STATUS
- PG_WORKLOAD_GROUP
- PLAN_TABLE_DATA
- STATEMENT_HISTORY
- System Views
- GS_SESSION_CPU_STATISTICS
- GS_SESSION_MEMORY_STATISTICS
- GS_SQL_COUNT
- 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_ALL
- GS_WLM_USER_INFO
- GS_WLM_SESSION_STATISTICS
- GS_STAT_SESSION_CU
- MPP_TABLES
- PG_AVAILABLE_EXTENSION_VERSIONS
- PG_AVAILABLE_EXTENSIONS
- PG_CURSORS
- PG_EXT_STATS
- PG_GET_INVALID_BACKENDS
- PG_GET_SENDERS_CATCHUP_TIME
- PG_GROUP
- PG_GTT_RELSTATS
- PG_GTT_STATS
- PG_GTT_ATTACHED_PIDS
- PG_INDEXES
- PG_LOCKS
- PG_MATVIEWS
- PG_NODE_ENV
- PG_OS_THREADS
- PG_PREPARED_STATEMENTS
- PG_PREPARED_XACTS
- PG_REPLICATION_SLOTS
- PG_RLSPOLICIES
- PG_ROLES
- PG_RULES
- PG_SECLABELS
- PG_SESSION_WLMSTAT
- PG_SESSION_IOSTAT
- PG_SETTINGS
- PG_SHADOW
- PG_STATS
- PG_STAT_ACTIVITY
- PG_STAT_ALL_INDEXES
- PG_STAT_ALL_TABLES
- PG_STAT_BAD_BLOCK
- PG_STAT_BGWRITER
- PG_STAT_DATABASE
- PG_STAT_DATABASE_CONFLICTS
- PG_STAT_USER_FUNCTIONS
- PG_STAT_USER_INDEXES
- PG_STAT_USER_TABLES
- PG_STAT_REPLICATION
- PG_STAT_SYS_INDEXES
- PG_STAT_SYS_TABLES
- PG_STAT_XACT_ALL_TABLES
- PG_STAT_XACT_SYS_TABLES
- PG_STAT_XACT_USER_FUNCTIONS
- PG_STAT_XACT_USER_TABLES
- PG_STATIO_ALL_INDEXES
- PG_STATIO_ALL_SEQUENCES
- PG_STATIO_ALL_TABLES
- PG_STATIO_SYS_INDEXES
- PG_STATIO_SYS_SEQUENCES
- PG_STATIO_SYS_TABLES
- PG_STATIO_USER_INDEXES
- PG_STATIO_USER_SEQUENCES
- PG_STATIO_USER_TABLES
- PG_THREAD_WAIT_STATUS
- PG_TABLES
- PG_TDE_INFO
- PG_TIMEZONE_NAMES
- PG_TOTAL_USER_RESOURCE_INFO
- PG_USER
- PG_USER_MAPPINGS
- PG_VIEWS
- PG_WLM_STATISTICS
- PLAN_TABLE
- GS_FILE_STAT
- GS_OS_RUN_INFO
- GS_REDO_STAT
- GS_SESSION_MEMORY
- GS_SESSION_MEMORY_DETAIL
- GS_SESSION_STAT
- GS_SESSION_TIME
- GS_THREAD_MEMORY_DETAIL
- GS_TOTAL_MEMORY_DETAIL
- PG_TIMEZONE_ABBREVS
- PG_TOTAL_USER_RESOURCE_INFO_OID
- PG_VARIABLE_INFO
- GS_INSTANCE_TIME
- 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 Functions
- SEQUENCE Functions
- Array Functions and Operators
- Range Functions and Operators
- Aggregate Functions
- Window Functions
- Security Functions
- Encrypted Equality Functions
- Set Returning Functions
- Conditional Expression Functions
- System Information Functions
- System Administration Functions
- Statistics Information Functions
- Trigger Functions
- Global Temporary Table Functions
- AI Feature Functions
- Other System Functions
- Supported Data Types
- SQL Syntax
- ABORT
- ALTER DATABASE
- ALTER DATA SOURCE
- ALTER DEFAULT PRIVILEGES
- ALTER DIRECTORY
- ALTER FOREIGN TABLE
- ALTER FUNCTION
- ALTER GROUP
- ALTER INDEX
- ALTER LARGE OBJECT
- ALTER MATERIALIZED VIEW
- ALTER ROLE
- ALTER ROW LEVEL SECURITY POLICY
- ALTER RULE
- ALTER SCHEMA
- ALTER SEQUENCE
- ALTER SERVER
- ALTER SESSION
- ALTER SYNONYM
- ALTER SYSTEM KILL SESSION
- ALTER SYSTEM SET
- ALTER TABLE
- ALTER TABLE PARTITION
- ALTER 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
- CLOSE
- CLUSTER
- COMMENT
- COMMIT | END
- COMMIT PREPARED
- COPY
- CREATE CLIENT MASTER KEY
- CREATE COLUMN ENCRYPTION KEY
- CREATE DATABASE
- CREATE DATA SOURCE
- CREATE DIRECTORY
- CREATE FOREIGN TABLE
- CREATE FUNCTION
- CREATE GROUP
- CREATE INDEX
- CREATE MATERIALIZED VIEW
- CREATE ROW LEVEL SECURITY POLICY
- CREATE PROCEDURE
- CREATE ROLE
- CREATE RULE
- CREATE SCHEMA
- CREATE SEQUENCE
- CREATE SERVER
- CREATE SYNONYM
- CREATE TABLE
- CREATE TABLE AS
- CREATE TABLE PARTITION
- CREATE TABLESPACE
- CREATE TEXT SEARCH CONFIGURATION
- CREATE TEXT SEARCH DICTIONARY
- CREATE TRIGGER
- CREATE TYPE
- CREATE USER
- CREATE USER MAPPING
- CREATE VIEW
- CURSOR
- DEALLOCATE
- DECLARE
- DELETE
- DO
- DROP CLIENT MASTER KEY
- DROP COLUMN ENCRYPTION KEY
- DROP DATABASE
- DROP DATA SOURCE
- DROP DIRECTORY
- DROP FOREIGN TABLE
- DROP FUNCTION
- DROP GROUP
- DROP INDEX
- DROP MATERIALIZED VIEW
- DROP OWNED
- DROP ROW LEVEL SECURITY POLICY
- DROP PROCEDURE
- DROP ROLE
- DROP RULE
- DROP SCHEMA
- DROP SEQUENCE
- DROP SERVER
- DROP SYNONYM
- DROP TABLE
- DROP TABLESPACE
- DROP TEXT SEARCH CONFIGURATION
- DROP TEXT SEARCH DICTIONARY
- DROP TRIGGER
- DROP TYPE
- DROP USER
- DROP USER MAPPING
- DROP VIEW
- EXECUTE
- EXPLAIN
- EXPLAIN PLAN
- FETCH
- GRANT
- INSERT
- LOCK
- MOVE
- MERGE INTO
- PREPARE
- PREPARE TRANSACTION
- REASSIGN OWNED
- 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
- SHUTDOW
- START TRANSACTION
- TRUNCATE
- UPDATE
- VACUUM
- VALUES
- GUC Parameters
- GUC Parameter Usage
- File Location
- Connection and Authentication
- Resource Consumption
- Parallel Import
- 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
- Upgrade Parameters
- Miscellaneous Parameters
- Wait Events
- Query
- System Performance Snapshot
- Equality Query in a Fully-encrypted Database
- Global Temporary Table
- Appendix
- DBE_PERF
- 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
- 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
- Lock
- Wait Events
- Configuration
- Operator
- Workload Manager
- Global Plancache
- Appendix
- 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
- System Catalogs and System Views
- Glossary
Date and Time Processing Functions and Operators
Date and Time Operators
WARNING: When the user uses date/time operators, explicit type prefixes are modified for corresponding operands to ensure that the operands parsed by the database are consistent with what the user expects, and no unexpected results occur. For example, abnormal mistakes will occur in the following example without an explicit data type.
SELECT date '2001-10-01' - '7' AS RESULT;
Table 1 Time and date operators
Operator | Example |
---|---|
+ | mogdb=# SELECT date '2001-09-28' + integer '7' AS RESULT; result 2001-10-05 00:00:00 (1 row) |
mogdb=# SELECT date '2001-09-28' + interval '1 hour' AS RESULT; result 2001-09-28 01:00:00 (1 row) |
|
mogdb=# SELECT date '2001-09-28' + time '03:00' AS RESULT; result 2001-09-28 03:00:00 (1 row) |
|
mogdb=# SELECT interval '1 day' + interval '1 hour' AS RESULT; result 1 day 01:00:00 (1 row) |
|
mogdb=# SELECT timestamp '2001-09-28 01:00' + interval '23 hours' AS RESULT; result 2001-09-29 00:00:00 (1 row) |
|
mogdb=# SELECT time '01:00' + interval '3 hours' AS RESULT; result 04:00:00 (1 row) |
|
- | mogdb=# SELECT date '2001-10-01' - date '2001-09-28' AS RESULT; result 3 days (1 row) |
mogdb=# SELECT date '2001-10-01' - integer '7' AS RESULT; result 2001-09-24 00:00:00 (1 row) |
|
mogdb=# SELECT date '2001-09-28' - interval '1 hour' AS RESULT; result 2001-09-27 23:00:00 (1 row) |
|
mogdb=# SELECT time '05:00' - time '03:00' AS RESULT; result 02:00:00 (1 row) |
|
mogdb=# SELECT time '05:00' - interval '2 hours' AS RESULT; result 03:00:00 (1 row) |
|
mogdb=# SELECT timestamp '2001-09-28 23:00' - interval '23 hours' AS RESULT; result 2001-09-28 00:00:00 (1 row) |
|
mogdb=# SELECT interval '1 day' - interval '1 hour' AS RESULT; result 23:00:00 (1 row) |
|
mogdb=# SELECT timestamp '2001-09-29 03:00' - timestamp '2001-09-27 12:00' AS RESULT; result 1 day 15:00:00 (1 row) |
|
* | mogdb=# SELECT 900 * interval '1 second' AS RESULT; result 00:15:00 (1 row) |
mogdb=# SELECT 21 * interval '1 day' AS RESULT; result 21 days (1 row) |
|
mogdb=# SELECT double precision '3.5' * interval '1 hour' AS RESULT; result 03:30:00 (1 row) |
|
/ | mogdb=# SELECT interval '1 hour' / double precision '1.5' AS RESULT; result 00:40:00 (1 row) |
Time/Date Functions
-
age(timestamp, timestamp)
Description: Subtracts arguments, producing a result in YYYY-MM-DD format. If the result is negative, the returned result is also negative.
Return type: interval
Example:
mogdb=# SELECT age(timestamp '2001-04-10', timestamp '1957-06-13'); age ------------------------- 43 years 9 mons 27 days (1 row)
-
age(timestamp)
Description: Subtracts from current_date
Return type: interval
Example:
mogdb=# SELECT age(timestamp '1957-06-13'); age ------------------------- 60 years 2 mons 18 days (1 row)
-
clock_timestamp()
Description: Specifies the current timestamp of the real-time clock.
Return type: timestamp with time zone
Example:
mogdb=# SELECT clock_timestamp(); clock_timestamp ------------------------------- 2017-09-01 16:57:36.636205+08 (1 row)
-
current_date
Description: current date
Return type: date
Example:
mogdb=# SELECT current_date; date ------------ 2017-09-01 (1 row)
-
current_time
Description: current time
Return type: time with time zone
Example:
mogdb=# SELECT current_time; timetz -------------------- 16:58:07.086215+08 (1 row)
-
current_timestamp
Description: Specifies the current date and time.
Return type: timestamp with time zone
Example:
mogdb=# SELECT current_timestamp; pg_systimestamp ------------------------------ 2017-09-01 16:58:19.22173+08 (1 row)
-
date_part(text, timestamp)
Description: Obtains the value of a subdomain in date or time, for example, the year or hour. Equivalent to extract(field from timestamp).
Return type: double precision
Example:
mogdb=# SELECT date_part('hour', timestamp '2001-02-16 20:38:40'); date_part ----------- 20 (1 row)
-
date_part(text, interval)
Description: Obtains the subdomain value of the date/time value. When obtaining the month value, if the value is greater than 12, obtain the remainder after it is divided by 12. Equivalent to extract(field from timestamp).
Return type: double precision
Example:
mogdb=# SELECT date_part('month', interval '2 years 3 months'); date_part ----------- 3 (1 row)
-
date_trunc(text, timestamp)
Description: Truncates to the precision specified by text.
Return type: timestamp
Example:
mogdb=# SELECT date_trunc('hour', timestamp '2001-02-16 20:38:40'); date_trunc --------------------- 2001-02-16 20:00:00 (1 row)
-
trunc(timestamp)
Description: By default, the data is intercepted by day.
Example:
mogdb=# SELECT trunc(timestamp '2001-02-16 20:38:40'); trunc --------------------- 2001-02-16 00:00:00 (1 row)
-
extract(field from timestamp)
Description: Obtains the hour.
Return type: double precision
Example:
mogdb=# SELECT extract(hour from timestamp '2001-02-16 20:38:40'); date_part ----------- 20 (1 row)
-
extract(field from interval)
Description: Obtains the month. If the value is greater than 12, obtain the remainder after it is divided by 12.
Return type: double precision
Example:
mogdb=# SELECT extract(month from interval '2 years 3 months'); date_part ----------- 3 (1 row)
-
isfinite(date)
Description: Tests for valid date.
Return type: Boolean
Example:
mogdb=# SELECT isfinite(date '2001-02-16'); isfinite ---------- t (1 row)
-
isfinite(timestamp)
Description: Tests for valid timestamp.
Return type: Boolean
Example:
mogdb=# SELECT isfinite(timestamp '2001-02-16 21:28:30'); isfinite ---------- t (1 row)
-
isfinite(interval)
Description: Tests for valid interval.
Return type: Boolean
Example:
mogdb=# SELECT isfinite(interval '4 hours'); isfinite ---------- t (1 row)
-
justify_days(interval)
Description: Sets the time interval in months (30 days as a month).
Return type: interval
Example:
mogdb=# SELECT justify_days(interval '35 days'); justify_days -------------- 1 mon 5 days (1 row)
-
justify_hours(interval)
Description: Sets the time interval in days (24 hours is one day).
Return type: interval
Example:
mogdb=# SELECT JUSTIFY_HOURS(INTERVAL '27 HOURS'); justify_hours ---------------- 1 day 03:00:00 (1 row)
-
justify_interval(interval)
Description: Adjusts interval using justify_days and justify_hours.
Return type: interval
Example:
mogdb=# SELECT JUSTIFY_INTERVAL(INTERVAL '1 MON -1 HOUR'); justify_interval ------------------ 29 days 23:00:00 (1 row)
-
localtime
Description: current time
Return type: time
Example:
mogdb=# SELECT localtime AS RESULT; result ---------------- 16:05:55.664681 (1 row)
-
localtimestamp
Description: Specifies the current date and time.
Return type: timestamp
Example:
mogdb=# SELECT localtimestamp; timestamp ---------------------------- 2017-09-01 17:03:30.781902 (1 row)
-
now()
Description: Specifies the current date and time.
Return type: timestamp with time zone
Example:
mogdb=# SELECT now(); now ------------------------------- 2017-09-01 17:03:42.549426+08 (1 row)
-
numtodsinterval(num, interval_unit)
Description: Converts a number to the interval type. num is a numeric-typed number. interval_unit is a string in the following format: 'DAY' | 'HOUR' | 'MINUTE' | 'SECOND'
You can set the IntervalStyle parameter to a to be compatible with the interval output format of the function.
Example:
mogdb=# SELECT numtodsinterval(100, 'HOUR'); numtodsinterval ----------------- 100:00:00 (1 row) mogdb=# SET intervalstyle = a; SET mogdb=# SELECT numtodsinterval(100, 'HOUR'); numtodsinterval ------------------------------- +000000004 04:00:00.000000000 (1 row)
-
pg_sleep(seconds)
Description: Server thread delay time, in seconds.
Return type: void
Example:
mogdb=# SELECT pg_sleep(10); pg_sleep ---------- (1 row)
-
statement_timestamp()
Description: Specifies the current date and time.
Return type: timestamp with time zone
Example:
mogdb=# SELECT statement_timestamp(); statement_timestamp ------------------------------- 2017-09-01 17:04:39.119267+08 (1 row)
-
sysdate
Description: Specifies the current date and time.
Return type: timestamp
Example:
mogdb=# SELECT sysdate; sysdate --------------------- 2017-09-01 17:04:49 (1 row)
-
timeofday()
Description: current date and time (like clock_timestamp, but returned as text)
Return type: text
Example:
mogdb=# SELECT timeofday(); timeofday ------------------------------------- Fri Sep 01 17:05:01.167506 2017 CST (1 row)
-
transaction_timestamp()
Description: current date and time (equivalent to current_timestamp)
Return type: timestamp with time zone
Example:
mogdb=# SELECT transaction_timestamp(); transaction_timestamp ------------------------------- 2017-09-01 17:05:13.534454+08 (1 row)
-
add_months(d,n)
Description: Returns the date date plus integer months.
Return type: timestamp
Example:
mogdb=# SELECT add_months(to_date('2017-5-29', 'yyyy-mm-dd'), 11) FROM dual; add_months --------------------- 2018-04-29 00:00:00 (1 row)
-
last_day(d)
Description: Returns the date of the last day of the month that contains date.
Return type: timestamp
Example:
mogdb=# select last_day(to_date('2017-01-01', 'YYYY-MM-DD')) AS cal_result; cal_result --------------------- 2017-01-31 00:00:00 (1 row)
-
next_day(x,y)
Description: Returns the time of the next week y started from x
Return type: timestamp
Example:
mogdb=# select next_day(timestamp '2017-05-25 00:00:00','Sunday')AS cal_result; cal_result --------------------- 2017-05-28 00:00:00 (1 row)
TIMESTAMPDIFF
TIMESTAMPDIFF(unit , timestamp_expr1, timestamp_expr2)
The timestampdiff function returns the result of timestamp_expr2 - timestamp_expr1 in the specified unit. timestamp_expr1 and timestamp_expr2 must be value expressions of the timestamp, timestamptz, or date type. unit indicates the unit of the difference between two dates.
NOTE: This function is valid only when MogDB is compatible with the MY type (that is, dbcompatibility = 'B').
-
year
Year.
mogdb=# SELECT TIMESTAMPDIFF(YEAR, '2018-01-01', '2020-01-01'); timestamp_diff ---------------- 2 (1 row)
-
quarter
Quarter.
mogdb=# SELECT TIMESTAMPDIFF(QUARTER, '2018-01-01', '2020-01-01'); timestamp_diff ---------------- 8 (1 row)
-
month
Month.
mogdb=# SELECT TIMESTAMPDIFF(MONTH, '2018-01-01', '2020-01-01'); timestamp_diff ---------------- 24 (1 row)
-
week
Week.
mogdb=# SELECT TIMESTAMPDIFF(WEEK, '2018-01-01', '2020-01-01'); timestamp_diff ---------------- 104 (1 row)
-
day
Day.
mogdb=# SELECT TIMESTAMPDIFF(DAY, '2018-01-01', '2020-01-01'); timestamp_diff ---------------- 730 (1 row)
-
hour
Hour.
mogdb=# SELECT TIMESTAMPDIFF(HOUR, '2020-01-01 10:10:10', '2020-01-01 11:11:11'); timestamp_diff ---------------- 1 (1 row)
-
minute
Minute.
mogdb=# SELECT TIMESTAMPDIFF(MINUTE, '2020-01-01 10:10:10', '2020-01-01 11:11:11'); timestamp_diff ---------------- 61 (1 row)
-
second
Second.
mogdb=# SELECT TIMESTAMPDIFF(SECOND, '2020-01-01 10:10:10', '2020-01-01 11:11:11'); timestamp_diff ---------------- 3661 (1 row)
-
microseconds
The seconds column, including fractional parts, multiplied by 1,000,000.
mogdb=# SELECT TIMESTAMPDIFF(MICROSECOND, '2020-01-01 10:10:10.000000', '2020-01-01 10:10:10.111111'); timestamp_diff ---------------- 111111 (1 row)
EXTRACT
EXTRACT(field FROM source)
The extract function retrieves subcolumns such as year or hour from date/time values. source must be a value expression of type timestamp, time, or interval. (Expressions of type date are cast to timestamp and can therefore be used as well.) field is an identifier or string that selects what column to extract from the source value. The extract function returns values of type double precision. The following are valid field names:
-
century
The first century starts at 0001-01-01 00:00:00 AD. This definition applies to all Gregorian calendar countries. There is no century number 0. You go from -1 century to 1 century.
Example:
mogdb=# SELECT EXTRACT(CENTURY FROM TIMESTAMP '2000-12-16 12:21:13'); date_part ----------- 20 (1 row)
-
day
-
For timestamp values, the day (of the month) column (1-31)
mogdb=# SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40'); date_part ----------- 16 (1 row)
-
For interval values, the number of days
mogdb=# SELECT EXTRACT(DAY FROM INTERVAL '40 days 1 minute'); date_part ----------- 40 (1 row)
-
-
decade
Year column divided by 10
mogdb=# SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40'); date_part ----------- 200 (1 row)
-
dow
Day of the week as Sunday(0) to Saturday (6)
mogdb=# SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40'); date_part ----------- 5 (1 row)
-
doy
Day of the year (1-365 or 366)
mogdb=# SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40'); date_part ----------- 47 (1 row)
-
epoch
-
For timestamp with time zone values, the number of seconds since 1970-01-01 00:00:00 UTC (can be negative);
for date and timestamp values, the number of seconds since 1970-01-01 00:00:00 local time;
for interval values, the total number of seconds in the interval.
mogdb=# SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40.12-08'); date_part -------------- 982384720.12 (1 row)
mogdb=# SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours'); date_part ----------- 442800 (1 row)
-
Way to convert an epoch value back to a timestamp
mogdb=# SELECT TIMESTAMP WITH TIME ZONE 'epoch' + 982384720.12 * INTERVAL '1 second' AS RESULT; result --------------------------- 2001-02-17 12:38:40.12+08 (1 row)
-
-
hour
Hour column (0-23)
mogdb=# SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40'); date_part ----------- 20 (1 row)
-
isodow
Day of the week (1-7)
Monday is 1 and Sunday is 7.
NOTE: This is identical to dow except for Sunday.
mogdb=# SELECT EXTRACT(ISODOW FROM TIMESTAMP '2001-02-18 20:38:40'); date_part ----------- 7 (1 row)
-
isoyear
The ISO 8601 year that the date falls in (not applicable to intervals).
Each ISO year begins with the Monday of the week containing January 4, so in early January or late December the ISO year may be different from the Gregorian year. See the week column for more information.
mogdb=# SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-01'); date_part ----------- 2005 (1 row)
mogdb=# SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-02'); date_part ----------- 2006 (1 row)
-
microseconds
The seconds column, including fractional parts, multiplied by 1,000,000
mogdb=# SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5'); date_part ----------- 28500000 (1 row)
-
millennium
Years in the 1900s are in the second millennium. The third millennium started from January 1, 2001.
mogdb=# SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40'); date_part ----------- 3 (1 row)
-
milliseconds
The seconds column, including fractional parts, multiplied by 1000. Note that this includes full seconds.
mogdb=# SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5'); date_part ----------- 28500 (1 row)
-
minute
Minutes column (0-59)
mogdb=# SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40'); date_part ----------- 38 (1 row)
-
month
For timestamp values, the number of the month within the year (1-12);
mogdb=# SELECT EXTRACT(MONTH FROM TIMESTAMP '2001-02-16 20:38:40'); date_part ----------- 2 (1 row)
For interval values, the number of months, modulo 12 (0-11)
mogdb=# SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months'); date_part ----------- 1 (1 row)
-
quarter
Quarter of the year (1-4) that the date is in
mogdb=# SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40'); date_part ----------- 1 (1 row)
-
second
Seconds column, including fractional parts (0-59)
mogdb=# SELECT EXTRACT(SECOND FROM TIME '17:12:28.5'); date_part ----------- 28.5 (1 row)
-
timezone
The time zone offset from UTC, measured in seconds. Positive values correspond to time zones east of UTC, negative values to zones west of UTC.
-
timezone_hour
The hour component of the time zone offset
-
timezone_minute
The minute component of the time zone offset
-
week
The number of the week of the year that the day is in. By definition (ISO 8601), the first week of a year contains January 4 of that year. (The ISO-8601 week starts on Monday.) In other words, the first Thursday of a year is in week 1 of that year.
Because of this, it is possible for early January dates to be part of the 52nd or 53rd week of the previous year, and late December dates to be part of the 1st week of the next year. For example, 2005-01-01 is part of the 53rd week of year 2004, 2006-01-01 is part of the 52nd week of year 2005, and 2012-12-31 is part of the 1st week of year 2013. You are advised to use the columns isoyear and week together to ensure consistency.
mogdb=# SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40'); date_part ----------- 7 (1 row)
-
year
Year column
mogdb=# SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40'); date_part ----------- 2001 (1 row)
date_part
The date_part function is modeled on the traditional Ingres equivalent to the SQL-standard function extract:
*date_part('field', source*)
Note that here the field parameter needs to be a string value, not a name. The valid field names for field are the same as for extract. For details, see EXTRACT.
Example:
Example:
mogdb=# SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40');
date_part
-----------
16
(1 row)
mogdb=# SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
date_part
-----------
4
(1 row)
[Table 2](#2 schema) specifies the schema for formatting date and time values.
Table 2 Schema for formatting date and time
Category | Pattern | Description |
---|---|---|
Hour | HH | Number of hours in one day (01-12) |
HH12 | Number of hours in one day (01-12) | |
HH24 | Number of hours in one day (00-23) | |
Minute | MI | Minute (00-59) |
Second | SS | Second (00-59) |
FF | Microsecond (000000-999999) | |
SSSSS | Second after midnight (0-86399) | |
Morning and afternoon | AM or A.M. | Morning identifier |
PM or P.M. | Afternoon identifier | |
Year | Y,YYY | Year with comma (with four digits or more) |
SYYYY | Year with four digits BC | |
YYYY | Year (with four digits or more) | |
YYY | Last three digits of a year | |
YY | Last two digits of a year | |
Y | Last one digit of a year | |
IYYY | ISO year (with four digits or more) | |
IYY | Last three digits of an ISO year | |
IY | Last two digits of an ISO year | |
I | Last one digit of an ISO year | |
RR | Last two digits of a year (A year of the 20th century can be stored in the 21st century.) | |
RRRR | Capable of receiving a year with four digits or two digits. If there are 2 digits, the value is the same as the returned value of RR. If there are 4 digits, the value is the same as YYYY. | |
BC or B.C.AD or A.D. | Era indicator Before Christ (BC) and After Christ (AD) | |
Month | MONTH | Full spelling of a month in uppercase (9 characters are filled in if the value is empty.) |
MON | Month in abbreviated format in uppercase (with three characters) | |
MM | Month (01-12) | |
RM | Month in Roman numerals (I-XII; I=JAN) and uppercase | |
Day | DAY | Full spelling of a date in uppercase (9 characters are filled in if the value is empty.) |
DY | Day in abbreviated format in uppercase (with three characters) | |
DDD | Day in a year (001-366) | |
DD | Day in a month (01-31) | |
D | Day in a week (1-7. Sunday is 1.) | |
Week | W | Week in a month (1-5) (The first week starts from the first day of the month.) |
WW | Week in a year (1-53) (The first week starts from the first day of the year.) | |
IW | Week in an ISO year (The first Thursday is in the first week.) | |
Century | CC | Century (with two digits) (The 21st century starts from 2001-01-01.) |
Julian date | J | Julian date (starting from January 1 of 4712 BC) |
Quarter | Q | Quarter |
NOTE: In the table, the rules for RR to calculate years are as follows:
- If the range of the input two-digit year is between 00 and 49: If the last two digits of the current year are between 00 and 49, the first two digits of the returned year are the same as the first two digits of the current year. If the last two digits of the current year are between 50 and 99, the first two digits of the returned year equal to the first two digits of the current year plus 1.
- If the range of the input two-digit year is between 50 and 99: If the last two digits of the current year are between 00 and 49, the first two digits of the returned year equal to the first two digits of the current year minus 1.
- If the last two digits of the current year are between 50 and 99, the first two digits of the returned year are the same as the first two digits of the current year.