Skip to content

Commit 7238db0

Browse files
authored
Merge pull request #571 from percona/ps-10190
PS-10190 [DOCS] - Binary Log UDFs functions documentation incomplete 8.4
2 parents 9274626 + 28041c1 commit 7238db0

File tree

1 file changed

+190
-91
lines changed

1 file changed

+190
-91
lines changed

docs/binlogging-replication-improvements.md

Lines changed: 190 additions & 91 deletions
Original file line numberDiff line numberDiff line change
@@ -13,10 +13,10 @@ Here's why:
1313

1414
* The same statement might affect different rows on the primary and replicas
1515

16-
```{.bash data-prompt="mysql>"}
17-
mysql> UPDATE table1 LIMIT 10 SET col1 = 'value';
18-
mysql> DELETE FROM table1 LIMIT 5;
19-
mysql> INSERT INTO table2 SELECT * FROM table1 LIMIT 3;
16+
```{.bash}
17+
UPDATE table1 LIMIT 10 SET col1 = 'value';
18+
DELETE FROM table1 LIMIT 5;
19+
INSERT INTO table2 SELECT * FROM table1 LIMIT 3;
2020
```
2121

2222
To make these statements safe for statement-based replication, you should do one of the following:
@@ -25,10 +25,10 @@ To make these statements safe for statement-based replication, you should do one
2525

2626
* Add an ORDER BY clause to make the result set deterministic
2727

28-
```{.bash data-prompt="mysql>"}
29-
mysql> UPDATE table1 SET col1 = 'value' ORDER BY id LIMIT 10;
30-
mysql> DELETE FROM table1 ORDER BY id LIMIT 5;
31-
mysql> INSERT INTO table2 SELECT * FROM table1 ORDER BY id LIMIT 3;
28+
```{.bash}
29+
UPDATE table1 SET col1 = 'value' ORDER BY id LIMIT 10;
30+
DELETE FROM table1 ORDER BY id LIMIT 5;
31+
INSERT INTO table2 SELECT * FROM table1 ORDER BY id LIMIT 3;
3232
```
3333

3434
The exception is when the LIMIT is used with an ORDER BY clause that uses a unique key - in this case, the statement becomes deterministic and safe for statement-based replication.
@@ -130,15 +130,15 @@ When enabled, all single-table `DROP TABLE` DDL statements are logged in the bin
130130

131131
You can enable `binlog_ddl_skip_rewrite` at runtime:
132132

133-
```{.bash data-prompt="mysql>"}
133+
```{.bash}
134134
-- Check current setting
135-
mysql> SHOW VARIABLES LIKE 'binlog_ddl_skip_rewrite';
135+
SHOW VARIABLES LIKE 'binlog_ddl_skip_rewrite';
136136
137137
-- Enable feature
138-
mysql> SET GLOBAL binlog_ddl_skip_rewrite = ON;
138+
SET GLOBAL binlog_ddl_skip_rewrite = ON;
139139
140140
-- Disable feature
141-
mysql> SET GLOBAL binlog_ddl_skip_rewrite = OFF;
141+
SET GLOBAL binlog_ddl_skip_rewrite = OFF;
142142
```
143143

144144
to enable the variable permanently, add the following line to the `my.cnf` configuration file:
@@ -158,146 +158,245 @@ After making this change, restart the MySQL service for it to take effect.
158158

159159
The following code block demonstrates how to enable `binlog_ddl_skip_rewrite` and shows the feature's effect on a `DROP TABLE` statement:
160160

161-
```{.bash data-prompt="mysql>"}
162-
mysql> SET binlog_ddl_skip_rewrite = ON;
161+
```{.bash}
162+
SET binlog_ddl_skip_rewrite = ON;
163163
/*comment at start*/DROP TABLE t /*comment at end*/;
164164
```
165165

166166
## Point-in-Time Recovery with `binlog_utils_udf`
167167

168-
Use the binlog_utils_udf component to assist with Point-in-Time Recovery (PiTR).
169-
The component installs user-defined functions (UDFs) that help you map GTIDs to
170-
binary log files and inspect the contents and timestamps of binlog files.
168+
Point-in-Time Recovery (PiTR) allows you to restore a database to any specific moment in time using binary logs. The `binlog_utils_udf` component provides user-defined functions (UDFs) that simplify PiTR operations by helping you:
171169

172-
### Functions
170+
* Map Global Transaction Identifiers (GTIDs) to specific binary log files
171+
* Inspect binary log contents and timestamps
172+
* Locate the exact binary log files needed for recovery operations
173173

174-
| Function | Returns | Description |
175-
|-----------------------------------------|----------------------|-------------------------------------------------------------------------|
176-
| get_binlog_by_gtid(gtid) | STRING (binlog name) | Returns the binlog file that contains the specified GTID. |
177-
| get_last_gtid_from_binlog(binlog) | STRING (GTID) | Returns the last GTID found in the specified binlog. |
178-
| get_gtid_set_by_binlog(binlog) | STRING (GTID set) | Returns all GTIDs found in the specified binlog. |
179-
| get_binlog_by_gtid_set(gtid_set) | STRING (binlog name) | Returns the first binlog file that contains at least one GTID from the specified set. |
180-
| get_first_record_timestamp_by_binlog(binlog) | INTEGER (timestamp) | Returns the timestamp of the first event in the specified binlog. |
181-
| get_last_record_timestamp_by_binlog(binlog) | INTEGER (timestamp) | Returns the timestamp of the last event in the specified binlog. |
174+
These functions are particularly useful when you need to determine which binary log files contain specific transactions or events during recovery planning.
182175

183-
### Notes
176+
### Prerequisites
184177

185-
* Timestamp-returning functions provide values with microsecond precision in
186-
UNIX time. Each value represents the number of microseconds since
187-
1970-01-01 00:00:00 UTC.
178+
Before using the `binlog_utils_udf` component, ensure the following requirements are met:
188179

189-
* Functions that accept a binlog name require a short file name only. Do not
190-
include a path. If the input contains a path separator (/), the server
191-
returns an error.
180+
* Percona Server for MySQL: The component is only available in Percona Server for MySQL, not in standard MySQL
192181

193-
* The server reads binlogs from the current binlog directory defined by the
194-
@@log_bin_basename system variable.
182+
* Binary logging enabled: The server must have binary logging enabled (`log_bin` system variable set to `ON`)
195183

196-
* Functions that return a binlog file name return the short name (no path).
184+
* GTID enabled: For GTID-related functions, GTID must be enabled (`gtid_mode` set to `ON`)
197185

198-
### Install the component
186+
* MySQL privileges: You need `SYSTEM_VARIABLES_ADMIN` privilege to install components. For binary log operations, `BINLOG_ADMIN` privilege may also be required. The `SUPER` privilege is deprecated in MySQL 8.0+ and should be replaced with specific dynamic privileges
199187

200-
Install the component once on each server where you want to use these UDFs.
188+
#### Install the component
201189

202-
```{.bash data-prompt="mysql>"}
203-
mysql> INSTALL COMPONENT 'file://component_binlog_utils_udf';
190+
Install the component on each server where you plan to use these functions:
191+
192+
```{.bash}
193+
INSTALL COMPONENT 'file://component_binlog_utils_udf';
194+
```
195+
196+
#### Verify installation
197+
198+
```{.bash}
199+
SELECT * FROM mysql.component WHERE component_urn = 'file://component_binlog_utils_udf';
200+
```
201+
202+
```{.bash}
203+
SELECT ROUTINE_NAME FROM INFORMATION_SCHEMA.ROUTINES
204+
-> WHERE ROUTINE_NAME LIKE 'get_%' AND ROUTINE_TYPE = 'FUNCTION';
205+
```
206+
207+
### Available functions
208+
209+
The `binlog_utils_udf` component provides six functions for binary log analysis and GTID mapping:
210+
211+
| Function | Returns | Description | Use Case |
212+
|-----------------------------------------|----------------------|-------------------------------------------------------------------------|----------|
213+
| [`get_binlog_by_gtid(gtid)`](#find-binary-log-by-gtid) | STRING (binlog name) | Returns the binary log file that contains the specified GTID. | Find which binary log contains a specific transaction |
214+
| [`get_last_gtid_from_binlog(binlog)`](#get-last-gtid-from-binary-log) | STRING (GTID) | Returns the last GTID found in the specified binary log. | Identify the final transaction in a binary log file |
215+
| [`get_gtid_set_by_binlog(binlog)`](#get-all-gtids-from-binary-log) | STRING (GTID set) | Returns all GTIDs found in the specified binary log. | Get complete list of transactions in a binary log |
216+
| [`get_binlog_by_gtid_set(gtid_set)`](#find-binary-log-by-gtid-set) | STRING (binlog name) | Returns the first binary log file that contains at least one GTID from the specified set. | Find binary log containing any transaction from a GTID set |
217+
| [`get_first_record_timestamp_by_binlog(binlog)`](#get-first-event-timestamp) | INTEGER (timestamp) | Returns the timestamp of the first event in the specified binary log. | Determine when a binary log file started |
218+
| [`get_last_record_timestamp_by_binlog(binlog)`](#get-last-event-timestamp) | INTEGER (timestamp) | Returns the timestamp of the last event in the specified binary log. | Determine when a binary log file ended |
219+
220+
### Important notes
221+
222+
* CAST requirement: When using these user-defined functions, you must use CAST to return a result. String functions require `CAST(...AS CHAR)` and timestamp functions require `CAST(...AS UNSIGNED)`.
223+
224+
* Timestamp precision: Timestamp-returning functions provide values with microsecond precision in UNIX time format. Each value represents the number of microseconds since 1970-01-01 00:00:00 UTC.
225+
226+
* Binary log file names: Functions that accept a binary log name require only the short file name (for example, `binlog.000001`). Do not include the full path. If the input contains a path separator (`/`), the server returns an error.
227+
228+
* Binary log directory: The server reads binary logs from the directory defined by the `@@log_bin_basename` system variable.
229+
230+
* Return values: Functions that return binary log file names return only the short name without the path.
231+
232+
* Performance considerations: These functions read binary log files directly from disk. For large binary log files, the functions may take several seconds to complete.
233+
234+
### Simplifying UDF usage without CAST()
235+
236+
While CAST() is required for proper function execution, you can configure your MySQL client to handle data type conversions automatically, reducing the need to use CAST() explicitly in your queries.
237+
238+
#### Configure the MySQL client
239+
240+
You can set the appropriate client character set and collation to simplify UDF usage:
241+
242+
```{.bash}
243+
-- Set client character set
244+
SET character_set_client = 'utf8mb4';
245+
246+
-- Set client collation
247+
SET collation_connection = 'utf8mb4_general_ci';
204248
```
205249

206-
You can confirm installation by checking the list of registered functions:
250+
Alternatively, you can configure these settings in your MySQL client configuration file (e.g., `~/.my.cnf` or `/etc/mysql/my.cnf`):
207251

208-
```{.bash data-prompt="mysql>"}
209-
mysql> SELECT ROUTINE_NAME FROM INFORMATION_SCHEMA.ROUTINES \G
252+
```ini
253+
[client]
254+
default-character-set=utf8mb4
255+
default-collation=utf8mb4_general_ci
210256
```
211257

258+
By configuring these settings, the MySQL client can handle data type conversions more effectively, allowing you to use the UDF functions without explicit CAST() statements in many cases.
259+
260+
!!! note
261+
262+
While client configuration can simplify usage, CAST() will still work and may be necessary in some scenarios. The choice between using CAST() explicitly or relying on client configuration depends on your specific use case and preferences.
263+
264+
212265

213266
### Usage examples
214267

215-
Replace the sample arguments with values from your environment. The examples
216-
show the typical way to call each function. For clarity, results are aliased.
268+
The following examples demonstrate how to use each function. Replace the sample arguments with values from your environment. All examples include CAST statements for proper function execution, though these may be optional if you've configured your MySQL client as described in the [Simplifying UDF usage without CAST()](#simplifying-udf-usage-without-cast) section.
217269

218-
#### get_binlog_by_gtid()
270+
#### Find binary log by GTID
219271

220-
Locate the binlog that contains a GTID:
272+
Use `get_binlog_by_gtid()` to locate which binary log file contains a specific transaction:
221273

222-
```{.bash data-prompt="mysql>"}
223-
mysql> SELECT get_binlog_by_gtid('UUID-GROUP:1') AS binlog;
274+
```{.bash}
275+
SELECT CAST(get_binlog_by_gtid('550e8400-e29b-41d4-a716-446655440000:123') AS CHAR) AS binlog;
224276
```
225277

226-
#### get_last_gtid_from_binlog()
278+
Use case: When you know a specific GTID and need to find which binary log file contains that transaction for recovery purposes.
279+
280+
#### Get last GTID from binary log
227281

228-
Return the last GTID in a binlog
282+
Use `get_last_gtid_from_binlog()` to find the final transaction in a specific binary log file:
229283

230-
```{.bash data-prompt="mysql>"}
231-
mysql> SELECT get_last_gtid_from_binlog('binlog.000001') AS last_gtid;
284+
```{.bash}
285+
SELECT CAST(get_last_gtid_from_binlog('binlog.000001') AS CHAR) AS last_gtid;
232286
```
233287

234-
#### get_gtid_set_by_binlog()
288+
Use case: Determine the last transaction processed in a binary log file before rotating to the next file.
235289

236-
Return all GTIDs in a binlog
290+
#### Get all GTIDs from binary log
237291

238-
```{.bash data-prompt="mysql>"}
239-
mysql> SELECT get_gtid_set_by_binlog('binlog.000001') AS gtid_set;
292+
Use `get_gtid_set_by_binlog()` to retrieve all GTIDs contained in a specific binary log file:
293+
294+
```{.bash}
295+
SELECT CAST(get_gtid_set_by_binlog('binlog.000001') AS CHAR) AS gtid_set;
240296
```
241297

242-
#### get_binlog_by_gtid_set()
298+
Use case: Get a complete list of all transactions in a binary log file for analysis or replication setup.
299+
300+
#### Find binary log by GTID set
243301

244-
Find a binlog that contains any GTID in a set
302+
Use `get_binlog_by_gtid_set()` to find the first binary log file that contains any GTID from a specified set:
245303

246-
```{.bash data-prompt="mysql>"}
247-
mysql> SELECT get_binlog_by_gtid_set('UUID1:7,UUID1:8') AS binlog;
304+
```{.bash}
305+
SELECT CAST(get_binlog_by_gtid_set('550e8400-e29b-41d4-a716-446655440000:7,550e8400-e29b-41d4-a716-446655440000:8') AS CHAR) AS binlog;
248306
```
249307

250-
#### get_first_record_timestamp_by_binlog() and get_last_record_timestamp_by_binlog(binlog)
308+
Use case: When you have a set of GTIDs and need to find which binary log file contains at least one of those transactions.
309+
310+
#### Get binary log timestamps
311+
312+
Use timestamp functions to determine when events occurred in binary log files. These functions return microsecond-precision timestamps in UNIX time format.
313+
314+
##### Get first event timestamp
251315

252-
Get the first event timestamp from a binlog. The function returns microseconds since the UNIX epoch. Use the tabs below to
253-
see the raw numeric value or a human-readable timestamp.
316+
Find when the first event was written to a binary log file:
254317

255-
=== "Raw Timestamp"
256-
```{.bash data-prompt="mysql>"}
257-
mysql> SELECT get_first_record_timestamp_by_binlog('binlog.000001') AS raw_ts;
318+
=== "Raw Timestamp (Microseconds)"
319+
```{.bash}
320+
SELECT CAST(get_first_record_timestamp_by_binlog('binlog.000001') AS UNSIGNED) AS raw_ts;
258321
```
259322

260-
=== "Human-Readable"
261-
```{.bash data-prompt="mysql>"}
262-
mysql> SELECT FROM_UNIXTIME(
263-
get_first_record_timestamp_by_binlog('binlog.000001') DIV 1000000
323+
=== "Human-Readable Format"
324+
```{.bash}
325+
SELECT FROM_UNIXTIME(
326+
CAST(get_first_record_timestamp_by_binlog('binlog.000001') AS UNSIGNED) DIV 1000000
264327
) AS first_event_ts;
265328
```
266329

267-
Get the last event timestamp from a binlog
330+
Use case: Determine when a binary log file started receiving events, useful for recovery planning.
268331

269-
=== "Raw Timestamp"
270-
```{.bash data-prompt="mysql>"}
271-
mysql> SELECT get_last_record_timestamp_by_binlog('binlog.000001') AS raw_ts;
332+
##### Get last event timestamp
333+
334+
Find when the last event was written to a binary log file:
335+
336+
=== "Raw Timestamp (Microseconds)"
337+
```{.bash}
338+
SELECT CAST(get_last_record_timestamp_by_binlog('binlog.000001') AS UNSIGNED) AS raw_ts;
272339
```
273340

274-
=== "Human-Readable"
275-
```{.bash data-prompt="mysql>"}
276-
mysql> SELECT FROM_UNIXTIME(
277-
get_last_record_timestamp_by_binlog('binlog.000001') DIV 1000000
341+
=== "Human-Readable Format"
342+
```{.bash}
343+
SELECT FROM_UNIXTIME(
344+
CAST(get_last_record_timestamp_by_binlog('binlog.000001') AS UNSIGNED) DIV 1000000
278345
) AS last_event_ts;
279346
```
280347

348+
Use case: Determine when a binary log file stopped receiving events, useful for understanding binary log rotation timing.
349+
350+
351+
### Troubleshooting
352+
353+
#### Common issues
354+
355+
Function returns NULL: This usually indicates that the specified GTID or binary log file does not exist. Verify that:
356+
357+
* The GTID format is correct (UUID:transaction_id)
281358

282-
??? example "Expected output"
359+
* The binary log file exists in the binary log directory
283360

284-
```{.text .no-copy}
285-
+---------------+
286-
| binlog |
287-
+---------------+
288-
| binlog.000001 |
289-
+---------------+
290-
```
361+
* GTID is enabled on the server
291362

292-
Actual values depend on your server state and binlog contents.
363+
Error: "Unknown function": The component is not installed. Install the component using the `INSTALL COMPONENT` command.
364+
365+
Error: "Access denied": You need `SYSTEM_VARIABLES_ADMIN` privilege to install the component and `BINLOG_ADMIN` privilege for binary log operations. The `SUPER` privilege is deprecated in MySQL 8.0+.
366+
367+
Performance issues: These functions read binary log files directly from disk. For large binary log files, expect execution times of several seconds.
368+
369+
#### Verify binary log files
370+
371+
Check which binary log files are available:
372+
373+
```{.bash}
374+
SHOW BINARY LOGS;
375+
```
376+
377+
#### Check GTID status
378+
379+
Verify GTID is enabled:
380+
381+
```{.bash}
382+
SHOW VARIABLES LIKE 'gtid_mode';
383+
```
293384

294385
### Uninstall the component
295386

296-
Remove the component and all associated UDFs:
387+
Remove the component and all associated functions:
297388

298-
```{.bash data-prompt="mysql>"}
299-
mysql> UNINSTALL COMPONENT 'file://component_binlog_utils_udf';
389+
```{.bash}
390+
UNINSTALL COMPONENT 'file://component_binlog_utils_udf';
300391
```
392+
393+
Verify removal:
394+
395+
```{.bash}
396+
SELECT * FROM mysql.component WHERE component_urn = 'file://component_binlog_utils_udf';
397+
```
398+
399+
The query should return no rows if the component is successfully uninstalled.
301400

302401
## Limitations
303402

0 commit comments

Comments
 (0)