Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

商品一覧, 商品詳細のパフォーマンス改善 #296

Merged
merged 1 commit into from
Sep 17, 2019

Conversation

nanasess
Copy link
Contributor

@nanasess nanasess commented Aug 5, 2019

  • dtb_products_class を full scan していたのを product_id で index scan するよう修正
  • PostgreSQL/MySQL で同一クエリを使用するよう修正

改善結果

RDBMS 改善前 改善後 備考
PostgreSQL 22.831 ms 2.426 ms (EXPLAIN ANALYZE で計測)
MySQL 579.5745 ms 2.943 ms (SHOW PROFILE で計測)

Explain の結果

こちらのデータ生成スクリプト で商品データを生成して計測

  • dtb_products 30000レコード
  • dtb_products_class 120000レコード

PostgreSQL

改善前

SELECT
  product_id,
  product_code_min,
  product_code_max,
  name,
  comment1,
  comment2,
  comment3,
  main_list_comment,
  main_image,
  main_list_image,
  price01_min,
  price01_max,
  price02_min,
  price02_max,
  stock_min,
  stock_max,
  stock_unlimited_min,
  stock_unlimited_max,
  deliv_date_id,
  status,
  del_flg,
  update_date
FROM (SELECT
  dtb_products.*,
  dtb_maker.name AS maker_name,
  (SELECT
    MIN(product_code)
  FROM dtb_products_class
  WHERE del_flg = 0
  AND product_id = dtb_products.product_id)  AS product_code_min,
  (SELECT MAX(product_code) FROM dtb_products_class WHERE del_flg = 0 AND product_id = dtb_products.product_id) AS product_code_max,
  (SELECT MIN(price01) FROM dtb_products_class WHERE del_flg = 0 AND product_id = dtb_products.product_id) AS price01_min,
  (SELECT MAX(price01) FROM dtb_products_class WHERE del_flg = 0 AND product_id = dtb_products.product_id) AS price01_max,
  (SELECT MIN(price02) FROM dtb_products_class WHERE del_flg = 0 AND product_id = dtb_products.product_id) AS price02_min,
  (SELECT  MAX(price02) FROM dtb_products_class WHERE del_flg = 0 AND product_id = dtb_products.product_id) AS price02_max,
  (SELECT MIN(stock) FROM dtb_products_class WHERE del_flg = 0 AND product_id = dtb_products.product_id) AS stock_min,
  (SELECT MAX(stock) FROM dtb_products_class WHERE del_flg = 0 AND product_id = dtb_products.product_id) AS stock_max,
  (SELECT MIN(stock_unlimited) FROM dtb_products_class WHERE del_flg = 0 AND product_id = dtb_products.product_id) AS stock_unlimited_min,
  (SELECT MAX(stock_unlimited) FROM dtb_products_class WHERE del_flg = 0 AND product_id = dtb_products.product_id) AS stock_unlimited_max,
  (SELECT MAX(point_rate) FROM dtb_products_class WHERE del_flg = 0 AND product_id = dtb_products.product_id) AS point_rate,
  (SELECT MAX(deliv_fee) FROM dtb_products_class WHERE del_flg = 0 AND product_id = dtb_products.product_id) AS deliv_fee
FROM dtb_products
LEFT JOIN dtb_maker
  ON dtb_products.maker_id = dtb_maker.maker_id
WHERE EXISTS (SELECT
  *
FROM dtb_products_class WHERE del_flg = 0
AND product_id = dtb_products.product_id)) AS alldtl
WHERE alldtl.product_id IN (30023, 30022, 30017, 30015, 30014, 30013, 30012, 30011, 30008, 30007, 30005, 30003, 30002, 30000, 29997)
AND alldtl.del_flg = 0
Nested Loop Semi Join  (cost=0.58..768.06 rows=15 width=419)
  ->  Index Scan using dtb_products_pkey on dtb_products  (cost=0.29..64.62 rows=15 width=163)
        Index Cond: (product_id = ANY ('{30023,30022,30017,30015,30014,30013,30012,30011,30008,30007,30005,30003,30002,30000,29997}'::integer[]))
        Filter: (del_flg = 0)
  ->  Index Only Scan using dtb_products_class_product_id_key on dtb_products_class  (cost=0.29..8.35 rows=3 width=4)
        Index Cond: (product_id = dtb_products.product_id)
  SubPlan 2
    ->  Result  (cost=4.27..4.28 rows=1 width=32)
          InitPlan 1 (returns $1)
            ->  Limit  (cost=0.42..4.27 rows=1 width=14)
                  ->  Index Only Scan using dtb_products_class_product_code_key on dtb_products_class dtb_products_class_1  (cost=0.42..11.98 rows=3 width=14)
                        Index Cond: ((product_id = dtb_products.product_id) AND (product_code IS NOT NULL))
  SubPlan 4
    ->  Result  (cost=4.27..4.28 rows=1 width=32)
          InitPlan 3 (returns $3)
            ->  Limit  (cost=0.42..4.27 rows=1 width=14)
                  ->  Index Only Scan Backward using dtb_products_class_product_code_key on dtb_products_class dtb_products_class_2  (cost=0.42..11.98 rows=3 width=14)
                        Index Cond: ((product_id = dtb_products.product_id) AND (product_code IS NOT NULL))
  SubPlan 6
    ->  Result  (cost=4.27..4.28 rows=1 width=32)
          InitPlan 5 (returns $5)
            ->  Limit  (cost=0.42..4.27 rows=1 width=8)
                  ->  Index Only Scan using dtb_products_class_price01_key on dtb_products_class dtb_products_class_3  (cost=0.42..11.98 rows=3 width=8)
                        Index Cond: ((product_id = dtb_products.product_id) AND (price01 IS NOT NULL))
  SubPlan 8
    ->  Result  (cost=4.27..4.28 rows=1 width=32)
          InitPlan 7 (returns $7)
            ->  Limit  (cost=0.42..4.27 rows=1 width=8)
                  ->  Index Only Scan Backward using dtb_products_class_price01_key on dtb_products_class dtb_products_class_4  (cost=0.42..11.98 rows=3 width=8)
                        Index Cond: ((product_id = dtb_products.product_id) AND (price01 IS NOT NULL))
  SubPlan 10
    ->  Result  (cost=4.27..4.28 rows=1 width=32)
          InitPlan 9 (returns $9)
            ->  Limit  (cost=0.42..4.27 rows=1 width=8)
                  ->  Index Only Scan using dtb_products_class_price02_key on dtb_products_class dtb_products_class_5  (cost=0.42..11.98 rows=3 width=8)
                        Index Cond: ((product_id = dtb_products.product_id) AND (price02 IS NOT NULL))
  SubPlan 12
    ->  Result  (cost=4.27..4.28 rows=1 width=32)
          InitPlan 11 (returns $11)
            ->  Limit  (cost=0.42..4.27 rows=1 width=8)
                  ->  Index Only Scan Backward using dtb_products_class_price02_key on dtb_products_class dtb_products_class_6  (cost=0.42..11.98 rows=3 width=8)
                        Index Cond: ((product_id = dtb_products.product_id) AND (price02 IS NOT NULL))
  SubPlan 14
    ->  Result  (cost=4.27..4.28 rows=1 width=32)
          InitPlan 13 (returns $13)
            ->  Limit  (cost=0.42..4.27 rows=1 width=4)
                  ->  Index Only Scan using dtb_products_class_stock_key on dtb_products_class dtb_products_class_7  (cost=0.42..11.98 rows=3 width=4)
                        Index Cond: ((product_id = dtb_products.product_id) AND (stock IS NOT NULL))
  SubPlan 16
    ->  Result  (cost=4.27..4.28 rows=1 width=32)
          InitPlan 15 (returns $15)
            ->  Limit  (cost=0.42..4.27 rows=1 width=4)
                  ->  Index Only Scan Backward using dtb_products_class_stock_key on dtb_products_class dtb_products_class_8  (cost=0.42..11.98 rows=3 width=4)
                        Index Cond: ((product_id = dtb_products.product_id) AND (stock IS NOT NULL))
  SubPlan 18
    ->  Result  (cost=4.15..4.16 rows=1 width=2)
          InitPlan 17 (returns $17)
            ->  Limit  (cost=0.29..4.15 rows=1 width=2)
                  ->  Index Only Scan using dtb_products_class_stock_unlimited_key on dtb_products_class dtb_products_class_9  (cost=0.29..11.85 rows=3 width=2)
                        Index Cond: ((product_id = dtb_products.product_id) AND (stock_unlimited IS NOT NULL))
  SubPlan 20
    ->  Result  (cost=4.15..4.16 rows=1 width=2)
          InitPlan 19 (returns $19)
            ->  Limit  (cost=0.29..4.15 rows=1 width=2)
                  ->  Index Only Scan Backward using dtb_products_class_stock_unlimited_key on dtb_products_class dtb_products_class_10  (cost=0.29..11.85 rows=3 width=2)
                        Index Cond: ((product_id = dtb_products.product_id) AND (stock_unlimited IS NOT NULL))
Planning Time: 3.475 ms
Execution Time: 22.831 ms

改善後

SELECT
  product_id,
  product_code_min,
  product_code_max,
  name,
  comment1,
  comment2,
  comment3,
  main_list_comment,
  main_image,
  main_list_image,
  price01_min,
  price01_max,
  price02_min,
  price02_max,
  stock_min,
  stock_max,
  stock_unlimited_min,
  stock_unlimited_max,
  deliv_date_id,
  status,
  del_flg,
  update_date
FROM (SELECT
  dtb_products.*,
  T4.product_code_min,
  T4.product_code_max,
  T4.price01_min,
  T4.price01_max,
  T4.price02_min,
  T4.price02_max,
  T4.stock_min,
  T4.stock_max,
  T4.stock_unlimited_min,
  T4.stock_unlimited_max,
  T4.point_rate,
  T4.deliv_fee,
  T4.class_count,
  dtb_maker.name AS maker_name
FROM (SELECT
  *
FROM dtb_products
WHERE product_id IN (30023, 30022, 30017, 30015, 30014, 30013, 30012, 30011, 30008, 30007, 30005, 30003, 30002, 30000, 29997)) AS dtb_products
JOIN (SELECT
  product_id,
  MIN(product_code) AS product_code_min,
  MAX(product_code) AS product_code_max,
  MIN(price01) AS price01_min,
  MAX(price01) AS price01_max,
  MIN(price02) AS price02_min,
  MAX(price02) AS price02_max,
  MIN(stock) AS stock_min,
  MAX(stock) AS stock_max,
  MIN(stock_unlimited) AS stock_unlimited_min,
  MAX(stock_unlimited) AS stock_unlimited_max,
  MAX(point_rate) AS point_rate,
  MAX(deliv_fee) AS deliv_fee,
  COUNT(*) AS class_count
FROM dtb_products_class
WHERE del_flg = 0
AND product_id IN (30023, 30022, 30017, 30015, 30014, 30013, 30012, 30011, 30008, 30007, 30005, 30003, 30002, 30000, 29997)
GROUP BY product_id) AS T4
  ON dtb_products.product_id = T4.product_id
LEFT JOIN dtb_maker
  ON dtb_products.maker_id = dtb_maker.maker_id) AS alldtl
WHERE alldtl.product_id IN (30023, 30022, 30017, 30015, 30014, 30013, 30012, 30011, 30008, 30007, 30005, 30003, 30002, 30000, 29997)
AND alldtl.del_flg = 0
Merge Join  (cost=0.58..478.39 rows=1 width=419)
  Merge Cond: (dtb_products.product_id = dtb_products_class.product_id)
  ->  Index Scan using dtb_products_pkey on dtb_products  (cost=0.29..406.95 rows=1 width=163)
        Index Cond: ((product_id = ANY ('{30023,30022,30017,30015,30014,30013,30012,30011,30008,30007,30005,30003,30002,30000,29997}'::integer[])) AND (product_id = ANY ('{30023,30022,30017,30015,30014,30013,30012,30011,30008,30007,30005,30003,30002,30000,29997}'::integer[])))
        Filter: (del_flg = 0)
  ->  GroupAggregate  (cost=0.29..70.86 rows=45 width=336)
        Group Key: dtb_products_class.product_id
        ->  Index Scan using dtb_products_class_product_id_key on dtb_products_class  (cost=0.29..69.17 rows=45 width=40)
              Index Cond: (product_id = ANY ('{30023,30022,30017,30015,30014,30013,30012,30011,30008,30007,30005,30003,30002,30000,29997}'::integer[]))
Planning Time: 0.932 ms
Execution Time: 2.426 ms

MySQL

改善前

SELECT
  product_id,
  product_code_min,
  product_code_max,
  name,
  comment1,
  comment2,
  comment3,
  main_list_comment,
  main_image,
  main_list_image,
  price01_min,
  price01_max,
  price02_min,
  price02_max,
  stock_min,
  stock_max,
  stock_unlimited_min,
  stock_unlimited_max,
  deliv_date_id,
  status,
  del_flg,
  update_date
FROM (SELECT
  dtb_products.*,
  T4.product_code_min,
  T4.product_code_max,
  T4.price01_min,
  T4.price01_max,
  T4.price02_min,
  T4.price02_max,
  T4.stock_min,
  T4.stock_max,
  T4.stock_unlimited_min,
  T4.stock_unlimited_max,
  T4.point_rate,
  T4.deliv_fee,
  T4.class_count,
  dtb_maker.name AS maker_name
FROM dtb_products
JOIN (SELECT
  product_id,
  MIN(product_code) AS product_code_min,
  MAX(product_code) AS product_code_max,
  MIN(price01) AS price01_min,
  MAX(price01) AS price01_max,
  MIN(price02) AS price02_min,
  MAX(price02) AS price02_max,
  MIN(stock) AS stock_min,
  MAX(stock) AS stock_max,
  MIN(stock_unlimited) AS stock_unlimited_min,
  MAX(stock_unlimited) AS stock_unlimited_max,
  MAX(point_rate) AS point_rate,
  MAX(deliv_fee) AS deliv_fee,
  COUNT(*) AS class_count
FROM dtb_products_class
WHERE del_flg = 0
GROUP BY product_id) AS T4
  ON dtb_products.product_id = T4.product_id
LEFT JOIN dtb_maker
  ON dtb_products.maker_id = dtb_maker.maker_id) AS alldtl
WHERE alldtl.product_id IN (30023, 30022, 30017, 30015, 30014, 30013, 30012, 30011, 30008, 30007, 30005, 30003, 30002, 30000, 29997)
AND alldtl.del_flg = 0
+----|-------------|--------------------|------------|--------|-----------------------------------------------------------------|-----------------------------------|---------|-----------------------------------|--------|----------|-------------+
| id | select_type | table              | partitions | type   | possible_keys                                                   | key                               | key_len | ref                               | rows   | filtered | Extra       |
+----|-------------|--------------------|------------|--------|-----------------------------------------------------------------|-----------------------------------|---------|-----------------------------------|--------|----------|-------------+
| 1  | PRIMARY     | dtb_products       | <null>     | range  | PRIMARY                                                         | PRIMARY                           | 4       | <null>                            | 15     |  10.0    | Using where |
| 1  | PRIMARY     | dtb_maker          | <null>     | eq_ref | PRIMARY                                                         | PRIMARY                           | 4       | eccube_db.dtb_products.maker_id   | 1      | 100.0    | Using index |
| 1  | PRIMARY     | <derived3>         | <null>     | ref    | <auto_key0>                                                     | <auto_key0>                       | 4       | eccube_db.dtb_products.product_id | 10     | 100.0    | <null>      |
| 3  | DERIVED     | dtb_products_class | <null>     | index  | dtb_products_class_unique_key,dtb_products_class_product_id_key | dtb_products_class_product_id_key | 4       | <null>                            | 119563 |  10.0    | Using where |
+----|-------------|--------------------|------------|--------|-----------------------------------------------------------------|-----------------------------------|---------|-----------------------------------|--------|----------|-------------+

改善後

SELECT
  product_id,
  product_code_min,
  product_code_max,
  name,
  comment1,
  comment2,
  comment3,
  main_list_comment,
  main_image,
  main_list_image,
  price01_min,
  price01_max,
  price02_min,
  price02_max,
  stock_min,
  stock_max,
  stock_unlimited_min,
  stock_unlimited_max,
  deliv_date_id,
  status,
  del_flg,
  update_date
FROM (SELECT
  dtb_products.*,
  T4.product_code_min,
  T4.product_code_max,
  T4.price01_min,
  T4.price01_max,
  T4.price02_min,
  T4.price02_max,
  T4.stock_min,
  T4.stock_max,
  T4.stock_unlimited_min,
  T4.stock_unlimited_max,
  T4.point_rate,
  T4.deliv_fee,
  T4.class_count,
  dtb_maker.name AS maker_name
FROM (SELECT
  *
FROM dtb_products
WHERE product_id IN (30023, 30022, 30017, 30015, 30014, 30013, 30012, 30011, 30008, 30007, 30005, 30003, 30002, 30000, 29997)) AS dtb_products
JOIN (SELECT
  product_id,
  MIN(product_code) AS product_code_min,
  MAX(product_code) AS product_code_max,
  MIN(price01) AS price01_min,
  MAX(price01) AS price01_max,
  MIN(price02) AS price02_min,
  MAX(price02) AS price02_max,
  MIN(stock) AS stock_min,
  MAX(stock) AS stock_max,
  MIN(stock_unlimited) AS stock_unlimited_min,
  MAX(stock_unlimited) AS stock_unlimited_max,
  MAX(point_rate) AS point_rate,
  MAX(deliv_fee) AS deliv_fee,
  COUNT(*) AS class_count
FROM dtb_products_class
WHERE del_flg = 0
AND product_id IN (30023, 30022, 30017, 30015, 30014, 30013, 30012, 30011, 30008, 30007, 30005, 30003, 30002, 30000, 29997)
GROUP BY product_id) AS T4
  ON dtb_products.product_id = T4.product_id
LEFT JOIN dtb_maker
  ON dtb_products.maker_id = dtb_maker.maker_id) AS alldtl
WHERE alldtl.product_id IN (30023, 30022, 30017, 30015, 30014, 30013, 30012, 30011, 30008, 30007, 30005, 30003, 30002, 30000, 29997)
AND alldtl.del_flg = 0
+----|-------------|--------------------|------------|--------|-----------------------------------------------------------------|-------------------------------|---------|---------------------------------|------|----------|------------------------------------+
| id | select_type | table              | partitions | type   | possible_keys                                                   | key                           | key_len | ref                             | rows | filtered | Extra                              |
+----|-------------|--------------------|------------|--------|-----------------------------------------------------------------|-------------------------------|---------|---------------------------------|------|----------|------------------------------------+
| 1  | PRIMARY     | <derived4>         | <null>     | ALL    | <null>                                                          | <null>                        | <null>  | <null>                          | 2    | 100.0    | Using where                        |
| 1  | PRIMARY     | dtb_products       | <null>     | eq_ref | PRIMARY                                                         | PRIMARY                       | 4       | T4.product_id                   | 1    |  10.0    | Using where                        |
| 1  | PRIMARY     | dtb_maker          | <null>     | eq_ref | PRIMARY                                                         | PRIMARY                       | 4       | eccube_db.dtb_products.maker_id | 1    | 100.0    | Using index                        |
| 4  | DERIVED     | dtb_products_class | <null>     | range  | dtb_products_class_unique_key,dtb_products_class_product_id_key | dtb_products_class_unique_key | 4       | <null>                          | 24   |  10.0    | Using index condition; Using where |
+----|-------------|--------------------|------------|--------|-----------------------------------------------------------------|-------------------------------|---------|---------------------------------|------|----------|------------------------------------+

その他

  • 商品詳細でも IN 句を使用しているが、 商品数がもっと多くなった場合は = を使用した方が良いかも

- dtb_products_class を full scan していたのを product_id で index scan するよう修正
- PostgreSQL/MySQL で同一クエリを使用するよう修正
@coveralls
Copy link

Coverage Status

Coverage increased (+0.1%) to 43.177% when pulling 63412dc on nanasess:improve/performance into b19397d on EC-CUBE:improve/php7.

@chihiro-adachi chihiro-adachi merged commit bdc63c4 into EC-CUBE:improve/php7 Sep 17, 2019
@chihiro-adachi
Copy link
Contributor

@nanasess 遅くなりましてすみません。PRありがとうございます。

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Projects
None yet
Development

Successfully merging this pull request may close these issues.

6 participants