1PGBENCH(1)               PostgreSQL 12.6 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           number of transactions per client: 1000
30           number of transactions actually processed: 10000/10000
31           tps = 85.184871 (including connections establishing)
32           tps = 85.296346 (excluding connections establishing)
33
34       The first six lines report some of the most important parameter
35       settings. The next line reports the number of transactions completed
36       and intended (the latter being just the product of number of clients
37       and number of transactions per client); these will be equal unless the
38       run failed before completion. (In -T mode, only the actual number of
39       transactions is printed.) The last two lines report the number of
40       transactions per second, figured with and without counting the time to
41       start database sessions.
42
43       The default TPC-B-like transaction test requires specific tables to be
44       set up beforehand.  pgbench should be invoked with the -i (initialize)
45       option to create and populate these tables. (When you are testing a
46       custom script, you don't need this step, but will instead need to do
47       whatever setup your test needs.) Initialization looks like:
48
49           pgbench -i [ other-options ] dbname
50
51       where dbname is the name of the already-created database to test in.
52       (You may also need -h, -p, and/or -U options to specify how to connect
53       to the database server.)
54
55           Caution
56           pgbench -i creates four tables pgbench_accounts, pgbench_branches,
57           pgbench_history, and pgbench_tellers, destroying any existing
58           tables of these names. Be very careful to use another database if
59           you have tables having these names!
60
61       At the default “scale factor” of 1, the tables initially contain this
62       many rows:
63
64           table                   # of rows
65           ---------------------------------
66           pgbench_branches        1
67           pgbench_tellers         10
68           pgbench_accounts        100000
69           pgbench_history         0
70
71       You can (and, for most purposes, probably should) increase the number
72       of rows by using the -s (scale factor) option. The -F (fillfactor)
73       option might also be used at this point.
74
75       Once you have done the necessary setup, you can run your benchmark with
76       a command that doesn't include -i, that is
77
78           pgbench [ options ] dbname
79
80       In nearly all cases, you'll need some options to make a useful test.
81       The most important options are -c (number of clients), -t (number of
82       transactions), -T (time limit), and -f (specify a custom script file).
83       See below for a full list.
84

OPTIONS

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

EXIT STATUS

424       A successful run will exit with status 0. Exit status 1 indicates
425       static problems such as invalid command-line options. Errors during the
426       run such as database errors or problems in the script will result in
427       exit status 2. In the latter case, pgbench will print partial results.
428

ENVIRONMENT

430       PGHOST
431       PGPORT
432       PGUSER
433           Default connection parameters.
434
435       This utility, like most other PostgreSQL utilities, uses the
436       environment variables supported by libpq (see Section 33.14).
437

NOTES

439   What Is the “Transaction” Actually Performed in pgbench?
440       pgbench executes test scripts chosen randomly from a specified list.
441       The scripts may include built-in scripts specified with -b and
442       user-provided scripts specified with -f. Each script may be given a
443       relative weight specified after an @ so as to change its selection
444       probability. The default weight is 1. Scripts with a weight of 0 are
445       ignored.
446
447       The default built-in transaction script (also invoked with -b
448       tpcb-like) issues seven commands per transaction over randomly chosen
449       aid, tid, bid and delta. The scenario is inspired by the TPC-B
450       benchmark, but is not actually TPC-B, hence the name.
451
452        1. BEGIN;
453
454        2. UPDATE pgbench_accounts SET abalance = abalance + :delta WHERE aid
455           = :aid;
456
457        3. SELECT abalance FROM pgbench_accounts WHERE aid = :aid;
458
459        4. UPDATE pgbench_tellers SET tbalance = tbalance + :delta WHERE tid =
460           :tid;
461
462        5. UPDATE pgbench_branches SET bbalance = bbalance + :delta WHERE bid
463           = :bid;
464
465        6. INSERT INTO pgbench_history (tid, bid, aid, delta, mtime) VALUES
466           (:tid, :bid, :aid, :delta, CURRENT_TIMESTAMP);
467
468        7. END;
469
470       If you select the simple-update built-in (also -N), steps 4 and 5
471       aren't included in the transaction. This will avoid update contention
472       on these tables, but it makes the test case even less like TPC-B.
473
474       If you select the select-only built-in (also -S), only the SELECT is
475       issued.
476
477   Custom Scripts
478       pgbench has support for running custom benchmark scenarios by replacing
479       the default transaction script (described above) with a transaction
480       script read from a file (-f option). In this case a “transaction”
481       counts as one execution of a script file.
482
483       A script file contains one or more SQL commands terminated by
484       semicolons. Empty lines and lines beginning with -- are ignored. Script
485       files can also contain “meta commands”, which are interpreted by
486       pgbench itself, as described below.
487
488           Note
489           Before PostgreSQL 9.6, SQL commands in script files were terminated
490           by newlines, and so they could not be continued across lines. Now a
491           semicolon is required to separate consecutive SQL commands (though
492           a SQL command does not need one if it is followed by a meta
493           command). If you need to create a script file that works with both
494           old and new versions of pgbench, be sure to write each SQL command
495           on a single line ending with a semicolon.
496
497       There is a simple variable-substitution facility for script files.
498       Variable names must consist of letters (including non-Latin letters),
499       digits, and underscores, with the first character not being a digit.
500       Variables can be set by the command-line -D option, explained above, or
501       by the meta commands explained below. In addition to any variables
502       preset by -D command-line options, there are a few variables that are
503       preset automatically, listed in Table 258. A value specified for these
504       variables using -D takes precedence over the automatic presets. Once
505       set, a variable's value can be inserted into a SQL command by writing
506       :variablename. When running more than one client session, each session
507       has its own set of variables.  pgbench supports up to 255 variable uses
508       in one statement.
509
510       Table 258. Automatic Variables
511       ┌─────────────┬────────────────────────────┐
512Variable     Description                
513       ├─────────────┼────────────────────────────┤
514       │client_id    │ unique number identifying  │
515       │             │ the client session (starts │
516       │             │ from zero)                 │
517       ├─────────────┼────────────────────────────┤
518       │default_seed │ seed used in hash          │
519       │             │ functions by default       │
520       ├─────────────┼────────────────────────────┤
521       │random_seed  │ random generator seed      │
522       │             │ (unless overwritten with   │
523       │             │ -D)                        │
524       ├─────────────┼────────────────────────────┤
525       │scale        │ current scale factor       │
526       └─────────────┴────────────────────────────┘
527
528       Script file meta commands begin with a backslash (\) and normally
529       extend to the end of the line, although they can be continued to
530       additional lines by writing backslash-return. Arguments to a meta
531       command are separated by white space. These meta commands are
532       supported:
533
534       \gset [prefix]
535           This command may be used to end SQL queries, taking the place of
536           the terminating semicolon (;).
537
538           When this command is used, the preceding SQL query is expected to
539           return one row, the columns of which are stored into variables
540           named after column names, and prefixed with prefix if provided.
541
542           The following example puts the final account balance from the first
543           query into variable abalance, and fills variables p_two and p_three
544           with integers from the third query. The result of the second query
545           is discarded.
546
547               UPDATE pgbench_accounts
548                 SET abalance = abalance + :delta
549                 WHERE aid = :aid
550                 RETURNING abalance \gset
551               -- compound of two queries
552               SELECT 1 \;
553               SELECT 2 AS two, 3 AS three \gset p_
554
555
556       \if expression
557       \elif expression
558       \else
559       \endif
560           This group of commands implements nestable conditional blocks,
561           similarly to psql's \if expression. Conditional expressions are
562           identical to those with \set, with non-zero values interpreted as
563           true.
564
565       \set varname expression
566           Sets variable varname to a value calculated from expression. The
567           expression may contain the NULL constant, Boolean constants TRUE
568           and FALSE, integer constants such as 5432, double constants such as
569           3.14159, references to variables :variablename, operators with
570           their usual SQL precedence and associativity, function calls, SQL
571           CASE generic conditional expressions and parentheses.
572
573           Functions and most operators return NULL on NULL input.
574
575           For conditional purposes, non zero numerical values are TRUE, zero
576           numerical values and NULL are FALSE.
577
578           Too large or small integer and double constants, as well as integer
579           arithmetic operators (+, -, * and /) raise errors on overflows.
580
581           When no final ELSE clause is provided to a CASE, the default value
582           is NULL.
583
584           Examples:
585
586               \set ntellers 10 * :scale
587               \set aid (1021 * random(1, 100000 * :scale)) % \
588                          (100000 * :scale) + 1
589               \set divx CASE WHEN :x <> 0 THEN :y/:x ELSE NULL END
590
591       \sleep number [ us | ms | s ]
592           Causes script execution to sleep for the specified duration in
593           microseconds (us), milliseconds (ms) or seconds (s). If the unit is
594           omitted then seconds are the default.  number can be either an
595           integer constant or a :variablename reference to a variable having
596           an integer value.
597
598           Example:
599
600               \sleep 10 ms
601
602       \setshell varname command [ argument ... ]
603           Sets variable varname to the result of the shell command command
604           with the given argument(s). The command must return an integer
605           value through its standard output.
606
607           command and each argument can be either a text constant or a
608           :variablename reference to a variable. If you want to use an
609           argument starting with a colon, write an additional colon at the
610           beginning of argument.
611
612           Example:
613
614               \setshell variable_to_be_assigned command literal_argument :variable ::literal_starting_with_colon
615
616       \shell command [ argument ... ]
617           Same as \setshell, but the result of the command is discarded.
618
619           Example:
620
621               \shell command literal_argument :variable ::literal_starting_with_colon
622
623   Built-in Operators
624       The arithmetic, bitwise, comparison and logical operators listed in
625       Table 259 are built into pgbench and may be used in expressions
626       appearing in \set.
627
628       Table 259. pgbench Operators by Increasing Precedence
629       ┌──────────────────┬──────────────────┬───────────┬────────┐
630Operator          Description      Example   Result 
631       ├──────────────────┼──────────────────┼───────────┼────────┤
632       │OR                │ logical or       │ 5 or 0    │ TRUE   │
633       ├──────────────────┼──────────────────┼───────────┼────────┤
634       │AND               │ logical and      │ 3 and 0   │ FALSE  │
635       ├──────────────────┼──────────────────┼───────────┼────────┤
636       │NOT               │ logical not      │ not false │ TRUE   │
637       ├──────────────────┼──────────────────┼───────────┼────────┤
638       │IS [NOT]          │ value tests      │ 1 is null │ FALSE  │
639       │(NULL|TRUE|FALSE) │                  │           │        │
640       ├──────────────────┼──────────────────┼───────────┼────────┤
641       │ISNULL|NOTNULL    │ null tests       │ 1 notnull │ TRUE   │
642       ├──────────────────┼──────────────────┼───────────┼────────┤
643       │=                 │ is equal         │ 5 = 4     │ FALSE  │
644       ├──────────────────┼──────────────────┼───────────┼────────┤
645       │<>                │ is not equal     │ 5 <> 4    │ TRUE   │
646       ├──────────────────┼──────────────────┼───────────┼────────┤
647       │!=                │ is not equal     │ 5 != 5    │ FALSE  │
648       ├──────────────────┼──────────────────┼───────────┼────────┤
649       │<                 │ lower than       │ 5 < 4     │ FALSE  │
650       ├──────────────────┼──────────────────┼───────────┼────────┤
651       │<=                │ lower or equal   │ 5 <= 4    │ FALSE  │
652       ├──────────────────┼──────────────────┼───────────┼────────┤
653       │>                 │ greater than     │ 5 > 4     │ TRUE   │
654       ├──────────────────┼──────────────────┼───────────┼────────┤
655       │>=                │ greater or equal │ 5 >= 4    │ TRUE   │
656       ├──────────────────┼──────────────────┼───────────┼────────┤
657       │|                 │ integer bitwise  │ 1 | 2     │ 3      │
658       │                  │ OR               │           │        │
659       ├──────────────────┼──────────────────┼───────────┼────────┤
660       │#                 │ integer bitwise  │ 1 # 3     │ 2      │
661       │                  │ XOR              │           │        │
662       ├──────────────────┼──────────────────┼───────────┼────────┤
663       │&                 │ integer bitwise  │ 1 & 3     │ 1      │
664       │                  │ AND              │           │        │
665       ├──────────────────┼──────────────────┼───────────┼────────┤
666       │~                 │ integer bitwise  │ ~ 1       │ -2     │
667       │                  │ NOT              │           │        │
668       ├──────────────────┼──────────────────┼───────────┼────────┤
669       │<<                │ integer bitwise  │ 1 << 2    │ 4      │
670       │                  │ shift left       │           │        │
671       ├──────────────────┼──────────────────┼───────────┼────────┤
672       │>>                │ integer bitwise  │ 8 >> 2    │ 2      │
673       │                  │ shift right      │           │        │
674       ├──────────────────┼──────────────────┼───────────┼────────┤
675       │+                 │ addition         │ 5 + 4     │ 9      │
676       ├──────────────────┼──────────────────┼───────────┼────────┤
677       │-                 │ subtraction      │ 3 - 2.0   │ 1.0    │
678       ├──────────────────┼──────────────────┼───────────┼────────┤
679       │*                 │ multiplication   │ 5 * 4     │ 20     │
680       ├──────────────────┼──────────────────┼───────────┼────────┤
681       │/                 │ division         │ 5 / 3     │ 1      │
682       │                  │ (integer         │           │        │
683       │                  │ truncates the    │           │        │
684       │                  │ results)         │           │        │
685       ├──────────────────┼──────────────────┼───────────┼────────┤
686       │%                 │ modulo           │ 3 % 2     │ 1      │
687       ├──────────────────┼──────────────────┼───────────┼────────┤
688       │-                 │ opposite         │ - 2.0     │ -2.0   │
689       └──────────────────┴──────────────────┴───────────┴────────┘
690
691   Built-In Functions
692       The functions listed in Table 260 are built into pgbench and may be
693       used in expressions appearing in \set.
694
695       Table 260. pgbench Functions
696       ┌───────────────────────┬───────────────┬───────────────────────────┬───────────────────────┬────────────────────────┐
697Function               Return Type   Description               Example               Result                 
698       ├───────────────────────┼───────────────┼───────────────────────────┼───────────────────────┼────────────────────────┤
699abs(a)                 │ same as a     │ absolute                  │ abs(-17)              │ 17                     │
700       │                       │               │ value                     │                       │                        │
701       ├───────────────────────┼───────────────┼───────────────────────────┼───────────────────────┼────────────────────────┤
702debug(a)               │ same as a     │ print a to                │ debug(5432.1)         │ 5432.1                 │
703       │                       │               │ stderr,                   │                       │                        │
704       │                       │               │         and               │                       │                        │
705       │                       │               │ return a                  │                       │                        │
706       ├───────────────────────┼───────────────┼───────────────────────────┼───────────────────────┼────────────────────────┤
707double(i)              │ double        │ cast to                   │ double(5432)          │ 5432.0                 │
708       │                       │               │ double                    │                       │                        │
709       ├───────────────────────┼───────────────┼───────────────────────────┼───────────────────────┼────────────────────────┤
710exp(x)                 │ double        │ exponential               │ exp(1.0)              │ 2.718281828459045      │
711       ├───────────────────────┼───────────────┼───────────────────────────┼───────────────────────┼────────────────────────┤
712greatest(a [,          │ double if any │ largest value             │ greatest(5,           │ 5                      │
713... ] )                a is double,  │ among                     │ 4, 3, 2)              │                        │
714       │                       │ else integer  │ arguments                 │                       │                        │
715       ├───────────────────────┼───────────────┼───────────────────────────┼───────────────────────┼────────────────────────┤
716hash(a [,              │ integer       │ alias for                 │ hash(10,              │ -5817877081768721676   │
717seed ] )               │               │ hash_murmur2()            │ 5432)                 │                        │
718       ├───────────────────────┼───────────────┼───────────────────────────┼───────────────────────┼────────────────────────┤
719hash_fnv1a(a           │ integer       │ FNV-1a hash               │ hash_fnv1a(10,        │ -7793829335365542153   │
720[, seed ] )            │               │                           │ 5432)                 │                        │
721       ├───────────────────────┼───────────────┼───────────────────────────┼───────────────────────┼────────────────────────┤
722hash_murmur2(a         │ integer       │ MurmurHash2               │ hash_murmur2(10,      │ -5817877081768721676   │
723[, seed ] )            │               │ hash                      │ 5432)                 │                        │
724       ├───────────────────────┼───────────────┼───────────────────────────┼───────────────────────┼────────────────────────┤
725int(x)                 │ integer       │ cast to int               │ int(5.4 + 3.8)        │ 9                      │
726       ├───────────────────────┼───────────────┼───────────────────────────┼───────────────────────┼────────────────────────┤
727least(a [, ...         │ double if any │ smallest value            │ least(5, 4, 3,        │ 2.1                    │
728] )                    a is double,  │ among                     │ 2.1)                  │                        │
729       │                       │ else integer  │ arguments                 │                       │                        │
730       ├───────────────────────┼───────────────┼───────────────────────────┼───────────────────────┼────────────────────────┤
731ln(x)                  │ double        │ natural                   │ ln(2.718281828459045) │ 1.0                    │
732       │                       │               │ logarithm                 │                       │                        │
733       ├───────────────────────┼───────────────┼───────────────────────────┼───────────────────────┼────────────────────────┤
734mod(i, j)              │ integer       │ modulo                    │ mod(54, 32)           │ 22                     │
735       ├───────────────────────┼───────────────┼───────────────────────────┼───────────────────────┼────────────────────────┤
736pi()                   │ double        │ value of the              │ pi()                  │ 3.14159265358979323846 │
737       │                       │               │ constant PI               │                       │                        │
738       ├───────────────────────┼───────────────┼───────────────────────────┼───────────────────────┼────────────────────────┤
739pow(x, y),             │ double        │ exponentiation            │ pow(2.0, 10),         │ 1024.0                 │
740power(x, y)            │               │                           │ power(2.0, 10)        │                        │
741       ├───────────────────────┼───────────────┼───────────────────────────┼───────────────────────┼────────────────────────┤
742random(lb, ub)         │ integer       │ uniformly-distributed     │ random(1, 10)         │ an integer between 1   │
743       │                       │               │ random integer            │                       │ and 10                 │
744       │                       │               │ in [lb, ub]               │                       │                        │
745       ├───────────────────────┼───────────────┼───────────────────────────┼───────────────────────┼────────────────────────┤
746random_exponential(lb, │ integer       │ exponentially-distributed │ random_exponential(1, │ an integer between 1   │
747ub, parameter)         │               │ random integer in         │ 10, 3.0)              │ and 10                 │
748       │                       │               │ [lb, ub],                 │                       │                        │
749       │                       │               │               see         │                       │                        │
750       │                       │               │ below                     │                       │                        │
751       ├───────────────────────┼───────────────┼───────────────────────────┼───────────────────────┼────────────────────────┤
752random_gaussian(lb,    │ integer       │ Gaussian-distributed      │ random_gaussian(1,    │ an integer between 1   │
753ub, parameter)         │               │ random integer in [lb,    │ 10, 2.5)              │ and 10                 │
754       │                       │               │ ub],                      │                       │                        │
755       │                       │               │               see below   │                       │                        │
756       ├───────────────────────┼───────────────┼───────────────────────────┼───────────────────────┼────────────────────────┤
757random_zipfian(lb, ub, │ integer       │ Zipfian-distributed       │ random_zipfian(1, 10, │ an integer between 1   │
758parameter)             │               │ random integer in [lb,    │ 1.5)                  │ and 10                 │
759       │                       │               │ ub],                      │                       │                        │
760       │                       │               │               see below   │                       │                        │
761       ├───────────────────────┼───────────────┼───────────────────────────┼───────────────────────┼────────────────────────┤
762sqrt(x)                │ double        │ square root               │ sqrt(2.0)             │ 1.414213562            │
763       └───────────────────────┴───────────────┴───────────────────────────┴───────────────────────┴────────────────────────┘
764
765       The random function generates values using a uniform distribution, that
766       is all the values are drawn within the specified range with equal
767       probability. The random_exponential, random_gaussian and random_zipfian
768       functions require an additional double parameter which determines the
769       precise shape of the distribution.
770
771       ·   For an exponential distribution, parameter controls the
772           distribution by truncating a quickly-decreasing exponential
773           distribution at parameter, and then projecting onto integers
774           between the bounds. To be precise, with
775
776               f(x) = exp(-parameter * (x - min) / (max - min + 1)) / (1 - exp(-parameter))
777
778           Then value i between min and max inclusive is drawn with
779           probability: f(i) - f(i + 1).
780
781           Intuitively, the larger the parameter, the more frequently values
782           close to min are accessed, and the less frequently values close to
783           max are accessed. The closer to 0 parameter is, the flatter (more
784           uniform) the access distribution. A crude approximation of the
785           distribution is that the most frequent 1% values in the range,
786           close to min, are drawn parameter% of the time. The parameter value
787           must be strictly positive.
788
789       ·   For a Gaussian distribution, the interval is mapped onto a standard
790           normal distribution (the classical bell-shaped Gaussian curve)
791           truncated at -parameter on the left and +parameter on the right.
792           Values in the middle of the interval are more likely to be drawn.
793           To be precise, if PHI(x) is the cumulative distribution function of
794           the standard normal distribution, with mean mu defined as (max +
795           min) / 2.0, with
796
797               f(x) = PHI(2.0 * parameter * (x - mu) / (max - min + 1)) /
798                      (2.0 * PHI(parameter) - 1)
799
800           then value i between min and max inclusive is drawn with
801           probability: f(i + 0.5) - f(i - 0.5). Intuitively, the larger the
802           parameter, the more frequently values close to the middle of the
803           interval are drawn, and the less frequently values close to the min
804           and max bounds. About 67% of values are drawn from the middle 1.0 /
805           parameter, that is a relative 0.5 / parameter around the mean, and
806           95% in the middle 2.0 / parameter, that is a relative 1.0 /
807           parameter around the mean; for instance, if parameter is 4.0, 67%
808           of values are drawn from the middle quarter (1.0 / 4.0) of the
809           interval (i.e., from 3.0 / 8.0 to 5.0 / 8.0) and 95% from the
810           middle half (2.0 / 4.0) of the interval (second and third
811           quartiles). The minimum allowed parameter value is 2.0.
812
813       ·   random_zipfian generates a bounded Zipfian distribution.  parameter
814           defines how skewed the distribution is. The larger the parameter,
815           the more frequently values closer to the beginning of the interval
816           are drawn. The distribution is such that, assuming the range starts
817           from 1, the ratio of the probability of drawing k versus drawing
818           k+1 is ((k+1)/k)**parameter. For example, random_zipfian(1, ...,
819           2.5) produces the value 1 about (2/1)**2.5 = 5.66 times more
820           frequently than 2, which itself is produced (3/2)**2.5 = 2.76 times
821           more frequently than 3, and so on.
822
823           pgbench's implementation is based on "Non-Uniform Random Variate
824           Generation", Luc Devroye, p. 550-551, Springer 1986. Due to
825           limitations of that algorithm, the parameter value is restricted to
826           the range [1.001, 1000].
827
828       Hash functions hash, hash_murmur2 and hash_fnv1a accept an input value
829       and an optional seed parameter. In case the seed isn't provided the
830       value of :default_seed is used, which is initialized randomly unless
831       set by the command-line -D option. Hash functions can be used to
832       scatter the distribution of random functions such as random_zipfian or
833       random_exponential. For instance, the following pgbench script
834       simulates possible real world workload typical for social media and
835       blogging platforms where few accounts generate excessive load:
836
837           \set r random_zipfian(0, 100000000, 1.07)
838           \set k abs(hash(:r)) % 1000000
839
840       In some cases several distinct distributions are needed which don't
841       correlate with each other and this is when implicit seed parameter
842       comes in handy:
843
844           \set k1 abs(hash(:r, :default_seed + 123)) % 1000000
845           \set k2 abs(hash(:r, :default_seed + 321)) % 1000000
846
847       As an example, the full definition of the built-in TPC-B-like
848       transaction is:
849
850           \set aid random(1, 100000 * :scale)
851           \set bid random(1, 1 * :scale)
852           \set tid random(1, 10 * :scale)
853           \set delta random(-5000, 5000)
854           BEGIN;
855           UPDATE pgbench_accounts SET abalance = abalance + :delta WHERE aid = :aid;
856           SELECT abalance FROM pgbench_accounts WHERE aid = :aid;
857           UPDATE pgbench_tellers SET tbalance = tbalance + :delta WHERE tid = :tid;
858           UPDATE pgbench_branches SET bbalance = bbalance + :delta WHERE bid = :bid;
859           INSERT INTO pgbench_history (tid, bid, aid, delta, mtime) VALUES (:tid, :bid, :aid, :delta, CURRENT_TIMESTAMP);
860           END;
861
862       This script allows each iteration of the transaction to reference
863       different, randomly-chosen rows. (This example also shows why it's
864       important for each client session to have its own variables — otherwise
865       they'd not be independently touching different rows.)
866
867   Per-Transaction Logging
868       With the -l option (but without the --aggregate-interval option),
869       pgbench writes information about each transaction to a log file. The
870       log file will be named prefix.nnn, where prefix defaults to
871       pgbench_log, and nnn is the PID of the pgbench process. The prefix can
872       be changed by using the --log-prefix option. If the -j option is 2 or
873       higher, so that there are multiple worker threads, each will have its
874       own log file. The first worker will use the same name for its log file
875       as in the standard single worker case. The additional log files for the
876       other workers will be named prefix.nnn.mmm, where mmm is a sequential
877       number for each worker starting with 1.
878
879       The format of the log is:
880
881           client_id transaction_no time script_no time_epoch time_us [ schedule_lag ]
882
883       where client_id indicates which client session ran the transaction,
884       transaction_no counts how many transactions have been run by that
885       session, time is the total elapsed transaction time in microseconds,
886       script_no identifies which script file was used (useful when multiple
887       scripts were specified with -f or -b), and time_epoch/time_us are a
888       Unix-epoch time stamp and an offset in microseconds (suitable for
889       creating an ISO 8601 time stamp with fractional seconds) showing when
890       the transaction completed. The schedule_lag field is the difference
891       between the transaction's scheduled start time, and the time it
892       actually started, in microseconds. It is only present when the --rate
893       option is used. When both --rate and --latency-limit are used, the time
894       for a skipped transaction will be reported as skipped.
895
896       Here is a snippet of a log file generated in a single-client run:
897
898           0 199 2241 0 1175850568 995598
899           0 200 2465 0 1175850568 998079
900           0 201 2513 0 1175850569 608
901           0 202 2038 0 1175850569 2663
902
903       Another example with --rate=100 and --latency-limit=5 (note the
904       additional schedule_lag column):
905
906           0 81 4621 0 1412881037 912698 3005
907           0 82 6173 0 1412881037 914578 4304
908           0 83 skipped 0 1412881037 914578 5217
909           0 83 skipped 0 1412881037 914578 5099
910           0 83 4722 0 1412881037 916203 3108
911           0 84 4142 0 1412881037 918023 2333
912           0 85 2465 0 1412881037 919759 740
913
914       In this example, transaction 82 was late, because its latency (6.173
915       ms) was over the 5 ms limit. The next two transactions were skipped,
916       because they were already late before they were even started.
917
918       When running a long test on hardware that can handle a lot of
919       transactions, the log files can become very large. The --sampling-rate
920       option can be used to log only a random sample of transactions.
921
922   Aggregated Logging
923       With the --aggregate-interval option, a different format is used for
924       the log files:
925
926           interval_start num_transactions sum_latency sum_latency_2 min_latency max_latency [ sum_lag sum_lag_2 min_lag max_lag [ skipped ] ]
927
928       where interval_start is the start of the interval (as a Unix epoch time
929       stamp), num_transactions is the number of transactions within the
930       interval, sum_latency is the sum of the transaction latencies within
931       the interval, sum_latency_2 is the sum of squares of the transaction
932       latencies within the interval, min_latency is the minimum latency
933       within the interval, and max_latency is the maximum latency within the
934       interval. The next fields, sum_lag, sum_lag_2, min_lag, and max_lag,
935       are only present if the --rate option is used. They provide statistics
936       about the time each transaction had to wait for the previous one to
937       finish, i.e., the difference between each transaction's scheduled start
938       time and the time it actually started. The very last field, skipped, is
939       only present if the --latency-limit option is used, too. It counts the
940       number of transactions skipped because they would have started too
941       late. Each transaction is counted in the interval when it was
942       committed.
943
944       Here is some example output:
945
946           1345828501 5601 1542744 483552416 61 2573
947           1345828503 7884 1979812 565806736 60 1479
948           1345828505 7208 1979422 567277552 59 1391
949           1345828507 7685 1980268 569784714 60 1398
950           1345828509 7073 1979779 573489941 236 1411
951
952       Notice that while the plain (unaggregated) log file shows which script
953       was used for each transaction, the aggregated log does not. Therefore
954       if you need per-script data, you need to aggregate the data on your
955       own.
956
957   Per-Statement Latencies
958       With the -r option, pgbench collects the elapsed transaction time of
959       each statement executed by every client. It then reports an average of
960       those values, referred to as the latency for each statement, after the
961       benchmark has finished.
962
963       For the default script, the output will look similar to this:
964
965           starting vacuum...end.
966           transaction type: <builtin: TPC-B (sort of)>
967           scaling factor: 1
968           query mode: simple
969           number of clients: 10
970           number of threads: 1
971           number of transactions per client: 1000
972           number of transactions actually processed: 10000/10000
973           latency average = 15.844 ms
974           latency stddev = 2.715 ms
975           tps = 618.764555 (including connections establishing)
976           tps = 622.977698 (excluding connections establishing)
977           statement latencies in milliseconds:
978                   0.002  \set aid random(1, 100000 * :scale)
979                   0.005  \set bid random(1, 1 * :scale)
980                   0.002  \set tid random(1, 10 * :scale)
981                   0.001  \set delta random(-5000, 5000)
982                   0.326  BEGIN;
983                   0.603  UPDATE pgbench_accounts SET abalance = abalance + :delta WHERE aid = :aid;
984                   0.454  SELECT abalance FROM pgbench_accounts WHERE aid = :aid;
985                   5.528  UPDATE pgbench_tellers SET tbalance = tbalance + :delta WHERE tid = :tid;
986                   7.335  UPDATE pgbench_branches SET bbalance = bbalance + :delta WHERE bid = :bid;
987                   0.371  INSERT INTO pgbench_history (tid, bid, aid, delta, mtime) VALUES (:tid, :bid, :aid, :delta, CURRENT_TIMESTAMP);
988                   1.212  END;
989
990       If multiple script files are specified, the averages are reported
991       separately for each script file.
992
993       Note that collecting the additional timing information needed for
994       per-statement latency computation adds some overhead. This will slow
995       average execution speed and lower the computed TPS. The amount of
996       slowdown varies significantly depending on platform and hardware.
997       Comparing average TPS values with and without latency reporting enabled
998       is a good way to measure if the timing overhead is significant.
999
1000   Good Practices
1001       It is very easy to use pgbench to produce completely meaningless
1002       numbers. Here are some guidelines to help you get useful results.
1003
1004       In the first place, never believe any test that runs for only a few
1005       seconds. Use the -t or -T option to make the run last at least a few
1006       minutes, so as to average out noise. In some cases you could need hours
1007       to get numbers that are reproducible. It's a good idea to try the test
1008       run a few times, to find out if your numbers are reproducible or not.
1009
1010       For the default TPC-B-like test scenario, the initialization scale
1011       factor (-s) should be at least as large as the largest number of
1012       clients you intend to test (-c); else you'll mostly be measuring update
1013       contention. There are only -s rows in the pgbench_branches table, and
1014       every transaction wants to update one of them, so -c values in excess
1015       of -s will undoubtedly result in lots of transactions blocked waiting
1016       for other transactions.
1017
1018       The default test scenario is also quite sensitive to how long it's been
1019       since the tables were initialized: accumulation of dead rows and dead
1020       space in the tables changes the results. To understand the results you
1021       must keep track of the total number of updates and when vacuuming
1022       happens. If autovacuum is enabled it can result in unpredictable
1023       changes in measured performance.
1024
1025       A limitation of pgbench is that it can itself become the bottleneck
1026       when trying to test a large number of client sessions. This can be
1027       alleviated by running pgbench on a different machine from the database
1028       server, although low network latency will be essential. It might even
1029       be useful to run several pgbench instances concurrently, on several
1030       client machines, against the same database server.
1031
1032   Security
1033       If untrusted users have access to a database that has not adopted a
1034       secure schema usage pattern, do not run pgbench in that database.
1035       pgbench uses unqualified names and does not manipulate the search path.
1036
1037
1038
1039PostgreSQL 12.6                      2021                           PGBENCH(1)
Impressum