Обсуждение: Advice on optimizing select/index

Поиск
Список
Период
Сортировка

Advice on optimizing select/index

От
Niels Kristian Schjødt
Дата:
Hi, I have a database where one of my tables (Adverts) are requested a LOT. It's a relatively narrow table with 12
columns,but the size is growing pretty rapidly. The table is used i relation to another one called (Car), and in the
formof "cars has many adverts". I have indexed the foreign key car_id on Adverts. 

However the performance when doing a "SELECT .* FROM cars LEFT OUTER JOIN adverts on cars.id = adverts.car_id WHERE
cars.brand= 'Audi'" is too poor. I have identified that it's the Adverts table part that performs very bad, and it's by
farthe biggest of the two. I would like to optimize the query/index, but I don't know if there at all is any
theoreticaloption of actually getting a performance boost on a join, where the foreign key is already indexed? 

One idea I'm thinking of my self is that I have a column called state on the adverts which can either be 'active' or
'deactivated'.The absolute amount of 'active adverts are relatively constant (currently 15%) where the remaining and
growingpart is 'deactivated'. 

In reality the adverts that are selected is all 'active'. I'm hence wondering if it theoretically (and in reality of
cause)would make my query faster if I did something like:  "SELECT .* FROM cars LEFT OUTER JOIN adverts on cars.id =
adverts.car_idWHERE cars.brand = 'Audi' AND adverts.state = 'active'" with a partial index on "INDEX adverts ON
(car_id)WHERE state = 'active'"? 

Regards Niels Kristian

Re: Advice on optimizing select/index

От
Robert Klemme
Дата:
On 22.05.2013 16:37, Niels Kristian Schjødt wrote:

> In reality the adverts that are selected is all 'active'. I'm hence
> wondering if it theoretically (and in reality of cause) would make my
> query faster if I did something like:  "SELECT .* FROM cars LEFT
> OUTER JOIN adverts on cars.id = adverts.car_id WHERE cars.brand =
> 'Audi' AND adverts.state = 'active'" with a partial index on "INDEX
> adverts ON (car_id) WHERE state = 'active'"?

That sounds reasonable to do.  If you have enough bandwidth on your
production database why not just try it out?  Otherwise you could do
this on a test database and see how it goes and what plan you get.  Btw.
did you look at the original plan?

Cheers

    robert


Re: Advice on optimizing select/index

От
Jeff Janes
Дата:
On Wed, May 22, 2013 at 7:37 AM, Niels Kristian Schjødt <nielskristian@autouncle.com> wrote:

One idea I'm thinking of my self is that I have a column called state on the adverts which can either be 'active' or 'deactivated'. The absolute amount of 'active adverts are relatively constant (currently 15%) where the remaining and growing part is 'deactivated'.

You might consider deleting the rows from the active table, rather than just setting an inactive flag, possibly inserting them into a history table, if you need to preserve the info.   You can do that in a single statement using "WITH foo as (delete from advert where ... returning *) insert into advert_history select * from foo"
 

In reality the adverts that are selected is all 'active'. I'm hence wondering if it theoretically (and in reality of cause) would make my query faster if I did something like:  "SELECT .* FROM cars LEFT OUTER JOIN adverts on cars.id = adverts.car_id WHERE cars.brand = 'Audi' AND adverts.state = 'active'" with a partial index on "INDEX adverts ON (car_id) WHERE state = 'active'"?


The left join isn't doing you much good there, as the made-up rows just get filtered out anyway.

The partial index could help, but not as much as partitioning away the inactive records from the table, as well as from the index.

Cheers,

Jeff