Thread: Performance problem with correlated sub-query
I have created a web app that stores and displays all the messages from my database maintenance jobs that run each night. The web app uses Java servlets and has PostgreSQL 7.0 as the back end.
When the user requests the first page, he gets a list of all the servers with maintenance records in the database, and a drop down list of all the dates of maintenance records. If the user chooses a date first, then the app uses a prepared statement with the date contained in a parameter, and this executes very quickly – no problems.
However, if the web page user does not choose a date, then the app uses a correlated sub-query to grab only the current (latest) day’s maintenance records. The query that is executed is:
select servername, databasename, message from messages o where o.date_of_msg =
(select max(date_of_msg) from messages i where i.servername = o.servername);
And this is a dog. It takes 15 – 20 minutes to execute the query (there are about 200,000 rows in the table). I have an index on (servername, date_of_msg), but it doesn’t seem to be used in this query.
Is there a way to improve the performance on this query?
Thanks,
Steve Howard
This message (including any attachments) contains confidential information intended for a specific individual and purpose, and is protected by law. If you are not the intended recipient, you should delete this message. Any disclosure, copying, or distribution of this message, or the taking of any action based on it, is strictly prohibited.
Howard, Steven (US - Tulsa) wrote: > select servername, databasename, message from messages o where > o.date_of_msg = (select max(date_of_msg) from messages i where > i.servername = o.servername); > > And this is a dog. It takes 15 – 20 minutes to execute the > query (there are about 200,000 rows in the table). I have an > index on (servername, date_of_msg), but it doesn’t seem to > be used in this query. Just off the top of my head: SELECT servername, databasename, message FROM messages o WHERE o.date_of_msg = ( SELECT date_of_msg FROM messages i WHERE i.servername = o.servername ORDER BY date_of_msg LIMIT 1 ); HTH, Mike Mascari
On Thu, 29 Apr 2004, Howard, Steven (US - Tulsa) wrote: > I have created a web app that stores and displays all the messages from > my database maintenance jobs that run each night. The web app uses Java > servlets and has PostgreSQL 7.0 as the back end. Step 1 is upgrade. ;) > However, if the web page user does not choose a date, then the app uses > a correlated sub-query to grab only the current (latest) day's > maintenance records. The query that is executed is: > > select servername, databasename, message from messages o where > o.date_of_msg = > > (select max(date_of_msg) from messages i where i.servername > = o.servername); This is likely to be running the subquery once for each row in messages, and probably not going to use an index in the inner either. The former might be optimized by recent versions. Changing the inner query to something like: (select date_of_msg from messages i where i.servername=o.servername order by date_of_msg desc limit 1) or changing it to use a subselect in from (something like): from messages o, (select servername, max(date_of_msg) from messages) i where o.servername=i.servername might both help, but I'm not sure either will work on 7.0. > And this is a dog. It takes 15 - 20 minutes to execute the query (there > are about 200,000 rows in the table). I have an index on (servername, > date_of_msg), but it doesn't seem to be used in this query. You might wish to play around with changing the indexes and the order of the columns in the multicolumn index as well.
Howard, Steven (US - Tulsa) wrote: > I have created a web app that stores and displays all the messages from > my database maintenance jobs that run each night. The web app uses Java > servlets and has PostgreSQL 7.0 as the back end. > > When the user requests the first page, he gets a list of all the servers > with maintenance records in the database, and a drop down list of all > the dates of maintenance records. If the user chooses a date first, then > the app uses a prepared statement with the date contained in a > parameter, and this executes very quickly – no problems. > > However, if the web page user does not choose a date, then the app uses > a correlated sub-query to grab only the current (latest) day’s > maintenance records. The query that is executed is: > > select servername, databasename, message from messages o where > o.date_of_msg = > > (select max(date_of_msg) from messages i where i.servername > = o.servername); > > And this is a dog. It takes 15 – 20 minutes to execute the query (there > are about 200,000 rows in the table). I have an index on (servername, > date_of_msg), but it doesn’t seem to be used in this query. Few basic checks.. - What does explain analyze says for the slow query? - Have you vacuumed and analyzed recently? - Have you done basic optimisations from default state? Check http://www.varlena.com/varlena/GeneralBits/Tidbits/perf.html and http://www.varlena.com/varlena/GeneralBits/Tidbits/annotated_conf_e.html And 7.0 is way too old. If you can afford to upgrade, upgrade to 7.4.2. HTH Shridhar
On 29/04/2004 14:34 "Howard, Steven (US - Tulsa)" wrote: > I have created a web app that stores and displays all the messages from > my database maintenance jobs that run each night. The web app uses Java > servlets and has PostgreSQL 7.0 as the back end. 7.0? That's positively ancient! > > When the user requests the first page, he gets a list of all the servers > with maintenance records in the database, and a drop down list of all > the dates of maintenance records. If the user chooses a date first, then > the app uses a prepared statement with the date contained in a > parameter, and this executes very quickly - no problems. > > > > However, if the web page user does not choose a date, then the app uses > a correlated sub-query to grab only the current (latest) day's > maintenance records. The query that is executed is: > > select servername, databasename, message from messages o where > o.date_of_msg = > > (select max(date_of_msg) from messages i where i.servername > = o.servername); > > > > And this is a dog. It takes 15 - 20 minutes to execute the query (there > are about 200,000 rows in the table). I have an index on (servername, > date_of_msg), but it doesn't seem to be used in this query. PG doesn't use indexes for things like count(), max, min()... You can avoid using max() by something like select my_date from my_table order by my_date desc limit 1; which will use the index. > > Is there a way to improve the performance on this query? In addition to the above, I'd strongly recommend upgrading to 7.4 to take advantage of the last ~4 years of continuous improvements. -- Paul Thomas +------------------------------+---------------------------------------------+ | Thomas Micro Systems Limited | Software Solutions for Business | | Computer Consultants | http://www.thomas-micro-systems-ltd.co.uk | +------------------------------+---------------------------------------------+
I apologize for my mistake in the version. I have 7.3, and not 7.0. However, I'll upgrade to 7.4. and work with some of the other suggestions made also. -----Original Message----- From: Paul Thomas [mailto:paul@tmsl.demon.co.uk] Sent: Thursday, April 29, 2004 9:20 AM To: Howard, Steven (US - Tulsa) Cc: pgsql-general @ postgresql . org Subject: Re: [GENERAL] Performance problem with correlated sub-query On 29/04/2004 14:34 "Howard, Steven (US - Tulsa)" wrote: > I have created a web app that stores and displays all the messages from > my database maintenance jobs that run each night. The web app uses Java > servlets and has PostgreSQL 7.0 as the back end. 7.0? That's positively ancient! > > When the user requests the first page, he gets a list of all the servers > with maintenance records in the database, and a drop down list of all > the dates of maintenance records. If the user chooses a date first, then > the app uses a prepared statement with the date contained in a > parameter, and this executes very quickly - no problems. > > > > However, if the web page user does not choose a date, then the app uses > a correlated sub-query to grab only the current (latest) day's > maintenance records. The query that is executed is: > > select servername, databasename, message from messages o where > o.date_of_msg = > > (select max(date_of_msg) from messages i where i.servername > = o.servername); > > > > And this is a dog. It takes 15 - 20 minutes to execute the query (there > are about 200,000 rows in the table). I have an index on (servername, > date_of_msg), but it doesn't seem to be used in this query. PG doesn't use indexes for things like count(), max, min()... You can avoid using max() by something like select my_date from my_table order by my_date desc limit 1; which will use the index. > > Is there a way to improve the performance on this query? In addition to the above, I'd strongly recommend upgrading to 7.4 to take advantage of the last ~4 years of continuous improvements. -- Paul Thomas +------------------------------+---------------------------------------- -----+ | Thomas Micro Systems Limited | Software Solutions for Business | | Computer Consultants | http://www.thomas-micro-systems-ltd.co.uk | +------------------------------+---------------------------------------- -----+ This message (including any attachments) contains confidential information intended for a specific individual and purpose,and is protected by law. If you are not the intended recipient, you should delete this message. Any disclosure,copying, or distribution of this message, or the taking of any action based on it, is strictly prohibited.