From 9d8c565268cadf4569b601c259f9b50436363d55 Mon Sep 17 00:00:00 2001 From: zcp100_zcp100 Date: Fri, 18 Aug 2023 10:20:00 +0800 Subject: [PATCH] =?UTF-8?q?update(mogdb):=E6=9B=B4=E6=96=B0sql=E5=8F=82?= =?UTF-8?q?=E8=80=83=E8=8B=B1=E6=96=87?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit --- .../sql-reference/ordinary-table.md | 52 +++ .../sql-reference-anonymous-block.md | 76 ++++ .../sql-reference/sql-reference-contraints.md | 152 ++++++++ .../sql-reference/sql-reference-cursor.md | 341 ++++++++++++++++++ .../sql-reference/sql-reference-dcf.md | 211 +++++++++++ .../sql-reference/sql-reference-index.md | 159 ++++++++ .../sql-reference/sql-reference-llvm.md | 90 +++++ .../sql-reference/sql-reference-lock.md | 76 ++++ .../sql-reference/sql-reference-trigger.md | 158 ++++++++ .../sql-reference/sql-reference.md | 36 ++ .../sql-reference/sql-syntax-format.md | 21 ++ .../sql-reference/sub-query.md | 181 ++++++++++ .../sql-reference/type-base-value.md | 83 +++++ 13 files changed, 1636 insertions(+) create mode 100644 product/en/docs-mogdb/v5.0/reference-guide/sql-reference/ordinary-table.md create mode 100644 product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-anonymous-block.md create mode 100644 product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-contraints.md create mode 100644 product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-cursor.md create mode 100644 product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-dcf.md create mode 100644 product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-index.md create mode 100644 product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-llvm.md create mode 100644 product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-lock.md create mode 100644 product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-trigger.md create mode 100644 product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference.md create mode 100644 product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-syntax-format.md create mode 100644 product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sub-query.md create mode 100644 product/en/docs-mogdb/v5.0/reference-guide/sql-reference/type-base-value.md diff --git a/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/ordinary-table.md b/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/ordinary-table.md new file mode 100644 index 00000000..6c198eab --- /dev/null +++ b/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/ordinary-table.md @@ -0,0 +1,52 @@ +--- +title: Ordinary Table +summary: Ordinary Table +author: zhang cuiping +date: 2023-04-07 +--- + +# Ordinary Table + +Create an empty table in the current database. The table will be owned by the creator. The same table can be stored in different databases. You can execute the CREATE TABLE statement to create a table. + +## Syntax + +``` +CREATE TABLE table_name + (column_name data_type [, ... ]); +``` + +## Parameter Description + +- **table_name** + + Specifies the name of the table to be created. + +- **column_name** + + Specifies the name of the column to be created in the new table. + +- **data_type** + + Specifies the data type of the column. + +## Examples + +Run the following commands to create a table named **customer_t1**. The table columns are **c_customer_sk**, **c_customer_id**, **c_first_name**, and **c_last_name**. The data types of the table columns are integer, char (5), char (6), and char (8), respectively. + +```sql +MogDB=# CREATE TABLE customer_t1 +( + c_customer_sk integer, + c_customer_id char(5), + c_first_name char(6), + c_last_name char(8), + Amount integer +); +``` + +If the following information is displayed, the table has been created: + +``` +CREATE TABLE +``` \ No newline at end of file diff --git a/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-anonymous-block.md b/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-anonymous-block.md new file mode 100644 index 00000000..065c487b --- /dev/null +++ b/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-anonymous-block.md @@ -0,0 +1,76 @@ +--- +title: Anonymous Blocks +summary: Anonymous Blocks +author: zhang cuiping +date: 2023-04-07 +--- + +# Anonymous Blocks + +An anonymous block is one of the character blocks of a stored procedure and has no name. It is generally used for scripts or activities that are not executed frequently. + +## Syntax + +[Figure 1](#anonymous) shows the syntax diagram for an anonymous block. + +**Figure 1** anonymous_block::= +![anonymous_block](https://cdn-mogdb.enmotech.com/docs-media/mogdb/reference-guide/anonymous_block.png) + +Details about the syntax diagram are as follows: + +- The execution section of an anonymous block starts with a BEGIN statement, has a break with an END statement, and ends with a semicolon (;). Type a slash (/) and press **Enter** to execute the statement. + + > ![img](https://cdn-mogdb.enmotech.com/docs-media/icon/icon-notice.gif) **NOTICE:** The terminator “/” must be written in an independent row. + +- The declaration section includes the variable definition, type, and cursor definition. +- A simplest anonymous block does not execute any commands. At least one statement, even a NULL statement, must be presented in any implementation blocks. + +## Parameter Description + +- **DECLARE** + + Specifies an optional keyword used to begin a DECLARE statement. This keyword can be used to declare a data type, variable, or cursor. The use of this keyword depends on the context in which the block is located. + +- **declaration_statements** + + Specifies the declaration of a data type, variable, cursor, exception, or procedure whose scope is limited to the block. Each declaration must be terminated with a semicolon (;). + +- **BEGIN** + + Specifies the mandatory keyword for introducing an executable section. The section can contain one or more SQL or PL/SQL statements. A BEGIN-END block can contain nested BEGIN-END blocks. + +- **execution_statements** + + Specifies PL/SQL or SQL statements. Each statement must be terminated with a semicolon (;). + +- **END** + + Specifies the required keyword for ending a block. + +## Examples + +```sql +-- Create a null statement block. +MogDB=# BEGIN + NULL; +END; +/ + +-- Create a demonstration table. +MogDB=# CREATE TABLE table1(id1 INT, id2 INT, id3 INT); +CREATE TABLE + +-- Use an anonymous block to insert data. +MogDB=# BEGIN + insert into table1 values(1,2,3); + END; + / +ANONYMOUS BLOCK EXECUTE + +-- Query the inserted data. +MogDB=# select * from table1; + id1 | id2 | id3 +-----+-----+----- + 1 | 2 | 3 +(1 rows) +``` \ No newline at end of file diff --git a/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-contraints.md b/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-contraints.md new file mode 100644 index 00000000..2f87a7fb --- /dev/null +++ b/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-contraints.md @@ -0,0 +1,152 @@ +--- +title: Constraints +summary: Constraints +author: zhang cuiping +date: 2023-04-07 +--- + +# Constraints + +Constraint clauses specify constraints that new or updated rows must satisfy for an INSERT or UPDATE operation to succeed. If there is any data behavior that violates the constraints, the behavior is terminated by the constraints. + +Constraints can be specified when a table is created (by executing the CREATE TABLE statement) or after a table is created (by executing the ALTER TABLE statement). + +Constraints can be column-level or table-level. Column-level constraints apply only to columns, and table-level constraints apply to the entire table. + +The common constraints of MogDB are as follows: + +- NOT NULL: specifies that a column cannot store **NULL** values. +- UNIQUE: ensures that the value of a column is unique. +- PRIMARY KEY: functions as the combination of NOT NULL and UNIQUE and ensures that a column (or the combination of two or more columns) has a unique identifier to help quickly locate a specific record in a table. +- FOREIGN KEY: ensures the referential integrity for data in one table to match values in another table. +- CHECK: ensures that values in a column meet specified conditions. + +## NOT NULL + +If no constraint is specified during table creation, the default value is **NULL**, indicating that **NULL** values can be inserted into columns. If you do not want a column to be set to **NULL**, you need to define the NOT NULL constraint on the column to specify that **NULL** values are not allowed in the column. When you insert data, if the column contains **NULL**, an error is reported and the data fails to be inserted. + +**NULL** does not mean that there is no data. It indicates unknown data. + +For example, create the **staff** table that contains five columns. The **NAME** and **ID** columns cannot be set to **NULL**. + +```sql +MogDB=# CREATE TABLE staff( + ID INT NOT NULL, + NAME char(8) NOT NULL, + AGE INT , + ADDRESS CHAR(50), + SALARY REAL +); +``` + +Insert data into the **staff** table. When a **NULL** value is inserted into the **ID** column, the database returns an error. + +```sql +MogDB=# INSERT INTO staff VALUES (1,'lily',28); +INSERT 0 1 +MogDB=# INSERT INTO staff (NAME,AGE) VALUES ('JUCE',28); +ERROR: null value in column "id" violates not-null constraint +DETAIL: Failing row contains (null, JUCE , 28, null, null). +``` + +## UNIQUE + +The UNIQUE constraint specifies that a group of one or more columns of a table can contain only unique values. + +For the UNIQUE constraint, **NULL** is not considered equal. + +For example, create the **staff1** table that contains five columns, where **AGE** is set to **UNIQUE**. Therefore, you cannot add two records with the same age. + +```sql +MogDB=# CREATE TABLE staff1( + ID INT NOT NULL, + NAME char(8) NOT NULL, + AGE INT NOT NULL UNIQUE , + ADDRESS CHAR(50), + SALARY REAL +); +``` + +Insert data into the **staff1** table. When two identical data records are inserted into the **AGE** column, the database returns an error. + +```sql +MogDB=# INSERT INTO staff1 VALUES (1,'lily',28); +INSERT 0 1 +MogDB=# INSERT INTO staff1 VALUES (2, 'JUCE',28); +ERROR: duplicate key value violates unique constraint "staff1_age_key" +DETAIL: Key (age)=(28) already exists. +``` + +## PRIMARY KEY + +PRIMARY KEY is the unique identifier of each record in a data table. It specifies that a column or multiple columns in a table can contain only unique (non-duplicate) and non-**NULL** values. + +PRIMARY KEY is the combination of NOT NULL and UNIQUE. Only one primary key can be specified for a table. + +For example, create the **staff2** table where **ID** indicates the primary key. + +```sql +MogDB=# CREATE TABLE staff2( + ID INT PRIMARY KEY , + NAME TEXT NOT NULL, + AGE INT NOT NULL, + ADDRESS CHAR(50), + SALARY REAL +); +NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "staff2_pkey" for table "staff2" +CREATE TABLE +``` + +## FOREIGN KEY + +The FOREIGN KEY constraint specifies that the value of a column (or a group of columns) must match the value in a row of another table. Generally, the FOREIGN KEY constraint in one table points to the UNIQUE KEY constraint in another table. That is, the referential integrity between two related tables is maintained. + +For example, create the **staff3** table that contains five columns. + +```sql +MogDB=# CREATE TABLE staff3( + ID INT PRIMARY KEY NOT NULL, + NAME TEXT NOT NULL, + AGE INT NOT NULL, + ADDRESS CHAR(50), + SALARY REAL +); +``` + +Create the **DEPARTMENT** table and add three columns. The **EMP_ID** column indicates the foreign key and it is similar to the **ID** column of the **staff3** table. + +```sql +MogDB=# CREATE TABLE DEPARTMENT( + ID INT PRIMARY KEY NOT NULL, + DEPT CHAR(50) NOT NULL, + EMP_ID INT references staff3(ID) +); +``` + +## CHECK + +The CHECK constraint 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 value, while an expression in a table constraint can reference multiple columns. **<>NULL** and **!=NULL** are invalid in an expression. Change them to **IS NOT NULL**. + +For example, create the **staff4** table and add a CHECK constraint to the **SALARY** column to ensure that the inserted value is greater than **0**. + +```sql +MogDB=# CREATE TABLE staff4( + ID INT PRIMARY KEY NOT NULL, + NAME TEXT NOT NULL, + AGE INT NOT NULL, + ADDRESS CHAR(50), + SALARY REAL CHECK(SALARY > 0) +); +NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "staff4_pkey" for table "staff4" +CREATE TABLE +``` + +Insert data into the **staff4** table. When the inserted value of the **SALARY** column is not greater than **0**, the database reports an error. + +```sql +MogDB=# INSERT INTO staff4(ID,NAME,AGE,SALARY) VALUES (2, 'JUCE',16,0); +ERROR: new row for relation "staff4" violates check constraint "staff4_salary_check" +DETAIL: N/A +``` \ No newline at end of file diff --git a/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-cursor.md b/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-cursor.md new file mode 100644 index 00000000..4bb262e7 --- /dev/null +++ b/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-cursor.md @@ -0,0 +1,341 @@ +--- +title: Cursors +summary: Cursors +author: zhang cuiping +date: 2023-04-07 +--- + +# Cursors + +To process SQL statements, the stored procedure process assigns a memory segment to store context association. Cursors are handles or pointers pointing to context regions. With cursors, stored procedures can control alterations in context regions. + +## Syntax + +- Define a cursor. + + ```css + CURSOR cursor_name + [ BINARY ] [ NO SCROLL ] [ { WITH | WITHOUT } HOLD ] + FOR query ; + ``` + +- Retrieve data by using a created cursor. + + ```css + FETCH [ direction { FROM | IN } ] cursor_name; + ``` + + The **direction** clause specifies optional parameters. + + ```sql + NEXT + | PRIOR + | FIRST + | LAST + | ABSOLUTE count + | RELATIVE count + | count + | ALL + | FORWARD + | FORWARD count + | FORWARD ALL + | BACKWARD + | BACKWARD count + | BACKWARD ALL + ``` + +- Reposition a cursor without retrieving any data. + + The MOVE statement works exactly like the FETCH statement, except that it only repositions the cursor and does not return rows. + + ```scss + MOVE [ direction [ FROM | IN ] ] cursor_name; + ``` + + The **direction** clause specifies optional parameters. + + ```sql + NEXT + | PRIOR + | FIRST + | LAST + | ABSOLUTE count + | RELATIVE count + | count + | ALL + | FORWARD + | FORWARD count + | FORWARD ALL + | BACKWARD + | BACKWARD count + | BACKWARD ALL + ``` + +- Close a cursor and release all resources associated with the cursor. + + ```less + CLOSE { cursor_name | ALL } ; + ``` + +## Parameter Description + +- **cursor_name** + + Specifies the name of the cursor to be created or closed. + +- **BINARY** + + Specifies that data retrieved by a cursor will be returned in binary format, not in text format. + +- **NO SCROLL** + + Specifies how a cursor retrieves rows. + + - **NO SCROLL**: specifies that the cursor cannot be used to retrieve rows in a nonsequential fashion. + - Unspecified: Based on the query's execution plan, the system automatically determines whether the cursor can be used to retrieve rows in a nonsequential fashion. + +- **WITH HOLD | WITHOUT HOLD** + + Specifies whether a cursor can be used after the transaction that created it ends. + + - **WITH HOLD**: The cursor can be used after the transaction that created it ends. + - **WITHOUT HOLD**: The cursor cannot be used outside of the transaction that created it. + - If neither **WITH HOLD** nor **WITHOUT HOLD** is specified, the default is **WITHOUT HOLD**. + - Cross-node transactions (for example, DDL-contained transactions created in MogDB with multiple DBnode) do not support **WITH HOLD**. + +- **query** + + Uses the **SELECT** or **VALUES** clause to specify the rows to be returned by a cursor. + + Value range: **SELECT** or **VALUES** clause + +- **direction_clause** + + Defines the fetch direction. + + Value range: + + - **NEXT** (default value) + + Fetches the next row. + + - PRIOR + + Fetches the prior row. + + - FIRST + + Fetches the first row of the query (same as **ABSOLUTE 1**). + + - LAST + + Fetches the last row of the query (same as **ABSOLUTE – 1**). + + - ABSOLUTE count + + Fetches the _count_th row of the query. + + **ABSOLUTE** fetches are not any faster than navigating to the desired row with a relative move, because the underlying implementation must traverse all the intermediate rows anyway. + + Value range: a possibly-signed integer + + - If **count** is positive, the _count_th row of the query will be fetched. + - If **count** is negative, the _abs(count)_th row from the end of the query result will be fetched. + - If **count** is set to **0**, the cursor is positioned before the first row. + + - RELATIVE count + + Fetches the _count_th succeeding row or the _count_th prior row. + + Value range: a possibly-signed integer + + - If **count** is positive, the _count_th succeeding rows will be fetched. + - If **count** is negative, the _abs(count)_th prior rows will be fetched. + - If the current row contains no data, **RELATIVE 0** returns **NULL**. + + - count + + Fetches the next *count* rows (same as **FORWARD** *count*). + + - ALL + + Fetches all remaining rows (same as **FORWARD ALL**). + + - FORWARD + + Fetches the next row (same as **NEXT**). + + - FORWARD count + + Fetches the *count* succeeding rows or *count* prior rows. + + - FORWARD ALL + + Fetches all remaining rows. + + - BACKWARD + + Fetches the prior row (same as **PRIOR**). + + - BACKWARD count + + Fetches the prior *count* rows (scanning backwards). + + Value range: a possibly-signed integer + + - If **count** is positive, the prior *count* rows will be fetched. + - If **count** is a negative, the succeeding *abs (count)* rows will be fetched. + - **BACKWARD 0** re-fetches the current row, if any. + + - BACKWARD ALL + + Fetches all prior rows (scanning backwards). + +- **{ FROM | IN } cursor_name** + + Specifies the cursor name using the keyword **FROM** or **IN**. + + Value range: an existing cursor name + +- **ALL** + + Closes all open cursors. + +## Examples + +Assume that the **customer_t1** table exists and contains the following data: + +```sql +MogDB=# SELECT * FROM customer_t1; + c_customer_sk | c_customer_id | c_first_name | c_last_name | amount +---------------+---------------+--------------+-------------+-------- + 3769 | | Grace | | + 3769 | hello | | | + 6885 | maps | Joes | | 2200 + 4321 | tpcds | Lily | | 3000 + 9527 | world | James | | 5000 +(5 rows) +``` + +- Read a table using a cursor. + + ```sql + -- Start a transaction. + MogDB=# START TRANSACTION; + START TRANSACTION + + -- Set up cursor1. + MogDB=# CURSOR cursor1 FOR SELECT * FROM customer_t1; + DECLARE CURSOR + + -- Fetch the first three rows in cursor1. + MogDB=# FETCH FORWARD 3 FROM cursor1; + c_customer_sk | c_customer_id | c_first_name | c_last_name | amount + ---------------+---------------+--------------+-------------+-------- + 3769 | | Grace | | + 3769 | hello | | | + 6885 | maps | Joes | | 2200 + (3 rows) + + -- Close the cursor and commit the transaction. + MogDB=# CLOSE cursor1; + CLOSE CURSOR + + -- End the transaction. + MogDB=# END; + COMMIT + ``` + +- Read the **VALUES** clause using a cursor. + + ```sql + -- Start a transaction. + MogDB=# START TRANSACTION; + START TRANSACTION + + -- Set up cursor2. + MogDB=# CURSOR cursor2 FOR VALUES(1,2),(0,3) ORDER BY 1; + DECLARE CURSOR + + -- Fetch the first two rows in cursor2. + MogDB=# FETCH FORWARD 2 FROM cursor2; + column1 | column2 + ---------+--------- + 0 | 3 + 1 | 2 + (2 rows) + + -- Close the cursor and commit the transaction. + MogDB=# CLOSE cursor2; + CLOSE CURSOR + + -- End the transaction. + MogDB=# END; + COMMIT + ``` + +- Use the **WITH HOLD** cursor. + + ```sql + -- Start a transaction. + MogDB=# START TRANSACTION; + + -- Set up the WITH HOLD cursor. + MogDB=# DECLARE cursor1 CURSOR WITH HOLD FOR SELECT * FROM customer_t1; + + -- Fetch the first two rows in cursor1. + MogDB=# FETCH FORWARD 2 FROM cursor1; + c_customer_sk | c_customer_id | c_first_name | c_last_name | amount + ---------------+---------------+--------------+-------------+-------- + 3769 | | Grace | | + 3769 | hello | | | + (2 rows) + + -- End the transaction. + MogDB=# END; + COMMIT + + -- Fetch the next row in cursor1. + MogDB=# FETCH FORWARD 1 FROM cursor1; + c_customer_sk | c_customer_id | c_first_name | c_last_name | amount + ---------------+---------------+--------------+-------------+-------- + 6885 | maps | Joes | | 2200 + (1 row) + + -- Close the cursor. + MogDB=# CLOSE cursor1; + CLOSE CURSOR + ``` + +- Use the MOVE statement. + + ```sql + -- Start a transaction. + MogDB=# START TRANSACTION; + START TRANSACTION + + -- Define cursor1. + MogDB=# CURSOR cursor1 FOR SELECT * FROM customer_t1; + DECLARE CURSOR + + -- Skip the first three rows in cursor1. + MogDB=# MOVE FORWARD 1 FROM cursor1; + MOVE 1 + + -- Fetch the first two rows in cursor1. + MogDB=# FETCH 2 FROM cursor1; + c_customer_sk | c_customer_id | c_first_name | c_last_name | amount + ---------------+---------------+--------------+-------------+-------- + 3769 | hello | | | + 6885 | maps | Joes | | 2200 + (2 rows) + + + -- Close the cursor. + MogDB=# CLOSE cursor1; + CLOSE CURSOR + + -- End the transaction. + MogDB=# END; + COMMIT + ``` \ No newline at end of file diff --git a/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-dcf.md b/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-dcf.md new file mode 100644 index 00000000..1b352eb4 --- /dev/null +++ b/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-dcf.md @@ -0,0 +1,211 @@ +--- +title: DCF +summary: DCF +author: zhang cuiping +date: 2023-04-07 +--- + +# DCF + +Distributed Consensus Framework (DCF) implements typical algorithms such as Paxos and Raft to solve distribution consistency problems. DCF provides capabilities such as log replication, cluster HA, and automatic leader election, and can forcibly start the minority and dynamically adjust traffic for log replication. In addition, multiple Paxos-based roles are provided and can be adjusted. + +DCF is a high-performance, highly mature, reliable, scalable, and easy-to-use independent basic library. Other systems can easily interconnect with DCF through interfaces to obtain the strong consistency, high availability, and automatic disaster recovery capabilities provided by the Paxos algorithm. + +## Architecture + +[Figure 1](#dcf) shows the functional architecture of the DCF, including the algorithm modules, storage module, communication module, and service layer. + +**Figure 1** Functional architecture of the DCF +![DCF功能架构图](https://cdn-mogdb.enmotech.com/docs-media/mogdb/reference-guide/functional-architecture-of-the-dcf.png) + +- **Algorithm modules:** + + Algorithm modules are implemented based on the Multi-Paxos protocol. Based on the service scenarios, and requirements for high performance and ecosystem, DCF has made many function extensions and performance optimization to enrich the functions compared with the basic Multi-Paxos protocol, and the performance is significantly improved in multiple deployment scenarios. It mainly includes a leader election module, a log replication module, a metadata module, and a cluster management module. + +- **Storage module:** + + For specific service scenarios and ultimate performance, the DCF extracts a set of public interfaces for log storage and implements a default high-performance storage module. For specific scenarios or users who have ultimate performance and cost requirements, you can connect the existing storage system to the log storage interface of DCF to meet specific requirements. This is one of the advantages of DCF as an independent third-party library. + +- **Communication module:** + + The communication module is implemented based on the Message Exchange Component (MEC) and provides the communication capability between DCF instances and the asynchronous event processing framework. The main features are as follows: multiple extensible communication protocols, unicast, broadcast, and loopback sending interfaces, asynchronous message processing framework, multi-channel mechanism, multi-priority queue, compression, and batch sending. + +- **Service layer:** + + The service layer is the basis for running the entire DCF and provides various basic services required for program running. For example, lock, asynchronous task scheduling, thread pool service, and timer. + +## Features + +- **Nodes can be added and deleted online, and the leader role can be handed over online.** + + Based on the standard Multi-Paxos, the DCF supports online node addition and deletion, and leader handover. This is more suitable for building a development ecosystem in a wide range of service scenarios. + +- **Priority-based leader election and policy-based majority are supported.** + + - **Policy-based majority**: In the classic Paxos theory, data can be submitted after the majority reaches a consensus. However, the majority is not specific and it cannot be guaranteed that one or some nodes can obtain complete data. In actual applications, the nodes that are geographically close to each other have strongly consistent data, but the nodes that are geographically far away from each other are always in a non-strongly consistent state. These nodes cannot be activated as the primary node for city-level disaster recovery. The policy-based majority mechanism enables users to dynamically configure one or more nodes to be strongly consistent and can be activated as the primary node immediately for disaster recovery. + - **Priority-based leader election**: You can specify the priority of each node. The DCF elects a leader node strictly according to the specified priority. The node with a lower priority is activated only when all the nodes with a higher priority are unavailable. + +- **Diversified node roles are provided.** + + In addition to typical roles such as Leader, Follower, and Candidate, the DCF also supports customized roles, for example, the Passive role (with logs, with data, without the right to be elected, and not participating in the majority voting) and the Log role (with logs, without data, without the right to be elected, and participating in the mkajority voting). With these node roles, DCF supports synchronous and hybrid (synchronous/asynchronous) multi-cluster deployment. + +- **Batch & Pipeline** + + - **Batch**: The DCF supports multi-level batch operations, including: + + - Combine multiple logs into a single message for sending. + - Combine multiple logs for writing to the disk. + - Combine multiple logs for replication. + + Batch operations can effectively reduce the extra loss due to the message granularity and improve the throughput. + + - **Pipeline**: Before the result of a message is returned, the next message is concurrently sent to the corresponding node. By increasing the number of concurrent messages (pipelines), the latency of each single concurrent request can be effectively reduced and the performance can be improved. DCF uses the asynchronous mode in multiple phases, such as log persistence, network sending, and log replication, to maximize the pipeline performance. + +- **Efficient flow control algorithm** + + Batching and pipelining can improve the throughput and performance of the entire system. However, if the batch size is too large, the latency of a single request is too long. As a result, the number of concurrent requests is too large, affecting the throughput and request latency. Therefore, the DCF designs a set of efficient and adaptive flow control algorithms, automatically detects parameters such as the network bandwidth, network sending latency, and number of concurrent requests, and adjusts batch and pipeline parameters to control service traffic injection. + + [Figure 2](#dcf2) shows the process of the flow control algorithm. + + **Figure 2** Process of the flow control algorithm + ![流控算法流程](https://cdn-mogdb.enmotech.com/docs-media/mogdb/reference-guide/process-of-the-flow-control-algorithm.jpg) + + The core algorithm process is as follows: + + 1. The primary DCF node periodically samples and calculates consensus information, including the end-to-end consensus latency, end-to-end consensus log bandwidth, and overall log playback bandwidth. + 2. Calculate a new control value: The primary node obtains the performance change trend based on the sampling result and historical results, adjusts the control direction and step based on the historical control value and change trend, and calculates a new control value for better performance. + 3. Update the control value after the control period expires. + 4. Continuously apply the control value to service traffic to control the frequency of service traffic injection. + +## Example + +Assume that there are three nodes in the cluster and their IP addresses are **192.168.0.11**, **192.168.0.12**, and **192.168.0.13**. The node IDs are 1, 2, and 3, and the node roles are Leader, Follower, and Follower. + +To use the DCF component, you need to set **enable_dcf** to **on** (disabled by default) and configure **DCF config** in the configuration file during FusionSphere OpenStack OM installation and deployment. + +Obtain the XML file template from **script/gspylib/etc/conf/centralized/cluster_config_template_HA.xml**. + +Each line of information is commented out. The content in bold is related to the DCF. The following is an example: + +```xml + + + + + + + + + + + + + + + + + + + + + + + + + +... +``` + +1. Cluster status query upon installation completion + + Use gs_ctl to query the cluster status. + + ```perl + # gs_ctl query –D + # gs_ctl query -D /nvme0/gaussdb/cluster/nvme0/dn1 + HA state: + local role : Primary + static connections : 2 + db state : Normal + detail information : Normal + Paxos replication info: + paxos write location : 964/87134528 + paxos commit location : 964/87134528 + local write location : 964/87134528 + local flush location : 964/87134528 + local replay location : 964/87134528 + dcf replication info : {"stream_id":1,"local_node_id":1,"role":"LEADER","term":3,"run_mode":0,"work_mode":0,"hb_interval":1000,"elc_timeout":3000,"applied_index":14300633605."commit_index":14300633605,"first_index":14300625186,"last_index":14300633605,"cluster_min_apply_idx'14300633605,"leader_id":1,"leader_ip":"172.16.137.38","leader_port":17783,"nodes":[{"node_id":1,"id":"172.16.137.38","port":17783,"role":"LEADER","next_index":14300633606,"match_index":14300633605,"apply_index":14300633605},{"node_id":2,"ip":"172.16.137.40","port":17783,"role":"FOLLOWER","next_index":14300633606,"match_index":14300633605,"apply_index":14300633605},{"node_id":3,"ip":"172.16.137.42","port":17783,"role":"FOLLOWER","next_index":14300633606,"match_index":14300633605,"apply_index":14300633605}}} + ``` + + Where: + + - **dcf_replication_info**: DCF information of the current node. + - **role**: role of the current node. The value can be **LEADER**, **FOLLOWER**, **LOGGER**, **PASSIVE**, **PRE_CANDICATE**, **CANDIDATE** or **UNKNOW**. The preceding code shows that the current node is a leader node. + - **term**: election term. + - **run_mode**: DCF running mode. The value **0** indicates the automatic election mode, and the value **2** indicates that automatic election is disabled. + - **work_mode**: DCF working mode. The value **0** indicates the majority mode, and the value **1** indicates the minority mode. + - **hb_interval**: heartbeat interval between DCF nodes, in milliseconds. + - **elc_timeout**: DCF election timeout period, in milliseconds. + - **applied_index**: log location that is applied to the state machine. + - **commit_index**: log location that has been saved by most DCF nodes. Logs before **commit_index** have been made persistent. + - **first_index**: location of the first log saved by DCF nodes. This location is moved backward when the DN invokes **dcf_truncate**. The previous logs will be cleared. + - **last_index**: location of the last log saved by DCF nodes. This location contains the logs that are stored in the memory of the DCF nodes but are not persisted. Therefore, the value of **last_index** is greater than and equal to that of **commit_index**. + - **cluster_min_apply_idx**: location of the log that has been applied and assumes the smallest index. + - **leader_id**: ID of the leader node. + - **leader_ip**: IP address of the leader node. + - **leader_port**: port of the leader node, for DCF internal use. + - **nodes**: information about other nodes in the cluster. + +2. Online cluster scale adjustment + + To add a copy online, run the following command: + + ```xml + # gs_ctl member --operation=add --nodeid= --ip= --port= -D + ``` + + To reduce the number of copies online, run the following command: + + ```xml + # gs_ctl member --operation=remove --nodeid= -D + ``` + + If the cluster is normal, a single copy can be deleted within 5 minutes. + +3. Forcible minority startup + + In case that the majority is faulty, no consensus can be reached based on the Paxos protocol. As a result, the system cannot continue to provide services. In order to provide emergency service capabilities, the minority needs to be started to continue to provide services. + + Run the following command to start up the minority: + + ```xml + # cm_ctl setrunmode -n -D --xmode=minority --votenum= + ``` + + In the three-copy cluster scenario, if two copies are faulty, data can be submitted as long as one copy is consistent. + + Run the following command to resume the majority. + + ```xml + # cm_ctl setrunmode -n -D --xmode=normal --votenum= + ``` + +4. Switchover + + Primary/standby switchover is supported when one primary and multiple standby database nodes are deployed to implement switchover between AZs. Switchover is performed for maintenance. Before a switchover, ensure that the database instances are running properly, and no catchup between the primary and standby nodes is ongoing after services are stopped. + + To promote a standby node to primary, run the following command: + + ```xml + # cm_ctl switchover –n -D + ``` + +5. Standby node rebuilding + + Full build is supported in primary/standby deployment. After receiving a full build request, the primary DN blocks recycling DCF logs and the standby DN replicates Xlogs and data files from the primary DN. After the standby DN is started, a time point is set for the DCF function to replicate logs. + + To start full build, run the following command: + + ```css + gs_ctl build -b full -D + ``` \ No newline at end of file diff --git a/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-index.md b/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-index.md new file mode 100644 index 00000000..6f7f06bf --- /dev/null +++ b/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-index.md @@ -0,0 +1,159 @@ +--- +title: Indexes +summary: Indexes +author: zhang cuiping +date: 2023-04-07 +--- + +# Indexes + +An index is a pointer to data in a table. The index in a database is very similar to the index directory in a book. + +Indexes are primarily used to enhance database performance (though inappropriate use can result in database performance deterioration). You are advised to create indexes on: + +- Columns that are often queried +- Join conditions. For a query on joined columns, you are advised to create a composite index on the columns. For example, select * from t1 join t2 on t1. a=t2. a and t1. b=t2.b. You can create a composite index on the a and b columns of table t1. +- Columns having filter criteria (especially scope criteria) of a **WHERE** clause +- Columns that are frequently used after **ORDER BY**, **GROUP BY**, and **DISTINCT** + +## Syntax + +- Single-column index + + A single-column index is created based on only one column in a table. + + ```scss + CREATE INDEX [ [schema_name.]index_name ] ON table_name (column_name); + ``` + +- Composite index + + A composite index is created based on multiple columns in a table. + + ```scss + CREATE INDEX [ [schema_name.]index_name ] ON table_name (column1_name,column2_name,...); + ``` + +- Unique index + + Duplicate values cannot be inserted into a column with a unique index. + + ```scss + CREATE UNIQUE INDEX [ [schema_name.]index_name ] ON table_name (column_name); + ``` + +- Local index + + A Local index is created on a subset of a table. The subset is defined by a condition expression. + + ```scss + CREATE INDEX [ [schema_name.]index_name ] ON table_name (expression); + ``` + +- Partial index + + A partial index contains entries for only a portion of a table, usually a portion that is more useful for indexing than the rest of the table. + + ```scss + CREATE INDEX [ [schema_name.]index_name ] ON table_name (column_name) + [ WHERE predicate ] + ``` + +- Index deletion + + ```sql + DROP INDEX index_name; + ``` + +## Parameter Description + +- **UNIQUE** + + Creates a unique index. In this way, the system checks whether new values are unique in the index column. Attempts to insert or update data which would result in duplicate entries will generate an error. + + Currently, only the B-tree index supports unique indexes. + +- **schema_name** + + Specifies the schema name. + + Value range: an existing schema name + +- **index_name** + + Specifies the name of the index to be created. The schema of the index is the same as that of the table. + + Value range: a string. + +- **table_name** + + Specifies the name of the table for which an index is to be created (optionally schema-qualified). + + Value range: an existing table name + +- **column_name** + + Specifies the name of the column for which an index is to be created. + + Multiple columns can be specified if the index method supports multi-column indexes. A global index supports a maximum of 31 columns, and other indexes support a maximum of 32 columns. + +- **expression** + + Specifies an expression index constraint based on one or more columns of the table. It must be written in parentheses. However, the parentheses can be omitted if the expression has the form of a function call. + + The expression index can be used to obtain fast access to data based on some transformation of the basic data. For example, an index computed on **upper(col)** would allow the **WHERE upper(col) = 'JIM'** clause to use an index. + + If an expression contains the **IS NULL** clause, the index for this expression is invalid. In this case, you are advised to create a partial index. + +- **WHERE predicate** + + Creates a partial index. A partial index contains entries for only a portion of a table, usually a portion that is more useful for indexing than the rest of the table. For example, if you have a table that contains both billed and unbilled orders where the unbilled orders take up a small portion of the total table and yet that is an often used portion, you can improve performance by creating an index on just that portion. In addition, the **WHERE** clause with a UNIQUE constraint can be used to enforce uniqueness over a subset of a table. + + Value range: The predicate expression can only refer to columns of the underlying table, but it can use all columns, not just the ones being indexed. Currently, subqueries and aggregate expressions are forbidden in the **WHERE** clause. + +## Examples + +Create the **tpcds.ship_mode_t1** table. + +```sql +MogDB=# CREATE SCHEMA tpcds; +MogDB=# CREATE TABLE tpcds.ship_mode_t1 +( + SM_SHIP_MODE_SK INTEGER NOT NULL, + SM_SHIP_MODE_ID CHAR(16) NOT NULL, + SM_TYPE CHAR(30) , + SM_CODE CHAR(10) , + SM_CARRIER CHAR(20) , + SM_CONTRACT CHAR(20) +) ; +``` + +Create a single-column index on the **SM_SHIP_MODE_ID** column in the **tpcds.ship_mode_t1** table. + +```makefile +MogDB=# CREATE UNIQUE INDEX ds_ship_mode_t1_index0 ON tpcds.ship_mode_t1(SM_SHIP_MODE_ID); +``` + +Create a common unique index on the **SM_SHIP_MODE_SK** column in the **tpcds.ship_mode_t1** table. + +```makefile +MogDB=# CREATE UNIQUE INDEX ds_ship_mode_t1_index1 ON tpcds.ship_mode_t1(SM_SHIP_MODE_SK); +``` + +Create an expression index on the **SM_CODE** column in the **tpcds.ship_mode_t1** table. + +```makefile +MogDB=# CREATE INDEX ds_ship_mode_t1_index2 ON tpcds.ship_mode_t1(SUBSTR(SM_CODE,1 ,4)); +``` + +Create a partial index on the **SM_SHIP_MODE_SK** column where **SM_SHIP_MODE_SK** is greater than **10** in the **tpcds.ship_mode_t1** table. + +```sql +MogDB=# CREATE UNIQUE INDEX ds_ship_mode_t1_index3 ON tpcds.ship_mode_t1(SM_SHIP_MODE_SK) WHERE SM_SHIP_MODE_SK>10; +``` + +Delete the created index. + +```makefile +MogDB=# DROP INDEX tpcds.ds_ship_mode_t1_index2; +``` \ No newline at end of file diff --git a/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-llvm.md b/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-llvm.md new file mode 100644 index 00000000..d5d7e55b --- /dev/null +++ b/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-llvm.md @@ -0,0 +1,90 @@ +--- +title: LLVM +summary: LLVM +author: zhang cuiping +date: 2023-04-07 +--- + +# LLVM + +Based on the query execution plan tree, with the library functions provided by the Low Level Virtual Machine (LLVM), MogDB moves the process of determining the actual execution path from the executor phase to the execution initialization phase. In this way, problems such as function calling, logic condition branch determination, and a large amount of data read that are related to the original query execution are avoided, to improve the query performance. + +LLVM dynamic compilation can be used to generate customized machine code for each query to replace original common functions. Query performance is improved by reducing redundant judgment conditions and virtual function calls, and by making local data more accurate during actual queries. + +LLVM needs to consume extra time to pre-generate intermediate representation (IR) and compile it into codes. Therefore, if the data volume is small or if a query itself consumes less time, the performance deteriorates. + +## Application Scenarios + +- Expressions supporting LLVM + + The query statements that contain the following expressions support LLVM optimization: + + 1. Case…when… + 2. IN + 3. Bool + - And + - Or + - Not + 4. BooleanTest + - **IS_NOT_UNKNOWN**: corresponds to SQL statement IS NOT UNKNOWN. + - **IS_UNKNOWN**: corresponds to SQL statement IS UNKNOWN. + - **IS_TRUE**: corresponds to SQL statement IS TRUE. + - **IS_NOT_TRUE**: corresponds to SQL statement IS NOT TRUE. + - **IS_FALSE**: corresponds to SQL statement IS FALSE. + - **IS_NOT_FALSE**: corresponds to SQL statement IS NOT FALSE. + 5. NullTest + - IS_NOT_NULL + - IS_NULL + 6. Operator + 7. Function + - lpad + - substring + - btrim + - rtrim + - length + 8. Nullif + + Supported data types for expression computing are bool, tinyint, smallint, int, bigint, float4, float8, numeric, date, time, timetz, timestamp, timestamptz, interval, bpchar, varchar, text, and oid. + + Consider using LLVM only if expressions are used in the following content in a vectorized executor: **filter** in the **Scan** node; **complicate hash condition**, **hash join filter**, and **hash join target** in the **Hash Join** node; **filter** and **join filter** in the **Nested Loop** node; **merge join filter** and **merge join target** in the **Merge Join** node; and **filter** in the **Group** node. + +- Operators supporting LLVM + + 1. Join: HashJoin + 2. Agg: HashAgg + 3. Sort + + Where HashJoin supports only Hash Inner Join, and the corresponding hash cond supports comparisons between int4, bigint, and bpchar. HashAgg supports sum and avg operations of bigint and numeric data types. Group By statements supports int4, bigint, bpchar, text, varchar, timestamp, and count(*) aggregation operation. Sort supports only comparisons between int4, bigint, numeric, bpchar, text, and varchar data types. Except the preceding operations, LLVM cannot be used. You can use the explain performance tool to check whether LLVM can be used. + +## Non-applicable Scenarios + +- LLVM does not apply to tables that have small amount of data. +- Query jobs with a non-vectorized execution path cannot be generated. + +## Other Factors Affecting LLVM Performance + +The LLVM optimization effect depends on not only operations and computing in the database, but also the selected hardware environment. + +- Number of C functions called by expressions + + CodeGen does not implement full-expression calculation, that is, some expressions use CodeGen while others invoke original C code for calculation. In an entire calculation process, if the later calculation method plays a dominate role, using LLVM may deteriorate the performance. By setting **log_min_message** to **DEBUG1**, you can view expressions that directly invoke C code. + +- Memory resources + + One of the key LLVM features is to ensure the locality of data, that is, data should be stored in registers as much as possible. Data loading should be reduced at the same time. Therefore, when using LLVM, value of **work_mem** must be set as large as required to ensure that code is implemented in the memory. Otherwise, performance deteriorates. + +- Cost estimation + + LLVM realizes a simple cost estimation model. You can determine whether to use LLVM for the current node based on the tables involved in the node computing. If the optimizer underestimates the actual number of rows involved, gains cannot be achieved as expected. And vice versa. + +## Suggestions for Using LLVM + +Currently, LLVM is enabled by default in the database kernel, and users can configure it as required. The overall suggestions are as follows: + +1. Set **work_mem** to an appropriate value as large as possible. If much data is flushed to disks, you are advised to disable LLVM by setting **enable_codegen** to **off**. + +2. Set **codegen_cost_threshold** to an appropriate value (the default value is **10000**). Ensure that LLVM is not used when the data volume is small. After **codegen_cost_threshold** is set, the database performance may deteriorate due to the use of LLVM. In this case, you are advised to increase the parameter value. + +3. If a large number of C functions are called, you are advised not to use the LLVM function. + + > ![img](https://cdn-mogdb.enmotech.com/docs-media/icon/icon-note.gif) **NOTE:** If resources are robust, the larger the data volume is, the better the performance improvement is. \ No newline at end of file diff --git a/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-lock.md b/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-lock.md new file mode 100644 index 00000000..13653e25 --- /dev/null +++ b/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-lock.md @@ -0,0 +1,76 @@ +--- +title: Locks +summary: Locks +author: zhang cuiping +date: 2023-04-07 +--- + +# Locks + +To ensure database data consistency, you can execute the LOCK TABLE statement to prevent other users from modifying tables. + +For example, an application needs to ensure that data in a table is not modified during transaction running. For this purpose, table usage can be locked. This prevents data from being concurrently modified. + +The LOCK TABLE statement is useless outside a transaction block, because the lock would remain held only to the completion of the statement. + +## Syntax + +```css +LOCK [ TABLE ] name IN lock_mode MODE +``` + +## Parameter Description + +- **name** + + Specifies the name of the table to be locked. + +- **lock_mode** + + Specifies the lock mode. The basic modes are as follows: + + - **ACCESS EXCLUSIVE** + + Guarantees that the holder is the only transaction accessing the table in any way. It is the default lock mode. + + - **ACCESS SHARE** + + Indicates the lock mode for reading tables without modifying them. + +## Examples + +Obtains an **ACCESS EXCLUSIVE** lock on a table when going to perform a delete operation. + +```sql +-- Create a sample table. +MogDB=# CREATE TABLE graderecord + ( + number INTEGER, + name CHAR(20), + class CHAR(20), + grade INTEGER + ); +-- Insert data. +MogDB=# insert into graderecord values('210101','Alan','21.01',92); +insert into graderecord values('210102','Ben','21.01',62); +insert into graderecord values('210103','Brain','21.01',26); +insert into graderecord values('210204','Carl','21.02',77); +insert into graderecord values('210205','David','21.02',47); +insert into graderecord values('210206','Eric','21.02',97); +insert into graderecord values('210307','Frank','21.03',90); +insert into graderecord values('210308','Gavin','21.03',100); +insert into graderecord values('210309','Henry','21.03',67); +insert into graderecord values('210410','Jack','21.04',75); +insert into graderecord values('210311','Jerry','21.04',60); + +-- Start the process. +MogDB=# START TRANSACTION; + +-- Provide the example table. +MogDB=# LOCK TABLE graderecord IN ACCESS EXCLUSIVE MODE; + +-- Delete the example table. +MogDB=# DELETE FROM graderecord WHERE name ='Alan'; + +MogDB=# COMMIT; +``` \ No newline at end of file diff --git a/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-trigger.md b/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-trigger.md new file mode 100644 index 00000000..28628f08 --- /dev/null +++ b/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference-trigger.md @@ -0,0 +1,158 @@ +--- +title: Triggers +summary: Triggers +author: zhang cuiping +date: 2023-04-07 +--- + +# Triggers + +A trigger automatically executes functions when an event occurs in a specified database. + +## Syntax + +- Create a trigger. + + ```less + CREATE TRIGGER trigger_name { BEFORE | AFTER | INSTEAD OF } { event [ OR ... ] } + ON table_name + [ FOR [ EACH ] { ROW | STATEMENT } ] + [ WHEN ( condition ) ] + EXECUTE PROCEDURE function_name ( arguments ); + ``` + +- Modify a trigger. + + ```sql + ALTER TRIGGER trigger_name ON table_name RENAME TO new_trigger_name; + ``` + +- Delete a trigger. + + ```sql + DROP TRIGGER trigger_name ON table_name [ CASCADE | RESTRICT ]; + ``` + +## Parameter Description + +- **trigger_name** + + Specifies the trigger name. + +- **BEFORE** + + Specifies that a trigger function is executed before the trigger event. + +- **AFTER** + + Specifies that a trigger function is executed after the trigger event. + +- **INSTEAD OF** + + Specifies that a trigger function directly replaces the trigger event. + +- **event** + + Specifies the event that will fire the trigger. Values are **INSERT**, **UPDATE**, **DELETE**, and **TRUNCATE**. Multiple events can be specified using **OR**. + +- **table_name** + + Specifies the name of the table corresponding to the trigger. + +- **FOR EACH ROW | FOR EACH STATEMENT** + + Specifies the frequency of firing the trigger. + + - **FOR EACH ROW** indicates that the trigger should be fired once for every row affected by the trigger event. + - **FOR EACH STATEMENT** indicates that the trigger should be fired just once per SQL statement. + + If neither is specified, the default value is **FOR EACH STATEMENT**. Constraint triggers can only be marked as **FOR EACH ROW**. + +- **function_name** + + Specifies a user-defined function, which must be declared as taking no parameters and returning data of trigger type. This function is executed when a trigger fires. + +- **arguments** + + Specifies an optional comma-separated list of parameters to be provided for the function when the trigger is executed. + +- **new_trigger_name** + + Specifies the new trigger name. + +## Examples + +```sql +-- Create a source table and a target table. +MogDB=# CREATE TABLE test_trigger_src_tbl(id1 INT, id2 INT, id3 INT); +MogDB=# CREATE TABLE test_trigger_des_tbl(id1 INT, id2 INT, id3 INT); + +-- Create a trigger function. +MogDB=# CREATE OR REPLACE FUNCTION tri_insert_func() RETURNS TRIGGER AS + $$ + DECLARE + BEGIN + INSERT INTO test_trigger_des_tbl VALUES(NEW.id1, NEW.id2, NEW.id3); + RETURN NEW; + END + $$ LANGUAGE PLPGSQL; + +MogDB=# CREATE OR REPLACE FUNCTION tri_update_func() RETURNS TRIGGER AS + $$ + DECLARE + BEGIN + UPDATE test_trigger_des_tbl SET id3 = NEW.id3 WHERE id1=OLD.id1; + RETURN OLD; + END + $$ LANGUAGE PLPGSQL; + +MogDB=# CREATE OR REPLACE FUNCTION TRI_DELETE_FUNC() RETURNS TRIGGER AS + $$ + DECLARE + BEGIN + DELETE FROM test_trigger_des_tbl WHERE id1=OLD.id1; + RETURN OLD; + END + $$ LANGUAGE PLPGSQL; + +-- Create an INSERT trigger. +MogDB=# CREATE TRIGGER insert_trigger + BEFORE INSERT ON test_trigger_src_tbl + FOR EACH ROW + EXECUTE PROCEDURE tri_insert_func(); + +-- Create an UPDATE trigger. +MogDB=# CREATE TRIGGER update_trigger + AFTER UPDATE ON test_trigger_src_tbl + FOR EACH ROW + EXECUTE PROCEDURE tri_update_func(); + +-- Create a DELETE trigger. +MogDB=# CREATE TRIGGER delete_trigger + BEFORE DELETE ON test_trigger_src_tbl + FOR EACH ROW + EXECUTE PROCEDURE tri_delete_func(); + +-- Execute the INSERT event and check the trigger results. +MogDB=# INSERT INTO test_trigger_src_tbl VALUES(100,200,300); +MogDB=# SELECT * FROM test_trigger_src_tbl; +MogDB=# SELECT * FROM test_trigger_des_tbl; // Check whether the trigger operation takes effect. + +-- Execute the UPDATE event and check the trigger results. +MogDB=# UPDATE test_trigger_src_tbl SET id3=400 WHERE id1=100; +MogDB=# SELECT * FROM test_trigger_src_tbl; +MogDB=# SELECT * FROM test_trigger_des_tbl; // Check whether the trigger operation takes effect. + +-- Execute the DELETE event and check the trigger results. +MogDB=# DELETE FROM test_trigger_src_tbl WHERE id1=100; +MogDB=# SELECT * FROM test_trigger_src_tbl; +MogDB=# SELECT * FROM test_trigger_des_tbl; // Check whether the trigger operation takes effect. + +-- Modify a trigger. +MogDB=# ALTER TRIGGER delete_trigger ON test_trigger_src_tbl RENAME TO delete_trigger_renamed; + +-- Delete a trigger. +MogDB=# DROP TRIGGER insert_trigger ON test_trigger_src_tbl; +MogDB=# DROP TRIGGER update_trigger ON test_trigger_src_tbl; +MogDB=# DROP TRIGGER delete_trigger_renamed ON test_trigger_src_tbl; +``` \ No newline at end of file diff --git a/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference.md b/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference.md new file mode 100644 index 00000000..7562124d --- /dev/null +++ b/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-reference.md @@ -0,0 +1,36 @@ +--- +title: SQL Reference +summary: SQL Reference +author: zhang cuiping +date: 2023-04-07 +--- + +# SQL Reference + +- **[MogDB SQL](mogdb-sql.md)** +- **[SQL Syntax Formats](sql-syntax-format.md)** +- **[Keywords](./keywords/keywords.md)** +- **[Constant and Macro](constant-and-macro.md)** +- **[Expressions](./expressions/expressions.md)** +- **[Type Conversion](./type-conversion/type-conversion.md)** +- **[Full Text Search](./full-text-search/full-text-search.md)** +- **[System Operation](system-operation.md)** +- **[Controlling Transactions](controlling-transactions.md)** +- **[DDL Syntax Overview](ddl-syntax-overview.md)** +- **[DML Syntax Overview](dml-syntax-overview.md)** +- **[DCL Syntax Overview](dcl-syntax-overview.md)** +- **[Subqueries](sub-query.md)** +- **[DCF](sql-reference-dcf.md)** +- **[LLVM](sql-reference-llvm.md)** +- **[Aliases](alias.md)** +- **[Locks](sql-reference-lock.md)** +- **[Transactions](transaction/sql-reference-transaction.md)** +- **[Ordinary Table](ordinary-table.md)** +- **[Partitioned Table](partition-table.md)** +- **[Indexes](sql-reference-index.md)** +- **[Constraints](sql-reference-contraints.md)** +- **[Cursors](sql-reference-cursor.md)** +- **[Anonymous Blocks](sql-reference-anonymous-block.md)** +- **[Triggers](sql-reference-trigger.md)** +- **[INSERT_RIGHT_REF_DEFAULT_VALUE](type-base-value.md)** +- **[Appendix](appendix/appendix.md)** \ No newline at end of file diff --git a/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-syntax-format.md b/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-syntax-format.md new file mode 100644 index 00000000..2dfc291f --- /dev/null +++ b/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sql-syntax-format.md @@ -0,0 +1,21 @@ +--- +title: SQL Syntax Formats +summary: SQL Syntax Formats +author: zhang cuiping +date: 2023-04-07 +--- + +# SQL Syntax Formats + +**Table 1** SQL syntax formats + +| Format | Description | +| :------------------------- | :----------------------------------------------------------- | +| [ ] | Items (keywords or arguments) in square brackets [ ] are optional. | +| ... | Preceding elements can appear repeatedly. | +| [ x \| y \| ... ] | Optional alternative items are grouped in square brackets and separated by vertical bars. One or none is selected. | +| { x \| y \| ... } | Alternative items are grouped in braces and separated by vertical bars. One is selected. | +| [x \| y \| ... ] [ ... ] | Multiple parameters or no parameter can be selected. If multiple parameters are selected, separate them with spaces. | +| [ x \| y \| ... ] [ ,... ] | Multiple parameters or no parameter can be selected. If multiple parameters are selected, separate them with commas (,). | +| { x \| y \| ... } [ ... ] | At least one parameter can be selected. If multiple parameters are selected, separate them with spaces. | +| { x \| y \| ... } [ ,... ] | At least one parameter can be selected. If multiple parameters are selected, separate them with commas (,). | \ No newline at end of file diff --git a/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sub-query.md b/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sub-query.md new file mode 100644 index 00000000..07ebab7c --- /dev/null +++ b/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/sub-query.md @@ -0,0 +1,181 @@ +--- +title: Subqueries +summary: Subqueries +author: zhang cuiping +date: 2023-04-07 +--- + +# Subqueries + +A subquery, also called an internal query, is a nested query. The subquery embeds a query statement in the **WHERE** clause of a database query and it is equivalent to a temporary table. The query result of a SELECT statement can be used as the input value of another statement. + +A subquery can be used with the SELECT, INSERT, UPDATE, and DELETE statements. + +The subquery must comply with the following rules: + +- The subquery must be enclosed in parentheses. +- The subquery can have only one column in the **SELECT** clause, unless there are multiple columns in the main query to compare with the columns selected by the subquery. +- **ORDER BY** cannot be used in the subquery, although it can be used in the main query. **GROUP BY** can be used in the subquery with the same function as **ORDER BY**. +- The subquery returns more than one row. It can be used only with multi-value operators, such as IN. +- The BETWEEN operator cannot be used with the subquery, but it can be used inside the subquery. + +## Subquery in the SELECT Statement + +The SELECT statement queries the data returned by the subquery. The basic syntax is as follows: + +```css +SELECT column_name [, column_name ] +FROM table1 [, table2 ] +WHERE column_name OPERATOR + (SELECT column_name [, column_name ] + FROM table1 [, table2 ] + [WHERE]); +``` + +Example: + +Create the **customer** table. The data is as follows: + +```sql +MogDB=# SELECT * FROM customer_t1; + c_customer_sk | c_customer_id | c_first_name | c_last_name | amount +---------------+---------------+--------------+-------------+-------- + 3869 | hello | Grace | | 1000 + 3869 | | Grace | | + 3869 | hello | | | + 6985 | maps | Joes | | 2200 + 9976 | world | James | | 5000 + 4421 | Admin | Local | | 3000 +(6 rows) +``` + +Run the following statement to use a subquery in the SELECT statement: + +```sql +MogDB=# SELECT * FROM customer_t1 WHERE c_customer_sk IN (SELECT c_customer_sk FROM customer_t1 WHERE amount > 2500) ; + c_customer_sk | c_customer_id | c_first_name | c_last_name | amount +---------------+---------------+--------------+-------------+-------- + 9976 | world | James | | 5000 + 4421 | Admin | Local | | 3000 +(2 rows) +``` + +## Subquery in the INSERT Statement + +Subqueries can also be used with the INSERT statement. The INSERT statement inserts the data returned by the subquery into another table. The basic syntax is as follows: + +```css +INSERT INTO table_name [ (column1 [, column2 ]) ] +SELECT [ *|column1 [, column2 ] ] +FROM table1 [, table2 ] +[ WHERE VALUE OPERATOR ] +``` + +Example: + +Create the **customer_bak** table whose structure is the same as that of the **customer_t1** table. + +```sql +MogDB=# CREATE TABLE customer_bak +( + c_customer_sk integer, + c_customer_id char(5), + c_first_name char(6), + c_last_name char(8), + Amount integer +); +CREATE TABLE +``` + +Insert data in the **customer_t1** table into the **customer_bak** table. + +```sql +MogDB=# INSERT INTO customer_bak SELECT * FROM customer_t1 WHERE c_customer_sk IN (SELECT c_customer_sk FROM customer_t1) ; +INSERT 0 6 +``` + +After the data is inserted, data in the **customer_bak** table is as follows: + +```sql +MogDB=# SELECT * FROM customer_bak; + c_customer_sk | c_customer_id | c_first_name | c_last_name | amount +---------------+---------------+--------------+-------------+-------- + 3869 | hello | Grace | | 1000 + 3869 | | Grace | | + 3869 | hello | | | + 6985 | maps | Joes | | 2200 + 9976 | world | James | | 5000 + 4421 | Admin | Local | | 3000 +(6 rows) +``` + +## Subquery in the UPDATE Statement + +When a subquery is run by executing the UPDATE statement, multiple columns in the table are updated. The basic syntax is as follows: + +```sql +UPDATE table +SET column_name = new_value +[ WHERE OPERATOR [ VALUE ] + (SELECT COLUMN_NAME + FROM TABLE_NAME + [ WHERE ]) +``` + +Example: + +Change the value of **amount** of all customers whose **c_customer_sk** is set to a value greater than **4000** in the **customer_t1** table to 0.50 times of the original value. + +```sql +MogDB=# UPDATE customer_t1 SET amount = amount * 0.50 WHERE c_customer_sk IN (SELECT c_customer_sk FROM customer_bak WHERE c_customer_sk > 5000 ); +UPDATE 2 +``` + +The update operation affects two rows. After the update, the data in the **customer_t1** table is as follows: + +```sql +MogDB=# SELECT * FROM customer_t1; + c_customer_sk | c_customer_id | c_first_name | c_last_name | amount +---------------+---------------+--------------+-------------+-------- + 3869 | hello | Grace | | 1000 + 3869 | | Grace | | + 3869 | hello | | | + 4421 | Admin | Local | | 3000 + 6985 | maps | Joes | | 1100 + 9976 | world | James | | 2500 +(6 rows) +``` + +## Subquery in the DELETE Statement + +The basic syntax is as follows: + +```sql +DELETE FROM TABLE_NAME +[ WHERE OPERATOR [ VALUE ] + (SELECT COLUMN_NAME + FROM TABLE_NAME + [ WHERE ]) +``` + +Example: + +Delete all customers whose **c_customer_sk** is set to a value greater than **4000** from the **customer_t1** table. + +```sql +MogDB=# DELETE FROM customer_t1 WHERE c_customer_sk IN (SELECT c_customer_sk FROM customer_bak WHERE c_customer_sk > 5000 ); +DELETE 2 +``` + +The deletion operation affects two rows. After deletion, the data in the **customer_t1** table is as follows: + +```sql +MogDB=# SELECT * FROM customer_t1; + c_customer_sk | c_customer_id | c_first_name | c_last_name | amount +---------------+---------------+--------------+-------------+-------- + 3869 | hello | Grace | | 1000 + 3869 | | Grace | | + 3869 | hello | | | + 4421 | Admin | Local | | 3000 +(4 rows) +``` \ No newline at end of file diff --git a/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/type-base-value.md b/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/type-base-value.md new file mode 100644 index 00000000..86afa0d0 --- /dev/null +++ b/product/en/docs-mogdb/v5.0/reference-guide/sql-reference/type-base-value.md @@ -0,0 +1,83 @@ +--- +title: INSERT_RIGHT_REF_DEFAULT_VALUE +summary: INSERT_RIGHT_REF_DEFAULT_VALUE +author: zhang cuiping +date: 2023-04-07 +--- + +# INSERT_RIGHT_REF_DEFAULT_VALUE + +In B-compatible mode, the INSERT statement supports right-value reference. If a referenced column has a NOT NULL constraint and does not have a default value, its base value is used for calculation. If there is no basic value, the NULL value is used for calculation (array type or user-defined type). The basic values of the supported types are shown in [Table 1](#type). + +**Table 1** Type basic values + +| Type | Basic Value | Description | +| :------------------------ | :----------------------------------- | :----------------------------------------------------------- | +| int | 0 | | +| tinyint | 0 | | +| smallint | 0 | | +| integer | 0 | | +| binary_integer | 0 | | +| bigint | 0 | | +| boolean | f | | +| numeric | 0 | | +| decimal | 0 | | +| dec | 0 | | +| double precision | 0 | | +| float8 | 0 | | +| float | 0 | | +| char(n) | "" | Note: When a character string is involved in calculation, the value type is converted based on built-in rules.
The length of the value stored by a fixed-length character string is the same as the specified length, and blank characters are filled (which may vary according to the storage mode). | +| varchar(n) | "" | | +| varchar2(n) | "" | | +| nchar(n) | "" | Note: When a character string is involved in calculation, the value type is converted based on built-in rules.
The length of the value stored by a fixed-length character string is the same as the specified length, and blank characters are filled (which may vary according to the storage mode). | +| nvarchar2(n) | "" | | +| nvarchar(n) | "" | | +| date | 01-01-1970 | | +| time | 00:00:00 | | +| timestamp | Current timestamp | | +| smalldatetime | Thu Jan 01 00:00:00 1970 | | +| interval year | @ 0 | | +| interval month | @ 0 | | +| interval day | @ 0 | | +| interval hour | @ 0 | | +| interval minute | @ 0 | | +| interval second | @ 0 | | +| interval day to second | @ 0 | | +| interval day to hour | @ 0 | | +| interval day to minute | @ 0 | | +| interval hour to minute | @ 0 | | +| interval hour to second | @ 0 | | +| interval minute to second | @ 0 | | +| reltime | @ 0 | | +| abstime | Wed Dec 31 16:00:00 1969 PST | | +| money | $0.00 | | +| int4range | empty | | +| blob | | Object without data content | +| raw | | Object without data content | +| bytea | \x | | +| point | (0,0) | | +| lseg | [(0,0),(0,0)] | | +| box | (0,0),(0,0) | | +| path | ((0,0)) | | +| polygon | ((0,0)) | | +| circle | <(0,0),0> | | +| cidr | 0.0.0.0/32 | | +| inet | 0.0.0.0 | | +| macaddr | 00:00:00:00:00:00 | | +| BIT | | Object without data content | +| BIT VARYING | | Object without data content | +| UUID | 00000000-0000-0000-0000-000000000000 | | +| json | null | The data content is null. | +| jsonb | null | The data content is null. | +| int8range | empty | | +| numrange | empty | | +| tsrange | empty | | +| tstzrange | empty | | +| daterange | empty | | +| hll | \x | | +| SET | "" | | +| tsvector | | Object without data content | +| tsquery | | Object without data content | +| HASH16 | 0000000000000000 | | +| HASH32 | 00000000000000000000000000000000 | | +| enum | The first item | | \ No newline at end of file -- Gitee