Skip to content

Conversation

@melegiul
Copy link
Contributor

@melegiul melegiul commented Apr 28, 2022

Reduces the number of database table joins in a single call to share providers getShareWith function from 10 to 6.
This is the current database query, which is executed on each call to circles share provider and its average slow query log time:

Query_time: 0.018108  Lock_time: 0.001674  Rows_sent: 5  Rows_examined: 919
Current share provider db query
SELECT `sh`.`id`,
 `sh`.`share_type`,
 `sh`.`share_with`,
 `sh`.`uid_owner`,
 `sh`.`uid_initiator`,
 `sh`.`parent`,
 `sh`.`item_type`,
 `sh`.`item_source`,
 `sh`.`item_target`,
 `sh`.`file_source`,
 `sh`.`file_target`,
 `sh`.`permissions`,
 `sh`.`stime`,
 `sh`.`accepted`,
 `sh`.`expiration`,
 `sh`.`token`,
 `sh`.`mail_send`,
 `sh_cc`.`unique_id` AS `sh_cc_unique_id`,
 `sh_cc`.`name` AS `sh_cc_name`,
 `sh_cc`.`display_name` AS `sh_cc_display_name`,
 `sh_cc`.`sanitized_name` AS `sh_cc_sanitized_name`,
 `sh_cc`.`source` AS `sh_cc_source`,
 `sh_cc`.`description` AS `sh_cc_description`,
 `sh_cc`.`settings` AS `sh_cc_settings`,
 `sh_cc`.`config` AS `sh_cc_config`,
 `sh_cc`.`contact_addressbook` AS `sh_cc_contact_addressbook`,
 `sh_cc`.`contact_groupname` AS `sh_cc_contact_groupname`,
 `sh_cc`.`creation` AS `sh_cc_creation`,
 `sh_cc_wn`.`circle_id` AS `sh_cc_wn_circle_id`,
 `sh_cc_wn`.`member_id` AS `sh_cc_wn_member_id`,
 `sh_cc_wn`.`single_id` AS `sh_cc_wn_single_id`,
 `sh_cc_wn`.`user_id` AS `sh_cc_wn_user_id`,
 `sh_cc_wn`.`instance` AS `sh_cc_wn_instance`,
 `sh_cc_wn`.`user_type` AS `sh_cc_wn_user_type`,
 `sh_cc_wn`.`level` AS `sh_cc_wn_level`,
 `sh_cc_wn`.`status` AS `sh_cc_wn_status`,
 `sh_cc_wn`.`note` AS `sh_cc_wn_note`,
 `sh_cc_wn`.`contact_id` AS `sh_cc_wn_contact_id`,
 `sh_cc_wn`.`cached_name` AS `sh_cc_wn_cached_name`,
 `sh_cc_wn`.`cached_update` AS `sh_cc_wn_cached_update`,
 `sh_cc_wn`.`contact_meta` AS `sh_cc_wn_contact_meta`,
 `sh_cc_wn`.`joined` AS `sh_cc_wn_joined`,
 `sh_in`.`circle_id` AS `sh_in_circle_id`,
 `sh_in`.`member_id` AS `sh_in_member_id`,
 `sh_in`.`single_id` AS `sh_in_single_id`,
 `sh_in`.`user_id` AS `sh_in_user_id`,
 `sh_in`.`instance` AS `sh_in_instance`,
 `sh_in`.`user_type` AS `sh_in_user_type`,
 `sh_in`.`level` AS `sh_in_level`,
 `sh_in`.`status` AS `sh_in_status`,
 `sh_in`.`note` AS `sh_in_note`,
 `sh_in`.`contact_id` AS `sh_in_contact_id`,
 `sh_in`.`cached_name` AS `sh_in_cached_name`,
 `sh_in`.`cached_update` AS `sh_in_cached_update`,
 `sh_in`.`contact_meta` AS `sh_in_contact_meta`,
 `sh_in`.`joined` AS `sh_in_joined`,
 `sh_in_by`.`circle_id` AS `sh_in_by_circle_id`,
 `sh_in_by`.`member_id` AS `sh_in_by_member_id`,
 `sh_in_by`.`single_id` AS `sh_in_by_single_id`,
 `sh_in_by`.`user_id` AS `sh_in_by_user_id`,
 `sh_in_by`.`instance` AS `sh_in_by_instance`,
 `sh_in_by`.`user_type` AS `sh_in_by_user_type`,
 `sh_in_by`.`level` AS `sh_in_by_level`,
 `sh_in_by`.`status` AS `sh_in_by_status`,
 `sh_in_by`.`note` AS `sh_in_by_note`,
 `sh_in_by`.`contact_id` AS `sh_in_by_contact_id`,
 `sh_in_by`.`cached_name` AS `sh_in_by_cached_name`,
 `sh_in_by`.`cached_update` AS `sh_in_by_cached_update`,
 `sh_in_by`.`contact_meta` AS `sh_in_by_contact_meta`,
 `sh_in_by`.`joined` AS `sh_in_by_joined`,
 `sh_ms`.`single_id` AS `sh_in_by_ms_single_id`,
 `sh_ms`.`circle_id` AS `sh_in_by_ms_circle_id`,
 `sh_ms`.`level` AS `sh_in_by_ms_level`,
 `sh_ms`.`inheritance_first` AS `sh_in_by_ms_inheritance_first`,
 `sh_ms`.`inheritance_last` AS `sh_in_by_ms_inheritance_last`,
 `sh_ms`.`inheritance_path` AS `sh_in_by_ms_inheritance_path`,
 `sh_ms`.`inheritance_depth` AS `sh_in_by_ms_inheritance_depth`,
 `sh_in_on`.`unique_id` AS `sh_in_on_unique_id`,
 `sh_in_on`.`name` AS `sh_in_on_name`,
 `sh_in_on`.`display_name` AS `sh_in_on_display_name`,
 `sh_in_on`.`sanitized_name` AS `sh_in_on_sanitized_name`,
 `sh_in_on`.`source` AS `sh_in_on_source`,
 `sh_in_on`.`description` AS `sh_in_on_description`,
 `sh_in_on`.`settings` AS `sh_in_on_settings`,
 `sh_in_on`.`config` AS `sh_in_on_config`,
 `sh_in_on`.`contact_addressbook` AS `sh_in_on_contact_addressbook`,
 `sh_in_on`.`contact_groupname` AS `sh_in_on_contact_groupname`,
 `sh_in_on`.`creation` AS `sh_in_on_creation`,
 `sh_fc`.`fileid` AS `sh_fc_fileid`,
 `sh_fc`.`path` AS `sh_fc_path`,
 `sh_fc`.`permissions` AS `sh_fc_permissions`,
 `sh_fc`.`storage` AS `sh_fc_storage`,
 `sh_fc`.`path_hash` AS `sh_fc_path_hash`,
 `sh_fc`.`parent` AS `sh_fc_parent`,
 `sh_fc`.`name` AS `sh_fc_name`,
 `sh_fc`.`mimetype` AS `sh_fc_mimetype`,
 `sh_fc`.`mimepart` AS `sh_fc_mimepart`,
 `sh_fc`.`size` AS `sh_fc_size`,
 `sh_fc`.`mtime` AS `sh_fc_mtime`,
 `sh_fc`.`storage_mtime` AS `sh_fc_storage_mtime`,
 `sh_fc`.`encrypted` AS `sh_fc_encrypted`,
 `sh_fc`.`unencrypted_size` AS `sh_fc_unencrypted_size`,
 `sh_fc`.`etag` AS `sh_fc_etag`,
 `sh_fc`.`checksum` AS `sh_fc_checksum`,
 `sh_fc_st`.`id` AS `sh_fc_st_id`,
 `sh_sh`.`id` AS `child_id`,
 `sh_sh`.`file_target` AS `child_file_target`,
 `sh_sh`.`permissions` AS `child_permissions` 
 FROM `*PREFIX*share` `sh` 
 LEFT JOIN `*PREFIX*circles_circle` `sh_cc` ON `sh_cc`.`unique_id` = `sh`.`share_with` 
 LEFT JOIN `*PREFIX*circles_membership` `sh_ms` ON (`sh_ms`.`single_id` = :dcValue3) AND (`sh_ms`.`circle_id` = `sh`.`share_with`) 
 LEFT JOIN `*PREFIX*filecache` `sh_fc` ON `sh`.`file_source` = `sh_fc`.`fileid` 
 LEFT JOIN `*PREFIX*circles_member` `sh_cc_wn` ON (`sh_cc_wn`.`circle_id` = `sh_cc`.`unique_id`) AND (`sh_cc_wn`.`level` = :dcValue2) 
 LEFT JOIN `*PREFIX*circles_circle` `sh_ms_cf` ON `sh_ms`.`circle_id` = `sh_ms_cf`.`unique_id` 
 LEFT JOIN `*PREFIX*circles_member` `sh_in` ON (`sh_ms`.`inheritance_first` = `sh_in`.`single_id`) AND (`sh_ms`.`circle_id` = `sh_in`.`circle_id`) 
 LEFT JOIN `*PREFIX*share` `sh_sh` ON (`sh_sh`.`parent` = `sh`.`id`) AND (`sh_sh`.`share_with` = `sh_ms`.`single_id`) 
 LEFT JOIN `*PREFIX*circles_member` `sh_in_by` ON (`sh_ms`.`single_id` = `sh_in_by`.`single_id`) AND (`sh_ms`.`inheritance_last` = `sh_in_by`.`circle_id`) 
 LEFT JOIN `*PREFIX*circles_circle` `sh_in_on` ON `sh_in_on`.`unique_id` = `sh_in`.`single_id` 
 LEFT JOIN `*PREFIX*storages` `sh_fc_st` ON `sh_fc`.`storage` = `sh_fc_st`.`numeric_id` 
 WHERE (`sh`.`share_type` = :dcValue1) AND (`sh_ms`.`level` >= :dcValue4) AND (`sh`.`parent` IS NULL)

With the the proposed changes the number of join statements is reduced to 6, which reduces the average slow query log runtime roughly by a factor of 10:

Query_time: 0.001494  Lock_time: 0.000390  Rows_sent: 1  Rows_examined: 66
Proposed share provider db query
"SELECT `sh`.`id`,
 `sh`.`share_type`,
 `sh`.`share_with`,
 `sh`.`uid_owner`,
 `sh`.`uid_initiator`,
 `sh`.`parent`,
 `sh`.`item_type`,
 `sh`.`item_source`,
 `sh`.`item_target`,
 `sh`.`file_source`,
 `sh`.`file_target`,
 `sh`.`permissions`,
 `sh`.`stime`,
 `sh`.`accepted`,
 `sh`.`expiration`,
 `sh`.`token`,
 `sh`.`mail_send`,
 `sh_cc`.`unique_id` AS `sh_cc_unique_id`,
 `sh_cc`.`name` AS `sh_cc_name`,
 `sh_cc`.`display_name` AS `sh_cc_display_name`,
 `sh_cc`.`sanitized_name` AS `sh_cc_sanitized_name`,
 `sh_cc`.`source` AS `sh_cc_source`,
 `sh_cc`.`description` AS `sh_cc_description`,
 `sh_cc`.`settings` AS `sh_cc_settings`,
 `sh_cc`.`config` AS `sh_cc_config`,
 `sh_cc`.`contact_addressbook` AS `sh_cc_contact_addressbook`,
 `sh_cc`.`contact_groupname` AS `sh_cc_contact_groupname`,
 `sh_cc`.`creation` AS `sh_cc_creation`,
 `sh_cc_wn`.`circle_id` AS `sh_cc_wn_circle_id`,
 `sh_cc_wn`.`member_id` AS `sh_cc_wn_member_id`,
 `sh_cc_wn`.`single_id` AS `sh_cc_wn_single_id`,
 `sh_cc_wn`.`user_id` AS `sh_cc_wn_user_id`,
 `sh_cc_wn`.`instance` AS `sh_cc_wn_instance`,
 `sh_cc_wn`.`user_type` AS `sh_cc_wn_user_type`,
 `sh_cc_wn`.`level` AS `sh_cc_wn_level`,
 `sh_cc_wn`.`status` AS `sh_cc_wn_status`,
 `sh_cc_wn`.`note` AS `sh_cc_wn_note`,
 `sh_cc_wn`.`contact_id` AS `sh_cc_wn_contact_id`,
 `sh_cc_wn`.`cached_name` AS `sh_cc_wn_cached_name`,
 `sh_cc_wn`.`cached_update` AS `sh_cc_wn_cached_update`,
 `sh_cc_wn`.`contact_meta` AS `sh_cc_wn_contact_meta`,
 `sh_cc_wn`.`joined` AS `sh_cc_wn_joined`,
 `sh_fc`.`fileid` AS `sh_fc_fileid`,
 `sh_fc`.`path` AS `sh_fc_path`,
 `sh_fc`.`permissions` AS `sh_fc_permissions`,
 `sh_fc`.`storage` AS `sh_fc_storage`,
 `sh_fc`.`path_hash` AS `sh_fc_path_hash`,
 `sh_fc`.`parent` AS `sh_fc_parent`,
 `sh_fc`.`name` AS `sh_fc_name`,
 `sh_fc`.`mimetype` AS `sh_fc_mimetype`,
 `sh_fc`.`mimepart` AS `sh_fc_mimepart`,
 `sh_fc`.`size` AS `sh_fc_size`,
 `sh_fc`.`mtime` AS `sh_fc_mtime`,
 `sh_fc`.`storage_mtime` AS `sh_fc_storage_mtime`,
 `sh_fc`.`encrypted` AS `sh_fc_encrypted`,
 `sh_fc`.`unencrypted_size` AS `sh_fc_unencrypted_size`,
 `sh_fc`.`etag` AS `sh_fc_etag`,
 `sh_fc`.`checksum` AS `sh_fc_checksum`,
 `sh_fc_st`.`id` AS `sh_fc_st_id`,
 `sh_sh`.`id` AS `child_id`,
 `sh_sh`.`file_target` AS `child_file_target`,
 `sh_sh`.`permissions` AS `child_permissions` 
FROM `*PREFIX*share` `sh` 
LEFT JOIN `*PREFIX*circles_circle` `sh_cc` ON `sh_cc`.`unique_id` = `sh`.`share_with` 
LEFT JOIN `*PREFIX*filecache` `sh_fc` ON `sh`.`file_source` = `sh_fc`.`fileid` 
LEFT JOIN `*PREFIX*circles_member` `sh_cc_wn` ON (`sh_cc_wn`.`circle_id` = `sh_cc`.`unique_id`) AND (`sh_cc_wn`.`level` = :dcValue2) 
INNER JOIN `*PREFIX*circles_membership` `sh_ms` ON `sh_cc`.`unique_id` = `sh_ms`.`circle_id` 
LEFT JOIN `*PREFIX*share` `sh_sh` ON (`sh_sh`.`parent` = `sh`.`id`) AND (`sh_sh`.`share_with` = `sh_ms`.`single_id`) 
LEFT JOIN `*PREFIX*storages` `sh_fc_st` ON `sh_fc`.`storage` = `sh_fc_st`.`numeric_id` 
WHERE (`sh`.`share_type` = :dcValue1) AND (`sh_ms`.`single_id` = :dcValue3) AND (`sh`.`parent` IS NULL)"

As the share provider is called frequently e.g. by nc client or cron jobs for requesting the users mounted files, this changes can reduce the CPU load on very large instances.

Reduces the number of database table joins in a single call to share providers getShareWith function from 10 to 6

Signed-off-by: Giuliano Mele <[email protected]>
@ArtificialOwl
Copy link
Member

Is it related to #972 ?

@melegiul
Copy link
Contributor Author

melegiul commented May 2, 2022

Is it related to #972 ?

Yes, I think it is related, this PR is also affecting the performance of the getShareWith() function.

@ArtificialOwl
Copy link
Member

The global request look good, code too.

Thanks for your time, hope you had fun understanding the tables :]

Mind if I move your code around to make it more integrated to the code ?

@melegiul
Copy link
Contributor Author

melegiul commented May 3, 2022

Mind if I move your code around to make it more integrated to the code ?

Thank you very much for your review :) Sure, feel free to move the code.
I really enjoyed to contribute, when I have more time I would like to contribute further

@melegiul melegiul merged commit 35589f4 into nextcloud:master May 4, 2022
@melegiul melegiul deleted the melegiul/enh/share-provider branch May 4, 2022 08:11
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.

2 participants