Skip to content

Commit 2171ef4

Browse files
authored
Merge pull request #365 from percona/ps-9342
PS-9342 8.4 - SEQUENCE_TABLE() -> PERCONA_SEQUENCE_TABLE() transition docum…
2 parents a46ba4e + bb4d73a commit 2171ef4

File tree

3 files changed

+248
-22
lines changed

3 files changed

+248
-22
lines changed

docs/percona-sequence-table.md

Lines changed: 188 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,188 @@
1+
# PERCONA_SEQUENCE_TABLE(n) function
2+
3+
Using the `PERCONA_SEQUENCE_TABLE()` function provides the following:
4+
5+
| Benefit | Description |
6+
|---------------------------|---------------------------------------------------------------------------------------------------|
7+
| Generates Sequences | Acts as an inline table-valued function that generates a sequence of numbers. |
8+
| Table-Valued Function | Unlike traditional scalar functions, `PERCONA_SEQUENCE_TABLE()` returns a virtual table with a single column named `value` containing the generated sequence. |
9+
| Simpler Syntax | Simplifies queries that need to generate predictable sequences of numbers. |
10+
| Flexibility | Allows dynamic definition of sequences within queries, offering more control compared to pre-defined tables for sequences. |
11+
| Predefined Sequence | Does not manage sequences like Oracle or PostgreSQL; instead, it allows definition and generation of sequences within a `SELECT` statement. |
12+
| Customization | Enables customization of starting value, increment/decrement amount, and number of values to generate. |
13+
14+
## Version update
15+
16+
Percona Server for MySQL 8.4 deprecated [`SEQUENCE_TABLE()`](sequence-table.md), and Percona may remove this function in a future release. We recommend that you use `PERCONA_SEQUENCE_TABLE()` instead.
17+
18+
To maintain compatibility with existing third-party software, `SEQUENCE_TABLE` is no longer a reserved term and can be used as a regular identifier.
19+
20+
## Table functions
21+
22+
The function is an inline table-valued function. This function creates a temporary table with multiple rows. You can use this function within a single SELECT statement. Oracle MySQL Server only has the `JSON_TABLE` table function. The Percona Server for MySQL has the `JSON_TABLE` and `PERCONA_SEQUENCE_TABLE()` table functions. A single SELECT statement generates a multi-row result set. In contrast, a scalar function (like [EXP(x)](https://dev.mysql.com/doc/refman/8.4/en/mathematical-functions.html#function_exp) or [LOWER(str)](https://dev.mysql.com/doc/refman/8.4/en/string-functions.html#function_lower) always returns a single value of a specific data type.
23+
24+
## Syntax
25+
26+
As with any [derived tables](https://dev.mysql.com/doc/refman/8.4/en/derived-tables.html), a table function requires an [alias](https://dev.mysql.com/doc/refman/8.4/en/identifiers.html) in the `SELECT` statement.
27+
28+
The result set is a single column with the predefined column name `value` of type `BIGINT UNSIGNED`. You can reference the `value` column in `SELECT` statements. The following statements are valid. Using `n` as the number of generated values, the following is the basic syntax:
29+
30+
### PERCONA_SEQUENCE_TABLE(n) [AS] alias
31+
32+
```{.text .no-copy}
33+
SELECT … FROM PERCONA_SEQUENCE_TABLE(n) [AS] alias
34+
35+
PERCONA_SEQUENCE_TABLE(n) [AS] alias
36+
```
37+
38+
```{.text .no-copy}
39+
SELECT * FROM PERCONA_SEQUENCE_TABLE(n) AS tt;
40+
SELECT <expr(value)> FROM PERCONA_SEQUENCE_TABLE(n) AS tt;
41+
```
42+
43+
The first number in the series, the initial term, is defined as `0`, and the series ends with a value less than `n`.
44+
45+
### Basic sequence generation
46+
47+
In this example, the following statement generates a sequence:
48+
49+
```{.bash data-prompt="mysql>"}
50+
mysql> SELECT * FROM PERCONA_SEQUENCE_TABLE(3) AS tt;
51+
```
52+
53+
??? example "Expected output"
54+
55+
```{.text .no-copy}
56+
+-------+
57+
| value |
58+
+-------+
59+
| 0 |
60+
| 1 |
61+
| 2 |
62+
+-------+
63+
```
64+
65+
### Start with a specific value
66+
67+
You can define the initial value using the `WHERE` clause. The following example starts the sequence with `4`.
68+
69+
```{.bash data-prompt="mysql>"}
70+
mysql> SELECT value AS result \
71+
FROM \
72+
(SELECT seq AS value
73+
FROM PERCONA_SEQUENCE_TABLE(8)) AS tt \
74+
WHERE value >= 4;
75+
```
76+
77+
??? example "Expected output"
78+
79+
```{.text .no-copy}
80+
+--------+
81+
| result |
82+
+--------+
83+
| 4 |
84+
| 5 |
85+
| 6 |
86+
| 7 |
87+
+--------+
88+
```
89+
90+
### Filter even numbers
91+
92+
Consecutive terms increase or decrease by a common difference. The default common difference value is `1`. However, it is possible to filter the results using the WHERE clause to simulate common differences greater than 1.
93+
94+
The following example prints only even numbers from the 0..7 range:
95+
96+
```{.bash data-prompt="mysql>"}
97+
mysql> SELECT value AS result \
98+
FROM PERCONA_SEQUENCE_TABLE(8) AS tt \
99+
WHERE value % 2 = 0;
100+
```
101+
102+
??? example "Expected output"
103+
104+
```{.text .no-copy}
105+
+--------+
106+
| result |
107+
+--------+
108+
| 0 |
109+
| 2 |
110+
| 4 |
111+
| 6 |
112+
+--------+
113+
```
114+
115+
### Generate random numbers
116+
117+
The following is an example of using the function to populate a table with a set of random numbers:
118+
119+
```{.bash data-prompt="mysql>"}
120+
mysql> SELECT FLOOR(RAND() * 100) AS result \
121+
FROM PERCONA_SEQUENCE_TABLE(4) AS tt;
122+
```
123+
124+
The output could be the following:
125+
126+
??? example "Expected output"
127+
128+
```{.text .no-copy}
129+
+--------+
130+
| result |
131+
+--------+
132+
| 24 |
133+
| 56 |
134+
| 70 |
135+
| 25 |
136+
+--------+
137+
```
138+
139+
### Generate random strings
140+
141+
You can populate a table with a set of pseudo-random strings with the following statement:
142+
143+
```{.bash data-prompt="mysql>"}
144+
mysql> SELECT MD5(value) AS result \
145+
FROM PERCONA_SEQUENCE_TABLE(4) AS tt;
146+
```
147+
148+
??? example "Expected output"
149+
150+
```{.text .no-copy}
151+
+----------------------------------+
152+
| result |
153+
+----------------------------------+
154+
| f17d9c990f40f8ac215f2ecdfd7d0451 |
155+
| 2e5751b7cfd7f053cd29e946fb2649a4 |
156+
| b026324c6904b2a9cb4b88d6d61c81d1 |
157+
| 26ab0db90d72e28ad0ba1e22ee510510 |
158+
+----------------------------------+
159+
```
160+
161+
### Add a sequence to a table
162+
163+
You can add the sequence as a column to a new table or an existing table, as shown in this example:
164+
165+
```{.bash data-prompt="mysql>"}
166+
mysql> CREATE TABLE t1 AS SELECT * FROM PERCONA_SEQUENCE_TABLE(4) AS tt;
167+
168+
mysql> SELECT * FROM t1;
169+
```
170+
171+
??? example "Expected output"
172+
173+
```{.text .no-copy}
174+
+-------+
175+
| value |
176+
+-------+
177+
| 0 |
178+
| 1 |
179+
| 2 |
180+
| 3 |
181+
+-------+
182+
```
183+
184+
Sequences are helpful for various purposes, such as populating tables and generating test data.
185+
186+
[`JSON_TABLE()`]: https://dev.mysql.com/doc/refman/8.4/en/json-table-functions.html
187+
188+
[SEQUENCE_TABLE()]: sequence-table.md

docs/sequence-table.md

Lines changed: 59 additions & 22 deletions
Original file line numberDiff line numberDiff line change
@@ -1,41 +1,65 @@
11
# SEQUENCE_TABLE(n) function
22

3-
Percona Server for MySQL supports the SEQUENCE_TABLE() function.
3+
Using `SEQUENCE_TABLE()` function provides the following:
44

5-
A sequence of numbers can be defined as an arithmetic progression when the common difference between two consecutive terms is always the same.
5+
| Benefit | Description |
6+
|---------------------------|---------------------------------------------------------------------------------------------------|
7+
| Generates Sequences | Acts as an inline table-valued function that generates a sequence of numbers. |
8+
| Table-Valued Function | Unlike traditional scalar functions, `SEQUENCE_TABLE()` returns a virtual table with a single column named `value` containing the generated sequence. |
9+
| Simpler Syntax | Simplifies queries that need to generate predictable sequences of numbers. |
10+
| Flexibility | Allows dynamic definition of sequences within queries, offering more control compared to pre-defined tables for sequences. |
11+
| Predefined Sequence | Does not manage sequences like Oracle or PostgreSQL; instead, it allows definition and generation of sequences within a `SELECT` statement. |
12+
| Customization | Enables customization of starting value, increment/decrement amount, and number of values to generate. |
613

7-
The function is an inline table-valued function. A single SELECT statement generates a multi-row result set. In contrast, a scalar function (like [EXP(x)](https://dev.mysql.com/doc/refman/{{vers}}/en/mathematical-functions.html#function_exp) or [LOWER(str)](https://dev.mysql.com/doc/refman/{{vers}}/en/string-functions.html#function_lower) always returns a single value of a specific data type.
14+
## Version update
815

9-
The [JSON_TABLE()](https://dev.mysql.com/doc/refman/{{vers}}/en/json-table-functions.html) is the only table function available in Oracle MySQL Server. `JSON_TABLE` and `SEQUENCE_TABLE()` are the only table functions available in Percona Server.
16+
Percona Server for MySQL 8.4 deprecated `SEQUENCE_TABLE()`, and this function can be removed in a future release. We recommend that you use [`PERCONA_SEQUENCE_TABLE()`](percona-sequence-table.md) instead.
1017

11-
The basic syntax is the following:
18+
To maintain compatibility with existing third-party software, `SEQUENCE_TABLE` is no longer a reserved term and can be used as a regular identifier.
19+
20+
## Table functions
21+
22+
The function is an inline table-valued function. This function creates a temporary table with multiple rows. You can use this function within a single SELECT statement. Oracle MySQL Server only has the `JSON_TABLE` table function. The Percona Server for MySQL has the `JSON_TABLE` and `SEQUENCE_TABLE()` table functions. A single SELECT statement generates a multi-row result set. In contrast, a scalar function (like [EXP(x)](https://dev.mysql.com/doc/refman/8.4/en/mathematical-functions.html#function_exp) or [LOWER(str)](https://dev.mysql.com/doc/refman/8.4/en/string-functions.html#function_lower) always returns a single value of a specific data type.
23+
24+
## Syntax
25+
26+
As with any [derived tables](https://dev.mysql.com/doc/refman/8.4/en/derived-tables.html), a table function requires an [alias](https://dev.mysql.com/doc/refman/8.4/en/identifiers.html) in the `SELECT` statement.
27+
28+
The result set is a single column with the predefined column name `value` of type `BIGINT UNSIGNED`. You can reference the `value` column in `SELECT` statements. The following statements are valid. Using `n` as the number of generated values, the following is the basic syntax:
1229

1330
* SEQUENCE_TABLE(n) [AS] alias
1431

15-
## Usage
1632

17-
??? example "Expected output"
33+
```{.text .no-copy}
34+
SELECT … FROM SEQUENCE_TABLE(n) [AS] alias
1835
19-
```{.text .no-copy}
20-
SELECT … FROM SEQUENCE_TABLE(n) [AS] alias
36+
SEQUENCE_TABLE(n) [AS] alias
37+
```
2138

22-
SEQUENCE_TABLE(n>) [AS] alias
23-
```
39+
```sql
40+
SELECT * FROM SEQUENCE_TABLE(n) AS tt;
41+
SELECT <expr(value)> FROM SEQUENCE_TABLE(n) AS tt;
42+
```
43+
44+
The first number in the series, the initial term, is defined as `0`, and the series ends with a value less than `n`.
2445

25-
`n:` The number of generated values.
46+
## Example usage
2647

27-
As with any [derived tables](https://dev.mysql.com/doc/refman/{{vers}}/en/derived-tables.html), a table function requires an [alias](https://dev.mysql.com/doc/refman/{{vers}}/en/identifiers.html) in the `SELECT` statement.
48+
Using `SEQUENCE_TABLE()`:
2849

29-
The result set is a single column with the predefined column name `value` of type `BIGINT UNSIGNED`. You can reference the `value` column in `SELECT` statements.
50+
```{.bash data-prompt="mysql>"}
51+
mysql> SELECT * FROM SEQUENCE_TABLE(5)) AS sequence_data;
52+
```
3053

31-
The following statements are valid:
54+
Using `PERCONA_SEQUENCE_TABLE()`:
3255

3356
```{.bash data-prompt="mysql>"}
34-
mysql> SELECT * FROM SEQUENCE_TABLE(n) AS tt;
35-
mysql> SELECT <expr(value)> FROM SEQUENCE_TABLE(n) AS tt;
57+
mysql> SELECT * FROM PERCONA_SEQUENCE_TABLE(5)) AS sequence_data;
3658
```
3759

38-
The first number in the series, the initial term, is defined as `0` and the series ends with a value less than `n`. In this example, enter the following statement to generate a sequence:
60+
### Basic sequence generation
61+
62+
In this example, the following statement generates a sequence:
3963

4064
```{.bash data-prompt="mysql>"}
4165
mysql> SELECT * FROM SEQUENCE_TABLE(3) AS tt;
@@ -53,9 +77,11 @@ mysql> SELECT * FROM SEQUENCE_TABLE(3) AS tt;
5377
+-------+
5478
```
5579

56-
You can define the initial term using the `WHERE` clause. The following example starts the sequence with `4`.
80+
### Start with a specific value
5781

58-
```{.bash data-prompt="mysql>"}
82+
You can define the initial value using the `WHERE` clause. The following example starts the sequence with `4`.
83+
84+
```sql
5985
SELECT value AS result FROM SEQUENCE_TABLE(8) AS tt WHERE value >= 4;
6086
```
6187

@@ -72,11 +98,13 @@ SELECT value AS result FROM SEQUENCE_TABLE(8) AS tt WHERE value >= 4;
7298
+--------+
7399
```
74100

101+
### Filter even numbers
102+
75103
Consecutive terms increase or decrease by a common difference. The default common difference value is `1`. However, it is possible to filter the results using the WHERE clause to simulate common differences greater than 1.
76104

77105
The following example prints only even numbers from the 0..7 range:
78106

79-
```{.bash data-prompt="mysql>"}
107+
```sql
80108
SELECT value AS result FROM SEQUENCE_TABLE(8) AS tt WHERE value % 2 = 0;
81109
```
82110

@@ -93,6 +121,8 @@ SELECT value AS result FROM SEQUENCE_TABLE(8) AS tt WHERE value % 2 = 0;
93121
+--------+
94122
```
95123

124+
### Generate random numbers
125+
96126
The following is an example of using the function to populate a table with a set of random numbers:
97127

98128
```{.bash data-prompt="mysql>"}
@@ -114,6 +144,8 @@ The output could be the following:
114144
+--------+
115145
```
116146

147+
### Generate random strings
148+
117149
You can populate a table with a set of pseudo-random strings with the following statement:
118150

119151
```{.bash data-prompt="mysql>"}
@@ -133,6 +165,8 @@ mysql> SELECT MD5(value) AS result FROM SEQUENCE_TABLE(4) AS tt;
133165
+----------------------------------+
134166
```
135167

168+
### Add a sequence to a table
169+
136170
You can add the sequence as a column to a new table or an existing table, as shown in this example:
137171

138172
```{.bash data-prompt="mysql>"}
@@ -154,4 +188,7 @@ mysql> SELECT * FROM t1;
154188
+-------+
155189
```
156190

157-
There are many uses for a sequence when populating tables.
191+
Sequences are helpful for various purposes, such as populating tables and generating test data.
192+
193+
[`JSON_TABLE()`]: https://dev.mysql.com/doc/refman/8.4/en/json-table-functions.html
194+
[`PERCONA_SEQUENCE_TABLE()`]: percona-sequence-table.md

mkdocs-base.yml

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -173,6 +173,7 @@ nav:
173173
- extended-select-into-outfile.md
174174
- innodb-expanded-fast-index-creation.md
175175
- kill-idle-trx.md
176+
- percona-sequence-table.md
176177
- procfs-plugin.md
177178
- proxy-protocol-support.md
178179
- sequence-table.md

0 commit comments

Comments
 (0)