Skip to content

Commit

Permalink
[api] remove duplicate indexes
Browse files Browse the repository at this point in the history
Remove duplicate indexes as suggested by pt-duplicate-key-checker.

A key or unique constraint on "a,b" is also an index on just "a".
Such duplicate indexes accumulate over the lifetime of a sw project
and do not normally hurt in production. However keeping them around
carries a performance penalty as all indexes need to be maintained
by the database engines.

If a previous database migration class was skipped or structure.sql
does not represent the current schema, this potentially removes
useful indexes - this would, however, be an operational problem.

* src/api/db/migrate/20170123115500_remove_duplicate_indexes.rb
  Migration class
* structure.sql: changed my same DDL
  • Loading branch information
Andreas Stieger authored and adrianschroeter committed Feb 3, 2017
1 parent dd0f3fa commit 2493155
Show file tree
Hide file tree
Showing 2 changed files with 219 additions and 16 deletions.
216 changes: 216 additions & 0 deletions src/api/db/migrate/20170123115500_remove_duplicate_indexes.rb
Original file line number Diff line number Diff line change
@@ -0,0 +1,216 @@
class RemoveDuplicateIndexes < ActiveRecord::Migration
def self.up
# generated by pt-duplicate-key-checker 2.2.20 from structure.sql as of 7669128

# ########################################################################
# obs.attrib_namespace_modifiable_bies
# ########################################################################

# index_attrib_namespace_modifiable_bies_on_attrib_namespace_id is a left-prefix of attrib_namespace_user_role_all_index
# Key definitions:
# KEY `index_attrib_namespace_modifiable_bies_on_attrib_namespace_id` (`attrib_namespace_id`),
# UNIQUE KEY `attrib_namespace_user_role_all_index` (`attrib_namespace_id`,`user_id`,`group_id`),
# Column types:
# `attrib_namespace_id` int(11) not null
# `user_id` int(11) default null
# `group_id` int(11) default null
# To remove this duplicate index, execute:
execute "ALTER TABLE `attrib_namespace_modifiable_bies` DROP INDEX `index_attrib_namespace_modifiable_bies_on_attrib_namespace_id`;"

# ########################################################################
# obs.attrib_types
# ########################################################################

# attrib_namespace_id is a left-prefix of index_attrib_types_on_attrib_namespace_id_and_name
# Key definitions:
# KEY `attrib_namespace_id` (`attrib_namespace_id`),
# UNIQUE KEY `index_attrib_types_on_attrib_namespace_id_and_name` (`attrib_namespace_id`,`name`),
# Column types:
# `attrib_namespace_id` int(11) not null
# `name` varchar(255) character set utf8 not null
# To remove this duplicate index, execute:
execute "ALTER TABLE `attrib_types` DROP INDEX `attrib_namespace_id`;"

# ########################################################################
# obs.binary_releases
# ########################################################################

# index_binary_releases_on_binary_name is a left-prefix of exact_search_index
# Key definitions:
# KEY `index_binary_releases_on_binary_name` (`binary_name`),
# KEY `exact_search_index` (`binary_name`,`binary_epoch`,`binary_version`,`binary_release`,`binary_arch`),
# Column types:
# `binary_name` varchar(255) collate utf8_unicode_ci not null
# `binary_epoch` varchar(64) collate utf8_unicode_ci default null
# `binary_version` varchar(64) collate utf8_unicode_ci not null
# `binary_release` varchar(64) collate utf8_unicode_ci not null
# `binary_arch` varchar(64) collate utf8_unicode_ci not null
# To remove this duplicate index, execute:
execute "ALTER TABLE `binary_releases` DROP INDEX `index_binary_releases_on_binary_name`;"

# FOREIGN KEY binary_releases_ibfk_3 (`repository_id`) REFERENCES `repositories` (`id`) is a duplicate of FOREIGN KEY binary_releases_ibfk_1 (`repository_id`) REFERENCES `repositories` (`id`)
# Key definitions:
# CONSTRAINT `binary_releases_ibfk_3` FOREIGN KEY (`repository_id`) REFERENCES `repositories` (`id`)
# CONSTRAINT `binary_releases_ibfk_1` FOREIGN KEY (`repository_id`) REFERENCES `repositories` (`id`)
# Column types:
# `repository_id` int(11) not null
# To remove this duplicate foreign key, execute:
execute "ALTER TABLE `binary_releases` DROP FOREIGN KEY `binary_releases_ibfk_3`;"

# FOREIGN KEY binary_releases_ibfk_4 (`release_package_id`) REFERENCES `packages` (`id`) is a duplicate of FOREIGN KEY binary_releases_ibfk_2 (`release_package_id`) REFERENCES `packages` (`id`)
# Key definitions:
# CONSTRAINT `binary_releases_ibfk_4` FOREIGN KEY (`release_package_id`) REFERENCES `packages` (`id`)
# CONSTRAINT `binary_releases_ibfk_2` FOREIGN KEY (`release_package_id`) REFERENCES `packages` (`id`)
# Column types:
# `release_package_id` int(11) default null
# To remove this duplicate foreign key, execute:
execute "ALTER TABLE `binary_releases` DROP FOREIGN KEY `binary_releases_ibfk_4`;"

# ########################################################################
# obs.bs_request_actions
# ########################################################################

# index_bs_request_actions_on_target_project is a left-prefix of index_bs_request_actions_on_target_project_and_source_project
# Key definitions:
# KEY `index_bs_request_actions_on_target_project` (`target_project`),
# KEY `index_bs_request_actions_on_target_project_and_source_project` (`target_project`,`source_project`),
# Column types:
# `target_project` varchar(255) character set utf8 collate utf8_unicode_ci default null
# `source_project` varchar(255) character set utf8 collate utf8_unicode_ci default null
# To remove this duplicate index, execute:
execute "ALTER TABLE `bs_request_actions` DROP INDEX `index_bs_request_actions_on_target_project_and_source_project`;"

# ########################################################################
# obs.cache_lines
# ########################################################################

# index_cache_lines_on_project is a left-prefix of index_cache_lines_on_project_and_package
# Key definitions:
# KEY `index_cache_lines_on_project` (`project`),
# KEY `index_cache_lines_on_project_and_package` (`project`,`package`)
# Column types:
# `project` varchar(255) collate utf8_unicode_ci default null
# `package` varchar(255) collate utf8_unicode_ci default null
# To remove this duplicate index, execute:
execute "ALTER TABLE `cache_lines` DROP INDEX `index_cache_lines_on_project`;"

# ########################################################################
# obs.channels
# ########################################################################

# package_id is a duplicate of index_unique
# Key definitions:
# KEY `package_id` (`package_id`),
# UNIQUE KEY `index_unique` (`package_id`),
# Column types:
# `package_id` int(11) not null
# To remove this duplicate index, execute:
execute "ALTER TABLE `channels` DROP INDEX `package_id`;"

# ########################################################################
# obs.history_elements
# ########################################################################

# index_history_elements_on_op_object_id is a left-prefix of index_search
# Key definitions:
# KEY `index_history_elements_on_op_object_id` (`op_object_id`),
# KEY `index_search` (`op_object_id`,`type`)
# Column types:
# `op_object_id` int(11) not null
# `type` varchar(255) collate utf8_unicode_ci not null
# To remove this duplicate index, execute:
execute "ALTER TABLE `history_elements` DROP INDEX `index_history_elements_on_op_object_id`;"

# ########################################################################
# obs.package_issues
# ########################################################################

# index_package_issues_on_package_id is a left-prefix of index_package_issues_on_package_id_and_issue_id
# Key definitions:
# KEY `index_package_issues_on_package_id` (`package_id`),
# KEY `index_package_issues_on_package_id_and_issue_id` (`package_id`,`issue_id`),
# Column types:
# `package_id` int(11) not null
# `issue_id` int(11) not null
# To remove this duplicate index, execute:
execute "ALTER TABLE `package_issues` DROP INDEX `index_package_issues_on_package_id`;"

# ########################################################################
# obs.packages
# ########################################################################

# index_packages_on_project_id is a left-prefix of packages_all_index
# Key definitions:
# KEY `index_packages_on_project_id` (`project_id`),
# UNIQUE KEY `packages_all_index` (`project_id`,`name`),
# Column types:
# `project_id` int(11) not null
# `name` varchar(200) collate utf8_bin not null
# To remove this duplicate index, execute:
execute "ALTER TABLE `packages` DROP INDEX `index_packages_on_project_id`;"

# ########################################################################
# obs.product_media
# ########################################################################

# product_id is a left-prefix of index_unique
# Key definitions:
# KEY `product_id` (`product_id`),
# UNIQUE KEY `index_unique` (`product_id`,`repository_id`,`name`,`arch_filter_id`),
# Column types:
# `product_id` int(11) default null
# `repository_id` int(11) default null
# `name` varchar(255) collate utf8_unicode_ci default null
# `arch_filter_id` int(11) default null
# To remove this duplicate index, execute:
execute "ALTER TABLE `product_media` DROP INDEX `product_id`;"

# ########################################################################
# obs.product_update_repositories
# ########################################################################

# product_id is a left-prefix of index_unique
# Key definitions:
# KEY `product_id` (`product_id`),
# UNIQUE KEY `index_unique` (`product_id`,`repository_id`,`arch_filter_id`),
# Column types:
# `product_id` int(11) default null
# `repository_id` int(11) default null
# `arch_filter_id` int(11) default null
# To remove this duplicate index, execute:
execute "ALTER TABLE `product_update_repositories` DROP INDEX `product_id`;"

# ########################################################################
# obs.reviews
# ########################################################################

# index_reviews_on_state is a left-prefix of index_reviews_on_state_and_by_user
# Key definitions:
# KEY `index_reviews_on_state` (`state`),
# KEY `index_reviews_on_state_and_by_user` (`state`,`by_user`),
# Column types:
# `state` varchar(255) collate utf8_unicode_ci default null
# `by_user` varchar(255) collate utf8_unicode_ci default null
# To remove this duplicate index, execute:
execute "ALTER TABLE `reviews` DROP INDEX `index_reviews_on_state`;"
end

def self.down
# re-add duplicate indexes.
# generated based the output of pt-duplicate-key-checker and the index definitions as of 7669128
execute "ALTER TABLE `attrib_namespace_modifiable_bies` ADD INDEX `index_attrib_namespace_modifiable_bies_on_attrib_namespace_id` (`attrib_namespace_id`);"
execute "ALTER TABLE `attrib_types` ADD INDEX `attrib_namespace_id` (`attrib_namespace_id`);"
execute "ALTER TABLE `binary_releases` ADD INDEX `index_binary_releases_on_binary_name` (`binary_name`);"
execute "ALTER TABLE `binary_releases` ADD CONSTRAINT `binary_releases_ibfk_3` FOREIGN KEY (`repository_id`) REFERENCES `repositories` (`id`);"
execute "ALTER TABLE `binary_releases` ADD CONSTRAINT `binary_releases_ibfk_4` FOREIGN KEY (`release_package_id`) REFERENCES `packages` (`id`);"
execute "ALTER TABLE `bs_request_actions` ADD INDEX `index_bs_request_actions_on_target_project_and_source_project` (`target_project`, `source_project`);"
execute "ALTER TABLE `cache_lines` ADD INDEX `index_cache_lines_on_project` (`project`);"
execute "ALTER TABLE `channels` ADD INDEX `package_id` (`package_id`);"
execute "ALTER TABLE `history_elements` ADD INDEX `index_history_elements_on_op_object_id` (`op_object_id`);"
execute "ALTER TABLE `package_issues` ADD INDEX `index_package_issues_on_package_id` (`package_id`);"
execute "ALTER TABLE `packages` ADD INDEX `index_packages_on_project_id` (`project_id`);"
execute "ALTER TABLE `product_media` ADD INDEX `product_id` (`product_id`);"
execute "ALTER TABLE `product_update_repositories` ADD INDEX `product_id` (`product_id`);"
execute "ALTER TABLE `reviews` ADD INDEX `index_reviews_on_state` (`state`);"
end
end
19 changes: 3 additions & 16 deletions src/api/db/structure.sql
Original file line number Diff line number Diff line change
Expand Up @@ -60,7 +60,6 @@ CREATE TABLE `attrib_namespace_modifiable_bies` (
UNIQUE KEY `attrib_namespace_user_role_all_index` (`attrib_namespace_id`,`user_id`,`group_id`),
KEY `bs_user_id` (`user_id`),
KEY `bs_group_id` (`group_id`),
KEY `index_attrib_namespace_modifiable_bies_on_attrib_namespace_id` (`attrib_namespace_id`),
CONSTRAINT `attrib_namespace_modifiable_bies_ibfk_1` FOREIGN KEY (`attrib_namespace_id`) REFERENCES `attrib_namespaces` (`id`),
CONSTRAINT `attrib_namespace_modifiable_bies_ibfk_4` FOREIGN KEY (`user_id`) REFERENCES `users` (`id`),
CONSTRAINT `attrib_namespace_modifiable_bies_ibfk_5` FOREIGN KEY (`group_id`) REFERENCES `groups` (`id`)
Expand Down Expand Up @@ -100,7 +99,6 @@ CREATE TABLE `attrib_types` (
PRIMARY KEY (`id`),
UNIQUE KEY `index_attrib_types_on_attrib_namespace_id_and_name` (`attrib_namespace_id`,`name`),
KEY `index_attrib_types_on_name` (`name`),
KEY `attrib_namespace_id` (`attrib_namespace_id`),
CONSTRAINT `attrib_types_ibfk_1` FOREIGN KEY (`attrib_namespace_id`) REFERENCES `attrib_namespaces` (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_bin;

Expand Down Expand Up @@ -176,17 +174,14 @@ CREATE TABLE `binary_releases` (
`binary_updateinfo_version` varchar(255) COLLATE utf8_unicode_ci DEFAULT NULL,
`modify_time` datetime DEFAULT NULL,
PRIMARY KEY (`id`),
KEY `index_binary_releases_on_binary_name` (`binary_name`),
KEY `ra_name_index` (`repository_id`,`binary_name`),
KEY `exact_search_index` (`binary_name`,`binary_epoch`,`binary_version`,`binary_release`,`binary_arch`),
KEY `release_package_id` (`release_package_id`),
KEY `index_binary_releases_on_binary_updateinfo` (`binary_updateinfo`),
KEY `index_binary_releases_on_medium` (`medium`),
KEY `index_binary_releases_on_binary_name_and_binary_arch` (`binary_name`,`binary_arch`),
CONSTRAINT `binary_releases_ibfk_1` FOREIGN KEY (`repository_id`) REFERENCES `repositories` (`id`),
CONSTRAINT `binary_releases_ibfk_2` FOREIGN KEY (`release_package_id`) REFERENCES `packages` (`id`),
CONSTRAINT `binary_releases_ibfk_3` FOREIGN KEY (`repository_id`) REFERENCES `repositories` (`id`),
CONSTRAINT `binary_releases_ibfk_4` FOREIGN KEY (`release_package_id`) REFERENCES `packages` (`id`)
CONSTRAINT `binary_releases_ibfk_2` FOREIGN KEY (`release_package_id`) REFERENCES `packages` (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;

CREATE TABLE `blacklist_tags` (
Expand Down Expand Up @@ -232,11 +227,10 @@ CREATE TABLE `bs_request_actions` (
`makeoriginolder` tinyint(1) DEFAULT '0',
PRIMARY KEY (`id`),
KEY `bs_request_id` (`bs_request_id`),
KEY `index_bs_request_actions_on_target_project` (`target_project`),
KEY `index_bs_request_actions_on_target_package` (`target_package`),
KEY `index_bs_request_actions_on_source_project` (`source_project`),
KEY `index_bs_request_actions_on_source_package` (`source_package`),
KEY `index_bs_request_actions_on_target_project_and_source_project` (`target_project`,`source_project`),
KEY `index_bs_request_actions_on_target_project` (`target_project`),
CONSTRAINT `bs_request_actions_ibfk_1` FOREIGN KEY (`bs_request_id`) REFERENCES `bs_requests` (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_bin;

Expand Down Expand Up @@ -275,7 +269,6 @@ CREATE TABLE `cache_lines` (
`request` int(11) DEFAULT NULL,
`created_at` datetime DEFAULT NULL,
PRIMARY KEY (`id`),
KEY `index_cache_lines_on_project` (`project`),
KEY `index_cache_lines_on_project_and_package` (`project`,`package`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;

Expand Down Expand Up @@ -337,7 +330,6 @@ CREATE TABLE `channels` (
`package_id` int(11) NOT NULL,
PRIMARY KEY (`id`),
UNIQUE KEY `index_unique` (`package_id`),
KEY `package_id` (`package_id`),
CONSTRAINT `channels_ibfk_1` FOREIGN KEY (`package_id`) REFERENCES `packages` (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;

Expand Down Expand Up @@ -576,7 +568,6 @@ CREATE TABLE `history_elements` (
PRIMARY KEY (`id`),
KEY `index_history_elements_on_created_at` (`created_at`),
KEY `index_history_elements_on_type` (`type`),
KEY `index_history_elements_on_op_object_id` (`op_object_id`),
KEY `index_search` (`op_object_id`,`type`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;

Expand Down Expand Up @@ -687,7 +678,6 @@ CREATE TABLE `package_issues` (
`issue_id` int(11) NOT NULL,
`change` enum('added','deleted','changed','kept') DEFAULT NULL,
PRIMARY KEY (`id`),
KEY `index_package_issues_on_package_id` (`package_id`),
KEY `index_package_issues_on_package_id_and_issue_id` (`package_id`,`issue_id`),
KEY `index_package_issues_on_issue_id` (`issue_id`),
CONSTRAINT `package_issues_ibfk_1` FOREIGN KEY (`package_id`) REFERENCES `packages` (`id`),
Expand Down Expand Up @@ -722,7 +712,6 @@ CREATE TABLE `packages` (
UNIQUE KEY `packages_all_index` (`project_id`,`name`),
KEY `devel_package_id_index` (`develpackage_id`),
KEY `updated_at_index` (`updated_at`),
KEY `index_packages_on_project_id` (`project_id`),
CONSTRAINT `packages_ibfk_3` FOREIGN KEY (`develpackage_id`) REFERENCES `packages` (`id`),
CONSTRAINT `packages_ibfk_4` FOREIGN KEY (`project_id`) REFERENCES `projects` (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_bin;
Expand Down Expand Up @@ -758,7 +747,6 @@ CREATE TABLE `product_media` (
`arch_filter_id` int(11) DEFAULT NULL,
PRIMARY KEY (`id`),
UNIQUE KEY `index_unique` (`product_id`,`repository_id`,`name`,`arch_filter_id`),
KEY `product_id` (`product_id`),
KEY `repository_id` (`repository_id`),
KEY `index_product_media_on_name` (`name`),
KEY `index_product_media_on_arch_filter_id` (`arch_filter_id`),
Expand All @@ -774,7 +762,6 @@ CREATE TABLE `product_update_repositories` (
`arch_filter_id` int(11) DEFAULT NULL,
PRIMARY KEY (`id`),
UNIQUE KEY `index_unique` (`product_id`,`repository_id`,`arch_filter_id`),
KEY `product_id` (`product_id`),
KEY `repository_id` (`repository_id`),
KEY `index_product_update_repositories_on_arch_filter_id` (`arch_filter_id`),
CONSTRAINT `product_update_repositories_ibfk_1` FOREIGN KEY (`product_id`) REFERENCES `products` (`id`),
Expand Down Expand Up @@ -928,7 +915,6 @@ CREATE TABLE `reviews` (
PRIMARY KEY (`id`),
KEY `index_reviews_on_creator` (`creator`),
KEY `index_reviews_on_reviewer` (`reviewer`),
KEY `index_reviews_on_state` (`state`),
KEY `index_reviews_on_by_user` (`by_user`),
KEY `index_reviews_on_by_group` (`by_group`),
KEY `index_reviews_on_by_project` (`by_project`),
Expand Down Expand Up @@ -1411,6 +1397,7 @@ INSERT INTO schema_migrations (version) VALUES
('20170103132257'),
('20170111114943'),
('20170118091131'),
('20170123115500'),
('21'),
('22'),
('23'),
Expand Down

0 comments on commit 2493155

Please sign in to comment.