You signed in with another tab or window. Reload to refresh your session.You signed out in another tab or window. Reload to refresh your session.You switched accounts on another tab or window. Reload to refresh your session.Dismiss alert
@@ -118,27 +118,66 @@ SET binlog_ddl_skip_rewrite = ON;
118
118
/*comment at start*/DROPTABLEt/*comment at end*/;
119
119
```
120
120
121
-
## Binary log userdefined functions
121
+
## Binary log user-defined functions
122
122
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.
124
124
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:
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 |
133
170
134
171
!!! note
135
172
136
173
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.
137
174
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)).
139
176
140
177
All functions returning binlog file names return the name in short form, without a path component.
141
178
179
+
#### get_binlog_by_gtid
180
+
142
181
The basic syntax for `get_binlog_by_gtid()` is the following:
143
182
144
183
* get_binlog_by_gtid(string) [AS] alias
@@ -147,9 +186,9 @@ Usage: SELECT get_binlog_by_gtid(string) [AS] alias
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;
286
335
```
287
336
288
337
??? example "Expected output"
@@ -291,14 +340,66 @@ SELECT FROM_UNIXTIME(get_last_record_timestamp_by_binlog("bin.00003") DIV 100000
291
340
+---------------------+
292
341
| result |
293
342
+=====================+
294
-
| 2020-12-04 04:18:56 |
343
+
| 2024-12-04 04:18:56 |
295
344
+---------------------+
296
345
```
297
346
298
-
```sql
299
-
DROPFUNCTION 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
+
* Old UDFs that return STRING values used to not care about character set of that string 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;
300
399
```
301
400
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
+
302
403
## Limitations
303
404
304
405
For the following variables, do not define values with one or more dot (.) characters:
0 commit comments