MySQL Binlog Analysis
Did you ever see an unexpected value in the database and wonder how did that get there? Suppose you have a column that should be one of "red", "yellow", or "blue" but it's magically "purple". Quite odd!
You could start looking through your code base to see where SQL is written that updates this table, but if you have multiple codebases, or third party tools writing to the database it may be intractable to search everywhere.
At the very least it's useful to know the time the column was updated, and the general structure of the query. Sometimes the query shape (or comments) can help you understand where the query originated. Correlating the query timestamp with a user login can reveal even more clues.
The best way to find these row changes are in the MySQL binlog. To enable it to be maximally useful you'll need the following parameters set:
binlog_format = ROW
binlog_row_image = FULL
binlog_row_metadata = FULL
binlog_rows_query_log_events = ON
Also you may want to keep your binlogs retained longer with something like this (on RDS):
CALL mysql.rds_set_configuration('binlog retention hours', 168);
Then you'll want to fetch the binlog from the remote server as follows:
mysql> show binary logs;
+----------------------------+-----------+-----------+
| Log_name | File_size | Encrypted |
+----------------------------+-----------+-----------+
| mysql-bin-changelog.067971 | 554535 | No |
| mysql-bin-changelog.067972 | 819429 | No |
| mysql-bin-changelog.067973 | 689402 | No |
| mysql-bin-changelog.067974 | 531056 | No |
| mysql-bin-changelog.067975 | 613426 | No |
| mysql-bin-changelog.067976 | 281491 | No |
+----------------------------+-----------+-----------+
6 rows in set (0.03 sec)
We can remotely fetch the raw logs as follows:
mysqlbinlog --read-from-remote-server --host=$HOST --port=$PORT --user=$USER --password=$PWD --raw mysql-bin-changelog.067971
Then I usually like to unpack them as follows (you can also use grep to search for the character '-'):
mysqlbinlog -vv --base64-output=decode-rows --print-table-metadata mysql-bin-changelog.067978 > decoded-mysql-bin-changelog.067978
Here’s a reference to the print-table-metadata line: mysqlhighavailability.com/more-metadata-is-..
Hopefully you find what you're looking for!
$ cat decoded-mysql-bin-changelog.067978 | grep purple -C 1
#210406 0:03:02 server id 803665627 end_log_pos 368855 CRC32 0x71cac556 Rows_query
# UPDATE street_lights SET color = "purple" AND user = "admin"
Furthermore if you really wanted to you can embed comments. Usually these are stripped out in row based replication. But if you embed them with a future mysql version they work as described here:
stackoverflow.com/questions/4100350/embeddi..
/*!99999 source:app_code */ UPDATE street_lights SET color = "purple" AND user = "admin"
Then this comment source:app_code becomes visible in your binary log! Cool!