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

Add index to observation views #1855

Merged
merged 1 commit into from
Jan 26, 2024
Merged

Conversation

nimmolo
Copy link
Contributor

@nimmolo nimmolo commented Jan 26, 2024

Frequent queries of observation_views are

  • by :observation_id, for the show obs footer, or
  • by both :observation_id and :user_id, for the identify query.

In this case, we can use a single index on two columns for both queries, but the order matters.


Without index:

irb(main):001> ObservationView.where(observation_id: 81188).explain
  TRANSACTION (0.1ms)  BEGIN
  ObservationView Load (146.7ms)  SELECT `observation_views`.* FROM `observation_views` WHERE `observation_views`.`observation_id` = 81188
=> 
EXPLAIN SELECT `observation_views`.* FROM `observation_views` WHERE `observation_views`.`observation_id` = 81188
+----+-------------+-------------------+------------+------+---------------+------+---------+------+--------+----------+-------------+
| id | select_type | table             | partitions | type | possible_keys | key  | key_len | ref  | rows   | filtered | Extra       |
+----+-------------+-------------------+------------+------+---------------+------+---------+------+--------+----------+-------------+
|  1 | SIMPLE      | observation_views | NULL       | ALL  | NULL          | NULL | NULL    | NULL | 440629 |     10.0 | Using where |
+----+-------------+-------------------+------------+------+---------------+------+---------+------+--------+----------+-------------+
1 row in set (0.00 sec)

irb(main):004> ObservationView.where(user_id: 3477).where(observation_id: 81188).explain
  ObservationView Load (154.4ms)  SELECT `observation_views`.* FROM `observation_views` WHERE (`observation_views`.`user_id` = 3477) AND (`observation_views`.`observation_id` = 81188)
=> 
EXPLAIN SELECT `observation_views`.* FROM `observation_views` WHERE (`observation_views`.`user_id` = 3477) AND (`observation_views`.`observation_id` = 81188)
+----+-------------+-------------------+------------+------+---------------+------+---------+------+--------+----------+-------------+
| id | select_type | table             | partitions | type | possible_keys | key  | key_len | ref  | rows   | filtered | Extra       |
+----+-------------+-------------------+------------+------+---------------+------+---------+------+--------+----------+-------------+
|  1 | SIMPLE      | observation_views | NULL       | ALL  | NULL          | NULL | NULL    | NULL | 440629 |      1.0 | Using where |
+----+-------------+-------------------+------------+------+---------------+------+---------+------+--------+----------+-------------+
1 row in set (0.00 sec)

With index on [:observation_id, :user_id]:

irb(main):001> ObservationView.where(user_id: 3477).where(observation_id: 81188).explain
  TRANSACTION (0.1ms)  BEGIN
  ObservationView Load (0.5ms)  SELECT `observation_views`.* FROM `observation_views` WHERE (`observation_views`.`user_id` = 3477) AND (`observation_views`.`observation_id` = 81188)
=> 
EXPLAIN SELECT `observation_views`.* FROM `observation_views` WHERE (`observation_views`.`user_id` = 3477) AND (`observation_views`.`observation_id` = 81188)
+----+-------------+-------------------+------------+------+------------------------+------------------------+---------+-------------+------+----------+-------+
| id | select_type | table             | partitions | type | possible_keys          | key                    | key_len | ref         | rows | filtered | Extra |
+----+-------------+-------------------+------------+------+------------------------+------------------------+---------+-------------+------+----------+-------+
|  1 | SIMPLE      | observation_views | NULL       | ref  | user_observation_index | user_observation_index | 10      | const,const |    1 |    100.0 | NULL  |
+----+-------------+-------------------+------------+------+------------------------+------------------------+---------+-------------+------+----------+-------+
1 row in set (0.00 sec)

irb(main):002> ObservationView.where(observation_id: 81188).explain
  ObservationView Load (0.5ms)  SELECT `observation_views`.* FROM `observation_views` WHERE `observation_views`.`observation_id` = 81188
=> 
EXPLAIN SELECT `observation_views`.* FROM `observation_views` WHERE `observation_views`.`observation_id` = 81188
+----+-------------+-------------------+------------+------+------------------------+------------------------+---------+-------+------+----------+-------+
| id | select_type | table             | partitions | type | possible_keys          | key                    | key_len | ref   | rows | filtered | Extra |
+----+-------------+-------------------+------------+------+------------------------+------------------------+---------+-------+------+----------+-------+
|  1 | SIMPLE      | observation_views | NULL       | ref  | user_observation_index | user_observation_index | 5       | const |    2 |    100.0 | NULL  |
+----+-------------+-------------------+------------+------+------------------------+------------------------+---------+-------+------+----------+-------+
1 row in set (0.00 sec)

With index on [:user_id, :observation_id]:

irb(main):001> ObservationView.where(user_id: 3477).where(observation_id: 81188).explain
  TRANSACTION (0.1ms)  BEGIN
  ObservationView Load (0.4ms)  SELECT `observation_views`.* FROM `observation_views` WHERE (`observation_views`.`user_id` = 3477) AND (`observation_views`.`observation_id` = 81188)
=> 
EXPLAIN SELECT `observation_views`.* FROM `observation_views` WHERE (`observation_views`.`user_id` = 3477) AND (`observation_views`.`observation_id` = 81188)
+----+-------------+-------------------+------------+------+------------------------+------------------------+---------+-------------+------+----------+-------+
| id | select_type | table             | partitions | type | possible_keys          | key                    | key_len | ref         | rows | filtered | Extra |
+----+-------------+-------------------+------------+------+------------------------+------------------------+---------+-------------+------+----------+-------+
|  1 | SIMPLE      | observation_views | NULL       | ref  | user_observation_index | user_observation_index | 10      | const,const |    1 |    100.0 | NULL  |
+----+-------------+-------------------+------------+------+------------------------+------------------------+---------+-------------+------+----------+-------+
1 row in set (0.00 sec)

irb(main):002> ObservationView.where(observation_id: 81188).explain
  ObservationView Load (148.8ms)  SELECT `observation_views`.* FROM `observation_views` WHERE `observation_views`.`observation_id` = 81188
=> 
EXPLAIN SELECT `observation_views`.* FROM `observation_views` WHERE `observation_views`.`observation_id` = 81188
+----+-------------+-------------------+------------+------+---------------+------+---------+------+--------+----------+-------------+
| id | select_type | table             | partitions | type | possible_keys | key  | key_len | ref  | rows   | filtered | Extra       |
+----+-------------+-------------------+------------+------+---------------+------+---------+------+--------+----------+-------------+
|  1 | SIMPLE      | observation_views | NULL       | ALL  | NULL          | NULL | NULL    | NULL | 440629 |     10.0 | Using where |
+----+-------------+-------------------+------------+------+---------------+------+---------+------+--------+----------+-------------+
1 row in set (0.00 sec)

In this last case, the two-column index is not usable for :observation_id, because it comes second.

@coveralls
Copy link
Collaborator

Coverage Status

coverage: 94.517%. remained the same
when pulling 3ad1f73 on nimmo-add-target-index-to-comments
into 0c41b7b on main.

@nimmolo nimmolo merged commit f54d931 into main Jan 26, 2024
5 checks passed
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Projects
None yet
Development

Successfully merging this pull request may close these issues.

None yet

2 participants