Skip to content

Commit b7df488

Browse files
committed
join default_tree_scope only when a limit_depth is given
Although the query issued by the closure_tree_class.has_tree call has an optional argument `limit_depth` to reduce the load, the cost remains excessively high when dealing with the hierarchy table containing huge amount of records. Below is the execution plan of the query. ```sql MySQL [app_db]> EXPLAIN SELECT `tags`.* FROM `tags` INNER JOIN `tag_hierarchies` ON `tags`.`id` = `tag_hierarchies`.`descendant_id` INNER JOIN ( SELECT descendant_id, MAX(generations) AS depth FROM `tag_hierarchies` GROUP BY descendant_id ) AS generation_depth ON `tags`.id = generation_depth.descendant_id WHERE `tag_hierarchies`.`ancestor_id` = 2 AND ( `tags`.`id` != '2' ) ORDER BY `tag_hierarchies`.generations ASC, sort_order, generation_depth.depth; +----+-------------+-----------------+------------+--------+-------------------------------+------------------+---------+--------------------------------------+---------+----------+----------------------------------------------+ | id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra | +----+-------------+-----------------+------------+--------+-------------------------------+------------------+---------+--------------------------------------+---------+----------+----------------------------------------------+ | 1 | PRIMARY | tag_hierarchies | NULL | ref | tag_anc_desc_idx,tag_desc_idx | tag_anc_desc_idx | 4 | const | 14 | 100.00 | Using index; Using temporary; Using filesort | | 1 | PRIMARY | tags | NULL | eq_ref | PRIMARY | PRIMARY | 8 | app_db.tag_hierarchies.descendant_id | 1 | 100.00 | Using where | | 1 | PRIMARY | <derived2> | NULL | ref | <auto_key0> | <auto_key0> | 4 | app_db.tags.id | 10 | 100.00 | Using where | | 2 | DERIVED | tag_hierarchies | NULL | index | tag_anc_desc_idx,tag_desc_idx | tag_desc_idx | 4 | NULL | 970,482 | 100.00 | Using index | +----+-------------+-----------------+------------+--------+-------------------------------+------------------+---------+--------------------------------------+---------+----------+----------------------------------------------+ 4 rows in set (0.003 sec) ``` The default_tree_scope is only meaningful when limit_depth is specified (though it's questionable whether it actually reduces the load). I have confirmed that even without the join, the load is not significantly higher.
1 parent 53f4dc5 commit b7df488

File tree

2 files changed

+25
-3
lines changed

2 files changed

+25
-3
lines changed

lib/closure_tree/hash_tree.rb

+5-1
Original file line numberDiff line numberDiff line change
@@ -11,7 +11,11 @@ def hash_tree(options = {})
1111
# There is no default depth limit. This might be crazy-big, depending
1212
# on your tree shape. Hash huge trees at your own peril!
1313
def hash_tree(options = {})
14-
_ct.hash_tree(_ct.default_tree_scope(all, options[:limit_depth]))
14+
if options[:limit_depth]
15+
_ct.hash_tree(_ct.default_tree_scope(all, options[:limit_depth]))
16+
else
17+
_ct.hash_tree(all)
18+
end
1519
end
1620
end
1721
end

test/support/tag_examples.rb

+20-2
Original file line numberDiff line numberDiff line change
@@ -761,9 +761,19 @@ def assert_parent_and_children
761761
assert_equal @full_tree, @tag_class.hash_tree(limit_depth: 4)
762762
end
763763

764+
it 'joins the default scope when a limit_depth is given' do
765+
queries = sql_queries { @tag_class.hash_tree(limit_depth: 2) }
766+
assert queries.any? { |query| query.match?(%r{INNER JOIN \( SELECT descendant_id, MAX\(generations\) as depth}) }
767+
end
768+
764769
it 'no limit' do
765770
assert_equal @full_tree, @tag_class.hash_tree
766771
end
772+
773+
it 'does not join the default scope when there is no limit' do
774+
queries = sql_queries { @tag_class.hash_tree }
775+
assert_equal queries.any? { |query| query.match?(%r{INNER JOIN \( SELECT descendant_id, MAX\(generations\) as depth}) }, false
776+
end
767777
end
768778

769779
describe '.hash_tree' do
@@ -805,6 +815,16 @@ def assert_parent_and_children
805815
assert_equal @full_tree[@a], @a.children.hash_tree
806816
end
807817

818+
it 'joins the default scope when a limit_depth is given' do
819+
queries = sql_queries { @a.self_and_descendants.hash_tree(limit_depth: 2) }
820+
assert queries.any? { |query| query.match?(%r{INNER JOIN \( SELECT descendant_id, MAX\(generations\) as depth}) }
821+
end
822+
823+
it 'does not join the default scope when there is no limit' do
824+
queries = sql_queries { @a.self_and_descendants.hash_tree }
825+
assert_equal queries.any? { |query| query.match?(%r{INNER JOIN \( SELECT descendant_id, MAX\(generations\) as depth}) }, false
826+
end
827+
808828
it 'limit_depth 3 from b.parent' do
809829
assert_equal @three_tree.slice(@a), @b.parent.hash_tree(limit_depth: 3)
810830
end
@@ -899,8 +919,6 @@ def assert_parent_and_children
899919
@c3 = @tag_class.find_or_create_by_path %w[a3 b3 c3]
900920
@b3 = @c3.parent
901921
@a3 = @b3.parent
902-
903-
904922
end
905923

906924
it 'should return 0 for root' do

0 commit comments

Comments
 (0)