InformIT

PostgreSQL: Tuning SQL Statements Efficiently

Date: Dec 28, 2001

Article is provided courtesy of Sams.

Return to the article

Since the first programs were written, programmers and administrators have tried to tune their applications to reach the maximum amount of performance. This article provides an overview of how PostgreSQL databases can be tuned efficiently. You will learn how a query is executed by the database, and what you can do to increase the overall performance of your PostgreSQL server.

Since the first programs were written, programmers and administrators have tried to tune their applications to reach the maximum amount of performance. Back in the early days, people optimized their programs by hacking some assembler code. With the introduction of SQL, a lot of work has moved to the optimizer of a database. Finding the best way through a query may be difficult. In many cases, it is necessary to give the SQL optimizer some hints so the query can be executed faster.

In this article, we will provide an overview of how PostgreSQL databases can be tuned efficiently. You will learn how a query is executed by the database, and what you can do to increase the overall performance of your PostgreSQL server.

Tuning databases has always been a crucial thing. In this section, you learn about the basics of tuning a PostgreSQL database efficiently. In general, two types of tuning can be distinguished: the performance of the hardware and the queries sent to the server can be tuned.

Hardware Tuning

To understand hardware performance issues, it is important to understand what is going on inside a database and a computer. Information is stored on hard disks, in memory, and in the CPU itself (registers). Every piece of information processed by the system has to be loaded into the CPU—the longer it takes to load the data, the lower the performance of your system will be.

Caching is a method to reduce the average time data needs to reach the CPU. The target is to keep as much information as possible in memory. In many cases, this raises the overall performance of your system.

Another important thing is the sort buffer of your database, which defines the amount of data the database is allowed to sort in memory before writing to a temporary file. Because hard disks are much slower than RAM, it is recommended to sort as much data as possible in the memory, as long as there is enough RAM available on the system. If the system is lacking memory, the kernel has to swap to disk; this decreases the performance of your system.

The target of tuning is to find the right settings for your server. If the amount of cache is too high, your system runs out of memory, and swapping decreases the overall performance of the database. If the amount of cache is too low, your system suffers because of additional I/O operations. The same applies to the size of the sort buffers. It takes some skill to find the right setting for your systems. There are no general rules because it largely depends on the type of operations you have to perform with your database.

Tuning Individual SQL Statements

Let's have a look at how individual SQL statements can be tuned. To do this, we create a database called tuning using the shell command createdb:

 [hs@athlon hs]$ createdb tuning
CREATE DATABASE

If the database has successfully been created, we use a small Perl script to generate some data:

#!/usr/bin/perl
 
open(DATA, "> data.sql") or die "cannot open data.sql for writing\n";
 
print DATA "CREATE TABLE data1 (id int4, val numeric(9,2));\n";
print DATA "CREATE TABLE data2 (id int4, val numeric(9,2));\n";
 
# inserting data into the first table
print DATA "COPY data1 FROM stdin;\n";
for   (my $i=0; $i<100000; $i++)
{
    print DATA "$i ".cos($i)."\n";
}
print DATA "\\.\n";
 
# creating a second table and inserting data
print DATA "COPY data2 FROM stdin;\n";
for   ($i=0; $i<10000; $i++)
{
    $j=$i*2;
    print DATA "$j ".($i%10)."\n";
    print DATA "$j ".($i%11)."\n";
}
print DATA "\\.\n";
 
close(DATA);

We create two tables, and insert 120.000 records into the tables. We recommend that you test your optimal settings with the expected amount of data your database has to face—otherwise, the results may differ significantly.

After running the script shown above, we can insert the data in file data.sql. It contains all the records we have just created:

[hs@athlon perl]$ psql tuning < data.sql
CREATE
CREATE

On my testing platform (Athlon 500, 512MB Ram, RedHat 7.1 on XFS filesystem, 15GB IBM IDE hard disk) the operation takes less than four seconds to complete.

Let's see if the data has been inserted into the database correctly. We use psql tuning to connect to the database and then look at the data structure:

tuning=# \d data1
      Table "data1"
 Attribute |   Type   | Modifier
-----------+--------------+----------
 id    | integer   |
 val    | numeric(9,2) |
 
tuning=# \d data2
      Table "data2"
 Attribute |   Type   | Modifier
-----------+--------------+----------
 id    | integer   |
 val    | numeric(9,2) |

The database contains two tables. Let's perform a simple query. We quit psql using \q, and send the command to the server using psql. We have chosen this way to execute the query; otherwise, we couldn't use the time Shell command:

[hs@athlon perl]$ time psql tuning -c "SELECT * FROM data1 WHERE id=20000";
 id  | val
-------+------
 20000 | 0.81
(1 row)
 
 
real  0m0.295s
user  0m0.000s
sys   0m0.020s

As you can see, it takes about 0.3 seconds to execute the query. Let's have a look at what the database does internally:

tuning=# EXPLAIN SELECT * FROM data1 WHERE id=20000;
NOTICE: QUERY PLAN:
 
Seq Scan on data1 (cost=0.00..22.50 rows=10 width=16)
 
EXPLAIN

A sequential scan is performed because we have not defined an index yet. We define an index for every column and run the query again:

[hs@athlon perl]$ time psql tuning < makeindex.sql
CREATE
CREATE
CREATE
CREATE
 
real  0m7.766s
user  0m0.010s
sys   0m0.000s

Creating all indices takes about 7.8 seconds. Let's run the query again:

[hs@athlon perl]$ time psql tuning -c "SELECT * FROM data1 WHERE id=20000";
 id  | val
-------+------
 20000 | 0.81
(1 row)
 
 
real  0m0.053s
user  0m0.010s
sys   0m0.000s

The query is several times faster now because the database performs an index scan instead of a sequential scan:

tuning=# EXPLAIN SELECT * FROM data1 WHERE id=20000;
NOTICE: QUERY PLAN:
 
Index Scan using idx_data1_id on data1 (cost=0.00..861.76 rows=1000 width=16)
 
EXPLAIN

However, defining indices is not all a programmer can do to speed up a query. In many situations, a lot of performance can be gained by giving the optimizer a few hints on how to execute a query. Let's have a look at a query that we can use to count all ids that contain the values 9 and 3 in the val columns. If two rows containing a certain id match our criteria, the value is counted. We also want the result to be distinct, which means that no value may be counted more than once:

[hs@athlon perl]$ time psql -c "SELECT DISTINCT COUNT(a.id) FROM data2 AS a, data2 AS b 
      WHERE a.id=b.id AND a.val=3 AND b.val=9" -d tuning
 count
-------
  182
(1 row)
 
 
real  0m0.152s
user  0m0.020s
sys   0m0.010s

The query returns 182, which is the correct amount of ids. Let's have a look at the execution plan of the query. The execution plan can be generated by using the EXPLAIN command:

[hs@athlon perl]$ time psql -c "EXPLAIN SELECT DISTINCT COUNT(a.id) FROM data2 AS a, data2 AS b 
      WHERE a.id=b.id AND a.val=3 AND b.val=9" -d tuning
NOTICE: QUERY PLAN:
 
Unique (cost=274.66..274.67 rows=1 width=8)
 -> Sort (cost=274.66..274.66 rows=1 width=8)
    -> Aggregate (cost=274.65..274.65 rows=1 width=8)
       -> Merge Join (cost=268.65..273.65 rows=400 width=8)
          -> Sort (cost=134.33..134.33 rows=200 width=4)
             -> Index Scan using idx_data2_val on data2 a (cost=0.00..126.68 rows=200 width=4)
          -> Sort (cost=134.33..134.33 rows=200 width=4)
             -> Index Scan using idx_data2_val on data2 b (cost=0.00..126.68 rows=200 width=4)
 
EXPLAIN
 
real  0m0.081s
user  0m0.020s
sys   0m0.000s

According to the data returned by PostgreSQL, a lot of different operations have to be processed to find the right result. Especially the sort operations seem to be very crucial because a lot of data is involved in the process.

In order to speed up the query, we perform the same operation as before, but this time we tell the optimizer to turn off sort operations. This can easily be done by setting the runtime parameter enable_sort to off. Note that this parameter is normally set to on. If you want to set it to off globally, you have to edit the postgresql.conf file in your data directory:

[hs@athlon perl]$ time psql -c "SET enable_sort TO off; SELECT DISTINCT COUNT(a.id) 
          FROM data2 AS a, data2 AS b WHERE a.id=b.id AND a.val=3 AND b.val=9" -d tuning
 count
-------
  182
(1 row)
 
 
real  0m0.137s
user  0m0.000s
sys   0m0.020s

The query seems to be 10% faster now, which is already a significant change. If the difference between the two times is rather slow, we recommend that you perform the test several times with different values so that caching effects can be avoided.

Let's try to turn the hash joins off as well:

[hs@athlon perl]$ time psql -c "SET enable_sort TO off; SET enable_hashjoin TO off; 
     SELECT DISTINCT COUNT(a.id) FROM data2 AS a, data2 AS b WHERE a.id=b.id 
     AND a.val=3 AND b.val=9" -d tuning
 count
-------
  182
(1 row)
 
 
real  0m0.334s
user  0m0.020s
sys   0m0.010s

Now, the query is much slower than before. Although the query can still be executed fast, the optimizer cannot find a real quick way through the query anymore.

In the execution plan in the following listing, we can see what is done by the database internally. Because many operations may not be done, the database has found another way through the query:

[hs@athlon perl]$ time psql -c "SET enable_sort TO off; SET enable_hashjoin TO off; EXPLAIN SELECT
DISTINCT COUNT(a.id) FROM data2 AS a, data2 AS b WHERE a.id=b.id AND a.val=3 
     AND b.val=9" -d tuning 
NOTICE: QUERY PLAN:
 
Unique (cost=100001955.24..100001955.25 rows=1 width=8)
 -> Sort (cost=100001955.24..100001955.24 rows=1 width=8)
    -> Aggregate (cost=1955.23..1955.23 rows=1 width=8)
       -> Merge Join (cost=0.00..1954.23 rows=400 width=8)
          -> Index Scan using idx_data2_id on data2 a (cost=0.00..974.62 rows=200 width=4)
          -> Index Scan using idx_data2_id on data2 b (cost=0.00..974.62 rows=200 width=4)
 
EXPLAIN
 
real  0m0.084s
user  0m0.020s
sys   0m0.000s

The previous example shows that influencing the way the optimizer works does not always lead to better results. In many cases, the execution plan is very close to the optimum, but this may not be true any more, especially when performing complex queries. The reason for that lies in the number of ways a query can be processed. The more tables involved in the query, the more settings have to be checked by the optimizer. For very complex queries, the optimizer does not check all possibilities any more (this cannot be done), so the execution plan may not lead to the best results.

Let's have a look at a second example:

[hs@athlon perl]$ time psql -c "SELECT data1.id FROM data1, data2 WHERE data1.id=data2.id 
      ORDER BY data1.id DESC LIMIT 5" -d tuning
 id
-------
 19998
 19998
 19996
 19996
 19994
(5 rows)
 
 
real  0m1.846s
user  0m0.010s
sys   0m0.010s

This time, we want to find all ids in the data1 table, which can also be found in table number two. The result has to be in a descending order. As you can see, it takes nearly two seconds to complete the query.

[hs@athlon perl]$ time psql -c "EXPLAIN SELECT data1.id FROM data1, data2 WHERE data1.id=data2.id 
     ORDER BY data1.id DESC LIMIT 5" -d tuning
NOTICE: QUERY PLAN:
 
Limit (cost=0.00..3.23 rows=5 width=8)
 -> Nested Loop (cost=0.00..12924101.01 rows=20000000 width=8)
    -> Index Scan Backward using idx_data1_id on data1 (cost=0.00..5854.61 rows=100000 width=4)
    -> Index Scan using idx_data2_id on data2 (cost=0.00..126.68 rows=200 width=4)
 
EXPLAIN
 
real  0m0.068s
user  0m0.020s
sys   0m0.000s

The execution plan tells us that the database has to perform a nested loop, which is bad, in many cases. Let's try the same query again, but this time we turn off the nested loops:

[hs@athlon perl]$ time psql -c "SET enable_nestloop TO off; SELECT data1.id FROM data1, data2 
     WHERE data1.id=data2.id ORDER BY data1.id DESC LIMIT 5" -d tuning
 id
-------
 19998
 19998
 19996
 19996
 19994
(5 rows)
 
 
real  0m0.911s
user  0m0.020s
sys   0m0.000s

Wow, the query needed only 0.9 seconds instead of 1.8 seconds. The execution plan of the modified query tell us why this way of executing the query is so much faster:

[hs@athlon perl]$ time psql -c "SET enable_nestloop TO off; EXPLAIN SELECT data1.id 
FROM data1, data2 WHERE data1.id=data2.id ORDER BY data1.id DESC LIMIT 5" -d tuning
NOTICE: QUERY PLAN:
 
Limit (cost=3988128.89..3988128.89 rows=5 width=8)
 -> Sort (cost=3988128.89..3988128.89 rows=20000000 width=8)
    -> Merge Join (cost=0.00..8279.22 rows=20000000 width=8)
       -> Index Scan using idx_data1_id on data1 (cost=0.00..5854.61 rows=100000 width=4)
       -> Index Scan using idx_data2_id on data2 (cost=0.00..924.62 rows=20000 width=4)
 
EXPLAIN
 
real  0m0.066s
sys   0m0.010s
user  0m0.010s

The nested loop has been substituted by a merge join and a sort operation, which is much faster in this example.

Conclusion

You can see that a lot of performance can be gained by setting PostgreSQL's runtime parameter correctly. Although the default settings execute most queries really quickly, it is still worth performing some basic tuning. Especially complex queries may be accelerated significantly.

There are no general rules for tuning, and so many things have to be done using trial and error, but I guess most people will like this kind of work.

800 East 96th Street, Indianapolis, Indiana 46240