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

Bug/57305 sorting by custom field has strong impact on performance for the project list #16841

Merged
Show file tree
Hide file tree
Changes from all commits
Commits
Show all changes
28 commits
Select commit Hold shift + click to select a range
72dcb21
[#57305] Sorting by custom field has strong impact on performance for…
toy Sep 27, 2024
b6f64e2
remove unused option `if` from work package property select
toy Sep 27, 2024
4f77de6
using instance variables instead of writers for work package selects
toy Sep 27, 2024
82a7e2e
inline set_xxx! methods in CustomFieldSelect
toy Oct 4, 2024
86ab142
rename order_statements to order_statement swithcing it to return sin…
toy Oct 4, 2024
ae8d82a
apply null handling to ordering projects by custom field
toy Oct 4, 2024
544e7d4
rename CustomField#null_handling to order_null_handling
toy Oct 4, 2024
edd62d8
using joins for custom field ordering, grouping should be broken
toy Oct 4, 2024
b886078
move deciding which custom field can be grouped by to order statements
toy Oct 4, 2024
4a72b89
enable grouping by float, string and link too
toy Oct 10, 2024
ac27483
remove replacing nil by false which doesn't seem to be needed
toy Oct 10, 2024
48eda6e
handle joins for groupping by custom field
toy Oct 8, 2024
70b1acb
fix join statement for group by to return ids instead of positions
toy Oct 9, 2024
119de6e
handle absent values in group by
toy Oct 9, 2024
8b3ceff
pass group_by_join_statement to WorkPackageSelect.scoped_column_sum
toy Oct 10, 2024
924e9c8
disambigute value in summable_select_statement
toy Oct 10, 2024
ac2c910
use receive_messages as rubocop suggests
toy Oct 10, 2024
ac6202b
deduplicate queries using template
toy Oct 10, 2024
76e4096
ensure group_by_join_statement is nil when group_by_statement is nil
toy Oct 10, 2024
526d287
order empty values before present values for all custom field formats
toy Oct 11, 2024
fbb246f
fix order of list custom field groups to be same as when ordering
toy Oct 14, 2024
ae6702a
use MIN instead of ANY_VALUE, as latter is available only in PostgreS…
toy Oct 14, 2024
e508268
fix columns used in summing
toy Oct 15, 2024
7e0ed44
use group_id instead of id to name the column used to group from summing
toy Oct 15, 2024
9c99bc8
extract method to calm rubocop
toy Oct 15, 2024
bb9b32e
add resulting join sqls from template in comment
toy Oct 18, 2024
98ca48c
fix link strategy to return nil when value is not set
toy Nov 11, 2024
dc28e44
move creation of angular boostrap __ng2-bootstrap-has-run mark, so it…
toy Nov 13, 2024
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
220 changes: 106 additions & 114 deletions app/models/custom_field/order_statements.rb
Original file line number Diff line number Diff line change
Expand Up @@ -27,152 +27,144 @@
#++

module CustomField::OrderStatements
# Returns a ORDER BY clause that can used to sort customized
# objects by their value of the custom field.
# Returns false, if the custom field can not be used for sorting.
def order_statements
# Returns the expression to use in ORDER BY clause to sort objects by their
# value of the custom field.
def order_statement
case field_format
when "string", "date", "bool", "link", "int", "float", "list", "user", "version"
"cf_order_#{id}.value"
end
end

# Returns the join statement that is required to sort objects by their value
# of the custom field.
def order_join_statement
case field_format
when "list"
[order_by_list_sql]
when "string", "date", "bool", "link"
[coalesce_select_custom_value_as_string]
when "int", "float"
# Make the database cast values into numeric
# Postgresql will raise an error if a value can not be casted!
# CustomValue validations should ensure that it doesn't occur
[select_custom_value_as_decimal]
join_for_order_by_string_sql
when "int"
join_for_order_by_int_sql
when "float"
join_for_order_by_float_sql
when "list"
join_for_order_by_list_sql
when "user"
[order_by_user_sql]
join_for_order_by_user_sql
when "version"
[order_by_version_sql]
join_for_order_by_version_sql
end
end

##
# Returns the null handling for the given direction
def null_handling(asc)
return unless %w[int float].include?(field_format)

# Returns the ORDER BY option defining order of objects without value for the
# custom field.
def order_null_handling(asc)
null_direction = asc ? "FIRST" : "LAST"
Arel.sql("NULLS #{null_direction}")
end

# Returns the grouping result
# which differ for multi-value select fields,
# because in this case we do want the primary CV values
# Returns the expression to use in GROUP BY (and ORDER BY) clause to group
# objects by their value of the custom field.
def group_by_statement
return order_statements unless field_format == "list"
return unless can_be_used_for_grouping?

if multi_value?
# We want to return the internal IDs in the case of grouping
select_custom_values_as_group
else
coalesce_select_custom_value_as_string
end
order_statement
end

private

def coalesce_select_custom_value_as_string
# COALESCE is here to make sure that blank and NULL values are sorted equally
<<-SQL.squish
COALESCE(#{select_custom_value_as_string}, '')
SQL
end
# Returns the expression to use in SELECT clause if it differs from one used
# to group by
def group_by_select_statement
return unless field_format == "list"

def select_custom_value_as_string
<<-SQL.squish
(
SELECT cv_sort.value
FROM #{CustomValue.quoted_table_name} cv_sort
WHERE #{cv_sort_only_custom_field_condition_sql}
LIMIT 1
)
SQL
# MIN needed to not add this column to group by, ANY_VALUE can be used when
# minimum required PostgreSQL becomes 16
"MIN(cf_order_#{id}.ids)"
end

def select_custom_values_as_group
<<-SQL.squish
COALESCE(
(
SELECT string_agg(cv_sort.value, '.')
FROM #{CustomValue.quoted_table_name} cv_sort
WHERE #{cv_sort_only_custom_field_condition_sql}
AND cv_sort.value IS NOT NULL
),
''
)
SQL
end
# Returns the join statement that is required to group objects by their value
# of the custom field.
def group_by_join_statement
return unless can_be_used_for_grouping?

def select_custom_value_as_decimal
<<-SQL.squish
(
SELECT CAST(cv_sort.value AS decimal(60,3))
FROM #{CustomValue.quoted_table_name} cv_sort
WHERE #{cv_sort_only_custom_field_condition_sql}
AND cv_sort.value <> ''
AND cv_sort.value IS NOT NULL
LIMIT 1
)
SQL
order_join_statement
end

def order_by_list_sql
columns = multi_value? ? "array_agg(co_sort.position ORDER BY co_sort.position)" : "co_sort.position"
limit = multi_value? ? "" : "LIMIT 1"
private

def can_be_used_for_grouping? = field_format.in?(%w[list date bool int float string link])

# Template for all the join statements.
#
# For single value custom fields the join ensures single value for every
# customized object using DISTINCT ON and selecting first value by id of
# custom value:
#
# LEFT OUTER JOIN (
# SELECT DISTINCT ON (cv.customized_id), cv.customized_id, xxx "value"
# FROM custom_values cv
# WHERE …
# ORDER BY cv.customized_id, cv.id
# ) cf_order_NNN ON cf_order_NNN.customized_id = …
#
# For multi value custom fields the GROUP BY and value aggregate function
# ensure single value for every customized object:
#
# LEFT OUTER JOIN (
# SELECT cv.customized_id, ARRAY_AGG(xxx ORDERY BY yyy) "value"
# FROM custom_values cv
# WHERE …
# GROUP BY cv.customized_id, cv.id
# ) cf_order_NNN ON cf_order_NNN.customized_id = …
#
def join_for_order_sql(value:, add_select: nil, join: nil, multi_value: false)
<<-SQL.squish
(
SELECT #{columns}
FROM #{CustomOption.quoted_table_name} co_sort
INNER JOIN #{CustomValue.quoted_table_name} cv_sort
ON cv_sort.value IS NOT NULL AND cv_sort.value != '' AND co_sort.id = cv_sort.value::bigint
WHERE #{cv_sort_only_custom_field_condition_sql}
#{limit}
)
LEFT OUTER JOIN (
SELECT
#{multi_value ? '' : 'DISTINCT ON (cv.customized_id)'}
cv.customized_id
, #{value} "value"
#{", #{add_select}" if add_select}
FROM #{CustomValue.quoted_table_name} cv
#{join}
WHERE cv.customized_type = #{CustomValue.connection.quote(self.class.customized_class.name)}
AND cv.custom_field_id = #{id}
AND cv.value IS NOT NULL
AND cv.value != ''
#{multi_value ? 'GROUP BY cv.customized_id' : 'ORDER BY cv.customized_id, cv.id'}
) cf_order_#{id}
ON cf_order_#{id}.customized_id = #{self.class.customized_class.quoted_table_name}.id
SQL
end

def order_by_user_sql
columns_array = "ARRAY[cv_user.lastname, cv_user.firstname, cv_user.mail]"
def join_for_order_by_string_sql = join_for_order_sql(value: "cv.value")

columns = multi_value? ? "array_agg(#{columns_array} ORDER BY #{columns_array})" : columns_array
limit = multi_value? ? "" : "LIMIT 1"
def join_for_order_by_int_sql = join_for_order_sql(value: "cv.value::decimal(60)")

<<-SQL.squish
(
SELECT #{columns}
FROM #{User.quoted_table_name} cv_user
INNER JOIN #{CustomValue.quoted_table_name} cv_sort
ON cv_sort.value IS NOT NULL AND cv_sort.value != '' AND cv_user.id = cv_sort.value::bigint
WHERE #{cv_sort_only_custom_field_condition_sql}
#{limit}
)
SQL
def join_for_order_by_float_sql = join_for_order_sql(value: "cv.value::double precision")

def join_for_order_by_list_sql
join_for_order_sql(
value: multi_value? ? "ARRAY_AGG(co.position ORDER BY co.position)" : "co.position",
add_select: "#{multi_value? ? "ARRAY_TO_STRING(ARRAY_AGG(cv.value ORDER BY co.position), '.')" : 'cv.value'} ids",
join: "INNER JOIN #{CustomOption.quoted_table_name} co ON co.id = cv.value::bigint",
multi_value:
)
end

def order_by_version_sql
columns = multi_value? ? "array_agg(cv_version.name ORDER BY cv_version.name)" : "cv_version.name"
limit = multi_value? ? "" : "LIMIT 1"
def join_for_order_by_user_sql
columns_array = "ARRAY[users.lastname, users.firstname, users.mail]"

<<-SQL.squish
(
SELECT #{columns}
FROM #{Version.quoted_table_name} cv_version
INNER JOIN #{CustomValue.quoted_table_name} cv_sort
ON cv_sort.value IS NOT NULL AND cv_sort.value != '' AND cv_version.id = cv_sort.value::bigint
WHERE #{cv_sort_only_custom_field_condition_sql}
#{limit}
)
SQL
join_for_order_sql(
value: multi_value? ? "ARRAY_AGG(#{columns_array} ORDER BY #{columns_array})" : columns_array,
join: "INNER JOIN #{User.quoted_table_name} users ON users.id = cv.value::bigint",
multi_value:
)
end

def cv_sort_only_custom_field_condition_sql
<<-SQL.squish
cv_sort.customized_type='#{self.class.customized_class.name}'
AND cv_sort.customized_id=#{self.class.customized_class.quoted_table_name}.id
AND cv_sort.custom_field_id=#{id}
SQL
def join_for_order_by_version_sql
join_for_order_sql(
value: multi_value? ? "array_agg(versions.name ORDER BY versions.name)" : "versions.name",
join: "INNER JOIN #{Version.quoted_table_name} versions ON versions.id = cv.value::bigint",
multi_value:
)
end
end
2 changes: 1 addition & 1 deletion app/models/custom_value/link_strategy.rb
Original file line number Diff line number Diff line change
Expand Up @@ -28,7 +28,7 @@

class CustomValue::LinkStrategy < CustomValue::FormatStrategy
def typed_value
formatted_value
formatted_value if value.present?
end

def parse_value(val)
Expand Down
12 changes: 9 additions & 3 deletions app/models/queries/projects/orders/custom_field_order.rb
Original file line number Diff line number Diff line change
Expand Up @@ -58,10 +58,16 @@ def available?
private

def order(scope)
joined_statement = custom_field.order_statements.map do |statement|
Arel.sql("#{statement} #{direction}")
if (join_statement = custom_field.order_join_statement)
scope = scope.joins(join_statement)
end

scope.order(joined_statement)
order_statement = "#{custom_field.order_statement} #{direction}"

if (null_handling = custom_field.order_null_handling(direction == :asc))
order_statement = "#{order_statement} #{null_handling}"
end

scope.order(Arel.sql(order_statement))
Dismissed Show dismissed Hide dismissed
end
end
60 changes: 23 additions & 37 deletions app/models/queries/work_packages/selects/custom_field_select.rb
Original file line number Diff line number Diff line change
Expand Up @@ -32,21 +32,20 @@ def initialize(custom_field)

@cf = custom_field

set_name!
set_sortable!
set_groupable!
set_summable!
end

def groupable_custom_field?(custom_field)
%w(list date bool int).include?(custom_field.field_format)
@name = custom_field.column_name.to_sym
@sortable = custom_field.order_statement
@sortable_join = custom_field.order_join_statement
@groupable = custom_field.group_by_statement
@groupable_join = custom_field.group_by_join_statement
@groupable_select = custom_field.group_by_select_statement
@summable = summable_statement
end

def caption
@cf.name
end

delegate :null_handling, to: :custom_field
def null_handling(...) = custom_field.order_null_handling(...)

def custom_field
@cf
Expand All @@ -68,32 +67,6 @@ def self.instances(context = nil)

private

def set_name!
self.name = custom_field.column_name.to_sym
end

def set_sortable!
self.sortable = custom_field.order_statements || false
end

def set_groupable!
self.groupable = custom_field.group_by_statement if groupable_custom_field?(custom_field)
self.groupable ||= false
end

def set_summable!
self.summable = if %w(float int).include?(custom_field.field_format)
select = summable_select_statement

->(query, grouped) {
Queries::WorkPackages::Selects::WorkPackageSelect
.scoped_column_sum(summable_scope(query), select, grouped && query.group_by_statement)
}
else
false
end
end

def summable_scope(query)
WorkPackage
.where(id: query.results.work_packages)
Expand All @@ -105,9 +78,22 @@ def summable_scope(query)

def summable_select_statement
if custom_field.field_format == "int"
"COALESCE(SUM(value::BIGINT)::BIGINT, 0) #{name}"
"COALESCE(SUM(#{CustomValue.quoted_table_name}.value::BIGINT)::BIGINT, 0) #{name}"
else
"COALESCE(ROUND(SUM(#{CustomValue.quoted_table_name}.value::NUMERIC), 2)::FLOAT, 0.0) #{name}"
end
end

def summable_statement
if %w[float int].include?(custom_field.field_format)
select = summable_select_statement

->(query, grouped) {
Queries::WorkPackages::Selects::WorkPackageSelect
.scoped_column_sum(summable_scope(query), select, grouped:, query:)
}
else
"COALESCE(ROUND(SUM(value::NUMERIC), 2)::FLOAT, 0.0) #{name}"
false
end
end
Comment on lines +87 to 98
Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Diff may make it confusing, this is extracted from set_summable!

end
7 changes: 2 additions & 5 deletions app/models/queries/work_packages/selects/property_select.rb
Original file line number Diff line number Diff line change
Expand Up @@ -130,15 +130,12 @@ def caption
shared_with_users: {
sortable: false,
groupable: false

}
}

def self.instances(_context = nil)
property_selects.filter_map do |name, options|
next unless !options[:if] || options[:if].call

new(name, options.except(:if))
property_selects.map do |name, options|
new(name, options)
end
end
end
Loading