1About pgreplay
2==============
3
4pgreplay reads a PostgreSQL log file (*not* a WAL file), extracts the
5SQL statements and executes them in the same order and with the original
6timing against a PostgreSQL database.
7
8If the execution of statements gets behind schedule, warning messages
9are issued that indicate that the server cannot handle the load in a
10timely fashion.
11
12A final report gives you a useful statistical analysis of your workload
13and its execution.
14
15The idea is to replay a real-world database workload as exactly as possible.
16
17This is useful for performance tests, particularly in the following
18situations:
19- You want to compare the performance of your PostgreSQL application
20 on different hardware or different operating systems.
21- You want to upgrade your database and want to make sure that the new
22 database version does not suffer from performance regressions that
23 affect you.
24
25Moreover, pgreplay can give you some feeling as to how your application
26*might* scale by allowing you to try to replay the workload at a higher
27speed (if that is possible, see "implementation details" below).
28Be warned, though, that 500 users working at double speed is not really
29the same as 1000 users working at normal speed.
30
31While pgreplay will find out if your database application will encounter
32performance problems, it does not provide a lot of help in the analysis of
33the cause of these problems. Combine pgreplay with a specialized analysis
34program like pgFouine (http://pgfouine.projects.postgresql.org/) for that.
35
36As an additional feature, pgreplay lets you split the replay in two
37parts: you can parse the log file and create a "replay file", which
38contains just the statements to be replayed and is hopefully much
39smaller than the original log file.
40Such a replay file can then be run against a database.
41
42pgreplay is written by Laurenz Albe <laurenz.albe@wien.gv.at> and
43is inspired by "Playr" which never made it out of Beta.
44
45Installation
46============
47
48pgreplay needs PostgreSQL 8.0 or better.
49
50It is supposed to compile without warnings and run on all platforms
51supported by PostgreSQL.
52Since I only got to test it on Linux, AIX, FreeBSD and Windows, there may be
53problems with other platforms. I am interested in reports and fixes for
54these platforms.
55On Windows, only the MinGW build environment is supported (I have no
56other compiler). That means that there is currently no 64-bit build
57for Windows (but a 32-bit executable should work fine anywhere).
58
59To build pgreplay, you will need the pg_config utility. If you installed
60PostgreSQL using installation packages, you will probably have to install
61the development package that contains pg_config and the header files.
62
63If PostgreSQL is installed in the default location, the installation
64process will look like this:
65
66unpack the tarball
67./configure
68make
69make test (optional, described below)
70make install (as superuser)
71
72If your PostgreSQL installation is in a nonstandard directory, you
73will have to use the --with-postgres=<path to location of pg_config>
74switch of "configure".
75
76Unless you link it statically, pgreplay requires the PostgreSQL client
77shared library on the system where it is run.
78
79The following utilities are only necessary if you intend to develop pgreplay:
80- autoconf 2.62 or better to generate 'configure'
81- GNU tar to 'make tarball' (unless you want to roll it by hand)
82- groff to make the HTML documentation with 'make html'
83
84Testing
85-------
86
87You can run a test on pgreplay before installing by running "make test".
88This will parse sample log files and check that the result is as
89expected.
90
91Then an attempt is made to replay the log files and check if that
92works as expected. For this you need psql installed and a PostgreSQL server
93running (on this or another machine) so that the following command
94will succeed:
95
96psql -U postgres -d postgres -l
97
98You can setup the PGPORT and PGHOST environment variables and a password
99file for the user if necessary.
100
101Usage
102=====
103
104First, you will need to record your real-life workload.
105For that, set the following parameters in postgresql.conf:
106
107log_min_messages = error (or more)
108 (if you know that you have no cancel requests, 'log' will do)
109log_min_error_statement = log (or more)
110log_connections = on
111log_disconnections = on
112log_line_prefix = '%m|%u|%d|%c|' (if you don't use CSV logging)
113log_statement = 'all'
114lc_messages must be set to English (the encoding does not matter)
115bytea_output = escape (from version 9.0 on, only if you want to replay
116 the log on 8.4 or earlier)
117
118It is highly recommended that you use CSV logging, because anything that
119the PostgreSQL server or any loaded modules write to standard error will
120be written to the stderr log and might confuse the parser.
121
122Then let your users have their way with the database.
123
124Make sure that you have a pg_dumpall of the database cluster from the time
125of the start of your log file (or use the -b option with the time of your
126backup). Alternatively, you can use point in time recovery to clone your
127database at the appropriate time.
128
129When you are done, restore the database (in the "before" state) to the
130machine where you want to perform the load test and run pgreplay against
131that database.
132
133Try to create a scenario as similar to your production system as
134possible (except for the change you want to test, of course). For example,
135if your clients connect over the network, run pgreplay on a different
136machine from where the database server is running.
137
138Since passwords are not logged (and pgreplay consequently has no way of
139knowing them), you have two options: either change pg_hba.conf on the
140test database to allow "trust" authentication or (if that is unacceptable)
141create a password file as described by the PostgreSQL documentation.
142Alternatively, you can change the passwords of all application users
143to one single password that you supply to pgreplay with the -W option.
144
145Limitations
146===========
147
148pgreplay can only replay what is logged by PostgreSQL.
149This leads to some limitations:
150
151- COPY statements will not be replayed, because the copy data are not logged.
152 I could have supported COPY TO statements, but that would have imposed a
153 requirement that the directory structure on the replay system must be
154 identical to the original machine.
155 And if your application runs on the same machine as your database and they
156 interact on the file system, pgreplay will probably not help you much
157 anyway.
158- Fast-path API function calls are not logged and will not be replayed.
159 Unfortunately, this includes the Large Object API.
160- Since the log file is always written in the database encoding (which you
161 can specify with the -E switch of pgreplay), all "SET client_encoding"
162 statements will be ignored.
163- If your cluster contains databases with different encoding, the log file
164 will have mixed encoding as well. You cannot use pgreplay well in such
165 an environment, because many statements against databases whose
166 encoding does not match the -E switch will fail.
167- Since the preparation time of prepared statements is not logged (unless
168 log_min_messages is debug2 or more), these statements will be prepared
169 immediately before they are first executed during replay.
170
171While pgreplay makes sure that commands are sent to the server in the
172order in which they were originally executed, there is no way to guarantee
173that they will be executed in the same order during replay: Network
174delay, processor contention and other factors may cause a later command
175to "overtake" an earlier one. While this does not matter if the
176commands don't affect each other, it can lead to SQL statements hitting
177locks unexpectedly, causing replay to deadlock and "hang".
178This is particularly likely if many different sessions change the same data
179repeatedly in short intervals.
180
181You can work around this problem by canceling the waiting statement with
182pg_cancel_backend. Replay should continue normally after that.
183
184Implementation details
185======================
186
187pgreplay will track the "session ID" associated with each log entry (the
188session ID uniquely identifies a database connection).
189For each new session ID, a new database connection will be opened during
190replay. Each statement will be sent on the corresponding connection, so
191transactions are preserved and concurrent sessions cannot get in each
192other's way.
193
194The order of statements in the log file is strictly preserved, so there
195cannot be any race conditions caused by different execution speeds on
196separate connections. On the other hand, that means that long running
197queries on one connection may stall execution on concurrent connections,
198but that's all you can get if you want to reproduce the exact same
199workload on a system that behaves differently.
200
201As an example, consider this (simplified) log file:
202
203session 1|connect
204session 2|connect
205session 1|statement: BEGIN
206session 1|statement: SELECT something(1)
207session 2|statement: BEGIN
208session 2|statement: SELECT something(2)
209session 1|statement: SELECT something(3)
210session 2|statement: ROLLBACK
211session 2|disconnect
212session 1|statement: COMMIT
213session 2|disconnect
214
215This will cause two database connections to be opened, so the ROLLBACK in
216session 2 will not affect session 1.
217If "SELECT something(2)" takes longer than expected (longer than it did in
218the original), that will not stall the execution of "SELECT something(3)"
219because it runs on a different connection. The ROLLBACK, however, has to
220wait for the completion of the long statement. Since the order of statements
221is preserved, the COMMIT on session 1 will have to wait until the ROLLBACK
222on session 2 has started (but it does not have to wait for the completion of
223the ROLLBACK).
224
225pgreplay is implemented in C and makes heavy use of asynchronous command
226processing (which is the reason why it is implemented in C).
227This way a single process can handle many concurrent connections, which
228makes it possible to get away without multithreading or multiprocessing.
229
230This avoids the need for synchronization and many portability problems.
231But since TINSTAAFL, the choice of C brings along its own portability
232problems. Go figure.
233
234Replay file format
235------------------
236
237The replay file is a binary file, integer numbers are stored in network
238byte order.
239
240Each record in the replay file corresponds to one database operation
241and is constructed as follows:
242- 4-byte unsigned int: log file timestamp in seconds since 2000-01-01
243- 4-byte unsigned int: fractional part of log file timestamp in microseconds
244- 8-byte unsigned int: session id
245- 1-byte unsigned int: type of the database action:
246 0 is connect
247 1 is disconnect
248 2 is simple statement execution
249 3 is statement preparation
250 4 is execution of a prepared statement
251 5 is cancel request
252- The remainder of the record is specific to the action, strings are stored
253 with a preceeding 4-byte unsigned int that contains the length.
254 Read the source for details.
255- Each record is terminated by a new-line character (byte 0x0A).
256
257pgreplay and pgFouine
258=====================
259
260pgFouine (http://pgfouine.projects.postgresql.org/) is a PostgreSQL log file
261analyzer that allows you to understand your database workload and find
262bottlenecks and slow queries.
263
264Because both pgreplay and pgFouine target performance questions, it would be
265nice if they could operate on the same log files. But pgFouine needs the
266statement to be logged along with its duration, which is logged at the end of
267query execution, whereas pgreplay needs it at execution start time, so they
268cannot use the same log file.
269
270If you use CSV logging, there is a workaround with which you can turn a
271log file for pgFouine into a log file for pgreplay. The following describes
272this procedure for PostgreSQL 8.4 (there is an additional field in the CSV log
273from 9.0 on, and pgFouine currently does not work with the new format).
274
275For recording, use the following configuration parameters:
276
277log_destination = 'csvlog'
278redirect_stderr = on
279log_min_messages = error
280log_min_error_statement = log
281log_connections = on
282log_disconnections = on
283log_duration = off
284log_min_duration_statement = 0
285log_statement = 'none'
286lc_messages must be set to English (the encoding does not matter)
287
288The resulting CSV log file can be parsed by pgFouine. Then you need a
289PostgreSQL database to create a new CSV file as follows:
290
291CREATE TABLE postgres_log
292(
293 log_time timestamp(3) with time zone,
294 user_name text,
295 database_name text,
296 process_id integer,
297 connection_from text,
298 session_id text,
299 session_line_num bigint,
300 command_tag text,
301 session_start_time timestamp with time zone,
302 virtual_transaction_id text,
303 transaction_id bigint,
304 error_severity text,
305 sql_state_code text,
306 message text,
307 detail text,
308 hint text,
309 internal_query text,
310 internal_query_pos integer,
311 context text,
312 query text,
313 query_pos integer,
314 location text
315);
316
317COPY postgres_log FROM '/path/to/for_pgfouine.csv' WITH CSV;
318
319UPDATE postgres_log SET
320 log_time = log_time - CAST(substring(message FROM E'\\d+.\\d* ms') AS interval),
321 message = regexp_replace(message, E'^duration: \\d+.\\d* ms ', '')
322WHERE error_severity = 'LOG' AND message ~ E'^duration: \\d+.\\d* ms ';
323
324COPY (SELECT
325 to_char(log_time, 'YYYY-MM-DD HH24:MI:SS.MS TZ'),
326 user_name, database_name, process_id, connection_from,
327 session_id, session_line_num, command_tag, session_start_time,
328 virtual_transaction_id, transaction_id, error_severity,
329 sql_state_code, message, detail, hint, internal_query,
330 internal_query_pos, context, query, query_pos, location
331 FROM postgres_log ORDER BY log_time, session_line_num)
332 TO '/path/to/for_pgreplay.csv' WITH CSV;
333
334The resulting "for_pgreplay.csv" can be parsed by pgreplay.
335
336Support
337=======
338
339If you have a problem or question, the preferred option is to send an
340e-mail to pgreplay-general@lists.pgfoundry.org
341You can subscribe here:
342http://lists.pgfoundry.org/mailman/listinfo/pgreplay-general
343There is a mail archive here:
344http://lists.pgfoundry.org/pipermail/pgreplay-general/
345
346There is the option to open an issue on GitHub:
347https://github.com/laurenz/pgreplay/issues
348This requires a GitHub account.
349
350You can also use the issue trackers on pgFoundry:
351http://pgfoundry.org/tracker/?group_id=1000479
352pgFoundry also offers forums for questions:
353http://pgfoundry.org/forum/?group_id=1000479
354The trackers and forums require a pgFoundry account.
355
356I will also answer e-mail sent to me at laurenz.albe@wien.gv.at, but that way
357you exclude others from helping you or benefiting from your experience.
358
359TODO list
360=========
361
362Nothing currently. Tell me if you have good ideas.
363