Copybara | 854996b | 2021-09-07 19:36:02 +0000 | [diff] [blame^] | 1 | # Copyright 2016 The Chromium Authors. All rights reserved. |
| 2 | # Use of this source code is governed by a BSD-style |
| 3 | # license that can be found in the LICENSE file or at |
| 4 | # https://developers.google.com/open-source/licenses/bsd |
| 5 | |
| 6 | """Convert a user's issue sorting directives into SQL clauses. |
| 7 | |
| 8 | Some sort directives translate into simple ORDER BY column specifications. |
| 9 | Other sort directives require that a LEFT JOIN be done to bring in |
| 10 | relevant information that is then used in the ORDER BY. |
| 11 | |
| 12 | Sorting based on strings can slow down the DB because long sort-keys |
| 13 | must be loaded into RAM, which means that fewer sort-keys fit into the |
| 14 | DB's sorting buffers at a time. Also, Monorail defines the sorting |
| 15 | order of well-known labels and statuses based on the order in which |
| 16 | they are defined in the project's config. So, we determine the sort order of |
| 17 | labels and status values before executing the query and then use the MySQL |
| 18 | FIELD() function to sort their IDs in the desired order, without sorting |
| 19 | strings. |
| 20 | |
| 21 | For more info, see the "Sorting in Monorail" and "What makes Monorail Fast?" |
| 22 | design docs. |
| 23 | """ |
| 24 | from __future__ import print_function |
| 25 | from __future__ import division |
| 26 | from __future__ import absolute_import |
| 27 | |
| 28 | import logging |
| 29 | |
| 30 | from framework import sql |
| 31 | from proto import tracker_pb2 |
| 32 | from tracker import tracker_constants |
| 33 | |
| 34 | |
| 35 | NATIVE_SORTABLE_FIELDS = [ |
| 36 | 'id', 'stars', 'attachments', 'opened', 'closed', 'modified', |
| 37 | 'ownermodified', 'statusmodified', 'componentmodified', |
| 38 | ] |
| 39 | |
| 40 | FIELDS_TO_COLUMNS = { |
| 41 | 'id': 'local_id', |
| 42 | 'stars': 'star_count', |
| 43 | 'attachments': 'attachment_count', |
| 44 | 'ownermodified': 'owner_modified', |
| 45 | 'statusmodified': 'status_modified', |
| 46 | 'componentmodified': 'component_modified', |
| 47 | } |
| 48 | |
| 49 | APPROVAL_STATUS_SORT_ORDER = [ |
| 50 | '\'not_set\'', '\'needs_review\'', '\'na\'', '\'review_requested\'', |
| 51 | '\'review_started\'', '\'need_info\'', '\'approved\'', '\'not_approved\''] |
| 52 | |
| 53 | |
| 54 | def BuildSortClauses( |
| 55 | sort_directives, harmonized_labels, harmonized_statuses, |
| 56 | harmonized_fields): |
| 57 | """Return LEFT JOIN and ORDER BY clauses needed to sort the results.""" |
| 58 | if not sort_directives: |
| 59 | return [], [] |
| 60 | |
| 61 | all_left_joins = [] |
| 62 | all_order_by = [] |
| 63 | for i, sd in enumerate(sort_directives): |
| 64 | left_join_parts, order_by_parts = _OneSortDirective( |
| 65 | i, sd, harmonized_labels, harmonized_statuses, harmonized_fields) |
| 66 | all_left_joins.extend(left_join_parts) |
| 67 | all_order_by.extend(order_by_parts) |
| 68 | |
| 69 | return all_left_joins, all_order_by |
| 70 | |
| 71 | |
| 72 | def _ProcessProjectSD(fmt): |
| 73 | """Convert a 'project' sort directive into SQL.""" |
| 74 | left_joins = [] |
| 75 | order_by = [(fmt('Issue.project_id {sort_dir}'), [])] |
| 76 | return left_joins, order_by |
| 77 | |
| 78 | |
| 79 | def _ProcessReporterSD(fmt): |
| 80 | """Convert a 'reporter' sort directive into SQL.""" |
| 81 | left_joins = [ |
| 82 | (fmt('User AS {alias} ON Issue.reporter_id = {alias}.user_id'), [])] |
| 83 | order_by = [ |
| 84 | (fmt('ISNULL({alias}.email) {sort_dir}'), []), |
| 85 | (fmt('{alias}.email {sort_dir}'), [])] |
| 86 | return left_joins, order_by |
| 87 | |
| 88 | |
| 89 | def _ProcessOwnerSD(fmt): |
| 90 | """Convert a 'owner' sort directive into SQL.""" |
| 91 | left_joins = [ |
| 92 | (fmt('User AS {alias}_exp ON Issue.owner_id = {alias}_exp.user_id'), []), |
| 93 | (fmt('User AS {alias}_der ON ' |
| 94 | 'Issue.derived_owner_id = {alias}_der.user_id'), [])] |
| 95 | order_by = [ |
| 96 | (fmt('(ISNULL({alias}_exp.email) AND ISNULL({alias}_der.email)) ' |
| 97 | '{sort_dir}'), []), |
| 98 | (fmt('CONCAT({alias}_exp.email, {alias}_der.email) {sort_dir}'), [])] |
| 99 | return left_joins, order_by |
| 100 | |
| 101 | |
| 102 | def _ProcessCcSD(fmt): |
| 103 | """Convert a 'cc' sort directive into SQL.""" |
| 104 | # Note: derived cc's are included automatically. |
| 105 | # Note: This sorts on the best Cc, not all Cc addresses. |
| 106 | # Being more exact might require GROUP BY and GROUP_CONCAT(). |
| 107 | left_joins = [ |
| 108 | (fmt('Issue2Cc AS {alias} ON Issue.id = {alias}.issue_id ' |
| 109 | 'LEFT JOIN User AS {alias}_user ' |
| 110 | 'ON {alias}.cc_id = {alias}_user.user_id'), [])] |
| 111 | order_by = [ |
| 112 | (fmt('ISNULL({alias}_user.email) {sort_dir}'), []), |
| 113 | (fmt('{alias}_user.email {sort_dir}'), [])] |
| 114 | return left_joins, order_by |
| 115 | |
| 116 | |
| 117 | def _ProcessComponentSD(fmt): |
| 118 | """Convert a 'component' sort directive into SQL.""" |
| 119 | # Note: derived components are included automatically. |
| 120 | # Note: This sorts on the best component, not all of them. |
| 121 | # Being more exact might require GROUP BY and GROUP_CONCAT(). |
| 122 | left_joins = [ |
| 123 | (fmt('Issue2Component AS {alias} ON Issue.id = {alias}.issue_id ' |
| 124 | 'LEFT JOIN ComponentDef AS {alias}_component ' |
| 125 | 'ON {alias}.component_id = {alias}_component.id'), [])] |
| 126 | order_by = [ |
| 127 | (fmt('ISNULL({alias}_component.path) {sort_dir}'), []), |
| 128 | (fmt('{alias}_component.path {sort_dir}'), [])] |
| 129 | return left_joins, order_by |
| 130 | |
| 131 | |
| 132 | def _ProcessSummarySD(fmt): |
| 133 | """Convert a 'summary' sort directive into SQL.""" |
| 134 | left_joins = [ |
| 135 | (fmt('IssueSummary AS {alias} ON Issue.id = {alias}.issue_id'), [])] |
| 136 | order_by = [(fmt('{alias}.summary {sort_dir}'), [])] |
| 137 | return left_joins, order_by |
| 138 | |
| 139 | |
| 140 | def _ProcessStatusSD(fmt, harmonized_statuses): |
| 141 | """Convert a 'status' sort directive into SQL.""" |
| 142 | left_joins = [] |
| 143 | # Note: status_def_rows are already ordered by REVERSED rank. |
| 144 | wk_status_ids = [ |
| 145 | stat_id for stat_id, rank, _ in harmonized_statuses |
| 146 | if rank is not None] |
| 147 | odd_status_ids = [ |
| 148 | stat_id for stat_id, rank, _ in harmonized_statuses |
| 149 | if rank is None] |
| 150 | wk_status_ph = sql.PlaceHolders(wk_status_ids) |
| 151 | # Even though oddball statuses sort lexographically, use FIELD to determine |
| 152 | # the order so that the database sorts ints rather than strings for speed. |
| 153 | odd_status_ph = sql.PlaceHolders(odd_status_ids) |
| 154 | |
| 155 | order_by = [] # appended to below: both well-known and oddball can apply |
| 156 | sort_col = ('IF(ISNULL(Issue.status_id), Issue.derived_status_id, ' |
| 157 | 'Issue.status_id)') |
| 158 | # Reverse sort by using rev_sort_dir because we want NULLs at the end. |
| 159 | if wk_status_ids: |
| 160 | order_by.append( |
| 161 | (fmt('FIELD({sort_col}, {wk_status_ph}) {rev_sort_dir}', |
| 162 | sort_col=sort_col, wk_status_ph=wk_status_ph), |
| 163 | wk_status_ids)) |
| 164 | if odd_status_ids: |
| 165 | order_by.append( |
| 166 | (fmt('FIELD({sort_col}, {odd_status_ph}) {rev_sort_dir}', |
| 167 | sort_col=sort_col, odd_status_ph=odd_status_ph), |
| 168 | odd_status_ids)) |
| 169 | |
| 170 | return left_joins, order_by |
| 171 | |
| 172 | |
| 173 | def _ProcessBlockedSD(fmt): |
| 174 | """Convert a 'blocked' sort directive into SQL.""" |
| 175 | left_joins = [ |
| 176 | (fmt('IssueRelation AS {alias} ON Issue.id = {alias}.issue_id ' |
| 177 | 'AND {alias}.kind = %s'), |
| 178 | ['blockedon'])] |
| 179 | order_by = [(fmt('ISNULL({alias}.dst_issue_id) {sort_dir}'), [])] |
| 180 | return left_joins, order_by |
| 181 | |
| 182 | |
| 183 | def _ProcessBlockedOnSD(fmt): |
| 184 | """Convert a 'blockedon' sort directive into SQL.""" |
| 185 | left_joins = [ |
| 186 | (fmt('IssueRelation AS {alias} ON Issue.id = {alias}.issue_id ' |
| 187 | 'AND {alias}.kind = %s'), |
| 188 | ['blockedon'])] |
| 189 | order_by = [(fmt('ISNULL({alias}.dst_issue_id) {sort_dir}'), []), |
| 190 | (fmt('{alias}.dst_issue_id {sort_dir}'), [])] |
| 191 | return left_joins, order_by |
| 192 | |
| 193 | |
| 194 | def _ProcessBlockingSD(fmt): |
| 195 | """Convert a 'blocking' sort directive into SQL.""" |
| 196 | left_joins = [ |
| 197 | (fmt('IssueRelation AS {alias} ON Issue.id = {alias}.dst_issue_id ' |
| 198 | 'AND {alias}.kind = %s'), |
| 199 | ['blockedon'])] |
| 200 | order_by = [(fmt('ISNULL({alias}.issue_id) {sort_dir}'), []), |
| 201 | (fmt('{alias}.issue_id {sort_dir}'), [])] |
| 202 | return left_joins, order_by |
| 203 | |
| 204 | |
| 205 | def _ProcessMergedIntoSD(fmt): |
| 206 | """Convert a 'mergedinto' sort directive into SQL.""" |
| 207 | left_joins = [ |
| 208 | (fmt('IssueRelation AS {alias} ON Issue.id = {alias}.issue_id ' |
| 209 | 'AND {alias}.kind = %s'), |
| 210 | ['mergedinto'])] |
| 211 | order_by = [(fmt('ISNULL({alias}.dst_issue_id) {sort_dir}'), []), |
| 212 | (fmt('{alias}.dst_issue_id {sort_dir}'), [])] |
| 213 | return left_joins, order_by |
| 214 | |
| 215 | |
| 216 | def _ProcessOwnerLastVisitSD(fmt): |
| 217 | """Convert a 'ownerlastvisit' sort directive into SQL.""" |
| 218 | left_joins = [ |
| 219 | (fmt('User AS {alias} ON (Issue.owner_id = {alias}.user_id OR ' |
| 220 | 'Issue.derived_owner_id = {alias}.user_id)'), [])] |
| 221 | order_by = [ |
| 222 | (fmt('ISNULL({alias}.last_visit_timestamp) {sort_dir}'), []), |
| 223 | (fmt('{alias}.last_visit_timestamp {sort_dir}'), [])] |
| 224 | return left_joins, order_by |
| 225 | |
| 226 | |
| 227 | def _ProcessCustomAndLabelSD( |
| 228 | sd, harmonized_labels, harmonized_fields, alias, sort_dir, fmt): |
| 229 | """Convert a label or custom field sort directive into SQL.""" |
| 230 | left_joins = [] |
| 231 | order_by = [] |
| 232 | phase_name = None |
| 233 | # If a custom field is an approval_type with no suffix, the |
| 234 | # approvals should be sorted by status. |
| 235 | approval_suffix = '-status' |
| 236 | approval_fd_list = [] |
| 237 | |
| 238 | # Check for reserved suffixes in col_name sd. |
| 239 | # TODO(jojwang): check for other suffixes in |
| 240 | # tracker_constants.RESERVED_COL_NAME_SUFFIXES |
| 241 | if sd.endswith(tracker_constants.APPROVER_COL_SUFFIX): |
| 242 | field_name = sd[:-len(tracker_constants.APPROVER_COL_SUFFIX)] |
| 243 | fd_list = [] |
| 244 | approval_fd_list = [fd for fd in harmonized_fields |
| 245 | if fd.field_name.lower() == field_name] |
| 246 | approval_suffix = tracker_constants.APPROVER_COL_SUFFIX |
| 247 | else: |
| 248 | field_name = sd |
| 249 | if '.' in sd: |
| 250 | phase_name, field_name = sd.split('.', 1) |
| 251 | |
| 252 | fd_list = [fd for fd in harmonized_fields |
| 253 | if fd.field_name.lower() == field_name] |
| 254 | if not phase_name: |
| 255 | approval_fd_list = [fd for fd in fd_list if |
| 256 | fd.field_type == tracker_pb2.FieldTypes.APPROVAL_TYPE] |
| 257 | |
| 258 | # 'alias' is used for all the CustomField, Approval, and Label sort clauses. |
| 259 | # Custom field aliases are alwyas appended by the value_col name. |
| 260 | # Approval aliases are always appended with 'approval'. |
| 261 | # Label clauses use 'alias' as-is. |
| 262 | if fd_list: |
| 263 | int_left_joins, int_order_by = _CustomFieldSortClauses( |
| 264 | fd_list, tracker_pb2.FieldTypes.INT_TYPE, 'int_value', |
| 265 | alias, sort_dir, phase_name=phase_name) |
| 266 | str_left_joins, str_order_by = _CustomFieldSortClauses( |
| 267 | fd_list, tracker_pb2.FieldTypes.STR_TYPE, 'str_value', |
| 268 | alias, sort_dir, phase_name=phase_name) |
| 269 | user_left_joins, user_order_by = _CustomFieldSortClauses( |
| 270 | fd_list, tracker_pb2.FieldTypes.USER_TYPE, 'user_id', |
| 271 | alias, sort_dir, phase_name=phase_name) |
| 272 | left_joins.extend(int_left_joins + str_left_joins + user_left_joins) |
| 273 | order_by.extend(int_order_by + str_order_by + user_order_by) |
| 274 | |
| 275 | if approval_fd_list: |
| 276 | approval_left_joins, approval_order_by = _ApprovalFieldSortClauses( |
| 277 | approval_fd_list, approval_suffix, fmt) |
| 278 | left_joins.extend(approval_left_joins) |
| 279 | order_by.extend(approval_order_by) |
| 280 | |
| 281 | label_left_joinss, label_order_by = _LabelSortClauses( |
| 282 | sd, harmonized_labels, fmt) |
| 283 | left_joins.extend(label_left_joinss) |
| 284 | order_by.extend(label_order_by) |
| 285 | |
| 286 | return left_joins, order_by |
| 287 | |
| 288 | |
| 289 | def _ApprovalFieldSortClauses( |
| 290 | approval_fd_list, approval_suffix, fmt): |
| 291 | """Give LEFT JOIN and ORDER BY terms for approval sort directives.""" |
| 292 | approver_left_joins = None |
| 293 | if approval_suffix == tracker_constants.APPROVER_COL_SUFFIX: |
| 294 | tbl_name = 'IssueApproval2Approver' |
| 295 | approver_left_joins = ( |
| 296 | fmt('User AS {alias}_approval_user ' |
| 297 | 'ON {alias}_approval.approver_id = {alias}_approval_user.user_id'), |
| 298 | []) |
| 299 | order_by = [ |
| 300 | (fmt('ISNULL({alias}_approval_user.email) {sort_dir}'), []), |
| 301 | (fmt('{alias}_approval_user.email {sort_dir}'), [])] |
| 302 | else: |
| 303 | tbl_name = 'Issue2ApprovalValue' |
| 304 | order_by = [ |
| 305 | (fmt('FIELD({alias}_approval.status, {approval_status_ph}) ' |
| 306 | '{rev_sort_dir}', |
| 307 | approval_status_ph=sql.PlaceHolders(APPROVAL_STATUS_SORT_ORDER)), |
| 308 | APPROVAL_STATUS_SORT_ORDER |
| 309 | )] |
| 310 | |
| 311 | left_joins = [( |
| 312 | fmt('{tbl_name} AS {alias}_approval ' |
| 313 | 'ON Issue.id = {alias}_approval.issue_id ' |
| 314 | 'AND {alias}_approval.approval_id IN ({approval_ids_ph})', |
| 315 | approval_ids_ph=sql.PlaceHolders(approval_fd_list), |
| 316 | tbl_name=tbl_name), |
| 317 | [fd.field_id for fd in approval_fd_list] |
| 318 | )] |
| 319 | |
| 320 | if approver_left_joins: |
| 321 | left_joins.append(approver_left_joins) |
| 322 | |
| 323 | return left_joins, order_by |
| 324 | |
| 325 | |
| 326 | def _LabelSortClauses(sd, harmonized_labels, fmt): |
| 327 | """Give LEFT JOIN and ORDER BY terms for label sort directives.""" |
| 328 | # Note: derived labels should work automatically. |
| 329 | |
| 330 | # label_def_rows are already ordered by REVERSED rank. |
| 331 | wk_label_ids = [ |
| 332 | label_id for label_id, rank, label in harmonized_labels |
| 333 | if label.lower().startswith('%s-' % sd) and rank is not None] |
| 334 | odd_label_ids = [ |
| 335 | label_id for label_id, rank, label in harmonized_labels |
| 336 | if label.lower().startswith('%s-' % sd) and rank is None] |
| 337 | all_label_ids = wk_label_ids + odd_label_ids |
| 338 | |
| 339 | if all_label_ids: |
| 340 | left_joins = [ |
| 341 | (fmt('Issue2Label AS {alias} ON Issue.id = {alias}.issue_id ' |
| 342 | 'AND {alias}.label_id IN ({all_label_ph})', |
| 343 | all_label_ph=sql.PlaceHolders(all_label_ids)), |
| 344 | all_label_ids)] |
| 345 | else: |
| 346 | left_joins = [] |
| 347 | |
| 348 | order_by = [] |
| 349 | # Reverse sort by using rev_sort_dir because we want NULLs at the end. |
| 350 | if wk_label_ids: |
| 351 | order_by.append( |
| 352 | (fmt('FIELD({alias}.label_id, {wk_label_ph}) {rev_sort_dir}', |
| 353 | wk_label_ph=sql.PlaceHolders(wk_label_ids)), |
| 354 | wk_label_ids)) |
| 355 | if odd_label_ids: |
| 356 | # Even though oddball labels sort lexographically, use FIELD to determine |
| 357 | # the order so that the database sorts ints rather than strings for speed |
| 358 | order_by.append( |
| 359 | (fmt('FIELD({alias}.label_id, {odd_label_ph}) {rev_sort_dir}', |
| 360 | odd_label_ph=sql.PlaceHolders(odd_label_ids)), |
| 361 | odd_label_ids)) |
| 362 | |
| 363 | return left_joins, order_by |
| 364 | |
| 365 | |
| 366 | def _CustomFieldSortClauses( |
| 367 | fd_list, value_type, value_column, alias, sort_dir, phase_name=None): |
| 368 | """Give LEFT JOIN and ORDER BY terms for custom fields of the given type.""" |
| 369 | relevant_fd_list = [fd for fd in fd_list if fd.field_type == value_type] |
| 370 | if not relevant_fd_list: |
| 371 | return [], [] |
| 372 | |
| 373 | field_ids_ph = sql.PlaceHolders(relevant_fd_list) |
| 374 | def Fmt(sql_str): |
| 375 | return sql_str.format( |
| 376 | value_column=value_column, sort_dir=sort_dir, |
| 377 | field_ids_ph=field_ids_ph, alias=alias + '_' + value_column, |
| 378 | phase_name=phase_name) |
| 379 | |
| 380 | left_joins = [ |
| 381 | (Fmt('Issue2FieldValue AS {alias} ON Issue.id = {alias}.issue_id ' |
| 382 | 'AND {alias}.field_id IN ({field_ids_ph})'), |
| 383 | [fd.field_id for fd in relevant_fd_list])] |
| 384 | |
| 385 | if phase_name: |
| 386 | left_joins.append( |
| 387 | (Fmt('IssuePhaseDef AS {alias}_phase ' |
| 388 | 'ON {alias}.phase_id = {alias}_phase.id ' |
| 389 | 'AND LOWER({alias}_phase.name) = LOWER(%s)'), |
| 390 | [phase_name])) |
| 391 | |
| 392 | if value_type == tracker_pb2.FieldTypes.USER_TYPE: |
| 393 | left_joins.append( |
| 394 | (Fmt('User AS {alias}_user ON {alias}.user_id = {alias}_user.user_id'), |
| 395 | [])) |
| 396 | order_by = [ |
| 397 | (Fmt('ISNULL({alias}_user.email) {sort_dir}'), []), |
| 398 | (Fmt('{alias}_user.email {sort_dir}'), [])] |
| 399 | else: |
| 400 | # Unfortunately, this sorts on the best field value, not all of them. |
| 401 | order_by = [ |
| 402 | (Fmt('ISNULL({alias}.{value_column}) {sort_dir}'), []), |
| 403 | (Fmt('{alias}.{value_column} {sort_dir}'), [])] |
| 404 | |
| 405 | return left_joins, order_by |
| 406 | |
| 407 | |
| 408 | _PROCESSORS = { |
| 409 | 'component': _ProcessComponentSD, |
| 410 | 'project': _ProcessProjectSD, |
| 411 | 'reporter': _ProcessReporterSD, |
| 412 | 'owner': _ProcessOwnerSD, |
| 413 | 'cc': _ProcessCcSD, |
| 414 | 'summary': _ProcessSummarySD, |
| 415 | 'blocked': _ProcessBlockedSD, |
| 416 | 'blockedon': _ProcessBlockedOnSD, |
| 417 | 'blocking': _ProcessBlockingSD, |
| 418 | 'mergedinto': _ProcessMergedIntoSD, |
| 419 | 'ownerlastvisit': _ProcessOwnerLastVisitSD, |
| 420 | } |
| 421 | |
| 422 | |
| 423 | def _OneSortDirective( |
| 424 | i, sd, harmonized_labels, harmonized_statuses, harmonized_fields): |
| 425 | """Return SQL clauses to do the sorting for one sort directive.""" |
| 426 | alias = 'Sort%d' % i |
| 427 | if sd.startswith('-'): |
| 428 | sort_dir, rev_sort_dir = 'DESC', 'ASC' |
| 429 | sd = sd[1:] |
| 430 | else: |
| 431 | sort_dir, rev_sort_dir = 'ASC', 'DESC' |
| 432 | |
| 433 | def Fmt(sql_str, **kwargs): |
| 434 | return sql_str.format( |
| 435 | sort_dir=sort_dir, rev_sort_dir=rev_sort_dir, alias=alias, |
| 436 | sd=sd, col=FIELDS_TO_COLUMNS.get(sd, sd), **kwargs) |
| 437 | |
| 438 | if sd in NATIVE_SORTABLE_FIELDS: |
| 439 | left_joins = [] |
| 440 | order_by = [(Fmt('Issue.{col} {sort_dir}'), [])] |
| 441 | return left_joins, order_by |
| 442 | |
| 443 | elif sd in _PROCESSORS: |
| 444 | proc = _PROCESSORS[sd] |
| 445 | return proc(Fmt) |
| 446 | |
| 447 | elif sd == 'status': |
| 448 | return _ProcessStatusSD(Fmt, harmonized_statuses) |
| 449 | else: # otherwise, it must be a field or label, or both |
| 450 | return _ProcessCustomAndLabelSD( |
| 451 | sd, harmonized_labels, harmonized_fields, alias, sort_dir, Fmt) |