1PGBENCH(1)               PostgreSQL 15.4 Documentation              PGBENCH(1)
2
3
4

NAME

6       pgbench - run a benchmark test on PostgreSQL
7

SYNOPSIS

9       pgbench -i [option...] [dbname]
10
11       pgbench [option...] [dbname]
12

DESCRIPTION

14       pgbench is a simple program for running benchmark tests on PostgreSQL.
15       It runs the same sequence of SQL commands over and over, possibly in
16       multiple concurrent database sessions, and then calculates the average
17       transaction rate (transactions per second). By default, pgbench tests a
18       scenario that is loosely based on TPC-B, involving five SELECT, UPDATE,
19       and INSERT commands per transaction. However, it is easy to test other
20       cases by writing your own transaction script files.
21
22       Typical output from pgbench looks like:
23
24           transaction type: <builtin: TPC-B (sort of)>
25           scaling factor: 10
26           query mode: simple
27           number of clients: 10
28           number of threads: 1
29           maximum number of tries: 1
30           number of transactions per client: 1000
31           number of transactions actually processed: 10000/10000
32           number of failed transactions: 0 (0.000%)
33           latency average = 11.013 ms
34           latency stddev = 7.351 ms
35           initial connection time = 45.758 ms
36           tps = 896.967014 (without initial connection time)
37
38       The first seven lines report some of the most important parameter
39       settings. The sixth line reports the maximum number of tries for
40       transactions with serialization or deadlock errors (see Failures and
41       Serialization/Deadlock Retries for more information). The eighth line
42       reports the number of transactions completed and intended (the latter
43       being just the product of number of clients and number of transactions
44       per client); these will be equal unless the run failed before
45       completion or some SQL command(s) failed. (In -T mode, only the actual
46       number of transactions is printed.) The next line reports the number of
47       failed transactions due to serialization or deadlock errors (see
48       Failures and Serialization/Deadlock Retries for more information). The
49       last line reports the number of transactions per second.
50
51       The default TPC-B-like transaction test requires specific tables to be
52       set up beforehand.  pgbench should be invoked with the -i (initialize)
53       option to create and populate these tables. (When you are testing a
54       custom script, you don't need this step, but will instead need to do
55       whatever setup your test needs.) Initialization looks like:
56
57           pgbench -i [ other-options ] dbname
58
59       where dbname is the name of the already-created database to test in.
60       (You may also need -h, -p, and/or -U options to specify how to connect
61       to the database server.)
62
63           Caution
64           pgbench -i creates four tables pgbench_accounts, pgbench_branches,
65           pgbench_history, and pgbench_tellers, destroying any existing
66           tables of these names. Be very careful to use another database if
67           you have tables having these names!
68
69       At the default “scale factor” of 1, the tables initially contain this
70       many rows:
71
72           table                   # of rows
73           ---------------------------------
74           pgbench_branches        1
75           pgbench_tellers         10
76           pgbench_accounts        100000
77           pgbench_history         0
78
79       You can (and, for most purposes, probably should) increase the number
80       of rows by using the -s (scale factor) option. The -F (fillfactor)
81       option might also be used at this point.
82
83       Once you have done the necessary setup, you can run your benchmark with
84       a command that doesn't include -i, that is
85
86           pgbench [ options ] dbname
87
88       In nearly all cases, you'll need some options to make a useful test.
89       The most important options are -c (number of clients), -t (number of
90       transactions), -T (time limit), and -f (specify a custom script file).
91       See below for a full list.
92

OPTIONS

94       The following is divided into three subsections. Different options are
95       used during database initialization and while running benchmarks, but
96       some options are useful in both cases.
97
98   Initialization Options
99       pgbench accepts the following command-line initialization arguments:
100
101       dbname
102           Specifies the name of the database to test in. If this is not
103           specified, the environment variable PGDATABASE is used. If that is
104           not set, the user name specified for the connection is used.
105
106       -i
107       --initialize
108           Required to invoke initialization mode.
109
110       -I init_steps
111       --init-steps=init_steps
112           Perform just a selected set of the normal initialization steps.
113           init_steps specifies the initialization steps to be performed,
114           using one character per step. Each step is invoked in the specified
115           order. The default is dtgvp. The available steps are:
116
117           d (Drop)
118               Drop any existing pgbench tables.
119
120           t (create Tables)
121               Create the tables used by the standard pgbench scenario, namely
122               pgbench_accounts, pgbench_branches, pgbench_history, and
123               pgbench_tellers.
124
125           g or G (Generate data, client-side or server-side)
126               Generate data and load it into the standard tables, replacing
127               any data already present.
128
129               With g (client-side data generation), data is generated in
130               pgbench client and then sent to the server. This uses the
131               client/server bandwidth extensively through a COPY.  pgbench
132               uses the FREEZE option with version 14 or later of PostgreSQL
133               to speed up subsequent VACUUM, unless partitions are enabled.
134               Using g causes logging to print one message every 100,000 rows
135               while generating data for the pgbench_accounts table.
136
137               With G (server-side data generation), only small queries are
138               sent from the pgbench client and then data is actually
139               generated in the server. No significant bandwidth is required
140               for this variant, but the server will do more work. Using G
141               causes logging not to print any progress message while
142               generating data.
143
144               The default initialization behavior uses client-side data
145               generation (equivalent to g).
146
147           v (Vacuum)
148               Invoke VACUUM on the standard tables.
149
150           p (create Primary keys)
151               Create primary key indexes on the standard tables.
152
153           f (create Foreign keys)
154               Create foreign key constraints between the standard tables.
155               (Note that this step is not performed by default.)
156
157       -F fillfactor
158       --fillfactor=fillfactor
159           Create the pgbench_accounts, pgbench_tellers and pgbench_branches
160           tables with the given fillfactor. Default is 100.
161
162       -n
163       --no-vacuum
164           Perform no vacuuming during initialization. (This option suppresses
165           the v initialization step, even if it was specified in -I.)
166
167       -q
168       --quiet
169           Switch logging to quiet mode, producing only one progress message
170           per 5 seconds. The default logging prints one message each 100,000
171           rows, which often outputs many lines per second (especially on good
172           hardware).
173
174           This setting has no effect if G is specified in -I.
175
176       -s scale_factor
177       --scale=scale_factor
178           Multiply the number of rows generated by the scale factor. For
179           example, -s 100 will create 10,000,000 rows in the pgbench_accounts
180           table. Default is 1. When the scale is 20,000 or larger, the
181           columns used to hold account identifiers (aid columns) will switch
182           to using larger integers (bigint), in order to be big enough to
183           hold the range of account identifiers.
184
185       --foreign-keys
186           Create foreign key constraints between the standard tables. (This
187           option adds the f step to the initialization step sequence, if it
188           is not already present.)
189
190       --index-tablespace=index_tablespace
191           Create indexes in the specified tablespace, rather than the default
192           tablespace.
193
194       --partition-method=NAME
195           Create a partitioned pgbench_accounts table with NAME method.
196           Expected values are range or hash. This option requires that
197           --partitions is set to non-zero. If unspecified, default is range.
198
199       --partitions=NUM
200           Create a partitioned pgbench_accounts table with NUM partitions of
201           nearly equal size for the scaled number of accounts. Default is 0,
202           meaning no partitioning.
203
204       --tablespace=tablespace
205           Create tables in the specified tablespace, rather than the default
206           tablespace.
207
208       --unlogged-tables
209           Create all tables as unlogged tables, rather than permanent tables.
210
211   Benchmarking Options
212       pgbench accepts the following command-line benchmarking arguments:
213
214       -b scriptname[@weight]
215       --builtin=scriptname[@weight]
216           Add the specified built-in script to the list of scripts to be
217           executed. Available built-in scripts are: tpcb-like, simple-update
218           and select-only. Unambiguous prefixes of built-in names are
219           accepted. With the special name list, show the list of built-in
220           scripts and exit immediately.
221
222           Optionally, write an integer weight after @ to adjust the
223           probability of selecting this script versus other ones. The default
224           weight is 1. See below for details.
225
226       -c clients
227       --client=clients
228           Number of clients simulated, that is, number of concurrent database
229           sessions. Default is 1.
230
231       -C
232       --connect
233           Establish a new connection for each transaction, rather than doing
234           it just once per client session. This is useful to measure the
235           connection overhead.
236
237       -d
238       --debug
239           Print debugging output.
240
241       -D varname=value
242       --define=varname=value
243           Define a variable for use by a custom script (see below). Multiple
244           -D options are allowed.
245
246       -f filename[@weight]
247       --file=filename[@weight]
248           Add a transaction script read from filename to the list of scripts
249           to be executed.
250
251           Optionally, write an integer weight after @ to adjust the
252           probability of selecting this script versus other ones. The default
253           weight is 1. (To use a script file name that includes an @
254           character, append a weight so that there is no ambiguity, for
255           example filen@me@1.) See below for details.
256
257       -j threads
258       --jobs=threads
259           Number of worker threads within pgbench. Using more than one thread
260           can be helpful on multi-CPU machines. Clients are distributed as
261           evenly as possible among available threads. Default is 1.
262
263       -l
264       --log
265           Write information about each transaction to a log file. See below
266           for details.
267
268       -L limit
269       --latency-limit=limit
270           Transactions that last more than limit milliseconds are counted and
271           reported separately, as late.
272
273           When throttling is used (--rate=...), transactions that lag behind
274           schedule by more than limit ms, and thus have no hope of meeting
275           the latency limit, are not sent to the server at all. They are
276           counted and reported separately as skipped.
277
278           When the --max-tries option is used, a transaction which fails due
279           to a serialization anomaly or from a deadlock will not be retried
280           if the total time of all its tries is greater than limit ms. To
281           limit only the time of tries and not their number, use
282           --max-tries=0. By default, the option --max-tries is set to 1 and
283           transactions with serialization/deadlock errors are not retried.
284           See Failures and Serialization/Deadlock Retries for more
285           information about retrying such transactions.
286
287       -M querymode
288       --protocol=querymode
289           Protocol to use for submitting queries to the server:
290
291           •   simple: use simple query protocol.
292
293           •   extended: use extended query protocol.
294
295           •   prepared: use extended query protocol with prepared statements.
296
297           In the prepared mode, pgbench reuses the parse analysis result
298           starting from the second query iteration, so pgbench runs faster
299           than in other modes.
300
301           The default is simple query protocol. (See Chapter 55 for more
302           information.)
303
304       -n
305       --no-vacuum
306           Perform no vacuuming before running the test. This option is
307           necessary if you are running a custom test scenario that does not
308           include the standard tables pgbench_accounts, pgbench_branches,
309           pgbench_history, and pgbench_tellers.
310
311       -N
312       --skip-some-updates
313           Run built-in simple-update script. Shorthand for -b simple-update.
314
315       -P sec
316       --progress=sec
317           Show progress report every sec seconds. The report includes the
318           time since the beginning of the run, the TPS since the last report,
319           and the transaction latency average, standard deviation, and the
320           number of failed transactions since the last report. Under
321           throttling (-R), the latency is computed with respect to the
322           transaction scheduled start time, not the actual transaction
323           beginning time, thus it also includes the average schedule lag
324           time. When --max-tries is used to enable transaction retries after
325           serialization/deadlock errors, the report includes the number of
326           retried transactions and the sum of all retries.
327
328       -r
329       --report-per-command
330           Report the following statistics for each command after the
331           benchmark finishes: the average per-statement latency (execution
332           time from the perspective of the client), the number of failures,
333           and the number of retries after serialization or deadlock errors in
334           this command. The report displays retry statistics only if the
335           --max-tries option is not equal to 1.
336
337       -R rate
338       --rate=rate
339           Execute transactions targeting the specified rate instead of
340           running as fast as possible (the default). The rate is given in
341           transactions per second. If the targeted rate is above the maximum
342           possible rate, the rate limit won't impact the results.
343
344           The rate is targeted by starting transactions along a
345           Poisson-distributed schedule time line. The expected start time
346           schedule moves forward based on when the client first started, not
347           when the previous transaction ended. That approach means that when
348           transactions go past their original scheduled end time, it is
349           possible for later ones to catch up again.
350
351           When throttling is active, the transaction latency reported at the
352           end of the run is calculated from the scheduled start times, so it
353           includes the time each transaction had to wait for the previous
354           transaction to finish. The wait time is called the schedule lag
355           time, and its average and maximum are also reported separately. The
356           transaction latency with respect to the actual transaction start
357           time, i.e., the time spent executing the transaction in the
358           database, can be computed by subtracting the schedule lag time from
359           the reported latency.
360
361           If --latency-limit is used together with --rate, a transaction can
362           lag behind so much that it is already over the latency limit when
363           the previous transaction ends, because the latency is calculated
364           from the scheduled start time. Such transactions are not sent to
365           the server, but are skipped altogether and counted separately.
366
367           A high schedule lag time is an indication that the system cannot
368           process transactions at the specified rate, with the chosen number
369           of clients and threads. When the average transaction execution time
370           is longer than the scheduled interval between each transaction,
371           each successive transaction will fall further behind, and the
372           schedule lag time will keep increasing the longer the test run is.
373           When that happens, you will have to reduce the specified
374           transaction rate.
375
376       -s scale_factor
377       --scale=scale_factor
378           Report the specified scale factor in pgbench's output. With the
379           built-in tests, this is not necessary; the correct scale factor
380           will be detected by counting the number of rows in the
381           pgbench_branches table. However, when testing only custom
382           benchmarks (-f option), the scale factor will be reported as 1
383           unless this option is used.
384
385       -S
386       --select-only
387           Run built-in select-only script. Shorthand for -b select-only.
388
389       -t transactions
390       --transactions=transactions
391           Number of transactions each client runs. Default is 10.
392
393       -T seconds
394       --time=seconds
395           Run the test for this many seconds, rather than a fixed number of
396           transactions per client.  -t and -T are mutually exclusive.
397
398       -v
399       --vacuum-all
400           Vacuum all four standard tables before running the test. With
401           neither -n nor -v, pgbench will vacuum the pgbench_tellers and
402           pgbench_branches tables, and will truncate pgbench_history.
403
404       --aggregate-interval=seconds
405           Length of aggregation interval (in seconds). May be used only with
406           -l option. With this option, the log contains per-interval summary
407           data, as described below.
408
409       --failures-detailed
410           Report failures in per-transaction and aggregation logs, as well as
411           in the main and per-script reports, grouped by the following types:
412
413           •   serialization failures;
414
415           •   deadlock failures;
416
417           See Failures and Serialization/Deadlock Retries for more
418           information.
419
420       --log-prefix=prefix
421           Set the filename prefix for the log files created by --log. The
422           default is pgbench_log.
423
424       --max-tries=number_of_tries
425           Enable retries for transactions with serialization/deadlock errors
426           and set the maximum number of these tries. This option can be
427           combined with the --latency-limit option which limits the total
428           time of all transaction tries; moreover, you cannot use an
429           unlimited number of tries (--max-tries=0) without --latency-limit
430           or --time. The default value is 1 and transactions with
431           serialization/deadlock errors are not retried. See Failures and
432           Serialization/Deadlock Retries for more information about retrying
433           such transactions.
434
435       --progress-timestamp
436           When showing progress (option -P), use a timestamp (Unix epoch)
437           instead of the number of seconds since the beginning of the run.
438           The unit is in seconds, with millisecond precision after the dot.
439           This helps compare logs generated by various tools.
440
441       --random-seed=seed
442           Set random generator seed. Seeds the system random number
443           generator, which then produces a sequence of initial generator
444           states, one for each thread. Values for seed may be: time (the
445           default, the seed is based on the current time), rand (use a strong
446           random source, failing if none is available), or an unsigned
447           decimal integer value. The random generator is invoked explicitly
448           from a pgbench script (random...  functions) or implicitly (for
449           instance option --rate uses it to schedule transactions). When
450           explicitly set, the value used for seeding is shown on the
451           terminal. Any value allowed for seed may also be provided through
452           the environment variable PGBENCH_RANDOM_SEED. To ensure that the
453           provided seed impacts all possible uses, put this option first or
454           use the environment variable.
455
456           Setting the seed explicitly allows to reproduce a pgbench run
457           exactly, as far as random numbers are concerned. As the random
458           state is managed per thread, this means the exact same pgbench run
459           for an identical invocation if there is one client per thread and
460           there are no external or data dependencies. From a statistical
461           viewpoint reproducing runs exactly is a bad idea because it can
462           hide the performance variability or improve performance unduly,
463           e.g., by hitting the same pages as a previous run. However, it may
464           also be of great help for debugging, for instance re-running a
465           tricky case which leads to an error. Use wisely.
466
467       --sampling-rate=rate
468           Sampling rate, used when writing data into the log, to reduce the
469           amount of log generated. If this option is given, only the
470           specified fraction of transactions are logged. 1.0 means all
471           transactions will be logged, 0.05 means only 5% of the transactions
472           will be logged.
473
474           Remember to take the sampling rate into account when processing the
475           log file. For example, when computing TPS values, you need to
476           multiply the numbers accordingly (e.g., with 0.01 sample rate,
477           you'll only get 1/100 of the actual TPS).
478
479       --show-script=scriptname
480           Show the actual code of builtin script scriptname on stderr, and
481           exit immediately.
482
483       --verbose-errors
484           Print messages about all errors and failures (errors without
485           retrying) including which limit for retries was exceeded and how
486           far it was exceeded for the serialization/deadlock failures. (Note
487           that in this case the output can be significantly increased.). See
488           Failures and Serialization/Deadlock Retries for more information.
489
490   Common Options
491       pgbench also accepts the following common command-line arguments for
492       connection parameters:
493
494       -h hostname
495       --host=hostname
496           The database server's host name
497
498       -p port
499       --port=port
500           The database server's port number
501
502       -U login
503       --username=login
504           The user name to connect as
505
506       -V
507       --version
508           Print the pgbench version and exit.
509
510       -?
511       --help
512           Show help about pgbench command line arguments, and exit.
513

EXIT STATUS

515       A successful run will exit with status 0. Exit status 1 indicates
516       static problems such as invalid command-line options or internal errors
517       which are supposed to never occur. Early errors that occur when
518       starting benchmark such as initial connection failures also exit with
519       status 1. Errors during the run such as database errors or problems in
520       the script will result in exit status 2. In the latter case, pgbench
521       will print partial results.
522

ENVIRONMENT

524       PGDATABASE
525       PGHOST
526       PGPORT
527       PGUSER
528           Default connection parameters.
529
530       This utility, like most other PostgreSQL utilities, uses the
531       environment variables supported by libpq (see Section 34.15).
532
533       The environment variable PG_COLOR specifies whether to use color in
534       diagnostic messages. Possible values are always, auto and never.
535

NOTES

537   What Is the “Transaction” Actually Performed in pgbench?
538       pgbench executes test scripts chosen randomly from a specified list.
539       The scripts may include built-in scripts specified with -b and
540       user-provided scripts specified with -f. Each script may be given a
541       relative weight specified after an @ so as to change its selection
542       probability. The default weight is 1. Scripts with a weight of 0 are
543       ignored.
544
545       The default built-in transaction script (also invoked with -b
546       tpcb-like) issues seven commands per transaction over randomly chosen
547       aid, tid, bid and delta. The scenario is inspired by the TPC-B
548       benchmark, but is not actually TPC-B, hence the name.
549
550        1. BEGIN;
551
552        2. UPDATE pgbench_accounts SET abalance = abalance + :delta WHERE aid
553           = :aid;
554
555        3. SELECT abalance FROM pgbench_accounts WHERE aid = :aid;
556
557        4. UPDATE pgbench_tellers SET tbalance = tbalance + :delta WHERE tid =
558           :tid;
559
560        5. UPDATE pgbench_branches SET bbalance = bbalance + :delta WHERE bid
561           = :bid;
562
563        6. INSERT INTO pgbench_history (tid, bid, aid, delta, mtime) VALUES
564           (:tid, :bid, :aid, :delta, CURRENT_TIMESTAMP);
565
566        7. END;
567
568       If you select the simple-update built-in (also -N), steps 4 and 5
569       aren't included in the transaction. This will avoid update contention
570       on these tables, but it makes the test case even less like TPC-B.
571
572       If you select the select-only built-in (also -S), only the SELECT is
573       issued.
574
575   Custom Scripts
576       pgbench has support for running custom benchmark scenarios by replacing
577       the default transaction script (described above) with a transaction
578       script read from a file (-f option). In this case a “transaction”
579       counts as one execution of a script file.
580
581       A script file contains one or more SQL commands terminated by
582       semicolons. Empty lines and lines beginning with -- are ignored. Script
583       files can also contain “meta commands”, which are interpreted by
584       pgbench itself, as described below.
585
586           Note
587           Before PostgreSQL 9.6, SQL commands in script files were terminated
588           by newlines, and so they could not be continued across lines. Now a
589           semicolon is required to separate consecutive SQL commands (though
590           an SQL command does not need one if it is followed by a meta
591           command). If you need to create a script file that works with both
592           old and new versions of pgbench, be sure to write each SQL command
593           on a single line ending with a semicolon.
594
595           It is assumed that pgbench scripts do not contain incomplete blocks
596           of SQL transactions. If at runtime the client reaches the end of
597           the script without completing the last transaction block, it will
598           be aborted.
599
600       There is a simple variable-substitution facility for script files.
601       Variable names must consist of letters (including non-Latin letters),
602       digits, and underscores, with the first character not being a digit.
603       Variables can be set by the command-line -D option, explained above, or
604       by the meta commands explained below. In addition to any variables
605       preset by -D command-line options, there are a few variables that are
606       preset automatically, listed in Table 288. A value specified for these
607       variables using -D takes precedence over the automatic presets. Once
608       set, a variable's value can be inserted into an SQL command by writing
609       :variablename. When running more than one client session, each session
610       has its own set of variables.  pgbench supports up to 255 variable uses
611       in one statement.
612
613       Table 288. pgbench Automatic Variables
614       ┌─────────────┬────────────────────────────┐
615Variable     Description                
616       ├─────────────┼────────────────────────────┤
617       │client_id    │ unique number identifying  │
618       │             │ the client session (starts │
619       │             │ from zero)                 │
620       ├─────────────┼────────────────────────────┤
621       │default_seed │ seed used in hash and      │
622       │             │ pseudorandom permutation   │
623       │             │ functions by default       │
624       ├─────────────┼────────────────────────────┤
625       │random_seed  │ random generator seed      │
626       │             │ (unless overwritten with   │
627       │             │ -D)                        │
628       ├─────────────┼────────────────────────────┤
629       │scale        │ current scale factor       │
630       └─────────────┴────────────────────────────┘
631
632       Script file meta commands begin with a backslash (\) and normally
633       extend to the end of the line, although they can be continued to
634       additional lines by writing backslash-return. Arguments to a meta
635       command are separated by white space. These meta commands are
636       supported:
637
638       \gset [prefix] \aset [prefix]
639           These commands may be used to end SQL queries, taking the place of
640           the terminating semicolon (;).
641
642           When the \gset command is used, the preceding SQL query is expected
643           to return one row, the columns of which are stored into variables
644           named after column names, and prefixed with prefix if provided.
645
646           When the \aset command is used, all combined SQL queries (separated
647           by \;) have their columns stored into variables named after column
648           names, and prefixed with prefix if provided. If a query returns no
649           row, no assignment is made and the variable can be tested for
650           existence to detect this. If a query returns more than one row, the
651           last value is kept.
652
653           \gset and \aset cannot be used in pipeline mode, since the query
654           results are not yet available by the time the commands would need
655           them.
656
657           The following example puts the final account balance from the first
658           query into variable abalance, and fills variables p_two and p_three
659           with integers from the third query. The result of the second query
660           is discarded. The result of the two last combined queries are
661           stored in variables four and five.
662
663               UPDATE pgbench_accounts
664                 SET abalance = abalance + :delta
665                 WHERE aid = :aid
666                 RETURNING abalance \gset
667               -- compound of two queries
668               SELECT 1 \;
669               SELECT 2 AS two, 3 AS three \gset p_
670               SELECT 4 AS four \; SELECT 5 AS five \aset
671
672       \if expression
673       \elif expression
674       \else
675       \endif
676           This group of commands implements nestable conditional blocks,
677           similarly to psql's \if expression. Conditional expressions are
678           identical to those with \set, with non-zero values interpreted as
679           true.
680
681       \set varname expression
682           Sets variable varname to a value calculated from expression. The
683           expression may contain the NULL constant, Boolean constants TRUE
684           and FALSE, integer constants such as 5432, double constants such as
685           3.14159, references to variables :variablename, operators with
686           their usual SQL precedence and associativity, function calls, SQL
687           CASE generic conditional expressions and parentheses.
688
689           Functions and most operators return NULL on NULL input.
690
691           For conditional purposes, non zero numerical values are TRUE, zero
692           numerical values and NULL are FALSE.
693
694           Too large or small integer and double constants, as well as integer
695           arithmetic operators (+, -, * and /) raise errors on overflows.
696
697           When no final ELSE clause is provided to a CASE, the default value
698           is NULL.
699
700           Examples:
701
702               \set ntellers 10 * :scale
703               \set aid (1021 * random(1, 100000 * :scale)) % \
704                          (100000 * :scale) + 1
705               \set divx CASE WHEN :x <> 0 THEN :y/:x ELSE NULL END
706
707       \sleep number [ us | ms | s ]
708           Causes script execution to sleep for the specified duration in
709           microseconds (us), milliseconds (ms) or seconds (s). If the unit is
710           omitted then seconds are the default.  number can be either an
711           integer constant or a :variablename reference to a variable having
712           an integer value.
713
714           Example:
715
716               \sleep 10 ms
717
718       \setshell varname command [ argument ... ]
719           Sets variable varname to the result of the shell command command
720           with the given argument(s). The command must return an integer
721           value through its standard output.
722
723           command and each argument can be either a text constant or a
724           :variablename reference to a variable. If you want to use an
725           argument starting with a colon, write an additional colon at the
726           beginning of argument.
727
728           Example:
729
730               \setshell variable_to_be_assigned command literal_argument :variable ::literal_starting_with_colon
731
732       \shell command [ argument ... ]
733           Same as \setshell, but the result of the command is discarded.
734
735           Example:
736
737               \shell command literal_argument :variable ::literal_starting_with_colon
738
739       \startpipeline
740       \endpipeline
741           These commands delimit the start and end of a pipeline of SQL
742           statements. In pipeline mode, statements are sent to the server
743           without waiting for the results of previous statements. See
744           Section 34.5 for more details. Pipeline mode requires the use of
745           extended query protocol.
746
747   Built-in Operators
748       The arithmetic, bitwise, comparison and logical operators listed in
749       Table 289 are built into pgbench and may be used in expressions
750       appearing in \set. The operators are listed in increasing precedence
751       order. Except as noted, operators taking two numeric inputs will
752       produce a double value if either input is double, otherwise they
753       produce an integer result.
754
755       Table 289. pgbench Operators
756       ┌────────────────────────────────────────┐
757       │                                        │
758       │       Operator                         │
759       │                                        │
760       │              .PP Description           │
761       │                                        │
762       │              .PP Example(s)            │
763       ├────────────────────────────────────────┤
764       │                                        │
765boolean OR booleanboolean
766       │                                        │
767       │              .PP Logical OR            │
768       │                                        │
769       │              .PP 5 or 0 → TRUE         │
770       ├────────────────────────────────────────┤
771       │                                        │
772boolean AND booleanboolean
773       │                                        │
774       │              .PP Logical AND           │
775       │                                        │
776       │              .PP 3 and 0 → FALSE       │
777       ├────────────────────────────────────────┤
778       │                                        │
779       │       NOT booleanboolean
780       │                                        │
781       │              .PP Logical NOT           │
782       │                                        │
783       │              .PP not false → TRUE      │
784       ├────────────────────────────────────────┤
785       │                                        │
786boolean IS [NOT]                 │
787       │       (NULL|TRUE|FALSE) → boolean
788       │                                        │
789       │              .PP Boolean value tests   │
790       │                                        │
791       │              .PP 1 is null → FALSE     │
792       ├────────────────────────────────────────┤
793       │                                        │
794value ISNULL|NOTNULL → boolean
795       │                                        │
796       │              .PP Nullness tests        │
797       │                                        │
798       │              .PP 1 notnull → TRUE      │
799       ├────────────────────────────────────────┤
800       │                                        │
801number = numberboolean
802       │                                        │
803       │              .PP Equal                 │
804       │                                        │
805       │              .PP 5 = 4 → FALSE         │
806       ├────────────────────────────────────────┤
807       │                                        │
808number <> numberboolean
809       │                                        │
810       │              .PP Not equal             │
811       │                                        │
812       │              .PP 5 <> 4 → TRUE         │
813       ├────────────────────────────────────────┤
814       │                                        │
815number != numberboolean
816       │                                        │
817       │              .PP Not equal             │
818       │                                        │
819       │              .PP 5 != 5 → FALSE        │
820       ├────────────────────────────────────────┤
821       │                                        │
822number < numberboolean
823       │                                        │
824       │              .PP Less than             │
825       │                                        │
826       │              .PP 5 < 4 → FALSE         │
827       ├────────────────────────────────────────┤
828       │                                        │
829number <= numberboolean
830       │                                        │
831       │              .PP Less than or equal to │
832       │                                        │
833       │              .PP 5 <= 4 → FALSE        │
834       ├────────────────────────────────────────┤
835       │                                        │
836number > numberboolean
837       │                                        │
838       │              .PP Greater than          │
839       │                                        │
840       │              .PP 5 > 4 → TRUE          │
841       ├────────────────────────────────────────┤
842       │                                        │
843number >= numberboolean
844       │                                        │
845       │              .PP Greater than or equal │
846       │       to                               │
847       │                                        │
848       │              .PP 5 >= 4 → TRUE         │
849       ├────────────────────────────────────────┤
850       │                                        │
851integer | integerinteger
852       │                                        │
853       │              .PP Bitwise OR            │
854       │                                        │
855       │              .PP 1 | 2 → 3             │
856       ├────────────────────────────────────────┤
857       │                                        │
858integer # integerinteger
859       │                                        │
860       │              .PP Bitwise XOR           │
861       │                                        │
862       │              .PP 1 # 3 → 2             │
863       ├────────────────────────────────────────┤
864       │                                        │
865integer & integerinteger
866       │                                        │
867       │              .PP Bitwise AND           │
868       │                                        │
869       │              .PP 1 & 3 → 1             │
870       ├────────────────────────────────────────┤
871       │                                        │
872       │       ~ integerinteger
873       │                                        │
874       │              .PP Bitwise NOT           │
875       │                                        │
876       │              .PP ~ 1 → -2              │
877       ├────────────────────────────────────────┤
878       │                                        │
879integer << integerinteger
880       │                                        │
881       │              .PP Bitwise shift left    │
882       │                                        │
883       │              .PP 1 << 2 → 4            │
884       ├────────────────────────────────────────┤
885       │                                        │
886integer >> integerinteger
887       │                                        │
888       │              .PP Bitwise shift right   │
889       │                                        │
890       │              .PP 8 >> 2 → 2            │
891       ├────────────────────────────────────────┤
892       │                                        │
893number + numbernumber
894       │                                        │
895       │              .PP Addition              │
896       │                                        │
897       │              .PP 5 + 4 → 9             │
898       ├────────────────────────────────────────┤
899       │                                        │
900number - numbernumber
901       │                                        │
902       │              .PP Subtraction           │
903       │                                        │
904       │              .PP 3 - 2.0 → 1.0         │
905       ├────────────────────────────────────────┤
906       │                                        │
907number * numbernumber
908       │                                        │
909       │              .PP Multiplication        │
910       │                                        │
911       │              .PP 5 * 4 → 20            │
912       ├────────────────────────────────────────┤
913       │                                        │
914number / numbernumber
915       │                                        │
916       │              .PP Division (truncates   │
917       │       the result towards zero if both  │
918       │       inputs are integers)             │
919       │                                        │
920       │              .PP 5 / 3 → 1             │
921       ├────────────────────────────────────────┤
922       │                                        │
923integer % integerinteger
924       │                                        │
925       │              .PP Modulo (remainder)    │
926       │                                        │
927       │              .PP 3 % 2 → 1             │
928       ├────────────────────────────────────────┤
929       │                                        │
930       │       - numbernumber
931       │                                        │
932       │              .PP Negation              │
933       │                                        │
934       │              .PP - 2.0 → -2.0          │
935       └────────────────────────────────────────┘
936
937   Built-In Functions
938       The functions listed in Table 290 are built into pgbench and may be
939       used in expressions appearing in \set.
940
941       Table 290. pgbench Functions
942       ┌────────────────────────────────────────┐
943       │                                        │
944       │       Function                         │
945       │                                        │
946       │              .PP Description           │
947       │                                        │
948       │              .PP Example(s)            │
949       ├────────────────────────────────────────┤
950       │                                        │
951abs ( number ) → same type as    │
952       │       input                            │
953       │                                        │
954       │              .PP Absolute value        │
955       │                                        │
956       │              .PP abs(-17) → 17         │
957       ├────────────────────────────────────────┤
958       │                                        │
959debug ( number ) → same type as  │
960       │       input                            │
961       │                                        │
962       │              .PP Prints the argument   │
963       │       to stderr, and returns the       │
964       │       argument.                        │
965       │                                        │
966       │              .PP debug(5432.1) →       │
967       │       5432.1                           │
968       ├────────────────────────────────────────┤
969       │                                        │
970double ( number ) → double       │
971       │                                        │
972       │              .PP Casts to double.      │
973       │                                        │
974       │              .PP double(5432) → 5432.0 │
975       ├────────────────────────────────────────┤
976       │                                        │
977exp ( number ) → double          │
978       │                                        │
979       │              .PP Exponential (e raised │
980       │       to the given power)              │
981       │                                        │
982       │              .PP exp(1.0) →            │
983       │       2.718281828459045                │
984       ├────────────────────────────────────────┤
985       │                                        │
986greatest ( number [, ... ] ) →   │
987       │       double if any argument is        │
988       │       double, else integer             │
989       │                                        │
990       │              .PP Selects the largest   │
991       │       value among the arguments.       │
992       │                                        │
993       │              .PP greatest(5, 4, 3, 2)  │
994       │       → 5                              │
995       ├────────────────────────────────────────┤
996       │                                        │
997hash ( value [, seed ] ) →       │
998       │       integer                          │
999       │                                        │
1000       │              .PP This is an alias for  │
1001hash_murmur2.                    │
1002       │                                        │
1003       │              .PP hash(10, 5432) →      │
1004       │       -5817877081768721676             │
1005       ├────────────────────────────────────────┤
1006       │                                        │
1007hash_fnv1a ( value [, seed ] ) → │
1008       │       integer                          │
1009       │                                        │
1010       │              .PP Computes FNV-1a hash. │
1011       │                                        │
1012       │              .PP hash_fnv1a(10, 5432)  │
1013       │       → -7793829335365542153           │
1014       ├────────────────────────────────────────┤
1015       │                                        │
1016hash_murmur2 ( value [, seed ] ) │
1017       │       → integer                        │
1018       │                                        │
1019       │              .PP Computes MurmurHash2  
1020       │       hash.                            │
1021       │                                        │
1022       │              .PP hash_murmur2(10,      │
1023       │       5432) → -5817877081768721676     │
1024       ├────────────────────────────────────────┤
1025       │                                        │
1026int ( number ) → integer         │
1027       │                                        │
1028       │              .PP Casts to integer.     │
1029       │                                        │
1030       │              .PP int(5.4 + 3.8) → 9    │
1031       ├────────────────────────────────────────┤
1032       │                                        │
1033least ( number [, ... ] ) →      │
1034       │       double if any argument is        │
1035       │       double, else integer             │
1036       │                                        │
1037       │              .PP Selects the smallest  │
1038       │       value among the arguments.       │
1039       │                                        │
1040       │              .PP least(5, 4, 3, 2.1) → │
1041       │       2.1                              │
1042       ├────────────────────────────────────────┤
1043       │                                        │
1044ln ( number ) → double           │
1045       │                                        │
1046       │              .PP Natural logarithm     │
1047       │                                        │
1048       │              .PP ln(2.718281828459045) │
1049       │       → 1.0                            │
1050       ├────────────────────────────────────────┤
1051       │                                        │
1052mod ( integer, integer ) →       │
1053       │       integer                          │
1054       │                                        │
1055       │              .PP Modulo (remainder)    │
1056       │                                        │
1057       │              .PP mod(54, 32) → 22      │
1058       ├────────────────────────────────────────┤
1059       │                                        │
1060permute ( i, size [, seed ] ) →  │
1061       │       integer                          │
1062       │                                        │
1063       │              .PP Permuted value of i,  │
1064       │       in the range [0, size). This is  │
1065       │       the new position of i (modulo    │
1066size) in a pseudorandom          │
1067       │       permutation of the integers      │
1068       │       0...size-1, parameterized by     │
1069seed, see below.                 │
1070       │                                        │
1071       │              .PP permute(0, 4) → an    │
1072       │       integer between 0 and 3          │
1073       ├────────────────────────────────────────┤
1074       │                                        │
1075pi () → double                   │
1076       │                                        │
1077       │              .PP Approximate value of  │
1078       │       π                                │
1079       │                                        │
1080       │              .PP pi() →                │
1081       │       3.14159265358979323846           │
1082       ├────────────────────────────────────────┤
1083       │                                        │
1084pow ( x, y ) → double            │
1085       │                                        │
1086       │              .PP power ( x, y ) →      │
1087       │       double                           │
1088       │                                        │
1089       │              .PP x raised to the power │
1090       │       of y
1091       │                                        │
1092       │              .PP pow(2.0, 10) → 1024.0 │
1093       ├────────────────────────────────────────┤
1094       │                                        │
1095random ( lb, ub ) → integer      │
1096       │                                        │
1097       │              .PP Computes a            │
1098       │       uniformly-distributed random     │
1099       │       integer in [lb, ub].             │
1100       │                                        │
1101       │              .PP random(1, 10) → an    │
1102       │       integer between 1 and 10         │
1103       ├────────────────────────────────────────┤
1104       │                                        │
1105random_exponential ( lb, ub,     │
1106parameter ) → integer            │
1107       │                                        │
1108       │              .PP Computes an           │
1109       │       exponentially-distributed random │
1110       │       integer in [lb, ub], see below.  │
1111       │                                        │
1112       │              .PP random_exponential(1, │
1113       │       10, 3.0) → an integer between 1  │
1114       │       and 10                           │
1115       ├────────────────────────────────────────┤
1116       │                                        │
1117random_gaussian ( lb, ub,        │
1118parameter ) → integer            │
1119       │                                        │
1120       │              .PP Computes a            │
1121       │       Gaussian-distributed random      │
1122       │       integer in [lb, ub], see below.  │
1123       │                                        │
1124       │              .PP random_gaussian(1,    │
1125       │       10, 2.5) → an integer between 1  │
1126       │       and 10                           │
1127       ├────────────────────────────────────────┤
1128       │                                        │
1129random_zipfian ( lb, ub,         │
1130parameter ) → integer            │
1131       │                                        │
1132       │              .PP Computes a            │
1133       │       Zipfian-distributed random       │
1134       │       integer in [lb, ub], see below.  │
1135       │                                        │
1136       │              .PP random_zipfian(1, 10, │
1137       │       1.5) → an integer between 1 and  │
1138       │       10                               │
1139       ├────────────────────────────────────────┤
1140       │                                        │
1141sqrt ( number ) → double         │
1142       │                                        │
1143       │              .PP Square root           │
1144       │                                        │
1145       │              .PP sqrt(2.0) →           │
1146       │       1.414213562                      │
1147       └────────────────────────────────────────┘
1148
1149       The random function generates values using a uniform distribution, that
1150       is all the values are drawn within the specified range with equal
1151       probability. The random_exponential, random_gaussian and random_zipfian
1152       functions require an additional double parameter which determines the
1153       precise shape of the distribution.
1154
1155       •   For an exponential distribution, parameter controls the
1156           distribution by truncating a quickly-decreasing exponential
1157           distribution at parameter, and then projecting onto integers
1158           between the bounds. To be precise, with
1159
1160               f(x) = exp(-parameter * (x - min) / (max - min + 1)) / (1 - exp(-parameter))
1161
1162           Then value i between min and max inclusive is drawn with
1163           probability: f(i) - f(i + 1).
1164
1165           Intuitively, the larger the parameter, the more frequently values
1166           close to min are accessed, and the less frequently values close to
1167           max are accessed. The closer to 0 parameter is, the flatter (more
1168           uniform) the access distribution. A crude approximation of the
1169           distribution is that the most frequent 1% values in the range,
1170           close to min, are drawn parameter% of the time. The parameter value
1171           must be strictly positive.
1172
1173       •   For a Gaussian distribution, the interval is mapped onto a standard
1174           normal distribution (the classical bell-shaped Gaussian curve)
1175           truncated at -parameter on the left and +parameter on the right.
1176           Values in the middle of the interval are more likely to be drawn.
1177           To be precise, if PHI(x) is the cumulative distribution function of
1178           the standard normal distribution, with mean mu defined as (max +
1179           min) / 2.0, with
1180
1181               f(x) = PHI(2.0 * parameter * (x - mu) / (max - min + 1)) /
1182                      (2.0 * PHI(parameter) - 1)
1183
1184           then value i between min and max inclusive is drawn with
1185           probability: f(i + 0.5) - f(i - 0.5). Intuitively, the larger the
1186           parameter, the more frequently values close to the middle of the
1187           interval are drawn, and the less frequently values close to the min
1188           and max bounds. About 67% of values are drawn from the middle 1.0 /
1189           parameter, that is a relative 0.5 / parameter around the mean, and
1190           95% in the middle 2.0 / parameter, that is a relative 1.0 /
1191           parameter around the mean; for instance, if parameter is 4.0, 67%
1192           of values are drawn from the middle quarter (1.0 / 4.0) of the
1193           interval (i.e., from 3.0 / 8.0 to 5.0 / 8.0) and 95% from the
1194           middle half (2.0 / 4.0) of the interval (second and third
1195           quartiles). The minimum allowed parameter value is 2.0.
1196
1197       •   random_zipfian generates a bounded Zipfian distribution.  parameter
1198           defines how skewed the distribution is. The larger the parameter,
1199           the more frequently values closer to the beginning of the interval
1200           are drawn. The distribution is such that, assuming the range starts
1201           from 1, the ratio of the probability of drawing k versus drawing
1202           k+1 is ((k+1)/k)**parameter. For example, random_zipfian(1, ...,
1203           2.5) produces the value 1 about (2/1)**2.5 = 5.66 times more
1204           frequently than 2, which itself is produced (3/2)**2.5 = 2.76 times
1205           more frequently than 3, and so on.
1206
1207           pgbench's implementation is based on "Non-Uniform Random Variate
1208           Generation", Luc Devroye, p. 550-551, Springer 1986. Due to
1209           limitations of that algorithm, the parameter value is restricted to
1210           the range [1.001, 1000].
1211
1212           Note
1213           When designing a benchmark which selects rows non-uniformly, be
1214           aware that the rows chosen may be correlated with other data such
1215           as IDs from a sequence or the physical row ordering, which may skew
1216           performance measurements.
1217
1218           To avoid this, you may wish to use the permute function, or some
1219           other additional step with similar effect, to shuffle the selected
1220           rows and remove such correlations.
1221
1222       Hash functions hash, hash_murmur2 and hash_fnv1a accept an input value
1223       and an optional seed parameter. In case the seed isn't provided the
1224       value of :default_seed is used, which is initialized randomly unless
1225       set by the command-line -D option.
1226
1227       permute accepts an input value, a size, and an optional seed parameter.
1228       It generates a pseudorandom permutation of integers in the range [0,
1229       size), and returns the index of the input value in the permuted values.
1230       The permutation chosen is parameterized by the seed, which defaults to
1231       :default_seed, if not specified. Unlike the hash functions, permute
1232       ensures that there are no collisions or holes in the output values.
1233       Input values outside the interval are interpreted modulo the size. The
1234       function raises an error if the size is not positive.  permute can be
1235       used to scatter the distribution of non-uniform random functions such
1236       as random_zipfian or random_exponential so that values drawn more often
1237       are not trivially correlated. For instance, the following pgbench
1238       script simulates a possible real world workload typical for social
1239       media and blogging platforms where a few accounts generate excessive
1240       load:
1241
1242           \set size 1000000
1243           \set r random_zipfian(1, :size, 1.07)
1244           \set k 1 + permute(:r, :size)
1245
1246       In some cases several distinct distributions are needed which don't
1247       correlate with each other and this is when the optional seed parameter
1248       comes in handy:
1249
1250           \set k1 1 + permute(:r, :size, :default_seed + 123)
1251           \set k2 1 + permute(:r, :size, :default_seed + 321)
1252
1253       A similar behavior can also be approximated with hash:
1254
1255           \set size 1000000
1256           \set r random_zipfian(1, 100 * :size, 1.07)
1257           \set k 1 + abs(hash(:r)) % :size
1258
1259       However, since hash generates collisions, some values will not be
1260       reachable and others will be more frequent than expected from the
1261       original distribution.
1262
1263       As an example, the full definition of the built-in TPC-B-like
1264       transaction is:
1265
1266           \set aid random(1, 100000 * :scale)
1267           \set bid random(1, 1 * :scale)
1268           \set tid random(1, 10 * :scale)
1269           \set delta random(-5000, 5000)
1270           BEGIN;
1271           UPDATE pgbench_accounts SET abalance = abalance + :delta WHERE aid = :aid;
1272           SELECT abalance FROM pgbench_accounts WHERE aid = :aid;
1273           UPDATE pgbench_tellers SET tbalance = tbalance + :delta WHERE tid = :tid;
1274           UPDATE pgbench_branches SET bbalance = bbalance + :delta WHERE bid = :bid;
1275           INSERT INTO pgbench_history (tid, bid, aid, delta, mtime) VALUES (:tid, :bid, :aid, :delta, CURRENT_TIMESTAMP);
1276           END;
1277
1278       This script allows each iteration of the transaction to reference
1279       different, randomly-chosen rows. (This example also shows why it's
1280       important for each client session to have its own variables — otherwise
1281       they'd not be independently touching different rows.)
1282
1283   Per-Transaction Logging
1284       With the -l option (but without the --aggregate-interval option),
1285       pgbench writes information about each transaction to a log file. The
1286       log file will be named prefix.nnn, where prefix defaults to
1287       pgbench_log, and nnn is the PID of the pgbench process. The prefix can
1288       be changed by using the --log-prefix option. If the -j option is 2 or
1289       higher, so that there are multiple worker threads, each will have its
1290       own log file. The first worker will use the same name for its log file
1291       as in the standard single worker case. The additional log files for the
1292       other workers will be named prefix.nnn.mmm, where mmm is a sequential
1293       number for each worker starting with 1.
1294
1295       Each line in a log file describes one transaction. It contains the
1296       following space-separated fields:
1297
1298       client_id
1299           identifies the client session that ran the transaction
1300
1301       transaction_no
1302           counts how many transactions have been run by that session
1303
1304       time
1305           transaction's elapsed time, in microseconds
1306
1307       script_no
1308           identifies the script file that was used for the transaction
1309           (useful when multiple scripts are specified with -f or -b)
1310
1311       time_epoch
1312           transaction's completion time, as a Unix-epoch time stamp
1313
1314       time_us
1315           fractional-second part of transaction's completion time, in
1316           microseconds
1317
1318       schedule_lag
1319           transaction start delay, that is the difference between the
1320           transaction's scheduled start time and the time it actually
1321           started, in microseconds (present only if --rate is specified)
1322
1323       retries
1324           count of retries after serialization or deadlock errors during the
1325           transaction (present only if --max-tries is not equal to one)
1326
1327       When both --rate and --latency-limit are used, the time for a skipped
1328       transaction will be reported as skipped. If the transaction ends with a
1329       failure, its time will be reported as failed. If you use the
1330       --failures-detailed option, the time of the failed transaction will be
1331       reported as serialization or deadlock depending on the type of failure
1332       (see Failures and Serialization/Deadlock Retries for more information).
1333
1334       Here is a snippet of a log file generated in a single-client run:
1335
1336           0 199 2241 0 1175850568 995598
1337           0 200 2465 0 1175850568 998079
1338           0 201 2513 0 1175850569 608
1339           0 202 2038 0 1175850569 2663
1340
1341       Another example with --rate=100 and --latency-limit=5 (note the
1342       additional schedule_lag column):
1343
1344           0 81 4621 0 1412881037 912698 3005
1345           0 82 6173 0 1412881037 914578 4304
1346           0 83 skipped 0 1412881037 914578 5217
1347           0 83 skipped 0 1412881037 914578 5099
1348           0 83 4722 0 1412881037 916203 3108
1349           0 84 4142 0 1412881037 918023 2333
1350           0 85 2465 0 1412881037 919759 740
1351
1352       In this example, transaction 82 was late, because its latency (6.173
1353       ms) was over the 5 ms limit. The next two transactions were skipped,
1354       because they were already late before they were even started.
1355
1356       The following example shows a snippet of a log file with failures and
1357       retries, with the maximum number of tries set to 10 (note the
1358       additional retries column):
1359
1360           3 0 47423 0 1499414498 34501 3
1361           3 1 8333 0 1499414498 42848 0
1362           3 2 8358 0 1499414498 51219 0
1363           4 0 72345 0 1499414498 59433 6
1364           1 3 41718 0 1499414498 67879 4
1365           1 4 8416 0 1499414498 76311 0
1366           3 3 33235 0 1499414498 84469 3
1367           0 0 failed 0 1499414498 84905 9
1368           2 0 failed 0 1499414498 86248 9
1369           3 4 8307 0 1499414498 92788 0
1370
1371       If the --failures-detailed option is used, the type of failure is
1372       reported in the time like this:
1373
1374           3 0 47423 0 1499414498 34501 3
1375           3 1 8333 0 1499414498 42848 0
1376           3 2 8358 0 1499414498 51219 0
1377           4 0 72345 0 1499414498 59433 6
1378           1 3 41718 0 1499414498 67879 4
1379           1 4 8416 0 1499414498 76311 0
1380           3 3 33235 0 1499414498 84469 3
1381           0 0 serialization 0 1499414498 84905 9
1382           2 0 serialization 0 1499414498 86248 9
1383           3 4 8307 0 1499414498 92788 0
1384
1385       When running a long test on hardware that can handle a lot of
1386       transactions, the log files can become very large. The --sampling-rate
1387       option can be used to log only a random sample of transactions.
1388
1389   Aggregated Logging
1390       With the --aggregate-interval option, a different format is used for
1391       the log files. Each log line describes one aggregation interval. It
1392       contains the following space-separated fields:
1393
1394       interval_start
1395           start time of the interval, as a Unix-epoch time stamp
1396
1397       num_transactions
1398           number of transactions within the interval
1399
1400       sum_latency
1401           sum of transaction latencies
1402
1403       sum_latency_2
1404           sum of squares of transaction latencies
1405
1406       min_latency
1407           minimum transaction latency
1408
1409       max_latency
1410           maximum transaction latency
1411
1412       sum_lag
1413           sum of transaction start delays (zero unless --rate is specified)
1414
1415       sum_lag_2
1416           sum of squares of transaction start delays (zero unless --rate is
1417           specified)
1418
1419       min_lag
1420           minimum transaction start delay (zero unless --rate is specified)
1421
1422       max_lag
1423           maximum transaction start delay (zero unless --rate is specified)
1424
1425       skipped
1426           number of transactions skipped because they would have started too
1427           late (zero unless --rate and --latency-limit are specified)
1428
1429       retried
1430           number of retried transactions (zero unless --max-tries is not
1431           equal to one)
1432
1433       retries
1434           number of retries after serialization or deadlock errors (zero
1435           unless --max-tries is not equal to one)
1436
1437       serialization_failures
1438           number of transactions that got a serialization error and were not
1439           retried afterwards (zero unless --failures-detailed is specified)
1440
1441       deadlock_failures
1442           number of transactions that got a deadlock error and were not
1443           retried afterwards (zero unless --failures-detailed is specified)
1444
1445       Here is some example output generated with these options:
1446
1447           pgbench --aggregate-interval=10 --time=20 --client=10 --log --rate=1000 --latency-limit=10 --failures-detailed --max-tries=10 test
1448
1449           1650260552 5178 26171317 177284491527 1136 44462 2647617 7321113867 0 9866 64 7564 28340 4148 0
1450           1650260562 4808 25573984 220121792172 1171 62083 3037380 9666800914 0 9998 598 7392 26621 4527 0
1451
1452       Notice that while the plain (unaggregated) log format shows which
1453       script was used for each transaction, the aggregated format does not.
1454       Therefore if you need per-script data, you need to aggregate the data
1455       on your own.
1456
1457   Per-Statement Report
1458       With the -r option, pgbench collects the following statistics for each
1459       statement:
1460
1461       •   latency — elapsed transaction time for each statement.  pgbench
1462           reports an average value of all successful runs of the statement.
1463
1464       •   The number of failures in this statement. See Failures and
1465           Serialization/Deadlock Retries for more information.
1466
1467       •   The number of retries after a serialization or a deadlock error in
1468           this statement. See Failures and Serialization/Deadlock Retries for
1469           more information.
1470
1471       The report displays retry statistics only if the --max-tries option is
1472       not equal to 1.
1473
1474       All values are computed for each statement executed by every client and
1475       are reported after the benchmark has finished.
1476
1477       For the default script, the output will look similar to this:
1478
1479           starting vacuum...end.
1480           transaction type: <builtin: TPC-B (sort of)>
1481           scaling factor: 1
1482           query mode: simple
1483           number of clients: 10
1484           number of threads: 1
1485           maximum number of tries: 1
1486           number of transactions per client: 1000
1487           number of transactions actually processed: 10000/10000
1488           number of failed transactions: 0 (0.000%)
1489           number of transactions above the 50.0 ms latency limit: 1311/10000 (13.110 %)
1490           latency average = 28.488 ms
1491           latency stddev = 21.009 ms
1492           initial connection time = 69.068 ms
1493           tps = 346.224794 (without initial connection time)
1494           statement latencies in milliseconds and failures:
1495              0.012  0  \set aid random(1, 100000 * :scale)
1496              0.002  0  \set bid random(1, 1 * :scale)
1497              0.002  0  \set tid random(1, 10 * :scale)
1498              0.002  0  \set delta random(-5000, 5000)
1499              0.319  0  BEGIN;
1500              0.834  0  UPDATE pgbench_accounts SET abalance = abalance + :delta WHERE aid = :aid;
1501              0.641  0  SELECT abalance FROM pgbench_accounts WHERE aid = :aid;
1502             11.126  0  UPDATE pgbench_tellers SET tbalance = tbalance + :delta WHERE tid = :tid;
1503             12.961  0  UPDATE pgbench_branches SET bbalance = bbalance + :delta WHERE bid = :bid;
1504              0.634  0  INSERT INTO pgbench_history (tid, bid, aid, delta, mtime) VALUES (:tid, :bid, :aid, :delta, CURRENT_TIMESTAMP);
1505              1.957  0  END;
1506
1507       Another example of output for the default script using serializable
1508       default transaction isolation level (PGOPTIONS='-c
1509       default_transaction_isolation=serializable' pgbench ...):
1510
1511           starting vacuum...end.
1512           transaction type: <builtin: TPC-B (sort of)>
1513           scaling factor: 1
1514           query mode: simple
1515           number of clients: 10
1516           number of threads: 1
1517           maximum number of tries: 10
1518           number of transactions per client: 1000
1519           number of transactions actually processed: 6317/10000
1520           number of failed transactions: 3683 (36.830%)
1521           number of transactions retried: 7667 (76.670%)
1522           total number of retries: 45339
1523           number of transactions above the 50.0 ms latency limit: 106/6317 (1.678 %)
1524           latency average = 17.016 ms
1525           latency stddev = 13.283 ms
1526           initial connection time = 45.017 ms
1527           tps = 186.792667 (without initial connection time)
1528           statement latencies in milliseconds, failures and retries:
1529             0.006     0      0  \set aid random(1, 100000 * :scale)
1530             0.001     0      0  \set bid random(1, 1 * :scale)
1531             0.001     0      0  \set tid random(1, 10 * :scale)
1532             0.001     0      0  \set delta random(-5000, 5000)
1533             0.385     0      0  BEGIN;
1534             0.773     0      1  UPDATE pgbench_accounts SET abalance = abalance + :delta WHERE aid = :aid;
1535             0.624     0      0  SELECT abalance FROM pgbench_accounts WHERE aid = :aid;
1536             1.098   320   3762  UPDATE pgbench_tellers SET tbalance = tbalance + :delta WHERE tid = :tid;
1537             0.582  3363  41576  UPDATE pgbench_branches SET bbalance = bbalance + :delta WHERE bid = :bid;
1538             0.465     0      0  INSERT INTO pgbench_history (tid, bid, aid, delta, mtime) VALUES (:tid, :bid, :aid, :delta, CURRENT_TIMESTAMP);
1539             1.933     0      0  END;
1540
1541       If multiple script files are specified, all statistics are reported
1542       separately for each script file.
1543
1544       Note that collecting the additional timing information needed for
1545       per-statement latency computation adds some overhead. This will slow
1546       average execution speed and lower the computed TPS. The amount of
1547       slowdown varies significantly depending on platform and hardware.
1548       Comparing average TPS values with and without latency reporting enabled
1549       is a good way to measure if the timing overhead is significant.
1550
1551   Failures and Serialization/Deadlock Retries
1552       When executing pgbench, there are three main types of errors:
1553
1554       •   Errors of the main program. They are the most serious and always
1555           result in an immediate exit from pgbench with the corresponding
1556           error message. They include:
1557
1558           •   errors at the beginning of pgbench (e.g. an invalid option
1559               value);
1560
1561           •   errors in the initialization mode (e.g. the query to create
1562               tables for built-in scripts fails);
1563
1564           •   errors before starting threads (e.g. could not connect to the
1565               database server, syntax error in the meta command, thread
1566               creation failure);
1567
1568           •   internal pgbench errors (which are supposed to never occur...).
1569
1570       •   Errors when the thread manages its clients (e.g. the client could
1571           not start a connection to the database server / the socket for
1572           connecting the client to the database server has become invalid).
1573           In such cases all clients of this thread stop while other threads
1574           continue to work.
1575
1576       •   Direct client errors. They lead to immediate exit from pgbench with
1577           the corresponding error message only in the case of an internal
1578           pgbench error (which are supposed to never occur...). Otherwise in
1579           the worst case they only lead to the abortion of the failed client
1580           while other clients continue their run (but some client errors are
1581           handled without an abortion of the client and reported separately,
1582           see below). Later in this section it is assumed that the discussed
1583           errors are only the direct client errors and they are not internal
1584           pgbench errors.
1585
1586       A client's run is aborted in case of a serious error; for example, the
1587       connection with the database server was lost or the end of script was
1588       reached without completing the last transaction. In addition, if
1589       execution of an SQL or meta command fails for reasons other than
1590       serialization or deadlock errors, the client is aborted. Otherwise, if
1591       an SQL command fails with serialization or deadlock errors, the client
1592       is not aborted. In such cases, the current transaction is rolled back,
1593       which also includes setting the client variables as they were before
1594       the run of this transaction (it is assumed that one transaction script
1595       contains only one transaction; see What Is the "Transaction" Actually
1596       Performed in pgbench?  for more information). Transactions with
1597       serialization or deadlock errors are repeated after rollbacks until
1598       they complete successfully or reach the maximum number of tries
1599       (specified by the --max-tries option) / the maximum time of retries
1600       (specified by the --latency-limit option) / the end of benchmark
1601       (specified by the --time option). If the last trial run fails, this
1602       transaction will be reported as failed but the client is not aborted
1603       and continues to work.
1604
1605           Note
1606           Without specifying the --max-tries option, a transaction will never
1607           be retried after a serialization or deadlock error because its
1608           default value is 1. Use an unlimited number of tries
1609           (--max-tries=0) and the --latency-limit option to limit only the
1610           maximum time of tries. You can also use the --time option to limit
1611           the benchmark duration under an unlimited number of tries.
1612
1613           Be careful when repeating scripts that contain multiple
1614           transactions: the script is always retried completely, so
1615           successful transactions can be performed several times.
1616
1617           Be careful when repeating transactions with shell commands. Unlike
1618           the results of SQL commands, the results of shell commands are not
1619           rolled back, except for the variable value of the \setshell
1620           command.
1621
1622       The latency of a successful transaction includes the entire time of
1623       transaction execution with rollbacks and retries. The latency is
1624       measured only for successful transactions and commands but not for
1625       failed transactions or commands.
1626
1627       The main report contains the number of failed transactions. If the
1628       --max-tries option is not equal to 1, the main report also contains
1629       statistics related to retries: the total number of retried transactions
1630       and total number of retries. The per-script report inherits all these
1631       fields from the main report. The per-statement report displays retry
1632       statistics only if the --max-tries option is not equal to 1.
1633
1634       If you want to group failures by basic types in per-transaction and
1635       aggregation logs, as well as in the main and per-script reports, use
1636       the --failures-detailed option. If you also want to distinguish all
1637       errors and failures (errors without retrying) by type including which
1638       limit for retries was exceeded and how much it was exceeded by for the
1639       serialization/deadlock failures, use the --verbose-errors option.
1640
1641   Good Practices
1642       It is very easy to use pgbench to produce completely meaningless
1643       numbers. Here are some guidelines to help you get useful results.
1644
1645       In the first place, never believe any test that runs for only a few
1646       seconds. Use the -t or -T option to make the run last at least a few
1647       minutes, so as to average out noise. In some cases you could need hours
1648       to get numbers that are reproducible. It's a good idea to try the test
1649       run a few times, to find out if your numbers are reproducible or not.
1650
1651       For the default TPC-B-like test scenario, the initialization scale
1652       factor (-s) should be at least as large as the largest number of
1653       clients you intend to test (-c); else you'll mostly be measuring update
1654       contention. There are only -s rows in the pgbench_branches table, and
1655       every transaction wants to update one of them, so -c values in excess
1656       of -s will undoubtedly result in lots of transactions blocked waiting
1657       for other transactions.
1658
1659       The default test scenario is also quite sensitive to how long it's been
1660       since the tables were initialized: accumulation of dead rows and dead
1661       space in the tables changes the results. To understand the results you
1662       must keep track of the total number of updates and when vacuuming
1663       happens. If autovacuum is enabled it can result in unpredictable
1664       changes in measured performance.
1665
1666       A limitation of pgbench is that it can itself become the bottleneck
1667       when trying to test a large number of client sessions. This can be
1668       alleviated by running pgbench on a different machine from the database
1669       server, although low network latency will be essential. It might even
1670       be useful to run several pgbench instances concurrently, on several
1671       client machines, against the same database server.
1672
1673   Security
1674       If untrusted users have access to a database that has not adopted a
1675       secure schema usage pattern, do not run pgbench in that database.
1676       pgbench uses unqualified names and does not manipulate the search path.
1677
1678
1679
1680PostgreSQL 15.4                      2023                           PGBENCH(1)
Impressum