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

Optimizing information_schema query for `foreign_keys` #31425

Merged
merged 1 commit into from Dec 13, 2017

Conversation

Projects
None yet
4 participants
@chiastolite
Contributor

chiastolite commented Dec 13, 2017

Use CONSTRAINT_SCHEMA key for information_schema.referential_constraints.
See https://dev.mysql.com/doc/refman/5.7/en/information-schema-optimization.html.

> EXPLAIN SELECT fk.referenced_table_name AS 'to_table', fk.referenced_column_name AS 'primary_key', fk.column_name AS 'column', fk.constraint_name AS 'name', rc.update_rule AS 'on_update', rc.delete_rule AS 'on_delete' FROM information_schema.referential_constraints rc JOIN information_schema.key_column_usage fk USING (constraint_schema, constraint_name) WHERE fk.referenced_column_name IS NOT NULL AND fk.table_schema = 'activerecord_unittest' AND fk.table_name = 'fk_test_has_pk' AND rc.constraint_schema = 'activerecord_unittest' AND rc.table_name = 'fk_test_has_pk'\G
*************************** 1. row ***************************
           id: 1
  select_type: SIMPLE
        table: rc
   partitions: NULL
         type: ALL
possible_keys: NULL
          key: CONSTRAINT_SCHEMA,TABLE_NAME
      key_len: NULL
          ref: NULL
         rows: NULL
     filtered: NULL
        Extra: Using where; Open_full_table; Scanned 0 databases
*************************** 2. row ***************************
           id: 1
  select_type: SIMPLE
        table: fk
   partitions: NULL
         type: ALL
possible_keys: NULL
          key: TABLE_SCHEMA,TABLE_NAME
      key_len: NULL
          ref: NULL
         rows: NULL
     filtered: NULL
        Extra: Using where; Open_full_table; Scanned 0 databases; Using join buffer (Block Nested Loop)
2 rows in set, 1 warning (0.00 sec)

This optimization is especially effective against many databases in same DB Server(like using apartment gem).

When 1000 databases(using following a script), it is 100 times faster(100ms -> 1ms).

for x in {1..1000};
do
  mysql -u root -e "create database IF NOT EXISTS bench${x}";
  mysql -u root -e "create table IF NOT EXISTS bench${x}.main_table (id bigint AUTO_INCREMENT, PRIMARY KEY (id))";
  mysql -u root -e "create table IF NOT EXISTS bench${x}.sub_table (id bigint AUTO_INCREMENT, main_id bigint, PRIMARY KEY (id), FOREIGN KEY(main_id) REFERENCES main_table(id))";
done;
Optimizing information_schema query for `foreign_keys`
Use CONSTRAINT_SCHEMA key for information_schema.referential_constraints.
See https://dev.mysql.com/doc/refman/5.7/en/information-schema-optimization.html.

```
> EXPLAIN SELECT fk.referenced_table_name AS 'to_table', fk.referenced_column_name AS 'primary_key', fk.column_name AS 'column', fk.constraint_name AS 'name', rc.update_rule AS 'on_update', rc.delete_rule AS 'on_delete' FROM information_schema.referential_constraints rc JOIN information_schema.key_column_usage fk USING (constraint_schema, constraint_name) WHERE fk.referenced_column_name IS NOT NULL AND fk.table_schema = 'activerecord_unittest' AND fk.table_name = 'fk_test_has_pk' AND rc.constraint_schema = 'activerecord_unittest' AND rc.table_name = 'fk_test_has_pk'\G
*************************** 1. row ***************************
           id: 1
  select_type: SIMPLE
        table: rc
   partitions: NULL
         type: ALL
possible_keys: NULL
          key: CONSTRAINT_SCHEMA,TABLE_NAME
      key_len: NULL
          ref: NULL
         rows: NULL
     filtered: NULL
        Extra: Using where; Open_full_table; Scanned 0 databases
*************************** 2. row ***************************
           id: 1
  select_type: SIMPLE
        table: fk
   partitions: NULL
         type: ALL
possible_keys: NULL
          key: TABLE_SCHEMA,TABLE_NAME
      key_len: NULL
          ref: NULL
         rows: NULL
     filtered: NULL
        Extra: Using where; Open_full_table; Scanned 0 databases; Using join buffer (Block Nested Loop)
2 rows in set, 1 warning (0.00 sec)
```
@rails-bot

This comment has been minimized.

Show comment
Hide comment
@rails-bot

rails-bot Dec 13, 2017

Thanks for the pull request, and welcome! The Rails team is excited to review your changes, and you should hear from @schneems (or someone else) soon.

If any changes to this PR are deemed necessary, please add them as extra commits. This ensures that the reviewer can see what has changed since they last reviewed the code. Due to the way GitHub handles out-of-date commits, this should also make it reasonably obvious what issues have or haven't been addressed. Large or tricky changes may require several passes of review and changes.

This repository is being automatically checked for code quality issues using Code Climate. You can see results for this analysis in the PR status below. Newly introduced issues should be fixed before a Pull Request is considered ready to review.

Please see the contribution instructions for more information.

rails-bot commented Dec 13, 2017

Thanks for the pull request, and welcome! The Rails team is excited to review your changes, and you should hear from @schneems (or someone else) soon.

If any changes to this PR are deemed necessary, please add them as extra commits. This ensures that the reviewer can see what has changed since they last reviewed the code. Due to the way GitHub handles out-of-date commits, this should also make it reasonably obvious what issues have or haven't been addressed. Large or tricky changes may require several passes of review and changes.

This repository is being automatically checked for code quality issues using Code Climate. You can see results for this analysis in the PR status below. Newly introduced issues should be fixed before a Pull Request is considered ready to review.

Please see the contribution instructions for more information.

@kamipo

This comment has been minimized.

Show comment
Hide comment
@kamipo

kamipo Dec 13, 2017

Member

I had tried to using CONSTRAINT_SCHEMA key for referential_constraints in #27580, but somehow can not used the key with the joining order. Changing joining order and using CONSTRAINT_SCHEMA are both fine to me.

Member

kamipo commented Dec 13, 2017

I had tried to using CONSTRAINT_SCHEMA key for referential_constraints in #27580, but somehow can not used the key with the joining order. Changing joining order and using CONSTRAINT_SCHEMA are both fine to me.

@kamipo kamipo merged commit f5735ff into rails:master Dec 13, 2017

1 check was pending

continuous-integration/travis-ci/pr The Travis CI build is in progress
Details
@kamipo

This comment has been minimized.

Show comment
Hide comment
@kamipo

kamipo Dec 13, 2017

Member

Thank you! And congrats on your first Rails contribution 🎉

Member

kamipo commented Dec 13, 2017

Thank you! And congrats on your first Rails contribution 🎉

@chiastolite chiastolite deleted the chiastolite:optimize_foregin_keys_query branch Dec 13, 2017

kamipo added a commit that referenced this pull request Jan 3, 2018

Merge pull request #31425 from chiastolite/optimize_foregin_keys_query
Optimizing information_schema query for `foreign_keys`
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment