From c5bcf2ca0320552402633799b1dc83ad87ea62d4 Mon Sep 17 00:00:00 2001 From: xixirangrang <35301108+hfxsd@users.noreply.github.com> Date: Thu, 29 Sep 2022 14:10:16 +0800 Subject: [PATCH 01/18] Create oracle-functions-to-tidb.md --- oracle-functions-to-tidb.md | 19 +++++++++++++++++++ 1 file changed, 19 insertions(+) create mode 100644 oracle-functions-to-tidb.md diff --git a/oracle-functions-to-tidb.md b/oracle-functions-to-tidb.md new file mode 100644 index 0000000000000..b448a64e9003c --- /dev/null +++ b/oracle-functions-to-tidb.md @@ -0,0 +1,19 @@ +--- +title: Mappings between Functions and Syntax of Oracle and TiDB +summary: Learn the mappings between functions and syntax of Oracle and TiDB +--- + +# Mappings between Functions and Syntax of Oracle and TiDB + +本文档提供了 Oracle 与 TiDB 的函数和语法差异对照,方便你根据 Oracle 函数查找对应的 TiDB 函数,了解 Oracle 与 TiDB 语法差异。 + +> **说明:** +> +> 本文的内容是基于 Oracle 12.2.0.1.0 和 TiDB v5.4.0,其他版本可能存在差异。 + +This document describes the mappings between functions and syntax of Oracle and TiDB. It helps you find the corresponding TiDB function based on the Oracle function, and understand the syntax differences between Oracle and TiDB. + +> **Note:** +> +> The functions and syntax in this document are based on Oracle 12.2.0.1.0 and TiDB v5.4.0. They might be different in other versions. + From c2ab39097c00f6157dd1b595a0ff9d007365bd29 Mon Sep 17 00:00:00 2001 From: xixirangrang <35301108+hfxsd@users.noreply.github.com> Date: Thu, 29 Sep 2022 14:13:05 +0800 Subject: [PATCH 02/18] Update oracle-functions-to-tidb.md --- oracle-functions-to-tidb.md | 8 +------- 1 file changed, 1 insertion(+), 7 deletions(-) diff --git a/oracle-functions-to-tidb.md b/oracle-functions-to-tidb.md index b448a64e9003c..c6d0bb27c18b3 100644 --- a/oracle-functions-to-tidb.md +++ b/oracle-functions-to-tidb.md @@ -5,15 +5,9 @@ summary: Learn the mappings between functions and syntax of Oracle and TiDB # Mappings between Functions and Syntax of Oracle and TiDB -本文档提供了 Oracle 与 TiDB 的函数和语法差异对照,方便你根据 Oracle 函数查找对应的 TiDB 函数,了解 Oracle 与 TiDB 语法差异。 - -> **说明:** -> -> 本文的内容是基于 Oracle 12.2.0.1.0 和 TiDB v5.4.0,其他版本可能存在差异。 - This document describes the mappings between functions and syntax of Oracle and TiDB. It helps you find the corresponding TiDB function based on the Oracle function, and understand the syntax differences between Oracle and TiDB. > **Note:** -> +> > The functions and syntax in this document are based on Oracle 12.2.0.1.0 and TiDB v5.4.0. They might be different in other versions. From 63c236901ad54625c8b40178e7f81e01a3146d35 Mon Sep 17 00:00:00 2001 From: xixirangrang <35301108+hfxsd@users.noreply.github.com> Date: Thu, 29 Sep 2022 18:17:30 +0800 Subject: [PATCH 03/18] Update oracle-functions-to-tidb.md --- oracle-functions-to-tidb.md | 183 ++++++++++++++++++++++++++++++++++++ 1 file changed, 183 insertions(+) diff --git a/oracle-functions-to-tidb.md b/oracle-functions-to-tidb.md index c6d0bb27c18b3..00cc97c9ac9af 100644 --- a/oracle-functions-to-tidb.md +++ b/oracle-functions-to-tidb.md @@ -11,3 +11,186 @@ This document describes the mappings between functions and syntax of Oracle and > > The functions and syntax in this document are based on Oracle 12.2.0.1.0 and TiDB v5.4.0. They might be different in other versions. +## Mappings between some Oracle and TiDB functions + +The following table shows the mappings between some Oracle and TiDB functions. + +| Function | Oracle syntax | TiDB syntax | Note | +|---|---|---|---| +| Convert data types |
  • `TO_NUMBER(key)`
  • `TO_CHAR(key)`
  • | `CONVERT(key,dataType)` | TiDB supports converting `BINARY`, `CHAR`, `DATE`, `DATETIME`, `TIME`, `SIGNED INTEGER`, `UNSIGNED INTEGER` and `DECIMAL` types. | +| Convert a date type to a string type |
  • `TO_CHAR(SYSDATE,'yyyy-MM-dd hh24:mi:ss')`
  • `TO_CHAR(SYSDATE,'yyyy-MM-dd')`
  • |
  • `DATE_FORMAT(NOW(),'%Y-%m-%d %H:%i:%s')`
  • `DATE_FORMAT(NOW(),'%Y-%m-%d')`
  • | TiDB format strings are case-sensitive. | +| Convert a string type to a date type |
  • `TO_DATE('2021-05-28 17:31:37','yyyy-MM-dd hh24:mi:ss')`
  • `TO_DATE('2021-05-28','yyyy-MM-dd hh24:mi:ss')`
  • |
  • `STR_TO_DATE('2021-05-28 17:31:37','%Y-%m-%d %H:%i:%s')`
  • `STR_TO_DATE('2021-05-28','%Y-%m-%d%T')`
  • | TiDB format strings are case-sensitive. | +| Get the current system time (precision to the second) | `SYSDATE` | `NOW()` | | +| Get the number of days between `date1` and `date2` | `date1 - date2` | `DATEDIFF(date1, date2)` | | +| Add or reduce date by `n` days | `DATEVAL + n` | `DATE_ADD(dateVal,INTERVAL n DAY)` | `n` can be a negative value.| +| Add or reduce date by `n` months | `ADD_MONTHS(dateVal,n)`| `DATE_ADD(dateVal,INTERVAL n MONTH)` | `n` can be a negative value. | +| Get the date (precision to the date) 获取日期到日 | `TRUNC(SYSDATE)` |
  • `CAST(NOW() AS DATE)`
  • `DATE_FORMAT(NOW(),'%Y-%m-%d')`
  • | In TiDB, `CAST` and `DATE_FORMAT` return the same result. | +| Get the month of the date | `TRUNC(SYSDATE,'mm')` | `DATE_ADD(CURDATE(),interval - day(CURDATE()) + 1 day)` | | +| Round down a value | `TRUNC(2.136) = 2`
    `TRUNC(2.136,2) = 2.14` | `TRUNCATE(2.136,0) = 2`
    `TRUNCATE(2.136,2) = 2.14` | | +| Combine the strings `a` and `b` | `'a' || 'b'` | `CONCAT('a','b')` | | +| Get the next value in a sequence | `SEQUENCENAME.NEXTVAL` | `NEXTVAL(sequenceName)` | | +| Left join or right join | `SELECT * FROM a, b WHERE a.id = b.id(+);`
    `SELECT * FROM a, b WHERE a.id(+) = b.id;` | `SELECT * FROM a LEFT JOIN b ON a.id = b.id;`
    `SELECT * FROM a RIGHT JOIN b ON a.id = b.id;` | When correlating queries, TiDB does not support using (+) to left join or right join. You can use `LEFT JOIN` or `RIGHT JOIN` instead. | +| Get random sequence values | `SYS_GUID()` | `UUID()` | TiDB returns a Universal Unique Identifier (UUID).| +| `NVL()` | `NVL(key,val)` | `IFNULL(key,val)` | If the value of the field is `NULL`, it returns the value of `val`; otherwise, it returns the value of the field. | +| `NVL2()` | `NVL2(key, val1, val2)` | `IF(key is NULL, val1, val2)` | If the value of the field is not `NULL`, it returns the value of `val1`; otherwise, it returns the value of `val2`. | +| `DECODE()` |
  • `DECODE(key,val1,val2,val3)`
  • `DECODE(value,if1,val1,if2,val2,...,ifn,valn,val)`
  • |
  • `IF(key=val1,val2,val3)`
  • `CASE WHEN value=if1 THEN val1 WHEN value=if2 THEN val2,...,WHEN value=ifn THEN valn ELSE val END`
  • |
  • If the value of the field is equal to val1, then val2 is returned; otherwise val3 is returned.
  • 当该字段值满足条件 1 (if1) 时,返回 val1,满足条件 2 (if2) 时,返回 val2,满足条件 3 (if3) 时,返回 val3。When the field value satisfies the condition 1 (if1), it returns val1. When it satisfies the condition 2 (if2), it returns val2. When it satisfies the condition 3 (if3), it returns val3.
  • | +| Get the length of a string | `LENGTH(str)` | `CHAR_LENGTH(str)` | | +| Get sub strings | `SUBSTR('abcdefg',0,2) = 'ab'`
    `SUBSTR('abcdefg',1,2) = 'ab'` | `SUBSTRING('abcdefg',0,2) = ''`
    `SUBSTRING('abcdefg',1,2) = 'ab'` |
  • In Oracle, the starting position 0 has the same effect as 1.
  • In TiDB, the substring starting from 0 is null. If you need to start from the beginning of the string, you should start from 1.
  • | +| Search a string for substrings | `INSTR('abcdefg','b',1,1)` | `INSTR('abcdefg','b')` | Search from the first character of the string 'abcdefg' and return the position of the first occurrence of the 'b' string. | +| Search a string for substrings| `INSTR('stst','s',1,2)` | `LENGTH(SUBSTRING_INDEX('stst','s',2)) + 1` | Search from the first character of 'stst' and return the second occurrence of the 's' character. | +| Search a string for substrings | `INSTR('abcabc','b',2,1)` | `LOCATE('b','abcabc',2)` | Search from the second character of the string `abcabc` and return the first occurrence of the character `b`. | +| Get the interval months between dates | `MONTHS_BETWEEN(ENDDATE,SYSDATE)` | `TIMESTAMPDIFF(MONTH,SYSDATE,ENDDATE)` | The results of `MONTHS_BETWEEN()` in Oracle and `TIMESTAMPDIFF()` in TiDB are different. `TIMESTAMPDIFF()` keeps only integer months. Note that the parameters in the two functions are in opposite positions. | +| Merge columns into rows | `LISTAGG(CONCAT(E.dimensionid,'---',E.DIMENSIONNAME),'***') within GROUP(ORDER BY DIMENSIONNAME)` | `GROUP_CONCAT(CONCAT(E.dimensionid,'---',E.DIMENSIONNAME) ORDER BY DIMENSIONNAME SEPARATOR '***')` | Combine a column of fields into one row and split them according to the `***` notation. | +| Get the current time (precision to the second) | `SYSTIMESTAMP` | `CURRENT_TIMESTAMP(6)` | | +| Convert ASCII values to corresponding characters | `CHR(n)` | `CHAR(n)` | The tab (`CHR(9)`), line feed (`CHR(10)`), and carriage return (`CHR(13)`) characters in Oracle correspond to `CHAR(9)`, `CHAR(10)`, and `CHAR(13)` in TiDB. | + +## Syntax differences + +This section describes some syntax differences between Oracle and TiDB. + +### Add an alias for a table in the DELETE stateemnt + +- Oracle supports adding an alias for a table in the DELETE statement. For example: + + ```sql + DELETE FROM test t WHERE t.xxx = xxx + ``` + +- TiDB does not support adding an alias for a table in the DELETE statement. For example: + + ```sql + DELETE FROM test WHERE xxx = xxx + ``` + +### String syntax + +- Oracle: strings can only be enclosed in single quotes (''). For example `'a'` +- TiDB: Strings can be enclosed in single quotes ('') or double quotes (""). For example, `'a'` and `"a"` + +### Difference between `NULL` and an empty string + +- Oracle does not distinguish between `NULL` and the empty string `''`, that is, `NULL` is equivalent to `''`. +- TiDB distinguishes between `NULL` and the empty string `''`. In TiDB, you need to convert `''` to `NULL`. + +### Read and write to the same table in an `INSERT` statement + +- Oracle supports reading and writing to the same table in the `INSERT` statement. For example: + + ```sql + INSERT INTO table1 VALUES (feild1,(SELECT feild2 FROM table1 WHERE...)) + ``` + +- TiDB does not support reading and writing to the same table in `INSERT` statements. For example: + + ```sql + INSERT INTO table1 VALUES(feild1,(SELECT T.fields2 FROM table1 T WHERE...) + ``` + +### Get the first n pieces of data + +- Oracle gets the first n pieces of data by `ROWNUM <= n`. For example `ROWNUM <= 10`. + +- TiDB gets the first n pieces of data by `LIMIT n`. For example `LIMIT 10`. The Hibernate Query Language (HQL) running SQL statements with `LIMIT` results in an error. You need to change the Hibernate statements to SQL statements. + +### `UPDATE` statement for multi-table updates + +- Oracle: it is not necessary to list the specific field update relationship when updating multiple tables. For example: + + ```sql + UPDATE test1 SET(test1.name,test1.age) = (SELECT test2.name,test2.age FROM test2 WHERE test2.id=test1.id) + ``` + +- TiDB: when updating multiple tables, you need to list all the specific field update relationships in `SET`. For example: + + ```sql + UPDATE test1,test2 SET test1.name=test2.name,test1.age=test2.age WHERE test1.id=test2.id + ``` + +### Derived table alias + +- Oracle:when querying multiple tables, a derived table alias is not necessary. For example: + + ```sql + SELECT * FROM (SELECT * FROM test) + ``` + +- TiDB: when querying multiple tables, each derived table must have an alias of its own. For example: + + ```sql + SELECT * FROM (SELECT * FROM test) t + ``` + +### Difference set operation + +- Oracle uses `MINUS` for difference set operations. For example: + + ```sql + SELECT * FROM t1 MINUS SELECT * FROM t2 + ``` + +- TiDB does not support `MINUS`. You need to change it to `EXCEPT`. For example: + + ```sql + SELECT * FROM t1 EXCEPT SELECT * FROM t2 + ``` + +### Alias for `NULL` and `''` + +- Oracle: `NULL` is equivalent to `''`, and no special conversion is needed to alias a null value. For example + + ```sql + SELECT NULL AS ... FROM DUAL + ``` + +- TiDB: `NULL` is different from `''`. To alias a null value, you need to change `NULL` to `''`. For example: + + ```sql + SELECT '' AS ... FROM DUAL + ``` + +### Comment syntax + +- Oracle: `--Comment`. Oracle does not need a space after `--`. + +- TiDB:`-- Comment`. TiDB needs a space after `--`. + +### Paging queries + +- Oracle: `OFFSET m` means skipping `m` rows. `FETCH NEXT n ROWS ONLY` means taking `n` rows. For example: + + ```sql + SELECT * FROM tables OFFSET 0 ROWS FETCH NEXT 2000 ROWS ONLY + ``` + +- TiDB: Use `LIMIT n OFFSET m` to replace `OFFSET m ROWS FETCH NEXT n ROWS ONLY`. For example: + + ```sql + SELECT * FROM tables LIMIT 2000 OFFSET 0 + ``` + +### `ORDER BY` sorting rules for `NULL` + +Rules for sorting `NULL` by the `ORDER BY` statement in Oracle. + +- In `ORDER BY COLUM ASC`, `NULL` is placed last by default. + +- In `ORDER BY COLUM DESC`, `NULL` is placed first by default. + +- In `ORDER BY COLUM [ASC|DESC] NULLS FIRST`, `NULL` is forced to be placed first. Non-`NULL` values are still sorted by the declared order `ASC|DESC`. + +- In `ORDER BY COLUM [ASC|DESC] NULLS LAST` , `NULL` is forced to be placed last. Non-`NULL` values are still sorted by the declared order `ASC|DESC`. + +Rules for sorting `NULL` by the `ORDER BY` statement in TiDB. + +- In `ORDER BY COLUM ASC`, `NULL` is placed first by default. + +- `ORDER BY COLUM DESC`, `NULL` is placed last by default. + +The following table shows some examples of equivalent `ORDER BY` statements in Oracle and TiDB: + +| `ORDER BY` in Oracle | Equivalent in TiDB | +| :------------------- | :----------------- | +| `SELECT * FROM t1 ORDER BY name NULLS FIRST;` |`SELECT * FROM t1 ORDER BY NAME ;` | +| `SELECT * FROM t1 ORDER BY name DESC NULLS LAST;` | `SELECT * FROM t1 ORDER BY NAME DESC;` | +| `SELECT * FROM t1 ORDER BY NAME DESC NULLS FIRST;` | `SELECT * FROM t1 ORDER BY ISNULL(name) DESC, name DESC;` | +|`SELECT * FROM t1 ORDER BY name ASC NULLS LAST;` | `SELECT * FROM t1 ORDER BY ISNULL(name), name;` | From 978d439496a62c55aa1ed6e06c3bd47154e4e959 Mon Sep 17 00:00:00 2001 From: xixirangrang <35301108+hfxsd@users.noreply.github.com> Date: Thu, 29 Sep 2022 18:31:37 +0800 Subject: [PATCH 04/18] updated toc --- TOC.md | 1 + functions-and-operators/string-functions.md | 2 ++ oracle-functions-to-tidb.md | 6 +++--- 3 files changed, 6 insertions(+), 3 deletions(-) diff --git a/TOC.md b/TOC.md index e39bd037d84bc..79688373bdef5 100644 --- a/TOC.md +++ b/TOC.md @@ -624,6 +624,7 @@ - [Set Operations](/functions-and-operators/set-operators.md) - [List of Expressions for Pushdown](/functions-and-operators/expressions-pushed-down.md) - [TiDB Specific Functions](/functions-and-operators/tidb-functions.md) + - [Mappings between Functions and Syntax of Oracle and TiDB](/oracle-functions-to-tidb.md) - [Clustered Indexes](/clustered-indexes.md) - [Constraints](/constraints.md) - [Generated Columns](/generated-columns.md) diff --git a/functions-and-operators/string-functions.md b/functions-and-operators/string-functions.md index 8dbe6028fab46..e79c25a80ab87 100644 --- a/functions-and-operators/string-functions.md +++ b/functions-and-operators/string-functions.md @@ -7,6 +7,8 @@ summary: Learn about the string functions in TiDB. TiDB supports most of the [string functions](https://dev.mysql.com/doc/refman/5.7/en/string-functions.html) available in MySQL 5.7 and some of the [functions](https://docs.oracle.com/en/database/oracle/oracle-database/21/sqlqr/SQL-Functions.html#GUID-93EC62F8-415D-4A7E-B050-5D5B2C127009) available in Oracle 21. +For mappings between functions and syntax of Oracle and TiDB, see [Mappings between Functions and Syntax of Oracle and TiDB](/oracle-functions-to-tidb.md). + ## Supported functions | Name | Description | diff --git a/oracle-functions-to-tidb.md b/oracle-functions-to-tidb.md index 00cc97c9ac9af..da5351719d6e3 100644 --- a/oracle-functions-to-tidb.md +++ b/oracle-functions-to-tidb.md @@ -24,7 +24,7 @@ The following table shows the mappings between some Oracle and TiDB functions. | Get the number of days between `date1` and `date2` | `date1 - date2` | `DATEDIFF(date1, date2)` | | | Add or reduce date by `n` days | `DATEVAL + n` | `DATE_ADD(dateVal,INTERVAL n DAY)` | `n` can be a negative value.| | Add or reduce date by `n` months | `ADD_MONTHS(dateVal,n)`| `DATE_ADD(dateVal,INTERVAL n MONTH)` | `n` can be a negative value. | -| Get the date (precision to the date) 获取日期到日 | `TRUNC(SYSDATE)` |
  • `CAST(NOW() AS DATE)`
  • `DATE_FORMAT(NOW(),'%Y-%m-%d')`
  • | In TiDB, `CAST` and `DATE_FORMAT` return the same result. | +| Get the date (precision to the date) | `TRUNC(SYSDATE)` |
  • `CAST(NOW() AS DATE)`
  • `DATE_FORMAT(NOW(),'%Y-%m-%d')`
  • | In TiDB, `CAST` and `DATE_FORMAT` return the same result. | | Get the month of the date | `TRUNC(SYSDATE,'mm')` | `DATE_ADD(CURDATE(),interval - day(CURDATE()) + 1 day)` | | | Round down a value | `TRUNC(2.136) = 2`
    `TRUNC(2.136,2) = 2.14` | `TRUNCATE(2.136,0) = 2`
    `TRUNCATE(2.136,2) = 2.14` | | | Combine the strings `a` and `b` | `'a' || 'b'` | `CONCAT('a','b')` | | @@ -33,7 +33,7 @@ The following table shows the mappings between some Oracle and TiDB functions. | Get random sequence values | `SYS_GUID()` | `UUID()` | TiDB returns a Universal Unique Identifier (UUID).| | `NVL()` | `NVL(key,val)` | `IFNULL(key,val)` | If the value of the field is `NULL`, it returns the value of `val`; otherwise, it returns the value of the field. | | `NVL2()` | `NVL2(key, val1, val2)` | `IF(key is NULL, val1, val2)` | If the value of the field is not `NULL`, it returns the value of `val1`; otherwise, it returns the value of `val2`. | -| `DECODE()` |
  • `DECODE(key,val1,val2,val3)`
  • `DECODE(value,if1,val1,if2,val2,...,ifn,valn,val)`
  • |
  • `IF(key=val1,val2,val3)`
  • `CASE WHEN value=if1 THEN val1 WHEN value=if2 THEN val2,...,WHEN value=ifn THEN valn ELSE val END`
  • |
  • If the value of the field is equal to val1, then val2 is returned; otherwise val3 is returned.
  • 当该字段值满足条件 1 (if1) 时,返回 val1,满足条件 2 (if2) 时,返回 val2,满足条件 3 (if3) 时,返回 val3。When the field value satisfies the condition 1 (if1), it returns val1. When it satisfies the condition 2 (if2), it returns val2. When it satisfies the condition 3 (if3), it returns val3.
  • | +| `DECODE()` |
  • `DECODE(key,val1,val2,val3)`
  • `DECODE(value,if1,val1,if2,val2,...,ifn,valn,val)`
  • |
  • `IF(key=val1,val2,val3)`
  • `CASE WHEN value=if1 THEN val1 WHEN value=if2 THEN val2,...,WHEN value=ifn THEN valn ELSE val END`
  • |
  • If the value of the field is equal to val1, then val2 is returned; otherwise val3 is returned.
  • When the field value satisfies the condition 1 (if1), it returns val1. When it satisfies the condition 2 (if2), it returns val2. When it satisfies the condition 3 (if3), it returns val3.
  • | | Get the length of a string | `LENGTH(str)` | `CHAR_LENGTH(str)` | | | Get sub strings | `SUBSTR('abcdefg',0,2) = 'ab'`
    `SUBSTR('abcdefg',1,2) = 'ab'` | `SUBSTRING('abcdefg',0,2) = ''`
    `SUBSTRING('abcdefg',1,2) = 'ab'` |
  • In Oracle, the starting position 0 has the same effect as 1.
  • In TiDB, the substring starting from 0 is null. If you need to start from the beginning of the string, you should start from 1.
  • | | Search a string for substrings | `INSTR('abcdefg','b',1,1)` | `INSTR('abcdefg','b')` | Search from the first character of the string 'abcdefg' and return the position of the first occurrence of the 'b' string. | @@ -48,7 +48,7 @@ The following table shows the mappings between some Oracle and TiDB functions. This section describes some syntax differences between Oracle and TiDB. -### Add an alias for a table in the DELETE stateemnt +### Add an alias for a table in the DELETE statement - Oracle supports adding an alias for a table in the DELETE statement. For example: From 48baab946292934696678c6f23f19bd737490135 Mon Sep 17 00:00:00 2001 From: xixirangrang <35301108+hfxsd@users.noreply.github.com> Date: Thu, 29 Sep 2022 18:32:42 +0800 Subject: [PATCH 05/18] Update oracle-functions-to-tidb.md --- oracle-functions-to-tidb.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/oracle-functions-to-tidb.md b/oracle-functions-to-tidb.md index da5351719d6e3..43ed9f5dafa5d 100644 --- a/oracle-functions-to-tidb.md +++ b/oracle-functions-to-tidb.md @@ -5,7 +5,7 @@ summary: Learn the mappings between functions and syntax of Oracle and TiDB # Mappings between Functions and Syntax of Oracle and TiDB -This document describes the mappings between functions and syntax of Oracle and TiDB. It helps you find the corresponding TiDB function based on the Oracle function, and understand the syntax differences between Oracle and TiDB. +This document describes the mappings between functions and syntax of Oracle and TiDB. It helps you find the corresponding TiDB functions based on the Oracle functions, and understand the syntax differences between Oracle and TiDB. > **Note:** > From e298b1069087b02cfcf45cf07a7386c429c698e7 Mon Sep 17 00:00:00 2001 From: xixirangrang <35301108+hfxsd@users.noreply.github.com> Date: Thu, 29 Sep 2022 20:08:01 +0800 Subject: [PATCH 06/18] Update oracle-functions-to-tidb.md --- oracle-functions-to-tidb.md | 120 ++++++++++++++++++------------------ 1 file changed, 60 insertions(+), 60 deletions(-) diff --git a/oracle-functions-to-tidb.md b/oracle-functions-to-tidb.md index 43ed9f5dafa5d..006c87493dbda 100644 --- a/oracle-functions-to-tidb.md +++ b/oracle-functions-to-tidb.md @@ -22,8 +22,8 @@ The following table shows the mappings between some Oracle and TiDB functions. | Convert a string type to a date type |
  • `TO_DATE('2021-05-28 17:31:37','yyyy-MM-dd hh24:mi:ss')`
  • `TO_DATE('2021-05-28','yyyy-MM-dd hh24:mi:ss')`
  • |
  • `STR_TO_DATE('2021-05-28 17:31:37','%Y-%m-%d %H:%i:%s')`
  • `STR_TO_DATE('2021-05-28','%Y-%m-%d%T')`
  • | TiDB format strings are case-sensitive. | | Get the current system time (precision to the second) | `SYSDATE` | `NOW()` | | | Get the number of days between `date1` and `date2` | `date1 - date2` | `DATEDIFF(date1, date2)` | | -| Add or reduce date by `n` days | `DATEVAL + n` | `DATE_ADD(dateVal,INTERVAL n DAY)` | `n` can be a negative value.| -| Add or reduce date by `n` months | `ADD_MONTHS(dateVal,n)`| `DATE_ADD(dateVal,INTERVAL n MONTH)` | `n` can be a negative value. | +| Increase or decrease date by `n` days | `DATEVAL + n` | `DATE_ADD(dateVal,INTERVAL n DAY)` | `n` can be a negative value.| +| Increase or decrease date by `n` months | `ADD_MONTHS(dateVal,n)`| `DATE_ADD(dateVal,INTERVAL n MONTH)` | `n` can be a negative value. | | Get the date (precision to the date) | `TRUNC(SYSDATE)` |
  • `CAST(NOW() AS DATE)`
  • `DATE_FORMAT(NOW(),'%Y-%m-%d')`
  • | In TiDB, `CAST` and `DATE_FORMAT` return the same result. | | Get the month of the date | `TRUNC(SYSDATE,'mm')` | `DATE_ADD(CURDATE(),interval - day(CURDATE()) + 1 day)` | | | Round down a value | `TRUNC(2.136) = 2`
    `TRUNC(2.136,2) = 2.14` | `TRUNCATE(2.136,0) = 2`
    `TRUNCATE(2.136,2) = 2.14` | | @@ -33,13 +33,13 @@ The following table shows the mappings between some Oracle and TiDB functions. | Get random sequence values | `SYS_GUID()` | `UUID()` | TiDB returns a Universal Unique Identifier (UUID).| | `NVL()` | `NVL(key,val)` | `IFNULL(key,val)` | If the value of the field is `NULL`, it returns the value of `val`; otherwise, it returns the value of the field. | | `NVL2()` | `NVL2(key, val1, val2)` | `IF(key is NULL, val1, val2)` | If the value of the field is not `NULL`, it returns the value of `val1`; otherwise, it returns the value of `val2`. | -| `DECODE()` |
  • `DECODE(key,val1,val2,val3)`
  • `DECODE(value,if1,val1,if2,val2,...,ifn,valn,val)`
  • |
  • `IF(key=val1,val2,val3)`
  • `CASE WHEN value=if1 THEN val1 WHEN value=if2 THEN val2,...,WHEN value=ifn THEN valn ELSE val END`
  • |
  • If the value of the field is equal to val1, then val2 is returned; otherwise val3 is returned.
  • When the field value satisfies the condition 1 (if1), it returns val1. When it satisfies the condition 2 (if2), it returns val2. When it satisfies the condition 3 (if3), it returns val3.
  • | +| `DECODE()` |
  • `DECODE(key,val1,val2,val3)`
  • `DECODE(value,if1,val1,if2,val2,...,ifn,valn,val)`
  • |
  • `IF(key=val1,val2,val3)`
  • `CASE WHEN value=if1 THEN val1 WHEN value=if2 THEN val2,...,WHEN value=ifn THEN valn ELSE val END`
  • |
  • If the value of the field is equal to val1, then it returns val2; otherwise it returns val3.
  • When the field value satisfies the condition 1 (if1), it returns val1. When it satisfies the condition 2 (if2), it returns val2. When it satisfies the condition 3 (if3), it returns val3.
  • | | Get the length of a string | `LENGTH(str)` | `CHAR_LENGTH(str)` | | | Get sub strings | `SUBSTR('abcdefg',0,2) = 'ab'`
    `SUBSTR('abcdefg',1,2) = 'ab'` | `SUBSTRING('abcdefg',0,2) = ''`
    `SUBSTRING('abcdefg',1,2) = 'ab'` |
  • In Oracle, the starting position 0 has the same effect as 1.
  • In TiDB, the substring starting from 0 is null. If you need to start from the beginning of the string, you should start from 1.
  • | | Search a string for substrings | `INSTR('abcdefg','b',1,1)` | `INSTR('abcdefg','b')` | Search from the first character of the string 'abcdefg' and return the position of the first occurrence of the 'b' string. | | Search a string for substrings| `INSTR('stst','s',1,2)` | `LENGTH(SUBSTRING_INDEX('stst','s',2)) + 1` | Search from the first character of 'stst' and return the second occurrence of the 's' character. | | Search a string for substrings | `INSTR('abcabc','b',2,1)` | `LOCATE('b','abcabc',2)` | Search from the second character of the string `abcabc` and return the first occurrence of the character `b`. | -| Get the interval months between dates | `MONTHS_BETWEEN(ENDDATE,SYSDATE)` | `TIMESTAMPDIFF(MONTH,SYSDATE,ENDDATE)` | The results of `MONTHS_BETWEEN()` in Oracle and `TIMESTAMPDIFF()` in TiDB are different. `TIMESTAMPDIFF()` keeps only integer months. Note that the parameters in the two functions are in opposite positions. | +| Get the interval months between dates | `MONTHS_BETWEEN(ENDDATE,SYSDATE)` | `TIMESTAMPDIFF(MONTH,SYSDATE,ENDDATE)` | The results of `MONTHS_BETWEEN()` in Oracle and `TIMESTAMPDIFF()` in TiDB are different. `TIMESTAMPDIFF()` keeps months only in integer. Note that the parameters in the two functions are in opposite positions. | | Merge columns into rows | `LISTAGG(CONCAT(E.dimensionid,'---',E.DIMENSIONNAME),'***') within GROUP(ORDER BY DIMENSIONNAME)` | `GROUP_CONCAT(CONCAT(E.dimensionid,'---',E.DIMENSIONNAME) ORDER BY DIMENSIONNAME SEPARATOR '***')` | Combine a column of fields into one row and split them according to the `***` notation. | | Get the current time (precision to the second) | `SYSTIMESTAMP` | `CURRENT_TIMESTAMP(6)` | | | Convert ASCII values to corresponding characters | `CHR(n)` | `CHAR(n)` | The tab (`CHR(9)`), line feed (`CHR(10)`), and carriage return (`CHR(13)`) characters in Oracle correspond to `CHAR(9)`, `CHAR(10)`, and `CHAR(13)` in TiDB. | @@ -50,17 +50,17 @@ This section describes some syntax differences between Oracle and TiDB. ### Add an alias for a table in the DELETE statement -- Oracle supports adding an alias for a table in the DELETE statement. For example: +Oracle supports adding an alias for a table in the DELETE statement. For example: - ```sql - DELETE FROM test t WHERE t.xxx = xxx - ``` +```sql +DELETE FROM test t WHERE t.xxx = xxx +``` -- TiDB does not support adding an alias for a table in the DELETE statement. For example: +TiDB does not support adding an alias for a table in the DELETE statement. For example: - ```sql - DELETE FROM test WHERE xxx = xxx - ``` +```sql +DELETE FROM test WHERE xxx = xxx +``` ### String syntax @@ -74,17 +74,17 @@ This section describes some syntax differences between Oracle and TiDB. ### Read and write to the same table in an `INSERT` statement -- Oracle supports reading and writing to the same table in the `INSERT` statement. For example: +Oracle supports reading and writing to the same table in the `INSERT` statement. For example: - ```sql - INSERT INTO table1 VALUES (feild1,(SELECT feild2 FROM table1 WHERE...)) - ``` +```sql +INSERT INTO table1 VALUES (feild1,(SELECT feild2 FROM table1 WHERE...)) +``` -- TiDB does not support reading and writing to the same table in `INSERT` statements. For example: +TiDB does not support reading and writing to the same table in `INSERT` statements. For example: - ```sql - INSERT INTO table1 VALUES(feild1,(SELECT T.fields2 FROM table1 T WHERE...) - ``` +```sql +INSERT INTO table1 VALUES(feild1,(SELECT T.fields2 FROM table1 T WHERE...) +``` ### Get the first n pieces of data @@ -94,59 +94,59 @@ This section describes some syntax differences between Oracle and TiDB. ### `UPDATE` statement for multi-table updates -- Oracle: it is not necessary to list the specific field update relationship when updating multiple tables. For example: +Oracle: it is not necessary to list the specific field update relationship when updating multiple tables. For example: - ```sql - UPDATE test1 SET(test1.name,test1.age) = (SELECT test2.name,test2.age FROM test2 WHERE test2.id=test1.id) - ``` +```sql +UPDATE test1 SET(test1.name,test1.age) = (SELECT test2.name,test2.age FROM test2 WHERE test2.id=test1.id) +``` -- TiDB: when updating multiple tables, you need to list all the specific field update relationships in `SET`. For example: +TiDB: when updating multiple tables, you need to list all the specific field update relationships in `SET`. For example: - ```sql - UPDATE test1,test2 SET test1.name=test2.name,test1.age=test2.age WHERE test1.id=test2.id - ``` +```sql +UPDATE test1,test2 SET test1.name=test2.name,test1.age=test2.age WHERE test1.id=test2.id +``` ### Derived table alias -- Oracle:when querying multiple tables, a derived table alias is not necessary. For example: +Oracle:when querying multiple tables, a derived table alias is not necessary. For example: - ```sql - SELECT * FROM (SELECT * FROM test) - ``` +```sql +SELECT * FROM (SELECT * FROM test) +``` -- TiDB: when querying multiple tables, each derived table must have an alias of its own. For example: +TiDB: when querying multiple tables, each derived table must have an alias of its own. For example: - ```sql - SELECT * FROM (SELECT * FROM test) t - ``` +```sql +SELECT * FROM (SELECT * FROM test) t +``` ### Difference set operation -- Oracle uses `MINUS` for difference set operations. For example: +Oracle uses `MINUS` for difference set operations. For example: - ```sql - SELECT * FROM t1 MINUS SELECT * FROM t2 - ``` +```sql +SELECT * FROM t1 MINUS SELECT * FROM t2 +``` -- TiDB does not support `MINUS`. You need to change it to `EXCEPT`. For example: +TiDB does not support `MINUS`. You need to change it to `EXCEPT`. For example: - ```sql - SELECT * FROM t1 EXCEPT SELECT * FROM t2 - ``` +```sql +SELECT * FROM t1 EXCEPT SELECT * FROM t2 +``` ### Alias for `NULL` and `''` -- Oracle: `NULL` is equivalent to `''`, and no special conversion is needed to alias a null value. For example +Oracle: `NULL` is equivalent to `''`, and no special conversion is needed to alias a null value. For example - ```sql - SELECT NULL AS ... FROM DUAL - ``` +```sql +SELECT NULL AS ... FROM DUAL +``` -- TiDB: `NULL` is different from `''`. To alias a null value, you need to change `NULL` to `''`. For example: +TiDB: `NULL` is different from `''`. To alias a null value, you need to change `NULL` to `''`. For example: - ```sql - SELECT '' AS ... FROM DUAL - ``` +```sql +SELECT '' AS ... FROM DUAL +``` ### Comment syntax @@ -156,17 +156,17 @@ This section describes some syntax differences between Oracle and TiDB. ### Paging queries -- Oracle: `OFFSET m` means skipping `m` rows. `FETCH NEXT n ROWS ONLY` means taking `n` rows. For example: +Oracle: `OFFSET m` means skipping `m` rows. `FETCH NEXT n ROWS ONLY` means taking `n` rows. For example: - ```sql - SELECT * FROM tables OFFSET 0 ROWS FETCH NEXT 2000 ROWS ONLY - ``` +```sql +SELECT * FROM tables OFFSET 0 ROWS FETCH NEXT 2000 ROWS ONLY +``` -- TiDB: Use `LIMIT n OFFSET m` to replace `OFFSET m ROWS FETCH NEXT n ROWS ONLY`. For example: +TiDB: Use `LIMIT n OFFSET m` to replace `OFFSET m ROWS FETCH NEXT n ROWS ONLY`. For example: - ```sql - SELECT * FROM tables LIMIT 2000 OFFSET 0 - ``` +```sql +SELECT * FROM tables LIMIT 2000 OFFSET 0 +``` ### `ORDER BY` sorting rules for `NULL` From 2ef62ab58f2a0489df12b228348bd3049b760ef2 Mon Sep 17 00:00:00 2001 From: xixirangrang Date: Thu, 29 Sep 2022 20:30:55 +0800 Subject: [PATCH 07/18] Update oracle-functions-to-tidb.md --- oracle-functions-to-tidb.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/oracle-functions-to-tidb.md b/oracle-functions-to-tidb.md index 006c87493dbda..3fd060eff0c03 100644 --- a/oracle-functions-to-tidb.md +++ b/oracle-functions-to-tidb.md @@ -83,7 +83,7 @@ INSERT INTO table1 VALUES (feild1,(SELECT feild2 FROM table1 WHERE...)) TiDB does not support reading and writing to the same table in `INSERT` statements. For example: ```sql -INSERT INTO table1 VALUES(feild1,(SELECT T.fields2 FROM table1 T WHERE...) +INSERT INTO table1 VALUES (feild1,(SELECT T.fields2 FROM table1 T WHERE...)) ``` ### Get the first n pieces of data From f14d0877792a3cd91ad08c57ca19815d92e78741 Mon Sep 17 00:00:00 2001 From: xixirangrang Date: Thu, 29 Sep 2022 20:53:12 +0800 Subject: [PATCH 08/18] Update oracle-functions-to-tidb.md --- oracle-functions-to-tidb.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/oracle-functions-to-tidb.md b/oracle-functions-to-tidb.md index 3fd060eff0c03..4994a4171cc01 100644 --- a/oracle-functions-to-tidb.md +++ b/oracle-functions-to-tidb.md @@ -25,7 +25,7 @@ The following table shows the mappings between some Oracle and TiDB functions. | Increase or decrease date by `n` days | `DATEVAL + n` | `DATE_ADD(dateVal,INTERVAL n DAY)` | `n` can be a negative value.| | Increase or decrease date by `n` months | `ADD_MONTHS(dateVal,n)`| `DATE_ADD(dateVal,INTERVAL n MONTH)` | `n` can be a negative value. | | Get the date (precision to the date) | `TRUNC(SYSDATE)` |
  • `CAST(NOW() AS DATE)`
  • `DATE_FORMAT(NOW(),'%Y-%m-%d')`
  • | In TiDB, `CAST` and `DATE_FORMAT` return the same result. | -| Get the month of the date | `TRUNC(SYSDATE,'mm')` | `DATE_ADD(CURDATE(),interval - day(CURDATE()) + 1 day)` | | +| Get the first date of the month | `TRUNC(SYSDATE,'mm')` | `DATE_ADD(CURDATE(),interval - day(CURDATE()) + 1 day)` | | | Round down a value | `TRUNC(2.136) = 2`
    `TRUNC(2.136,2) = 2.14` | `TRUNCATE(2.136,0) = 2`
    `TRUNCATE(2.136,2) = 2.14` | | | Combine the strings `a` and `b` | `'a' || 'b'` | `CONCAT('a','b')` | | | Get the next value in a sequence | `SEQUENCENAME.NEXTVAL` | `NEXTVAL(sequenceName)` | | From ea50d8b06a47381de24d99504760df80eaa58af8 Mon Sep 17 00:00:00 2001 From: xixirangrang Date: Thu, 29 Sep 2022 20:53:23 +0800 Subject: [PATCH 09/18] Apply suggestions from code review --- oracle-functions-to-tidb.md | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/oracle-functions-to-tidb.md b/oracle-functions-to-tidb.md index 4994a4171cc01..fbbdc2d4d872f 100644 --- a/oracle-functions-to-tidb.md +++ b/oracle-functions-to-tidb.md @@ -26,8 +26,8 @@ The following table shows the mappings between some Oracle and TiDB functions. | Increase or decrease date by `n` months | `ADD_MONTHS(dateVal,n)`| `DATE_ADD(dateVal,INTERVAL n MONTH)` | `n` can be a negative value. | | Get the date (precision to the date) | `TRUNC(SYSDATE)` |
  • `CAST(NOW() AS DATE)`
  • `DATE_FORMAT(NOW(),'%Y-%m-%d')`
  • | In TiDB, `CAST` and `DATE_FORMAT` return the same result. | | Get the first date of the month | `TRUNC(SYSDATE,'mm')` | `DATE_ADD(CURDATE(),interval - day(CURDATE()) + 1 day)` | | -| Round down a value | `TRUNC(2.136) = 2`
    `TRUNC(2.136,2) = 2.14` | `TRUNCATE(2.136,0) = 2`
    `TRUNCATE(2.136,2) = 2.14` | | -| Combine the strings `a` and `b` | `'a' || 'b'` | `CONCAT('a','b')` | | +| Truncate a value | `TRUNC(2.136) = 2`
    `TRUNC(2.136,2) = 2.14` | `TRUNCATE(2.136,0) = 2`
    `TRUNCATE(2.136,2) = 2.14` | | +| Combine the strings `a` and `b` | `'a' \|\| 'b'` | `CONCAT('a','b')` | | | Get the next value in a sequence | `SEQUENCENAME.NEXTVAL` | `NEXTVAL(sequenceName)` | | | Left join or right join | `SELECT * FROM a, b WHERE a.id = b.id(+);`
    `SELECT * FROM a, b WHERE a.id(+) = b.id;` | `SELECT * FROM a LEFT JOIN b ON a.id = b.id;`
    `SELECT * FROM a RIGHT JOIN b ON a.id = b.id;` | When correlating queries, TiDB does not support using (+) to left join or right join. You can use `LEFT JOIN` or `RIGHT JOIN` instead. | | Get random sequence values | `SYS_GUID()` | `UUID()` | TiDB returns a Universal Unique Identifier (UUID).| From e0401c76d54b185890f212e47f7c5569244d2c54 Mon Sep 17 00:00:00 2001 From: xixirangrang Date: Thu, 29 Sep 2022 21:00:04 +0800 Subject: [PATCH 10/18] Apply suggestions from code review --- oracle-functions-to-tidb.md | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/oracle-functions-to-tidb.md b/oracle-functions-to-tidb.md index fbbdc2d4d872f..f49a36ac60f6a 100644 --- a/oracle-functions-to-tidb.md +++ b/oracle-functions-to-tidb.md @@ -17,7 +17,7 @@ The following table shows the mappings between some Oracle and TiDB functions. | Function | Oracle syntax | TiDB syntax | Note | |---|---|---|---| -| Convert data types |
  • `TO_NUMBER(key)`
  • `TO_CHAR(key)`
  • | `CONVERT(key,dataType)` | TiDB supports converting `BINARY`, `CHAR`, `DATE`, `DATETIME`, `TIME`, `SIGNED INTEGER`, `UNSIGNED INTEGER` and `DECIMAL` types. | +| Convert data types |
  • `TO_NUMBER(key)`
  • `TO_CHAR(key)`
  • | `CONVERT(key,dataType)` | TiDB supports converting to the following types: `BINARY`, `CHAR`, `DATE`, `DATETIME`, `TIME`, `SIGNED INTEGER`, `UNSIGNED INTEGER` and `DECIMAL`. | | Convert a date type to a string type |
  • `TO_CHAR(SYSDATE,'yyyy-MM-dd hh24:mi:ss')`
  • `TO_CHAR(SYSDATE,'yyyy-MM-dd')`
  • |
  • `DATE_FORMAT(NOW(),'%Y-%m-%d %H:%i:%s')`
  • `DATE_FORMAT(NOW(),'%Y-%m-%d')`
  • | TiDB format strings are case-sensitive. | | Convert a string type to a date type |
  • `TO_DATE('2021-05-28 17:31:37','yyyy-MM-dd hh24:mi:ss')`
  • `TO_DATE('2021-05-28','yyyy-MM-dd hh24:mi:ss')`
  • |
  • `STR_TO_DATE('2021-05-28 17:31:37','%Y-%m-%d %H:%i:%s')`
  • `STR_TO_DATE('2021-05-28','%Y-%m-%d%T')`
  • | TiDB format strings are case-sensitive. | | Get the current system time (precision to the second) | `SYSDATE` | `NOW()` | | @@ -26,7 +26,7 @@ The following table shows the mappings between some Oracle and TiDB functions. | Increase or decrease date by `n` months | `ADD_MONTHS(dateVal,n)`| `DATE_ADD(dateVal,INTERVAL n MONTH)` | `n` can be a negative value. | | Get the date (precision to the date) | `TRUNC(SYSDATE)` |
  • `CAST(NOW() AS DATE)`
  • `DATE_FORMAT(NOW(),'%Y-%m-%d')`
  • | In TiDB, `CAST` and `DATE_FORMAT` return the same result. | | Get the first date of the month | `TRUNC(SYSDATE,'mm')` | `DATE_ADD(CURDATE(),interval - day(CURDATE()) + 1 day)` | | -| Truncate a value | `TRUNC(2.136) = 2`
    `TRUNC(2.136,2) = 2.14` | `TRUNCATE(2.136,0) = 2`
    `TRUNCATE(2.136,2) = 2.14` | | +| Truncate a value | `TRUNC(2.136) = 2`
    `TRUNC(2.136,2) = 2.13` | `TRUNCATE(2.136,0) = 2`
    `TRUNCATE(2.136,2) = 2.13` | Data precision is preserved. Truncate the corresponding decimal places without rounding. | | Combine the strings `a` and `b` | `'a' \|\| 'b'` | `CONCAT('a','b')` | | | Get the next value in a sequence | `SEQUENCENAME.NEXTVAL` | `NEXTVAL(sequenceName)` | | | Left join or right join | `SELECT * FROM a, b WHERE a.id = b.id(+);`
    `SELECT * FROM a, b WHERE a.id(+) = b.id;` | `SELECT * FROM a LEFT JOIN b ON a.id = b.id;`
    `SELECT * FROM a RIGHT JOIN b ON a.id = b.id;` | When correlating queries, TiDB does not support using (+) to left join or right join. You can use `LEFT JOIN` or `RIGHT JOIN` instead. | From dbe0e8ef694f1bdcd955ecce82f7b9b9546c5750 Mon Sep 17 00:00:00 2001 From: xixirangrang Date: Thu, 29 Sep 2022 21:34:24 +0800 Subject: [PATCH 11/18] Apply suggestions from code review --- oracle-functions-to-tidb.md | 38 +++++-------------------------------- 1 file changed, 5 insertions(+), 33 deletions(-) diff --git a/oracle-functions-to-tidb.md b/oracle-functions-to-tidb.md index f49a36ac60f6a..acbe6d1a95d51 100644 --- a/oracle-functions-to-tidb.md +++ b/oracle-functions-to-tidb.md @@ -28,7 +28,7 @@ The following table shows the mappings between some Oracle and TiDB functions. | Get the first date of the month | `TRUNC(SYSDATE,'mm')` | `DATE_ADD(CURDATE(),interval - day(CURDATE()) + 1 day)` | | | Truncate a value | `TRUNC(2.136) = 2`
    `TRUNC(2.136,2) = 2.13` | `TRUNCATE(2.136,0) = 2`
    `TRUNCATE(2.136,2) = 2.13` | Data precision is preserved. Truncate the corresponding decimal places without rounding. | | Combine the strings `a` and `b` | `'a' \|\| 'b'` | `CONCAT('a','b')` | | -| Get the next value in a sequence | `SEQUENCENAME.NEXTVAL` | `NEXTVAL(sequenceName)` | | +| Get the next value in a sequence | `sequence_name.NEXTVAL` | `NEXTVAL(sequence_name)` | | | Left join or right join | `SELECT * FROM a, b WHERE a.id = b.id(+);`
    `SELECT * FROM a, b WHERE a.id(+) = b.id;` | `SELECT * FROM a LEFT JOIN b ON a.id = b.id;`
    `SELECT * FROM a RIGHT JOIN b ON a.id = b.id;` | When correlating queries, TiDB does not support using (+) to left join or right join. You can use `LEFT JOIN` or `RIGHT JOIN` instead. | | Get random sequence values | `SYS_GUID()` | `UUID()` | TiDB returns a Universal Unique Identifier (UUID).| | `NVL()` | `NVL(key,val)` | `IFNULL(key,val)` | If the value of the field is `NULL`, it returns the value of `val`; otherwise, it returns the value of the field. | @@ -36,9 +36,9 @@ The following table shows the mappings between some Oracle and TiDB functions. | `DECODE()` |
  • `DECODE(key,val1,val2,val3)`
  • `DECODE(value,if1,val1,if2,val2,...,ifn,valn,val)`
  • |
  • `IF(key=val1,val2,val3)`
  • `CASE WHEN value=if1 THEN val1 WHEN value=if2 THEN val2,...,WHEN value=ifn THEN valn ELSE val END`
  • |
  • If the value of the field is equal to val1, then it returns val2; otherwise it returns val3.
  • When the field value satisfies the condition 1 (if1), it returns val1. When it satisfies the condition 2 (if2), it returns val2. When it satisfies the condition 3 (if3), it returns val3.
  • | | Get the length of a string | `LENGTH(str)` | `CHAR_LENGTH(str)` | | | Get sub strings | `SUBSTR('abcdefg',0,2) = 'ab'`
    `SUBSTR('abcdefg',1,2) = 'ab'` | `SUBSTRING('abcdefg',0,2) = ''`
    `SUBSTRING('abcdefg',1,2) = 'ab'` |
  • In Oracle, the starting position 0 has the same effect as 1.
  • In TiDB, the substring starting from 0 is null. If you need to start from the beginning of the string, you should start from 1.
  • | -| Search a string for substrings | `INSTR('abcdefg','b',1,1)` | `INSTR('abcdefg','b')` | Search from the first character of the string 'abcdefg' and return the position of the first occurrence of the 'b' string. | -| Search a string for substrings| `INSTR('stst','s',1,2)` | `LENGTH(SUBSTRING_INDEX('stst','s',2)) + 1` | Search from the first character of 'stst' and return the second occurrence of the 's' character. | -| Search a string for substrings | `INSTR('abcabc','b',2,1)` | `LOCATE('b','abcabc',2)` | Search from the second character of the string `abcabc` and return the first occurrence of the character `b`. | +| The position of the string in the source string | `INSTR('abcdefg','b',1,1)` | `INSTR('abcdefg','b')` | Search from the first character of the string 'abcdefg' and return the position of the first occurrence of the 'b' string. | +| The position of the string in the source string| `INSTR('stst','s',1,2)` | `LENGTH(SUBSTRING_INDEX('stst','s',2)) + 1` | Search from the first character of 'stst' and return the second occurrence of the 's' character. | +| The position of the string in the source string | `INSTR('abcabc','b',2,1)` | `LOCATE('b','abcabc',2)` | Search from the second character of the string `abcabc` and return the first occurrence of the character `b`. | | Get the interval months between dates | `MONTHS_BETWEEN(ENDDATE,SYSDATE)` | `TIMESTAMPDIFF(MONTH,SYSDATE,ENDDATE)` | The results of `MONTHS_BETWEEN()` in Oracle and `TIMESTAMPDIFF()` in TiDB are different. `TIMESTAMPDIFF()` keeps months only in integer. Note that the parameters in the two functions are in opposite positions. | | Merge columns into rows | `LISTAGG(CONCAT(E.dimensionid,'---',E.DIMENSIONNAME),'***') within GROUP(ORDER BY DIMENSIONNAME)` | `GROUP_CONCAT(CONCAT(E.dimensionid,'---',E.DIMENSIONNAME) ORDER BY DIMENSIONNAME SEPARATOR '***')` | Combine a column of fields into one row and split them according to the `***` notation. | | Get the current time (precision to the second) | `SYSTIMESTAMP` | `CURRENT_TIMESTAMP(6)` | | @@ -48,20 +48,6 @@ The following table shows the mappings between some Oracle and TiDB functions. This section describes some syntax differences between Oracle and TiDB. -### Add an alias for a table in the DELETE statement - -Oracle supports adding an alias for a table in the DELETE statement. For example: - -```sql -DELETE FROM test t WHERE t.xxx = xxx -``` - -TiDB does not support adding an alias for a table in the DELETE statement. For example: - -```sql -DELETE FROM test WHERE xxx = xxx -``` - ### String syntax - Oracle: strings can only be enclosed in single quotes (''). For example `'a'` @@ -70,7 +56,7 @@ DELETE FROM test WHERE xxx = xxx ### Difference between `NULL` and an empty string - Oracle does not distinguish between `NULL` and the empty string `''`, that is, `NULL` is equivalent to `''`. -- TiDB distinguishes between `NULL` and the empty string `''`. In TiDB, you need to convert `''` to `NULL`. +- TiDB distinguishes between `NULL` and the empty string `''`. ### Read and write to the same table in an `INSERT` statement @@ -134,20 +120,6 @@ TiDB does not support `MINUS`. You need to change it to `EXCEPT`. For example: SELECT * FROM t1 EXCEPT SELECT * FROM t2 ``` -### Alias for `NULL` and `''` - -Oracle: `NULL` is equivalent to `''`, and no special conversion is needed to alias a null value. For example - -```sql -SELECT NULL AS ... FROM DUAL -``` - -TiDB: `NULL` is different from `''`. To alias a null value, you need to change `NULL` to `''`. For example: - -```sql -SELECT '' AS ... FROM DUAL -``` - ### Comment syntax - Oracle: `--Comment`. Oracle does not need a space after `--`. From b17cf92371159d316ae2acdccc31efaaee1ad1f7 Mon Sep 17 00:00:00 2001 From: xixirangrang Date: Fri, 30 Sep 2022 10:11:50 +0800 Subject: [PATCH 12/18] Apply suggestions from code review --- oracle-functions-to-tidb.md | 8 ++++---- 1 file changed, 4 insertions(+), 4 deletions(-) diff --git a/oracle-functions-to-tidb.md b/oracle-functions-to-tidb.md index acbe6d1a95d51..93653da71d408 100644 --- a/oracle-functions-to-tidb.md +++ b/oracle-functions-to-tidb.md @@ -39,7 +39,7 @@ The following table shows the mappings between some Oracle and TiDB functions. | The position of the string in the source string | `INSTR('abcdefg','b',1,1)` | `INSTR('abcdefg','b')` | Search from the first character of the string 'abcdefg' and return the position of the first occurrence of the 'b' string. | | The position of the string in the source string| `INSTR('stst','s',1,2)` | `LENGTH(SUBSTRING_INDEX('stst','s',2)) + 1` | Search from the first character of 'stst' and return the second occurrence of the 's' character. | | The position of the string in the source string | `INSTR('abcabc','b',2,1)` | `LOCATE('b','abcabc',2)` | Search from the second character of the string `abcabc` and return the first occurrence of the character `b`. | -| Get the interval months between dates | `MONTHS_BETWEEN(ENDDATE,SYSDATE)` | `TIMESTAMPDIFF(MONTH,SYSDATE,ENDDATE)` | The results of `MONTHS_BETWEEN()` in Oracle and `TIMESTAMPDIFF()` in TiDB are different. `TIMESTAMPDIFF()` keeps months only in integer. Note that the parameters in the two functions are in opposite positions. | +| Get the number of months between dates | `MONTHS_BETWEEN(ENDDATE,SYSDATE)` | `TIMESTAMPDIFF(MONTH,SYSDATE,ENDDATE)` | The results of `MONTHS_BETWEEN()` in Oracle and `TIMESTAMPDIFF()` in TiDB are different. `TIMESTAMPDIFF()` keeps months only in integer. Note that the parameters in the two functions are in opposite positions. | | Merge columns into rows | `LISTAGG(CONCAT(E.dimensionid,'---',E.DIMENSIONNAME),'***') within GROUP(ORDER BY DIMENSIONNAME)` | `GROUP_CONCAT(CONCAT(E.dimensionid,'---',E.DIMENSIONNAME) ORDER BY DIMENSIONNAME SEPARATOR '***')` | Combine a column of fields into one row and split them according to the `***` notation. | | Get the current time (precision to the second) | `SYSTIMESTAMP` | `CURRENT_TIMESTAMP(6)` | | | Convert ASCII values to corresponding characters | `CHR(n)` | `CHAR(n)` | The tab (`CHR(9)`), line feed (`CHR(10)`), and carriage return (`CHR(13)`) characters in Oracle correspond to `CHAR(9)`, `CHAR(10)`, and `CHAR(13)` in TiDB. | @@ -72,11 +72,11 @@ TiDB does not support reading and writing to the same table in `INSERT` statemen INSERT INTO table1 VALUES (feild1,(SELECT T.fields2 FROM table1 T WHERE...)) ``` -### Get the first n pieces of data +### Get the first n rows of data -- Oracle gets the first n pieces of data by `ROWNUM <= n`. For example `ROWNUM <= 10`. +- Oracle gets the first n rows of data by `ROWNUM <= n`. For example `ROWNUM <= 10`. -- TiDB gets the first n pieces of data by `LIMIT n`. For example `LIMIT 10`. The Hibernate Query Language (HQL) running SQL statements with `LIMIT` results in an error. You need to change the Hibernate statements to SQL statements. +- TiDB gets the first n rows of data by `LIMIT n`. For example `LIMIT 10`. The Hibernate Query Language (HQL) running SQL statements with `LIMIT` results in an error. You need to change the Hibernate statements to SQL statements. ### `UPDATE` statement for multi-table updates From 01a96ff9c2c18e09d6ba3f5f6eff22aa7171c357 Mon Sep 17 00:00:00 2001 From: xixirangrang <35301108+hfxsd@users.noreply.github.com> Date: Fri, 30 Sep 2022 12:29:06 +0800 Subject: [PATCH 13/18] Update oracle-functions-to-tidb.md --- oracle-functions-to-tidb.md | 32 +++++++++++++++++--------------- 1 file changed, 17 insertions(+), 15 deletions(-) diff --git a/oracle-functions-to-tidb.md b/oracle-functions-to-tidb.md index 93653da71d408..64a8c7c6a14da 100644 --- a/oracle-functions-to-tidb.md +++ b/oracle-functions-to-tidb.md @@ -21,27 +21,27 @@ The following table shows the mappings between some Oracle and TiDB functions. | Convert a date type to a string type |
  • `TO_CHAR(SYSDATE,'yyyy-MM-dd hh24:mi:ss')`
  • `TO_CHAR(SYSDATE,'yyyy-MM-dd')`
  • |
  • `DATE_FORMAT(NOW(),'%Y-%m-%d %H:%i:%s')`
  • `DATE_FORMAT(NOW(),'%Y-%m-%d')`
  • | TiDB format strings are case-sensitive. | | Convert a string type to a date type |
  • `TO_DATE('2021-05-28 17:31:37','yyyy-MM-dd hh24:mi:ss')`
  • `TO_DATE('2021-05-28','yyyy-MM-dd hh24:mi:ss')`
  • |
  • `STR_TO_DATE('2021-05-28 17:31:37','%Y-%m-%d %H:%i:%s')`
  • `STR_TO_DATE('2021-05-28','%Y-%m-%d%T')`
  • | TiDB format strings are case-sensitive. | | Get the current system time (precision to the second) | `SYSDATE` | `NOW()` | | -| Get the number of days between `date1` and `date2` | `date1 - date2` | `DATEDIFF(date1, date2)` | | +| Get the current time (precision to the second) | `SYSTIMESTAMP` | `CURRENT_TIMESTAMP(6)` | | +| Get the number of days between two days | `date1 - date2` | `DATEDIFF(date1, date2)` | | +| Get the number of months between dates | `MONTHS_BETWEEN(ENDDATE,SYSDATE)` | `TIMESTAMPDIFF(MONTH,SYSDATE,ENDDATE)` | The results of `MONTHS_BETWEEN()` in Oracle and `TIMESTAMPDIFF()` in TiDB are different. `TIMESTAMPDIFF()` keeps months only in integer. Note that the parameters in the two functions are in opposite positions. | | Increase or decrease date by `n` days | `DATEVAL + n` | `DATE_ADD(dateVal,INTERVAL n DAY)` | `n` can be a negative value.| | Increase or decrease date by `n` months | `ADD_MONTHS(dateVal,n)`| `DATE_ADD(dateVal,INTERVAL n MONTH)` | `n` can be a negative value. | | Get the date (precision to the date) | `TRUNC(SYSDATE)` |
  • `CAST(NOW() AS DATE)`
  • `DATE_FORMAT(NOW(),'%Y-%m-%d')`
  • | In TiDB, `CAST` and `DATE_FORMAT` return the same result. | | Get the first date of the month | `TRUNC(SYSDATE,'mm')` | `DATE_ADD(CURDATE(),interval - day(CURDATE()) + 1 day)` | | | Truncate a value | `TRUNC(2.136) = 2`
    `TRUNC(2.136,2) = 2.13` | `TRUNCATE(2.136,0) = 2`
    `TRUNCATE(2.136,2) = 2.13` | Data precision is preserved. Truncate the corresponding decimal places without rounding. | -| Combine the strings `a` and `b` | `'a' \|\| 'b'` | `CONCAT('a','b')` | | | Get the next value in a sequence | `sequence_name.NEXTVAL` | `NEXTVAL(sequence_name)` | | | Left join or right join | `SELECT * FROM a, b WHERE a.id = b.id(+);`
    `SELECT * FROM a, b WHERE a.id(+) = b.id;` | `SELECT * FROM a LEFT JOIN b ON a.id = b.id;`
    `SELECT * FROM a RIGHT JOIN b ON a.id = b.id;` | When correlating queries, TiDB does not support using (+) to left join or right join. You can use `LEFT JOIN` or `RIGHT JOIN` instead. | | Get random sequence values | `SYS_GUID()` | `UUID()` | TiDB returns a Universal Unique Identifier (UUID).| | `NVL()` | `NVL(key,val)` | `IFNULL(key,val)` | If the value of the field is `NULL`, it returns the value of `val`; otherwise, it returns the value of the field. | | `NVL2()` | `NVL2(key, val1, val2)` | `IF(key is NULL, val1, val2)` | If the value of the field is not `NULL`, it returns the value of `val1`; otherwise, it returns the value of `val2`. | | `DECODE()` |
  • `DECODE(key,val1,val2,val3)`
  • `DECODE(value,if1,val1,if2,val2,...,ifn,valn,val)`
  • |
  • `IF(key=val1,val2,val3)`
  • `CASE WHEN value=if1 THEN val1 WHEN value=if2 THEN val2,...,WHEN value=ifn THEN valn ELSE val END`
  • |
  • If the value of the field is equal to val1, then it returns val2; otherwise it returns val3.
  • When the field value satisfies the condition 1 (if1), it returns val1. When it satisfies the condition 2 (if2), it returns val2. When it satisfies the condition 3 (if3), it returns val3.
  • | +| Combine the strings `a` and `b` | `'a' \|\| 'b'` | `CONCAT('a','b')` | | | Get the length of a string | `LENGTH(str)` | `CHAR_LENGTH(str)` | | | Get sub strings | `SUBSTR('abcdefg',0,2) = 'ab'`
    `SUBSTR('abcdefg',1,2) = 'ab'` | `SUBSTRING('abcdefg',0,2) = ''`
    `SUBSTRING('abcdefg',1,2) = 'ab'` |
  • In Oracle, the starting position 0 has the same effect as 1.
  • In TiDB, the substring starting from 0 is null. If you need to start from the beginning of the string, you should start from 1.
  • | | The position of the string in the source string | `INSTR('abcdefg','b',1,1)` | `INSTR('abcdefg','b')` | Search from the first character of the string 'abcdefg' and return the position of the first occurrence of the 'b' string. | | The position of the string in the source string| `INSTR('stst','s',1,2)` | `LENGTH(SUBSTRING_INDEX('stst','s',2)) + 1` | Search from the first character of 'stst' and return the second occurrence of the 's' character. | | The position of the string in the source string | `INSTR('abcabc','b',2,1)` | `LOCATE('b','abcabc',2)` | Search from the second character of the string `abcabc` and return the first occurrence of the character `b`. | -| Get the number of months between dates | `MONTHS_BETWEEN(ENDDATE,SYSDATE)` | `TIMESTAMPDIFF(MONTH,SYSDATE,ENDDATE)` | The results of `MONTHS_BETWEEN()` in Oracle and `TIMESTAMPDIFF()` in TiDB are different. `TIMESTAMPDIFF()` keeps months only in integer. Note that the parameters in the two functions are in opposite positions. | | Merge columns into rows | `LISTAGG(CONCAT(E.dimensionid,'---',E.DIMENSIONNAME),'***') within GROUP(ORDER BY DIMENSIONNAME)` | `GROUP_CONCAT(CONCAT(E.dimensionid,'---',E.DIMENSIONNAME) ORDER BY DIMENSIONNAME SEPARATOR '***')` | Combine a column of fields into one row and split them according to the `***` notation. | -| Get the current time (precision to the second) | `SYSTIMESTAMP` | `CURRENT_TIMESTAMP(6)` | | | Convert ASCII values to corresponding characters | `CHR(n)` | `CHAR(n)` | The tab (`CHR(9)`), line feed (`CHR(10)`), and carriage return (`CHR(13)`) characters in Oracle correspond to `CHAR(9)`, `CHAR(10)`, and `CHAR(13)` in TiDB. | ## Syntax differences @@ -50,13 +50,15 @@ This section describes some syntax differences between Oracle and TiDB. ### String syntax -- Oracle: strings can only be enclosed in single quotes (''). For example `'a'` -- TiDB: Strings can be enclosed in single quotes ('') or double quotes (""). For example, `'a'` and `"a"` +In Oracle, strings can only be enclosed in single quotes (''). For example `'a'` + +In TiDB, strings can be enclosed in single quotes ('') or double quotes (""). For example, `'a'` and `"a"` ### Difference between `NULL` and an empty string -- Oracle does not distinguish between `NULL` and the empty string `''`, that is, `NULL` is equivalent to `''`. -- TiDB distinguishes between `NULL` and the empty string `''`. +Oracle does not distinguish between `NULL` and the empty string `''`, that is, `NULL` is equivalent to `''`. + +TiDB distinguishes between `NULL` and the empty string `''`. ### Read and write to the same table in an `INSERT` statement @@ -74,9 +76,9 @@ INSERT INTO table1 VALUES (feild1,(SELECT T.fields2 FROM table1 T WHERE...)) ### Get the first n rows of data -- Oracle gets the first n rows of data by `ROWNUM <= n`. For example `ROWNUM <= 10`. +Oracle gets the first n rows of data by `ROWNUM <= n`. For example `ROWNUM <= 10`. -- TiDB gets the first n rows of data by `LIMIT n`. For example `LIMIT 10`. The Hibernate Query Language (HQL) running SQL statements with `LIMIT` results in an error. You need to change the Hibernate statements to SQL statements. +TiDB gets the first n rows of data by `LIMIT n`. For example `LIMIT 10`. The Hibernate Query Language (HQL) running SQL statements with `LIMIT` results in an error. You need to change the Hibernate statements to SQL statements. ### `UPDATE` statement for multi-table updates @@ -114,7 +116,7 @@ Oracle uses `MINUS` for difference set operations. For example: SELECT * FROM t1 MINUS SELECT * FROM t2 ``` -TiDB does not support `MINUS`. You need to change it to `EXCEPT`. For example: +TiDB does not support `MINUS`. You need to change it to `EXCEPT` to perform difference set operations. For example: ```sql SELECT * FROM t1 EXCEPT SELECT * FROM t2 @@ -122,9 +124,9 @@ SELECT * FROM t1 EXCEPT SELECT * FROM t2 ### Comment syntax -- Oracle: `--Comment`. Oracle does not need a space after `--`. +In Oracle, the comment syntax is `--Comment`. Oracle does not need a space after `--`. -- TiDB:`-- Comment`. TiDB needs a space after `--`. +In TiDB, the comment syntax is `-- Comment`. Note that TiDB needs a space after `--`. ### Paging queries @@ -164,5 +166,5 @@ The following table shows some examples of equivalent `ORDER BY` statements in O | :------------------- | :----------------- | | `SELECT * FROM t1 ORDER BY name NULLS FIRST;` |`SELECT * FROM t1 ORDER BY NAME ;` | | `SELECT * FROM t1 ORDER BY name DESC NULLS LAST;` | `SELECT * FROM t1 ORDER BY NAME DESC;` | -| `SELECT * FROM t1 ORDER BY NAME DESC NULLS FIRST;` | `SELECT * FROM t1 ORDER BY ISNULL(name) DESC, name DESC;` | -|`SELECT * FROM t1 ORDER BY name ASC NULLS LAST;` | `SELECT * FROM t1 ORDER BY ISNULL(name), name;` | +| `SELECT * FROM t1 ORDER BY name DESC NULLS FIRST;` | `SELECT * FROM t1 ORDER BY ISNULL(name) DESC, name DESC;` | +| `SELECT * FROM t1 ORDER BY name ASC NULLS LAST;` | `SELECT * FROM t1 ORDER BY ISNULL(name), name;` | From 2442b37eaea706ade6a184d0bc18322fe74cc8a9 Mon Sep 17 00:00:00 2001 From: Aolin Date: Fri, 30 Sep 2022 16:19:24 +0800 Subject: [PATCH 14/18] review --- oracle-functions-to-tidb.md | 110 ++++++++++++++++++------------------ 1 file changed, 55 insertions(+), 55 deletions(-) diff --git a/oracle-functions-to-tidb.md b/oracle-functions-to-tidb.md index 64a8c7c6a14da..8d25c71727211 100644 --- a/oracle-functions-to-tidb.md +++ b/oracle-functions-to-tidb.md @@ -1,6 +1,6 @@ --- title: Mappings between Functions and Syntax of Oracle and TiDB -summary: Learn the mappings between functions and syntax of Oracle and TiDB +summary: Learn the mappings between functions and syntax of Oracle and TiDB. --- # Mappings between Functions and Syntax of Oracle and TiDB @@ -17,32 +17,32 @@ The following table shows the mappings between some Oracle and TiDB functions. | Function | Oracle syntax | TiDB syntax | Note | |---|---|---|---| -| Convert data types |
  • `TO_NUMBER(key)`
  • `TO_CHAR(key)`
  • | `CONVERT(key,dataType)` | TiDB supports converting to the following types: `BINARY`, `CHAR`, `DATE`, `DATETIME`, `TIME`, `SIGNED INTEGER`, `UNSIGNED INTEGER` and `DECIMAL`. | -| Convert a date type to a string type |
  • `TO_CHAR(SYSDATE,'yyyy-MM-dd hh24:mi:ss')`
  • `TO_CHAR(SYSDATE,'yyyy-MM-dd')`
  • |
  • `DATE_FORMAT(NOW(),'%Y-%m-%d %H:%i:%s')`
  • `DATE_FORMAT(NOW(),'%Y-%m-%d')`
  • | TiDB format strings are case-sensitive. | -| Convert a string type to a date type |
  • `TO_DATE('2021-05-28 17:31:37','yyyy-MM-dd hh24:mi:ss')`
  • `TO_DATE('2021-05-28','yyyy-MM-dd hh24:mi:ss')`
  • |
  • `STR_TO_DATE('2021-05-28 17:31:37','%Y-%m-%d %H:%i:%s')`
  • `STR_TO_DATE('2021-05-28','%Y-%m-%d%T')`
  • | TiDB format strings are case-sensitive. | -| Get the current system time (precision to the second) | `SYSDATE` | `NOW()` | | -| Get the current time (precision to the second) | `SYSTIMESTAMP` | `CURRENT_TIMESTAMP(6)` | | -| Get the number of days between two days | `date1 - date2` | `DATEDIFF(date1, date2)` | | -| Get the number of months between dates | `MONTHS_BETWEEN(ENDDATE,SYSDATE)` | `TIMESTAMPDIFF(MONTH,SYSDATE,ENDDATE)` | The results of `MONTHS_BETWEEN()` in Oracle and `TIMESTAMPDIFF()` in TiDB are different. `TIMESTAMPDIFF()` keeps months only in integer. Note that the parameters in the two functions are in opposite positions. | -| Increase or decrease date by `n` days | `DATEVAL + n` | `DATE_ADD(dateVal,INTERVAL n DAY)` | `n` can be a negative value.| -| Increase or decrease date by `n` months | `ADD_MONTHS(dateVal,n)`| `DATE_ADD(dateVal,INTERVAL n MONTH)` | `n` can be a negative value. | -| Get the date (precision to the date) | `TRUNC(SYSDATE)` |
  • `CAST(NOW() AS DATE)`
  • `DATE_FORMAT(NOW(),'%Y-%m-%d')`
  • | In TiDB, `CAST` and `DATE_FORMAT` return the same result. | -| Get the first date of the month | `TRUNC(SYSDATE,'mm')` | `DATE_ADD(CURDATE(),interval - day(CURDATE()) + 1 day)` | | +| Cast a value as a certain type |
  • `TO_NUMBER(key)`
  • `TO_CHAR(key)`
  • | `CONVERT(key,dataType)` | TiDB supports casting a value as one of the following types: `BINARY`, `CHAR`, `DATE`, `DATETIME`, `TIME`, `SIGNED INTEGER`, `UNSIGNED INTEGER` and `DECIMAL`. | +| Convert a date to a string |
  • `TO_CHAR(SYSDATE,'yyyy-MM-dd hh24:mi:ss')`
  • `TO_CHAR(SYSDATE,'yyyy-MM-dd')`
  • |
  • `DATE_FORMAT(NOW(),'%Y-%m-%d %H:%i:%s')`
  • `DATE_FORMAT(NOW(),'%Y-%m-%d')`
  • | The format string of TiDB is case-sensitive. | +| Convert a string to a date |
  • `TO_DATE('2021-05-28 17:31:37','yyyy-MM-dd hh24:mi:ss')`
  • `TO_DATE('2021-05-28','yyyy-MM-dd hh24:mi:ss')`
  • |
  • `STR_TO_DATE('2021-05-28 17:31:37','%Y-%m-%d %H:%i:%s')`
  • `STR_TO_DATE('2021-05-28','%Y-%m-%d%T')`
  • | The format string of TiDB is case-sensitive. | +| Get the current system time in second precision | `SYSDATE` | `NOW()` | | +| Get the current system time in microsecond precision | `SYSTIMESTAMP` | `CURRENT_TIMESTAMP(6)` | | +| Get the number of days between two dates | `date1 - date2` | `DATEDIFF(date1, date2)` | | +| Get the number of months between two dates | `MONTHS_BETWEEN(ENDDATE,SYSDATE)` | `TIMESTAMPDIFF(MONTH,SYSDATE,ENDDATE)` | The results of `MONTHS_BETWEEN()` in Oracle and `TIMESTAMPDIFF()` in TiDB are different. `TIMESTAMPDIFF()` keeps months only in integer. Note that the parameters in the two functions are in opposite positions. | +| Add `n` days to a date | `DATEVAL + n` | `DATE_ADD(dateVal,INTERVAL n DAY)` | `n` can be a negative value.| +| Add `n` months to a date | `ADD_MONTHS(dateVal,n)`| `DATE_ADD(dateVal,INTERVAL n MONTH)` | `n` can be a negative value. | +| Get the day of a date | `TRUNC(SYSDATE)` |
  • `CAST(NOW() AS DATE)`
  • `DATE_FORMAT(NOW(),'%Y-%m-%d')`
  • | In TiDB, `CAST` and `DATE_FORMAT` return the same result. | +| Get the month of a date | `TRUNC(SYSDATE,'mm')` | `DATE_ADD(CURDATE(),interval - day(CURDATE()) + 1 day)` | | | Truncate a value | `TRUNC(2.136) = 2`
    `TRUNC(2.136,2) = 2.13` | `TRUNCATE(2.136,0) = 2`
    `TRUNCATE(2.136,2) = 2.13` | Data precision is preserved. Truncate the corresponding decimal places without rounding. | | Get the next value in a sequence | `sequence_name.NEXTVAL` | `NEXTVAL(sequence_name)` | | | Left join or right join | `SELECT * FROM a, b WHERE a.id = b.id(+);`
    `SELECT * FROM a, b WHERE a.id(+) = b.id;` | `SELECT * FROM a LEFT JOIN b ON a.id = b.id;`
    `SELECT * FROM a RIGHT JOIN b ON a.id = b.id;` | When correlating queries, TiDB does not support using (+) to left join or right join. You can use `LEFT JOIN` or `RIGHT JOIN` instead. | -| Get random sequence values | `SYS_GUID()` | `UUID()` | TiDB returns a Universal Unique Identifier (UUID).| +| Get a random sequence value | `SYS_GUID()` | `UUID()` | TiDB returns a Universal Unique Identifier (UUID).| | `NVL()` | `NVL(key,val)` | `IFNULL(key,val)` | If the value of the field is `NULL`, it returns the value of `val`; otherwise, it returns the value of the field. | | `NVL2()` | `NVL2(key, val1, val2)` | `IF(key is NULL, val1, val2)` | If the value of the field is not `NULL`, it returns the value of `val1`; otherwise, it returns the value of `val2`. | -| `DECODE()` |
  • `DECODE(key,val1,val2,val3)`
  • `DECODE(value,if1,val1,if2,val2,...,ifn,valn,val)`
  • |
  • `IF(key=val1,val2,val3)`
  • `CASE WHEN value=if1 THEN val1 WHEN value=if2 THEN val2,...,WHEN value=ifn THEN valn ELSE val END`
  • |
  • If the value of the field is equal to val1, then it returns val2; otherwise it returns val3.
  • When the field value satisfies the condition 1 (if1), it returns val1. When it satisfies the condition 2 (if2), it returns val2. When it satisfies the condition 3 (if3), it returns val3.
  • | -| Combine the strings `a` and `b` | `'a' \|\| 'b'` | `CONCAT('a','b')` | | +| `DECODE()` |
  • `DECODE(key,val1,val2,val3)`
  • `DECODE(value,if1,val1,if2,val2,...,ifn,valn,val)`
  • |
  • `IF(key=val1,val2,val3)`
  • `CASE WHEN value=if1 THEN val1 WHEN value=if2 THEN val2,...,WHEN value=ifn THEN valn ELSE val END`
  • |
  • If the value of the field is equal to val1, then it returns val2; otherwise it returns val3.
  • When the field value satisfies condition 1 (if1), it returns val1. When it satisfies condition 2 (if2), it returns val2. When it satisfies condition 3 (if3), it returns val3.
  • | +| Concatenating the string `a` and `b` | 'a' \|\| 'b' | `CONCAT('a','b')` | | | Get the length of a string | `LENGTH(str)` | `CHAR_LENGTH(str)` | | -| Get sub strings | `SUBSTR('abcdefg',0,2) = 'ab'`
    `SUBSTR('abcdefg',1,2) = 'ab'` | `SUBSTRING('abcdefg',0,2) = ''`
    `SUBSTRING('abcdefg',1,2) = 'ab'` |
  • In Oracle, the starting position 0 has the same effect as 1.
  • In TiDB, the substring starting from 0 is null. If you need to start from the beginning of the string, you should start from 1.
  • | -| The position of the string in the source string | `INSTR('abcdefg','b',1,1)` | `INSTR('abcdefg','b')` | Search from the first character of the string 'abcdefg' and return the position of the first occurrence of the 'b' string. | -| The position of the string in the source string| `INSTR('stst','s',1,2)` | `LENGTH(SUBSTRING_INDEX('stst','s',2)) + 1` | Search from the first character of 'stst' and return the second occurrence of the 's' character. | -| The position of the string in the source string | `INSTR('abcabc','b',2,1)` | `LOCATE('b','abcabc',2)` | Search from the second character of the string `abcabc` and return the first occurrence of the character `b`. | -| Merge columns into rows | `LISTAGG(CONCAT(E.dimensionid,'---',E.DIMENSIONNAME),'***') within GROUP(ORDER BY DIMENSIONNAME)` | `GROUP_CONCAT(CONCAT(E.dimensionid,'---',E.DIMENSIONNAME) ORDER BY DIMENSIONNAME SEPARATOR '***')` | Combine a column of fields into one row and split them according to the `***` notation. | -| Convert ASCII values to corresponding characters | `CHR(n)` | `CHAR(n)` | The tab (`CHR(9)`), line feed (`CHR(10)`), and carriage return (`CHR(13)`) characters in Oracle correspond to `CHAR(9)`, `CHAR(10)`, and `CHAR(13)` in TiDB. | +| Get the substring as specified | `SUBSTR('abcdefg',0,2) = 'ab'`
    `SUBSTR('abcdefg',1,2) = 'ab'` | `SUBSTRING('abcdefg',0,2) = ''`
    `SUBSTRING('abcdefg',1,2) = 'ab'` |
  • In Oracle, the starting position 0 has the same effect as 1.
  • In TiDB, the starting position 0 returns an empty string. If you need to start from the beginning of the string, the starting position should be 1.
  • | +| Get the position of a substring | `INSTR('abcdefg','b',1,1)` | `INSTR('abcdefg','b')` | Search from the first character of `'abcdefg'` and return the position of the first occurrence of `'b'`. | +| Get the position of a substring | `INSTR('stst','s',1,2)` | `LENGTH(SUBSTRING_INDEX('stst','s',2)) + 1` | Search from the first character of `'stst'` and return the position of the second occurrence of `'s'`. | +| Get the position of a substring | `INSTR('abcabc','b',2,1)` | `LOCATE('b','abcabc',2)` | Search from the second character of `abcabc` and return the position of the first occurrence of `b`. | +| Concatenate values of a column | `LISTAGG(CONCAT(E.dimensionid,'---',E.DIMENSIONNAME),'***') within GROUP(ORDER BY DIMENSIONNAME)` | `GROUP_CONCAT(CONCAT(E.dimensionid,'---',E.DIMENSIONNAME) ORDER BY DIMENSIONNAME SEPARATOR '***')` | Concatenate values of a specified column to one row with the `***` delimiter. | +| Convert a ASCII code to character | `CHR(n)` | `CHAR(n)` | The tab (`CHR(9)`), line feed (`CHR(10)`), and carriage return (`CHR(13)`) characters in Oracle correspond to `CHAR(9)`, `CHAR(10)`, and `CHAR(13)` in TiDB. | ## Syntax differences @@ -50,45 +50,45 @@ This section describes some syntax differences between Oracle and TiDB. ### String syntax -In Oracle, strings can only be enclosed in single quotes (''). For example `'a'` +In Oracle, a string can only be enclosed in single quotes (''). For example `'a'` -In TiDB, strings can be enclosed in single quotes ('') or double quotes (""). For example, `'a'` and `"a"` +In TiDB, a string can be enclosed in single quotes ('') or double quotes (""). For example, `'a'` and `"a"` ### Difference between `NULL` and an empty string -Oracle does not distinguish between `NULL` and the empty string `''`, that is, `NULL` is equivalent to `''`. +Oracle does not distinguish between `NULL` and an empty string `''`, that is, `NULL` is equivalent to `''`. -TiDB distinguishes between `NULL` and the empty string `''`. +TiDB distinguishes between `NULL` and an empty string `''`. ### Read and write to the same table in an `INSERT` statement -Oracle supports reading and writing to the same table in the `INSERT` statement. For example: +Oracle supports reading and writing to the same table in a `INSERT` statement. For example: ```sql INSERT INTO table1 VALUES (feild1,(SELECT feild2 FROM table1 WHERE...)) ``` -TiDB does not support reading and writing to the same table in `INSERT` statements. For example: +TiDB does not support reading and writing to the same table in a `INSERT` statement. For example: ```sql INSERT INTO table1 VALUES (feild1,(SELECT T.fields2 FROM table1 T WHERE...)) ``` -### Get the first n rows of data +### Get the first n rows from a query -Oracle gets the first n rows of data by `ROWNUM <= n`. For example `ROWNUM <= 10`. +In Oracle, to get the first n rows from a query, you can use the `ROWNUM <= n` clause. For example `ROWNUM <= 10`. -TiDB gets the first n rows of data by `LIMIT n`. For example `LIMIT 10`. The Hibernate Query Language (HQL) running SQL statements with `LIMIT` results in an error. You need to change the Hibernate statements to SQL statements. +In TiDB, to get the first n rows from a query, you can use the `LIMIT n` clause. For example `LIMIT 10`. The Hibernate Query Language (HQL) running SQL statements with `LIMIT` results in an error. You need to change the Hibernate statements to SQL statements. -### `UPDATE` statement for multi-table updates +### Update multiple tables in a `UPDATE` statement -Oracle: it is not necessary to list the specific field update relationship when updating multiple tables. For example: +In Oracle, it is not necessary to list the specific field update relationship when updating multiple tables. For example: ```sql UPDATE test1 SET(test1.name,test1.age) = (SELECT test2.name,test2.age FROM test2 WHERE test2.id=test1.id) ``` -TiDB: when updating multiple tables, you need to list all the specific field update relationships in `SET`. For example: +In TiDB, when updating multiple tables, you need to list all the specific field update relationships in `SET`. For example: ```sql UPDATE test1,test2 SET test1.name=test2.name,test1.age=test2.age WHERE test1.id=test2.id @@ -96,27 +96,27 @@ UPDATE test1,test2 SET test1.name=test2.name,test1.age=test2.age WHERE test1.id= ### Derived table alias -Oracle:when querying multiple tables, a derived table alias is not necessary. For example: +In Oracle, when querying multiple tables, it is unnecessary to add an alias to the derived table. For example: ```sql SELECT * FROM (SELECT * FROM test) ``` -TiDB: when querying multiple tables, each derived table must have an alias of its own. For example: +In TiDB, when querying multiple tables, every derived table must have its own alias. For example: ```sql SELECT * FROM (SELECT * FROM test) t ``` -### Difference set operation +### Set operations -Oracle uses `MINUS` for difference set operations. For example: +In Oracle, to get the rows that are in the first query result but not in the second, you can use the `MINUS` set operation. For example: ```sql SELECT * FROM t1 MINUS SELECT * FROM t2 ``` -TiDB does not support `MINUS`. You need to change it to `EXCEPT` to perform difference set operations. For example: +TiDB does not support the `MINUS` operation. You can use the `EXCEPT` set operation. For example: ```sql SELECT * FROM t1 EXCEPT SELECT * FROM t2 @@ -124,47 +124,47 @@ SELECT * FROM t1 EXCEPT SELECT * FROM t2 ### Comment syntax -In Oracle, the comment syntax is `--Comment`. Oracle does not need a space after `--`. +In Oracle, the comment syntax is `--Comment`. -In TiDB, the comment syntax is `-- Comment`. Note that TiDB needs a space after `--`. +In TiDB, the comment syntax is `-- Comment`. Note that there is a white space after `--` in TiDB. -### Paging queries +### Pagination -Oracle: `OFFSET m` means skipping `m` rows. `FETCH NEXT n ROWS ONLY` means taking `n` rows. For example: +In Oracle, you can use the `OFFSET m ROWS` to skip `m` rows and use the `FETCH NEXT n ROWS ONLY`to fetch `n` rows. For example: ```sql SELECT * FROM tables OFFSET 0 ROWS FETCH NEXT 2000 ROWS ONLY ``` -TiDB: Use `LIMIT n OFFSET m` to replace `OFFSET m ROWS FETCH NEXT n ROWS ONLY`. For example: +In TiDB, you can use the `LIMIT n OFFSET m` to replace `OFFSET m ROWS FETCH NEXT n ROWS ONLY`. For example: ```sql SELECT * FROM tables LIMIT 2000 OFFSET 0 ``` -### `ORDER BY` sorting rules for `NULL` +### Sorting order on `NULL` values -Rules for sorting `NULL` by the `ORDER BY` statement in Oracle. +In Oracle, `NULL` values are sorted by the `ORDER BY` clause in the following cases: -- In `ORDER BY COLUM ASC`, `NULL` is placed last by default. +- In the `ORDER BY column ASC` statement, `NULL` values are returned last. -- In `ORDER BY COLUM DESC`, `NULL` is placed first by default. +- In the `ORDER BY column DESC` statement, `NULL` values are returned first. -- In `ORDER BY COLUM [ASC|DESC] NULLS FIRST`, `NULL` is forced to be placed first. Non-`NULL` values are still sorted by the declared order `ASC|DESC`. +- In the `ORDER BY column [ASC|DESC] NULLS FIRST` statement, `NULL` values are returned before non-NULL values. Non-NULL values are returned in ascending order or descending order specified in `ASC|DESC`. -- In `ORDER BY COLUM [ASC|DESC] NULLS LAST` , `NULL` is forced to be placed last. Non-`NULL` values are still sorted by the declared order `ASC|DESC`. +- In the `ORDER BY column [ASC|DESC] NULLS LAST` statement, `NULL` values are returned after non-NULL values. Non-NULL values are returned in ascending order or descending order specified in `ASC|DESC`. -Rules for sorting `NULL` by the `ORDER BY` statement in TiDB. +In TiDB, `NULL` values are sorted by the `ORDER BY` clause in the following cases: -- In `ORDER BY COLUM ASC`, `NULL` is placed first by default. +- In the `ORDER BY column ASC` statement, `NULL` values are returned first. -- `ORDER BY COLUM DESC`, `NULL` is placed last by default. +- In the `ORDER BY column DESC` statement, `NULL` values are returned last. The following table shows some examples of equivalent `ORDER BY` statements in Oracle and TiDB: -| `ORDER BY` in Oracle | Equivalent in TiDB | +| `ORDER BY` in Oracle | Equivalent statements in TiDB | | :------------------- | :----------------- | -| `SELECT * FROM t1 ORDER BY name NULLS FIRST;` |`SELECT * FROM t1 ORDER BY NAME ;` | -| `SELECT * FROM t1 ORDER BY name DESC NULLS LAST;` | `SELECT * FROM t1 ORDER BY NAME DESC;` | +| `SELECT * FROM t1 ORDER BY name NULLS FIRST;` | `SELECT * FROM t1 ORDER BY name;` | +| `SELECT * FROM t1 ORDER BY name DESC NULLS LAST;` | `SELECT * FROM t1 ORDER BY name DESC;` | | `SELECT * FROM t1 ORDER BY name DESC NULLS FIRST;` | `SELECT * FROM t1 ORDER BY ISNULL(name) DESC, name DESC;` | | `SELECT * FROM t1 ORDER BY name ASC NULLS LAST;` | `SELECT * FROM t1 ORDER BY ISNULL(name), name;` | From fe5adcd4aadb504d64de1c45e785d41262d30d7d Mon Sep 17 00:00:00 2001 From: xixirangrang <35301108+hfxsd@users.noreply.github.com> Date: Fri, 30 Sep 2022 16:32:00 +0800 Subject: [PATCH 15/18] Update oracle-functions-to-tidb.md --- oracle-functions-to-tidb.md | 6 +++--- 1 file changed, 3 insertions(+), 3 deletions(-) diff --git a/oracle-functions-to-tidb.md b/oracle-functions-to-tidb.md index 8d25c71727211..8748e836a1068 100644 --- a/oracle-functions-to-tidb.md +++ b/oracle-functions-to-tidb.md @@ -42,7 +42,7 @@ The following table shows the mappings between some Oracle and TiDB functions. | Get the position of a substring | `INSTR('stst','s',1,2)` | `LENGTH(SUBSTRING_INDEX('stst','s',2)) + 1` | Search from the first character of `'stst'` and return the position of the second occurrence of `'s'`. | | Get the position of a substring | `INSTR('abcabc','b',2,1)` | `LOCATE('b','abcabc',2)` | Search from the second character of `abcabc` and return the position of the first occurrence of `b`. | | Concatenate values of a column | `LISTAGG(CONCAT(E.dimensionid,'---',E.DIMENSIONNAME),'***') within GROUP(ORDER BY DIMENSIONNAME)` | `GROUP_CONCAT(CONCAT(E.dimensionid,'---',E.DIMENSIONNAME) ORDER BY DIMENSIONNAME SEPARATOR '***')` | Concatenate values of a specified column to one row with the `***` delimiter. | -| Convert a ASCII code to character | `CHR(n)` | `CHAR(n)` | The tab (`CHR(9)`), line feed (`CHR(10)`), and carriage return (`CHR(13)`) characters in Oracle correspond to `CHAR(9)`, `CHAR(10)`, and `CHAR(13)` in TiDB. | +| Convert an ASCII code to character | `CHR(n)` | `CHAR(n)` | The tab (`CHR(9)`), line feed (`CHR(10)`), and carriage return (`CHR(13)`) characters in Oracle correspond to `CHAR(9)`, `CHAR(10)`, and `CHAR(13)` in TiDB. | ## Syntax differences @@ -62,7 +62,7 @@ TiDB distinguishes between `NULL` and an empty string `''`. ### Read and write to the same table in an `INSERT` statement -Oracle supports reading and writing to the same table in a `INSERT` statement. For example: +Oracle supports reading and writing to the same table in an `INSERT` statement. For example: ```sql INSERT INTO table1 VALUES (feild1,(SELECT feild2 FROM table1 WHERE...)) @@ -80,7 +80,7 @@ In Oracle, to get the first n rows from a query, you can use the `ROWNUM <= n` c In TiDB, to get the first n rows from a query, you can use the `LIMIT n` clause. For example `LIMIT 10`. The Hibernate Query Language (HQL) running SQL statements with `LIMIT` results in an error. You need to change the Hibernate statements to SQL statements. -### Update multiple tables in a `UPDATE` statement +### Update multiple tables in an `UPDATE` statement In Oracle, it is not necessary to list the specific field update relationship when updating multiple tables. For example: From 34e0a37abb7301555e862819c9eb28818e1bdd3e Mon Sep 17 00:00:00 2001 From: aolin Date: Fri, 30 Sep 2022 20:57:11 +0800 Subject: [PATCH 16/18] review --- functions-and-operators/string-functions.md | 4 +++ oracle-functions-to-tidb.md | 38 ++++++++++----------- 2 files changed, 23 insertions(+), 19 deletions(-) diff --git a/functions-and-operators/string-functions.md b/functions-and-operators/string-functions.md index e79c25a80ab87..6f4f5aac493dd 100644 --- a/functions-and-operators/string-functions.md +++ b/functions-and-operators/string-functions.md @@ -7,8 +7,12 @@ summary: Learn about the string functions in TiDB. TiDB supports most of the [string functions](https://dev.mysql.com/doc/refman/5.7/en/string-functions.html) available in MySQL 5.7 and some of the [functions](https://docs.oracle.com/en/database/oracle/oracle-database/21/sqlqr/SQL-Functions.html#GUID-93EC62F8-415D-4A7E-B050-5D5B2C127009) available in Oracle 21. + + For mappings between functions and syntax of Oracle and TiDB, see [Mappings between Functions and Syntax of Oracle and TiDB](/oracle-functions-to-tidb.md). + + ## Supported functions | Name | Description | diff --git a/oracle-functions-to-tidb.md b/oracle-functions-to-tidb.md index 8748e836a1068..421cf66ef88cd 100644 --- a/oracle-functions-to-tidb.md +++ b/oracle-functions-to-tidb.md @@ -1,19 +1,19 @@ --- -title: Mappings between Functions and Syntax of Oracle and TiDB -summary: Learn the mappings between functions and syntax of Oracle and TiDB. +title: Comparisons between Functions and Syntax of Oracle and TiDB +summary: Learn the comparisons between functions and syntax of Oracle and TiDB. --- -# Mappings between Functions and Syntax of Oracle and TiDB +# Comparisons between Functions and Syntax of Oracle and TiDB -This document describes the mappings between functions and syntax of Oracle and TiDB. It helps you find the corresponding TiDB functions based on the Oracle functions, and understand the syntax differences between Oracle and TiDB. +This document describes the comparisons between functions and syntax of Oracle and TiDB. It helps you find the corresponding TiDB functions based on the Oracle functions, and understand the syntax differences between Oracle and TiDB. > **Note:** > > The functions and syntax in this document are based on Oracle 12.2.0.1.0 and TiDB v5.4.0. They might be different in other versions. -## Mappings between some Oracle and TiDB functions +## Comparisons of functions -The following table shows the mappings between some Oracle and TiDB functions. +The following table shows the comparisons between some Oracle and TiDB functions. | Function | Oracle syntax | TiDB syntax | Note | |---|---|---|---| @@ -23,36 +23,36 @@ The following table shows the mappings between some Oracle and TiDB functions. | Get the current system time in second precision | `SYSDATE` | `NOW()` | | | Get the current system time in microsecond precision | `SYSTIMESTAMP` | `CURRENT_TIMESTAMP(6)` | | | Get the number of days between two dates | `date1 - date2` | `DATEDIFF(date1, date2)` | | -| Get the number of months between two dates | `MONTHS_BETWEEN(ENDDATE,SYSDATE)` | `TIMESTAMPDIFF(MONTH,SYSDATE,ENDDATE)` | The results of `MONTHS_BETWEEN()` in Oracle and `TIMESTAMPDIFF()` in TiDB are different. `TIMESTAMPDIFF()` keeps months only in integer. Note that the parameters in the two functions are in opposite positions. | +| Get the number of months between two dates | `MONTHS_BETWEEN(ENDDATE,SYSDATE)` | `TIMESTAMPDIFF(MONTH,SYSDATE,ENDDATE)` | The results of `MONTHS_BETWEEN()` in Oracle and `TIMESTAMPDIFF()` in TiDB are different. `TIMESTAMPDIFF()` returns an integer. Note that the parameters in the two functions are swapped. | | Add `n` days to a date | `DATEVAL + n` | `DATE_ADD(dateVal,INTERVAL n DAY)` | `n` can be a negative value.| | Add `n` months to a date | `ADD_MONTHS(dateVal,n)`| `DATE_ADD(dateVal,INTERVAL n MONTH)` | `n` can be a negative value. | | Get the day of a date | `TRUNC(SYSDATE)` |
  • `CAST(NOW() AS DATE)`
  • `DATE_FORMAT(NOW(),'%Y-%m-%d')`
  • | In TiDB, `CAST` and `DATE_FORMAT` return the same result. | | Get the month of a date | `TRUNC(SYSDATE,'mm')` | `DATE_ADD(CURDATE(),interval - day(CURDATE()) + 1 day)` | | -| Truncate a value | `TRUNC(2.136) = 2`
    `TRUNC(2.136,2) = 2.13` | `TRUNCATE(2.136,0) = 2`
    `TRUNCATE(2.136,2) = 2.13` | Data precision is preserved. Truncate the corresponding decimal places without rounding. | +| Truncate a value | `TRUNC(2.136) = 2`
    `TRUNC(2.136,2) = 2.13` | `TRUNCATE(2.136,0) = 2`
    `TRUNCATE(2.136,2) = 2.13` | Data precision is preserved. Truncate the corresponding decimal places without rounding. | | Get the next value in a sequence | `sequence_name.NEXTVAL` | `NEXTVAL(sequence_name)` | | -| Left join or right join | `SELECT * FROM a, b WHERE a.id = b.id(+);`
    `SELECT * FROM a, b WHERE a.id(+) = b.id;` | `SELECT * FROM a LEFT JOIN b ON a.id = b.id;`
    `SELECT * FROM a RIGHT JOIN b ON a.id = b.id;` | When correlating queries, TiDB does not support using (+) to left join or right join. You can use `LEFT JOIN` or `RIGHT JOIN` instead. | -| Get a random sequence value | `SYS_GUID()` | `UUID()` | TiDB returns a Universal Unique Identifier (UUID).| -| `NVL()` | `NVL(key,val)` | `IFNULL(key,val)` | If the value of the field is `NULL`, it returns the value of `val`; otherwise, it returns the value of the field. | -| `NVL2()` | `NVL2(key, val1, val2)` | `IF(key is NULL, val1, val2)` | If the value of the field is not `NULL`, it returns the value of `val1`; otherwise, it returns the value of `val2`. | -| `DECODE()` |
  • `DECODE(key,val1,val2,val3)`
  • `DECODE(value,if1,val1,if2,val2,...,ifn,valn,val)`
  • |
  • `IF(key=val1,val2,val3)`
  • `CASE WHEN value=if1 THEN val1 WHEN value=if2 THEN val2,...,WHEN value=ifn THEN valn ELSE val END`
  • |
  • If the value of the field is equal to val1, then it returns val2; otherwise it returns val3.
  • When the field value satisfies condition 1 (if1), it returns val1. When it satisfies condition 2 (if2), it returns val2. When it satisfies condition 3 (if3), it returns val3.
  • | -| Concatenating the string `a` and `b` | 'a' \|\| 'b' | `CONCAT('a','b')` | | +| Get a random sequence value | `SYS_GUID()` | `UUID()` | TiDB returns a Universal Unique Identifier (UUID). | +| Left join or right join | `SELECT * FROM a, b WHERE a.id = b.id(+);`
    `SELECT * FROM a, b WHERE a.id(+) = b.id;` | `SELECT * FROM a LEFT JOIN b ON a.id = b.id;`
    `SELECT * FROM a RIGHT JOIN b ON a.id = b.id;` | In a correlated query, TiDB does not support using (+) to left join or right join. You can use `LEFT JOIN` or `RIGHT JOIN` instead. | +| `NVL()` | `NVL(key,val)` | `IFNULL(key,val)` | If the value of the field is `NULL`, it returns `val`; otherwise, it returns the value of the field. | +| `NVL2()` | `NVL2(key, val1, val2)` | `IF(key is NULL, val1, val2)` | If the value of the field is not `NULL`, it returns `val1`; otherwise, it returns `val2`. | +| `DECODE()` |
  • `DECODE(key,val1,val2,val3)`
  • `DECODE(value,if1,val1,if2,val2,...,ifn,valn,val)`
  • |
  • `IF(key=val1,val2,val3)`
  • `CASE WHEN value=if1 THEN val1 WHEN value=if2 THEN val2,...,WHEN value=ifn THEN valn ELSE val END`
  • |
  • If the value of the field is `val1`, then it returns `val2`; otherwise it returns `val3`.
  • When the value of the field satisfies condition 1 (`if1`), it returns `val1`. When it satisfies condition 2 (`if2`), it returns `val2`. When it satisfies condition 3 (`if3`), it returns `val3`.
  • | +| Concatenate the string `a` and `b` | 'a' \|\| 'b' | `CONCAT('a','b')` | | | Get the length of a string | `LENGTH(str)` | `CHAR_LENGTH(str)` | | -| Get the substring as specified | `SUBSTR('abcdefg',0,2) = 'ab'`
    `SUBSTR('abcdefg',1,2) = 'ab'` | `SUBSTRING('abcdefg',0,2) = ''`
    `SUBSTRING('abcdefg',1,2) = 'ab'` |
  • In Oracle, the starting position 0 has the same effect as 1.
  • In TiDB, the starting position 0 returns an empty string. If you need to start from the beginning of the string, the starting position should be 1.
  • | +| Get the substring as specified | `SUBSTR('abcdefg',0,2) = 'ab'`
    `SUBSTR('abcdefg',1,2) = 'ab'` | `SUBSTRING('abcdefg',0,2) = ''`
    `SUBSTRING('abcdefg',1,2) = 'ab'` |
  • In Oracle, the starting position 0 has the same effect as 1.
  • In TiDB, the starting position 0 returns an empty string. If you want to get a substring from the beginning, the starting position should be 1.
  • | | Get the position of a substring | `INSTR('abcdefg','b',1,1)` | `INSTR('abcdefg','b')` | Search from the first character of `'abcdefg'` and return the position of the first occurrence of `'b'`. | | Get the position of a substring | `INSTR('stst','s',1,2)` | `LENGTH(SUBSTRING_INDEX('stst','s',2)) + 1` | Search from the first character of `'stst'` and return the position of the second occurrence of `'s'`. | | Get the position of a substring | `INSTR('abcabc','b',2,1)` | `LOCATE('b','abcabc',2)` | Search from the second character of `abcabc` and return the position of the first occurrence of `b`. | | Concatenate values of a column | `LISTAGG(CONCAT(E.dimensionid,'---',E.DIMENSIONNAME),'***') within GROUP(ORDER BY DIMENSIONNAME)` | `GROUP_CONCAT(CONCAT(E.dimensionid,'---',E.DIMENSIONNAME) ORDER BY DIMENSIONNAME SEPARATOR '***')` | Concatenate values of a specified column to one row with the `***` delimiter. | -| Convert an ASCII code to character | `CHR(n)` | `CHAR(n)` | The tab (`CHR(9)`), line feed (`CHR(10)`), and carriage return (`CHR(13)`) characters in Oracle correspond to `CHAR(9)`, `CHAR(10)`, and `CHAR(13)` in TiDB. | +| Convert an ASCII code to a character | `CHR(n)` | `CHAR(n)` | The Tab (`CHR(9)`), LF (`CHR(10)`), and CR (`CHR(13)`) characters in Oracle correspond to `CHAR(9)`, `CHAR(10)`, and `CHAR(13)` in TiDB. | -## Syntax differences +## Comparisons of syntax This section describes some syntax differences between Oracle and TiDB. ### String syntax -In Oracle, a string can only be enclosed in single quotes (''). For example `'a'` +In Oracle, a string can only be enclosed in single quotes (''). For example `'a'`. -In TiDB, a string can be enclosed in single quotes ('') or double quotes (""). For example, `'a'` and `"a"` +In TiDB, a string can be enclosed in single quotes ('') or double quotes (""). For example, `'a'` and `"a"`. ### Difference between `NULL` and an empty string From c10c1281b0d5a194316308ae09e0468c121e5de1 Mon Sep 17 00:00:00 2001 From: Aolin Date: Fri, 30 Sep 2022 21:21:49 +0800 Subject: [PATCH 17/18] Apply suggestions from code review --- TOC.md | 2 +- functions-and-operators/string-functions.md | 2 +- 2 files changed, 2 insertions(+), 2 deletions(-) diff --git a/TOC.md b/TOC.md index 79688373bdef5..24ea588889ad4 100644 --- a/TOC.md +++ b/TOC.md @@ -624,7 +624,7 @@ - [Set Operations](/functions-and-operators/set-operators.md) - [List of Expressions for Pushdown](/functions-and-operators/expressions-pushed-down.md) - [TiDB Specific Functions](/functions-and-operators/tidb-functions.md) - - [Mappings between Functions and Syntax of Oracle and TiDB](/oracle-functions-to-tidb.md) + - [Comparisons between Functions and Syntax of Oracle and TiDB](/oracle-functions-to-tidb.md) - [Clustered Indexes](/clustered-indexes.md) - [Constraints](/constraints.md) - [Generated Columns](/generated-columns.md) diff --git a/functions-and-operators/string-functions.md b/functions-and-operators/string-functions.md index 6f4f5aac493dd..f0aa8c30b3521 100644 --- a/functions-and-operators/string-functions.md +++ b/functions-and-operators/string-functions.md @@ -9,7 +9,7 @@ TiDB supports most of the [string functions](https://dev.mysql.com/doc/refman/5. -For mappings between functions and syntax of Oracle and TiDB, see [Mappings between Functions and Syntax of Oracle and TiDB](/oracle-functions-to-tidb.md). +For comparisons between functions and syntax of Oracle and TiDB, see [Mappings between Functions and Syntax of Oracle and TiDB](/oracle-functions-to-tidb.md). From c9febc7c5db4a62b1c26998d77b94718b51ea8a4 Mon Sep 17 00:00:00 2001 From: xixirangrang Date: Fri, 30 Sep 2022 21:22:34 +0800 Subject: [PATCH 18/18] Update functions-and-operators/string-functions.md --- functions-and-operators/string-functions.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/functions-and-operators/string-functions.md b/functions-and-operators/string-functions.md index f0aa8c30b3521..87c905f1be255 100644 --- a/functions-and-operators/string-functions.md +++ b/functions-and-operators/string-functions.md @@ -9,7 +9,7 @@ TiDB supports most of the [string functions](https://dev.mysql.com/doc/refman/5. -For comparisons between functions and syntax of Oracle and TiDB, see [Mappings between Functions and Syntax of Oracle and TiDB](/oracle-functions-to-tidb.md). +For comparisons between functions and syntax of Oracle and TiDB, see [Comparisons between Functions and Syntax of Oracle and TiDB](/oracle-functions-to-tidb.md).