Home > Articles > Data

📄 Contents

  1. Hardware Tuning
  2. Tuning Individual SQL Statements
  3. Conclusion
Like this article? We recommend

Like this article? We recommend

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.

InformIT Promotional Mailings & Special Offers

I would like to receive exclusive offers and hear about products from InformIT and its family of brands. I can unsubscribe at any time.

Overview


Pearson Education, Inc., 221 River Street, Hoboken, New Jersey 07030, (Pearson) presents this site to provide information about products and services that can be purchased through this site.

This privacy notice provides an overview of our commitment to privacy and describes how we collect, protect, use and share personal information collected through this site. Please note that other Pearson websites and online products and services have their own separate privacy policies.

Collection and Use of Information


To conduct business and deliver products and services, Pearson collects and uses personal information in several ways in connection with this site, including:

Questions and Inquiries

For inquiries and questions, we collect the inquiry or question, together with name, contact details (email address, phone number and mailing address) and any other additional information voluntarily submitted to us through a Contact Us form or an email. We use this information to address the inquiry and respond to the question.

Online Store

For orders and purchases placed through our online store on this site, we collect order details, name, institution name and address (if applicable), email address, phone number, shipping and billing addresses, credit/debit card information, shipping options and any instructions. We use this information to complete transactions, fulfill orders, communicate with individuals placing orders or visiting the online store, and for related purposes.

Surveys

Pearson may offer opportunities to provide feedback or participate in surveys, including surveys evaluating Pearson products, services or sites. Participation is voluntary. Pearson collects information requested in the survey questions and uses the information to evaluate, support, maintain and improve products, services or sites, develop new products and services, conduct educational research and for other purposes specified in the survey.

Contests and Drawings

Occasionally, we may sponsor a contest or drawing. Participation is optional. Pearson collects name, contact information and other information specified on the entry form for the contest or drawing to conduct the contest or drawing. Pearson may collect additional personal information from the winners of a contest or drawing in order to award the prize and for tax reporting purposes, as required by law.

Newsletters

If you have elected to receive email newsletters or promotional mailings and special offers but want to unsubscribe, simply email information@informit.com.

Service Announcements

On rare occasions it is necessary to send out a strictly service related announcement. For instance, if our service is temporarily suspended for maintenance we might send users an email. Generally, users may not opt-out of these communications, though they can deactivate their account information. However, these communications are not promotional in nature.

Customer Service

We communicate with users on a regular basis to provide requested services and in regard to issues relating to their account we reply via email or phone in accordance with the users' wishes when a user submits their information through our Contact Us form.

Other Collection and Use of Information


Application and System Logs

Pearson automatically collects log data to help ensure the delivery, availability and security of this site. Log data may include technical information about how a user or visitor connected to this site, such as browser type, type of computer/device, operating system, internet service provider and IP address. We use this information for support purposes and to monitor the health of the site, identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents and appropriately scale computing resources.

Web Analytics

Pearson may use third party web trend analytical services, including Google Analytics, to collect visitor information, such as IP addresses, browser types, referring pages, pages visited and time spent on a particular site. While these analytical services collect and report information on an anonymous basis, they may use cookies to gather web trend information. The information gathered may enable Pearson (but not the third party web trend services) to link information with application and system log data. Pearson uses this information for system administration and to identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents, appropriately scale computing resources and otherwise support and deliver this site and its services.

Cookies and Related Technologies

This site uses cookies and similar technologies to personalize content, measure traffic patterns, control security, track use and access of information on this site, and provide interest-based messages and advertising. Users can manage and block the use of cookies through their browser. Disabling or blocking certain cookies may limit the functionality of this site.

Do Not Track

This site currently does not respond to Do Not Track signals.

Security


Pearson uses appropriate physical, administrative and technical security measures to protect personal information from unauthorized access, use and disclosure.

Children


This site is not directed to children under the age of 13.

Marketing


Pearson may send or direct marketing communications to users, provided that

  • Pearson will not use personal information collected or processed as a K-12 school service provider for the purpose of directed or targeted advertising.
  • Such marketing is consistent with applicable law and Pearson's legal obligations.
  • Pearson will not knowingly direct or send marketing communications to an individual who has expressed a preference not to receive marketing.
  • Where required by applicable law, express or implied consent to marketing exists and has not been withdrawn.

Pearson may provide personal information to a third party service provider on a restricted basis to provide marketing solely on behalf of Pearson or an affiliate or customer for whom Pearson is a service provider. Marketing preferences may be changed at any time.

Correcting/Updating Personal Information


If a user's personally identifiable information changes (such as your postal address or email address), we provide a way to correct or update that user's personal data provided to us. This can be done on the Account page. If a user no longer desires our service and desires to delete his or her account, please contact us at customer-service@informit.com and we will process the deletion of a user's account.

Choice/Opt-out


Users can always make an informed choice as to whether they should proceed with certain services offered by InformIT. If you choose to remove yourself from our mailing list(s) simply visit the following page and uncheck any communication you no longer want to receive: www.informit.com/u.aspx.

Sale of Personal Information


Pearson does not rent or sell personal information in exchange for any payment of money.

While Pearson does not sell personal information, as defined in Nevada law, Nevada residents may email a request for no sale of their personal information to NevadaDesignatedRequest@pearson.com.

Supplemental Privacy Statement for California Residents


California residents should read our Supplemental privacy statement for California residents in conjunction with this Privacy Notice. The Supplemental privacy statement for California residents explains Pearson's commitment to comply with California law and applies to personal information of California residents collected in connection with this site and the Services.

Sharing and Disclosure


Pearson may disclose personal information, as follows:

  • As required by law.
  • With the consent of the individual (or their parent, if the individual is a minor)
  • In response to a subpoena, court order or legal process, to the extent permitted or required by law
  • To protect the security and safety of individuals, data, assets and systems, consistent with applicable law
  • In connection the sale, joint venture or other transfer of some or all of its company or assets, subject to the provisions of this Privacy Notice
  • To investigate or address actual or suspected fraud or other illegal activities
  • To exercise its legal rights, including enforcement of the Terms of Use for this site or another contract
  • To affiliated Pearson companies and other companies and organizations who perform work for Pearson and are obligated to protect the privacy of personal information consistent with this Privacy Notice
  • To a school, organization, company or government agency, where Pearson collects or processes the personal information in a school setting or on behalf of such organization, company or government agency.

Links


This web site contains links to other sites. Please be aware that we are not responsible for the privacy practices of such other sites. We encourage our users to be aware when they leave our site and to read the privacy statements of each and every web site that collects Personal Information. This privacy statement applies solely to information collected by this web site.

Requests and Contact


Please contact us about this Privacy Notice or if you have any requests or questions relating to the privacy of your personal information.

Changes to this Privacy Notice


We may revise this Privacy Notice through an updated posting. We will identify the effective date of the revision in the posting. Often, updates are made to provide greater clarity or to comply with changes in regulatory requirements. If the updates involve material changes to the collection, protection, use or disclosure of Personal Information, Pearson will provide notice of the change through a conspicuous notice on this site or other appropriate way. Continued use of the site after the effective date of a posted revision evidences acceptance. Please contact us if you have questions or concerns about the Privacy Notice or any objection to any revisions.

Last Update: November 17, 2020