Skip to content

Commit 896fe0c

Browse files
committed
PS-10187 [DOCS] - Binary Log UDFs functions documentation incomplete 8.0
modified: docs/binlogging-replication-improvements.md
1 parent 241e3bf commit 896fe0c

File tree

1 file changed

+144
-43
lines changed

1 file changed

+144
-43
lines changed

docs/binlogging-replication-improvements.md

Lines changed: 144 additions & 43 deletions
Original file line numberDiff line numberDiff line change
@@ -118,27 +118,66 @@ SET binlog_ddl_skip_rewrite = ON;
118118
/*comment at start*/DROP TABLE t /*comment at end*/;
119119
```
120120

121-
## Binary log user defined functions
121+
## Binary log user-defined functions
122122

123-
To implement Point in Time recovery, we have added the `binlog_utils_udf`. The following user-defined functions are included:
123+
To implement Point in Time recovery, we have added the `binlog_utils_udf` plugin. These functions help you locate specific transactions in binary logs and determine which binary log files contain particular GTIDs, which is essential for precise point-in-time recovery operations.
124124

125-
| Name | Returns | Description |
126-
| --- | --- | --- |
127-
| get_binlog_by_gtid() | Binlog file name as STRING | Returns the binlog file name that contains the specified GTID |
128-
| get_last_gtid_from_binlog() | GTID as STRING | Returns the last GTID found in the specified binlog |
129-
| get_gtid_set_by_binlog() | GTID set as STRING | Returns all GTIDs found in the specified binlog |
130-
| get_binlog_by_gtid_set() | Binlog file name as STRING | Returns the file name of the binlog which contains at least one GTID from the specified set. |
131-
| get_first_record_timestamp_by_binlog() | Timestamp as INTEGER | Returns the timestamp of the first event in the specified binlog |
132-
| get_last_record_timestamp_by_binlog() | Timestamp as INTEGER | Returns the timestamp of the last event in the specified binlog |
125+
### Prerequisites
126+
127+
Before using these functions, ensure that:
128+
129+
* Binary logging is enabled on your MySQL server
130+
* You have the `SYSTEM_VARIABLES_ADMIN` and `SERVICE_CONNECTION_ADMIN` privileges to install plugins
131+
* You have read access to the binary log directory
132+
* GTID-based replication is configured (for GTID-related functions)
133+
134+
### Installation
135+
136+
Before using the user-defined functions, you must install the plugin:
137+
138+
```{.bash data-prompt="mysql>"}
139+
mysql> INSTALL PLUGIN binlog_utils_udf SONAME 'binlog_utils_udf.so';
140+
```
141+
142+
After installation, you can verify the plugin is loaded by checking the `INFORMATION_SCHEMA.PLUGINS` table:
143+
144+
```{.bash data-prompt="mysql>"}
145+
mysql> SELECT PLUGIN_NAME, PLUGIN_STATUS FROM INFORMATION_SCHEMA.PLUGINS WHERE PLUGIN_NAME = 'binlog_utils_udf';
146+
```
147+
148+
### Understanding GTIDs
149+
150+
A Global Transaction Identifier (GTID) is a unique identifier for each transaction in a MySQL replication setup. GTIDs help ensure data consistency and enable precise point-in-time recovery. GTIDs follow the format `source_id:transaction_id`, where `source_id` is the server's UUID and `transaction_id` is a sequence number.
151+
152+
When using these user-defined functions, you must use CAST to return a result. For example:
153+
154+
```{.bash data-prompt="mysql>"}
155+
mysql> SELECT CAST(get_last_gtid_from_binlog("binlog.0001") AS CHAR) as result;
156+
```
157+
158+
### Available functions
159+
160+
The following user-defined functions are included:
161+
162+
| Name | Returns | Description | Use Case |
163+
| --- | --- | --- | --- |
164+
| [get_binlog_by_gtid()](#get_binlog_by_gtid) | Binlog file name as STRING | Returns the binlog file name that contains the specified GTID | Find which binary log file contains a specific transaction |
165+
| [get_last_gtid_from_binlog()](#get_last_gtid_from_binlog) | GTID as STRING | Returns the last GTID found in the specified binlog | Determine the most recent transaction in a binary log file |
166+
| [get_gtid_set_by_binlog()](#get_gtid_set_by_binlog) | GTID set as STRING | Returns all GTIDs found in the specified binlog | Get a complete list of transactions in a binary log file |
167+
| [get_binlog_by_gtid_set()](#get_binlog_by_gtid_set) | Binlog file name as STRING | Returns the file name of the binlog which contains at least one GTID from the specified set | Find binary log files containing any of the specified transactions |
168+
| [get_first_record_timestamp_by_binlog()](#get_first_record_timestamp_by_binlog) | Timestamp as INTEGER | Returns the timestamp of the first event in the specified binlog | Determine when a binary log file was first created |
169+
| [get_last_record_timestamp_by_binlog()](#get_last_record_timestamp_by_binlog) | Timestamp as INTEGER | Returns the timestamp of the last event in the specified binlog | Determine when the last transaction was written to a binary log file |
133170

134171
!!! note
135172

136173
All functions returning timestamps return their values as microsecond precision UNIX time. In other words, they represent the number of microseconds since 1-JAN-1970.
137174

138-
All functions accepting a binlog name as the parameter accepts only short names, without a path component. If the path separator (‘/’) is found in the input, an error is returned. This serves the purpose of restricting the locations from where binlogs can be read. They are always read from the current binlog directory ([@@log_bin_basename system variable](https://dev.mysql.com/doc/refman/8.0/en/replication-options-binary-log.html#sysvar_log_bin_basename)).
175+
All functions accepting a binlog name as a parameter accept only short names, without a path component. If the path separator ('/') is found in the input, an error is returned. This restriction serves the purpose of limiting the locations from which binlogs can be read. They are always read from the current binlog directory ([@@log_bin_basename system variable](https://dev.mysql.com/doc/refman/8.0/en/replication-options-binary-log.html#sysvar_log_bin_basename)).
139176

140177
All functions returning binlog file names return the name in short form, without a path component.
141178

179+
#### get_binlog_by_gtid
180+
142181
The basic syntax for `get_binlog_by_gtid()` is the following:
143182

144183
* get_binlog_by_gtid(string) [AS] alias
@@ -147,9 +186,9 @@ Usage: SELECT get_binlog_by_gtid(string) [AS] alias
147186

148187
Example:
149188

150-
```sql
151-
CREATE FUNCTION get_binlog_by_gtid RETURNS STRING SONAME 'binlog_utils_udf.so';
152-
SELECT get_binlog_by_gtid("F6F54186-8495-47B3-8D9F-011DDB1B65B3:1") AS result;
189+
```{.bash data-prompt="mysql>"}
190+
mysql> CREATE FUNCTION get_binlog_by_gtid RETURNS STRING SONAME 'binlog_utils_udf.so';
191+
mysql> SELECT CAST(get_binlog_by_gtid("F6F54186-8495-47B3-8D9F-011DDB1B65B3:1") AS CHAR) AS result;
153192
```
154193
??? example "Expected output"
155194

@@ -161,10 +200,12 @@ SELECT get_binlog_by_gtid("F6F54186-8495-47B3-8D9F-011DDB1B65B3:1") AS result;
161200
+--------------+
162201
```
163202

164-
```sql
165-
DROP FUNCTION get_binlog_by_gtid;
203+
```{.bash data-prompt="mysql>"}
204+
mysql> DROP FUNCTION get_binlog_by_gtid;
166205
```
167206

207+
#### get_last_gtid_from_binlog
208+
168209
The basic syntax for `get_last_gtid_from_binlog()` is the following:
169210

170211
* get_last_gtid_from_binlog(string) [AS] alias
@@ -173,9 +214,9 @@ Usage: SELECT get_last_gtid_from_binlog(string) [AS] alias
173214

174215
For example:
175216

176-
```sql
177-
CREATE FUNCTION get_last_gtid_from_binlog RETURNS STRING SONAME 'binlog_utils_udf.so';
178-
SELECT get_last_gtid_from_binlog("binlog.00001") AS result;
217+
```{.bash data-prompt="mysql>"}
218+
mysql> CREATE FUNCTION get_last_gtid_from_binlog RETURNS STRING SONAME 'binlog_utils_udf.so';
219+
mysql> SELECT CAST(get_last_gtid_from_binlog("binlog.00001") AS CHAR) AS result;
179220
```
180221

181222
??? example "Expected output"
@@ -188,10 +229,12 @@ SELECT get_last_gtid_from_binlog("binlog.00001") AS result;
188229
+-----------------------------------------+
189230
```
190231

191-
```sql
192-
DROP FUNCTION get_last_gtid_from_binlog;
232+
```{.bash data-prompt="mysql>"}
233+
mysql> DROP FUNCTION get_last_gtid_from_binlog;
193234
```
194235

236+
#### get_gtid_set_by_binlog
237+
195238
The basic syntax for `get_gtid_set_by_binlog()` is the following:
196239

197240
* get_gtid_set_by_binlog(string) [AS] alias
@@ -200,9 +243,9 @@ Usage: SELECT get_gtid_set_by_binlog(string) [AS] alias
200243

201244
For example:
202245

203-
```sql
204-
CREATE FUNCTION get_gtid_set_by_binlog RETURNS STRING SONAME 'binlog_utils_udf.so';
205-
SELECT get_gtid_set_by_binlog("binlog.00001") AS result;
246+
```{.bash data-prompt="mysql>"}
247+
mysql> CREATE FUNCTION get_gtid_set_by_binlog RETURNS STRING SONAME 'binlog_utils_udf.so';
248+
mysql> SELECT CAST(get_gtid_set_by_binlog("binlog.00001") AS CHAR) AS result;
206249
```
207250
??? example "Expected output"
208251

@@ -214,10 +257,12 @@ SELECT get_gtid_set_by_binlog("binlog.00001") AS result;
214257
+-------------------------+
215258
```
216259

217-
```sql
218-
DROP FUNCTION get_gtid_set_by_binlog;
260+
```{.bash data-prompt="mysql>"}
261+
mysql> DROP FUNCTION get_gtid_set_by_binlog;
219262
```
220263

264+
#### get_binlog_by_gtid_set
265+
221266
The basic syntax for `get_binlog_by_gtid_set()` is the following:
222267

223268

@@ -227,9 +272,9 @@ Usage: SELECT get_binlog_by_gtid_set(string) [AS] alias
227272

228273
Example:
229274

230-
```sql
231-
CREATE FUNCTION get_binlog_by_gtid_set RETURNS STRING SONAME 'binlog_utils_udf.so';
232-
SELECT get_binlog_by_gtid_set("11ea-b9a7:7,11ea-b9a7:8") AS result;
275+
```{.bash data-prompt="mysql>"}
276+
mysql> CREATE FUNCTION get_binlog_by_gtid_set RETURNS STRING SONAME 'binlog_utils_udf.so';
277+
mysql> SELECT CAST(get_binlog_by_gtid_set("11ea-b9a7:7,11ea-b9a7:8") AS CHAR) AS result;
233278
```
234279
??? example "Expected output"
235280

@@ -241,10 +286,12 @@ SELECT get_binlog_by_gtid_set("11ea-b9a7:7,11ea-b9a7:8") AS result;
241286
+---------------------------------------------------------------+
242287
```
243288

244-
```sql
245-
DROP FUNCTION get_binlog_by_gtid_set;
289+
```{.bash data-prompt="mysql>"}
290+
mysql> DROP FUNCTION get_binlog_by_gtid_set;
246291
```
247292

293+
#### get_first_record_timestamp_by_binlog
294+
248295
The basic syntax for `get_first_record_timestamp_by_binlog()` is the following:
249296

250297
* get_first_record_timestamp_by_binlog(TIMESTAMP) [AS] alias
@@ -253,9 +300,9 @@ Usage: SELECT get_first_record_timestamp_by_binlog(TIMESTAMP) [AS] alias
253300

254301
For example:
255302

256-
```sql
257-
CREATE FUNCTION get_first_record_timestamp_by_binlog RETURNS INTEGER SONAME 'binlog_utils_udf.so';
258-
SELECT FROM_UNIXTIME(get_first_record_timestamp_by_binlog("bin.00003") DIV 1000000) AS result;
303+
```{.bash data-prompt="mysql>"}
304+
mysql> CREATE FUNCTION get_first_record_timestamp_by_binlog RETURNS INTEGER SONAME 'binlog_utils_udf.so';
305+
mysql> SELECT FROM_UNIXTIME(CAST(get_first_record_timestamp_by_binlog("bin.00003") AS UNSIGNED) DIV 1000000) AS result;
259306
```
260307

261308
??? example "Expected output"
@@ -264,14 +311,16 @@ SELECT FROM_UNIXTIME(get_first_record_timestamp_by_binlog("bin.00003") DIV 10000
264311
+---------------------+
265312
| result |
266313
+=====================+
267-
| 2020-12-03 09:10:40 |
314+
| 2024-12-03 09:10:40 |
268315
+---------------------+
269316
```
270317

271-
```sql
272-
DROP FUNCTION get_first_record_timestamp_by_binlog;
318+
```{.bash data-prompt="mysql>"}
319+
mysql> DROP FUNCTION get_first_record_timestamp_by_binlog;
273320
```
274321

322+
#### get_last_record_timestamp_by_binlog
323+
275324
The basic syntax for `get_last_record_timestamp_by_binlog()` is the following:
276325

277326
* get_last_record_timestamp_by_binlog(TIMESTAMP) [AS] alias
@@ -280,9 +329,9 @@ Usage: SELECT get_last_record_timestamp_by_binlog(TIMESTAMP) [AS] alias
280329

281330
For example:
282331

283-
```sql
284-
CREATE FUNCTION get_last_record_timestamp_by_binlog RETURNS INTEGER SONAME 'binlog_utils_udf.so';
285-
SELECT FROM_UNIXTIME(get_last_record_timestamp_by_binlog("bin.00003") DIV 1000000) AS result;
332+
```{.bash data-prompt="mysql>"}
333+
mysql> CREATE FUNCTION get_last_record_timestamp_by_binlog RETURNS INTEGER SONAME 'binlog_utils_udf.so';
334+
mysql> SELECT FROM_UNIXTIME(CAST(get_last_record_timestamp_by_binlog("bin.00003") AS UNSIGNED) DIV 1000000) AS result;
286335
```
287336

288337
??? example "Expected output"
@@ -291,14 +340,66 @@ SELECT FROM_UNIXTIME(get_last_record_timestamp_by_binlog("bin.00003") DIV 100000
291340
+---------------------+
292341
| result |
293342
+=====================+
294-
| 2020-12-04 04:18:56 |
343+
| 2024-12-04 04:18:56 |
295344
+---------------------+
296345
```
297346

298-
```sql
299-
DROP FUNCTION get_last_record_timestamp_by_binlog;
347+
```{.bash data-prompt="mysql>"}
348+
mysql> DROP FUNCTION get_last_record_timestamp_by_binlog;
349+
```
350+
351+
### Troubleshooting
352+
353+
Common issues and solutions:
354+
355+
Function returns NULL or error:
356+
357+
* Ensure the binary log file exists in the current binlog directory
358+
359+
* Verify you have read permissions on the binary log files
360+
361+
* Check that the binary log file name is correct and does not include a path
362+
363+
Plugin installation fails:
364+
365+
* Verify you have the `SYSTEM_VARIABLES_ADMIN` and `SERVICE_CONNECTION_ADMIN` privileges
366+
367+
* Ensure the `binlog_utils_udf.so` file exists in the plugin directory
368+
369+
* Check that the plugin is compatible with your MySQL version
370+
371+
GTID format errors:
372+
373+
* Ensure GTIDs follow the correct format: `source_id:transaction_id`
374+
375+
* Verify that GTID-based replication is enabled on your server
376+
377+
Timestamp conversion issues:
378+
379+
* Remember that timestamps are returned in microseconds since Unix epoch
380+
381+
* Use `FROM_UNIXTIME()` with division by 1000000 to convert to readable format
382+
383+
Character set and display issues:
384+
385+
* UDFs developed before MySQL's UDF API character set enhancements used to not care about character set of STRING return values and it was always "binary"
386+
387+
* Oracle introduced the `--binary-as-hex` command line option and made it TRUE by default in interactive mode
388+
389+
* If you see unexpected hexadecimal output from UDF functions, start the mysql client with `--binary-as-hex=FALSE` or add this parameter to the client section of your MySQL config file
390+
391+
* The `--binary-as-hex=FALSE` option only affects how binary data is displayed in the output. You still need to use CAST operations (for example, `CAST(function_name() AS CHAR)`) for the UDF functions to work properly, regardless of this setting
392+
393+
### Uninstalling the plugin
394+
395+
To uninstall the `binlog_utils_udf` plugin, use the following command:
396+
397+
```{.bash data-prompt="mysql>"}
398+
mysql> UNINSTALL PLUGIN binlog_utils_udf;
300399
```
301400

401+
The plugin cannot be disabled without uninstalling. When uninstalled, all user-defined functions provided by the plugin are automatically removed and become unavailable.
402+
302403
## Limitations
303404

304405
For the following variables, do not define values with one or more dot (.) characters:

0 commit comments

Comments
 (0)