Adrià Vilanova Martínez | f19ea43 | 2024-01-23 20:20:52 +0100 | [diff] [blame^] | 1 | # Copyright 2016 The Chromium Authors |
| 2 | # Use of this source code is governed by a BSD-style license that can be |
| 3 | # found in the LICENSE file. |
Copybara | 854996b | 2021-09-07 19:36:02 +0000 | [diff] [blame] | 4 | |
| 5 | """Convert a user's issue search AST into SQL clauses. |
| 6 | |
| 7 | The main query is done on the Issues table. |
| 8 | + Some simple conditions are implemented as WHERE conditions on the Issue |
| 9 | table rows. These are generated by the _Compare() function. |
| 10 | + More complex conditions are implemented via a "LEFT JOIN ... ON ..." clause |
| 11 | plus a check in the WHERE clause to select only rows where the join's ON |
| 12 | condition was satisfied. These are generated by appending a clause to |
| 13 | the left_joins list plus calling _CompareAlreadyJoined(). Each such left |
| 14 | join defines a unique alias to keep it separate from other conditions. |
| 15 | |
| 16 | The functions that generate SQL snippets need to insert table names, column |
| 17 | names, alias names, and value placeholders into the generated string. These |
| 18 | functions use the string format() method and the "{varname}" syntax to avoid |
| 19 | confusion with the "%s" syntax used for SQL value placeholders. |
| 20 | """ |
| 21 | from __future__ import print_function |
| 22 | from __future__ import division |
| 23 | from __future__ import absolute_import |
| 24 | |
| 25 | import logging |
| 26 | |
| 27 | from framework import sql |
Adrià Vilanova Martínez | f19ea43 | 2024-01-23 20:20:52 +0100 | [diff] [blame^] | 28 | from mrproto import ast_pb2 |
| 29 | from mrproto import tracker_pb2 |
Copybara | 854996b | 2021-09-07 19:36:02 +0000 | [diff] [blame] | 30 | from search import query2ast |
| 31 | from services import tracker_fulltext |
| 32 | |
| 33 | |
| 34 | NATIVE_SEARCHABLE_FIELDS = { |
| 35 | 'id': 'local_id', |
| 36 | 'is_spam': 'is_spam', |
| 37 | 'stars': 'star_count', |
| 38 | 'attachments': 'attachment_count', |
| 39 | 'opened': 'opened', |
| 40 | 'closed': 'closed', |
| 41 | 'modified': 'modified', |
| 42 | 'ownermodified': 'owner_modified', |
| 43 | 'statusmodified': 'status_modified', |
| 44 | 'componentmodified': 'component_modified', |
| 45 | } |
| 46 | |
| 47 | |
| 48 | def BuildSQLQuery(query_ast, snapshot_mode=False): |
| 49 | """Translate the user's query into an SQL query. |
| 50 | |
| 51 | Args: |
| 52 | query_ast: user query abstract syntax tree parsed by query2ast.py. |
| 53 | |
| 54 | Returns: |
| 55 | A pair of lists (left_joins, where) to use when building the SQL SELECT |
| 56 | statement. Each of them is a list of (str, [val, ...]) pairs. |
| 57 | """ |
| 58 | left_joins = [] |
| 59 | where = [] |
| 60 | unsupported_conds = [] |
| 61 | # OR-queries are broken down into multiple simpler queries before they |
| 62 | # are sent to the backends, so we should never see an "OR".. |
| 63 | assert len(query_ast.conjunctions) == 1, 'OR-query should have been split' |
| 64 | conj = query_ast.conjunctions[0] |
| 65 | |
| 66 | for cond_num, cond in enumerate(conj.conds): |
| 67 | cond_left_joins, cond_where, unsupported = _ProcessCond(cond_num, cond, |
| 68 | snapshot_mode) |
| 69 | left_joins.extend(cond_left_joins) |
| 70 | where.extend(cond_where) |
| 71 | unsupported_conds.extend(unsupported) |
| 72 | |
| 73 | return left_joins, where, unsupported_conds |
| 74 | |
| 75 | |
| 76 | def _ProcessBlockedOnIDCond(cond, alias, _spare_alias, snapshot_mode): |
| 77 | """Convert a blockedon_id=issue_id cond to SQL.""" |
| 78 | return _ProcessRelatedIDCond(cond, alias, 'blockedon', |
| 79 | snapshot_mode=snapshot_mode) |
| 80 | |
| 81 | |
| 82 | def _ProcessBlockingIDCond(cond, alias, _spare_alias, snapshot_mode): |
| 83 | """Convert a blocking_id:1,2 cond to SQL.""" |
| 84 | return _ProcessRelatedIDCond(cond, alias, 'blockedon', reverse_relation=True, |
| 85 | snapshot_mode=snapshot_mode) |
| 86 | |
| 87 | |
| 88 | def _ProcessMergedIntoIDCond(cond, alias, _spare_alias, snapshot_mode): |
| 89 | """Convert a mergedinto:1,2 cond to SQL.""" |
| 90 | return _ProcessRelatedIDCond(cond, alias, 'mergedinto', |
| 91 | snapshot_mode=snapshot_mode) |
| 92 | |
| 93 | |
| 94 | def _ProcessRelatedIDCond(cond, alias, kind, reverse_relation=False, |
| 95 | snapshot_mode=False): |
| 96 | """Convert either blocking_id, blockedon_id, or mergedinto_id cond to SQL. |
| 97 | |
| 98 | Normally, we query for issue_id values where the dst_issue_id matches the |
| 99 | IDs specified in the cond. However, when reverse_relation is True, we |
| 100 | query for dst_issue_id values where issue_id matches. This is done for |
| 101 | blockedon_id. |
| 102 | """ |
| 103 | if snapshot_mode: |
| 104 | return [], [], [cond] |
| 105 | |
| 106 | matching_issue_col = 'issue_id' if reverse_relation else 'dst_issue_id' |
| 107 | ret_issue_col = 'dst_issue_id' if reverse_relation else 'issue_id' |
| 108 | ext_kind = 'blocking' if reverse_relation else kind |
| 109 | left_join = [] |
| 110 | where = [] |
| 111 | |
| 112 | issue_ids = cond.int_values |
| 113 | ext_issue_ids = cond.str_values |
| 114 | # Filter has:blockedon and has:blocking. |
| 115 | if (not issue_ids) and (not ext_issue_ids): |
| 116 | kind_cond_str, kind_cond_args = _Compare( |
| 117 | alias, ast_pb2.QueryOp.EQ, tracker_pb2.FieldTypes.STR_TYPE, 'kind', |
| 118 | [kind]) |
| 119 | left_join_str = ( |
| 120 | 'IssueRelation AS {alias} ON Issue.id = {alias}.{ret_issue_col} AND ' |
| 121 | '{kind_cond}').format( |
| 122 | alias=alias, ret_issue_col=ret_issue_col, kind_cond=kind_cond_str) |
| 123 | left_join_args = kind_cond_args |
| 124 | left_join.append((left_join_str, left_join_args)) |
| 125 | kind_cond_str, kind_cond_args = _Compare( |
| 126 | 'DIR', ast_pb2.QueryOp.EQ, tracker_pb2.FieldTypes.STR_TYPE, 'kind', |
| 127 | [ext_kind]) |
| 128 | ext_left_join_str = ('DanglingIssueRelation AS DIR ON ' |
| 129 | 'Issue.id = DIR.issue_id AND {kind_cond}').format( |
| 130 | kind_cond=kind_cond_str) |
| 131 | left_join.append((ext_left_join_str, kind_cond_args)) |
| 132 | where_str, where_args = _CompareAlreadyJoined(alias, |
| 133 | cond.op, ret_issue_col) |
| 134 | ext_where_str, ext_where_args = _CompareAlreadyJoined('DIR', |
| 135 | cond.op, 'issue_id') |
| 136 | where.append(('({where} OR {ext_where})'.format( |
| 137 | where=where_str, ext_where=ext_where_str), |
| 138 | where_args + ext_where_args)) |
| 139 | # Filter kind using provided issue ids. |
| 140 | if issue_ids: |
| 141 | kind_cond_str, kind_cond_args = _Compare( |
| 142 | alias, ast_pb2.QueryOp.EQ, tracker_pb2.FieldTypes.STR_TYPE, 'kind', |
| 143 | [kind]) |
| 144 | left_join_str = ( |
| 145 | 'IssueRelation AS {alias} ON Issue.id = {alias}.{ret_issue_col} AND ' |
| 146 | '{kind_cond}').format( |
| 147 | alias=alias, ret_issue_col=ret_issue_col, kind_cond=kind_cond_str) |
| 148 | left_join_args = kind_cond_args |
| 149 | related_cond_str, related_cond_args = _Compare( |
| 150 | alias, ast_pb2.QueryOp.EQ, tracker_pb2.FieldTypes.INT_TYPE, |
| 151 | matching_issue_col, issue_ids) |
| 152 | left_join_str += ' AND {related_cond}'.format(related_cond=related_cond_str) |
| 153 | left_join_args += related_cond_args |
| 154 | |
| 155 | left_join.append((left_join_str, left_join_args)) |
| 156 | where.append(_CompareAlreadyJoined(alias, cond.op, ret_issue_col)) |
| 157 | # Filter kind using provided external issue ids. |
| 158 | if ext_issue_ids: |
| 159 | kind_cond_str, kind_cond_args = _Compare( |
| 160 | 'DIR', ast_pb2.QueryOp.EQ, tracker_pb2.FieldTypes.STR_TYPE, 'kind', |
| 161 | [ext_kind]) |
| 162 | ext_left_join_str = ('DanglingIssueRelation AS DIR ON ' |
| 163 | 'Issue.id = DIR.issue_id AND {kind_cond}').format( |
| 164 | kind_cond=kind_cond_str) |
| 165 | related_cond_str, related_cond_args = _Compare( |
| 166 | 'DIR', ast_pb2.QueryOp.EQ, tracker_pb2.FieldTypes.INT_TYPE, |
| 167 | 'ext_issue_identifier', ext_issue_ids) |
| 168 | ext_left_join_str += ' AND {related_cond}'.format( |
| 169 | related_cond=related_cond_str) |
| 170 | kind_cond_args += related_cond_args |
| 171 | |
| 172 | left_join.append((ext_left_join_str, kind_cond_args)) |
| 173 | where.append(_CompareAlreadyJoined('DIR', cond.op, 'issue_id')) |
| 174 | return left_join, where, [] |
| 175 | |
| 176 | |
| 177 | def _GetFieldTypeAndValues(cond): |
| 178 | """Returns the field type and values to use from the condition. |
| 179 | |
| 180 | This function should be used when we do not know what values are present on |
| 181 | the condition. Eg: cond.int_values could be set if ast2ast.py preprocessing is |
| 182 | first done. If that preprocessing is not done then str_values could be set |
| 183 | instead. |
| 184 | If both int values and str values exist on the condition then the int values |
| 185 | are returned. |
| 186 | """ |
| 187 | if cond.int_values: |
| 188 | return tracker_pb2.FieldTypes.INT_TYPE, cond.int_values |
| 189 | else: |
| 190 | return tracker_pb2.FieldTypes.STR_TYPE, cond.str_values |
| 191 | |
| 192 | |
| 193 | def _ProcessOwnerCond(cond, alias, _spare_alias, snapshot_mode): |
| 194 | """Convert an owner:substring cond to SQL.""" |
| 195 | if snapshot_mode: |
| 196 | left_joins = [( |
| 197 | 'User AS {alias} ON ' |
| 198 | 'IssueSnapshot.owner_id = {alias}.user_id'.format(alias=alias), |
| 199 | [])] |
| 200 | else: |
| 201 | left_joins = [( |
| 202 | 'User AS {alias} ON (Issue.owner_id = {alias}.user_id ' |
| 203 | 'OR Issue.derived_owner_id = {alias}.user_id)'.format(alias=alias), |
| 204 | [])] |
| 205 | where = [_Compare(alias, cond.op, tracker_pb2.FieldTypes.STR_TYPE, 'email', |
| 206 | cond.str_values)] |
| 207 | |
| 208 | return left_joins, where, [] |
| 209 | |
| 210 | |
| 211 | def _ProcessOwnerIDCond(cond, _alias, _spare_alias, snapshot_mode): |
| 212 | """Convert an owner_id=user_id cond to SQL.""" |
| 213 | if snapshot_mode: |
| 214 | field_type, field_values = _GetFieldTypeAndValues(cond) |
| 215 | explicit_str, explicit_args = _Compare( |
| 216 | 'IssueSnapshot', cond.op, field_type, 'owner_id', field_values) |
| 217 | where = [(explicit_str, explicit_args)] |
| 218 | else: |
| 219 | field_type, field_values = _GetFieldTypeAndValues(cond) |
| 220 | explicit_str, explicit_args = _Compare( |
| 221 | 'Issue', cond.op, field_type, 'owner_id', field_values) |
| 222 | derived_str, derived_args = _Compare( |
| 223 | 'Issue', cond.op, field_type, 'derived_owner_id', field_values) |
| 224 | if cond.op in (ast_pb2.QueryOp.NE, ast_pb2.QueryOp.NOT_TEXT_HAS): |
| 225 | where = [(explicit_str, explicit_args), (derived_str, derived_args)] |
| 226 | else: |
| 227 | if cond.op == ast_pb2.QueryOp.IS_NOT_DEFINED: |
| 228 | op = ' AND ' |
| 229 | else: |
| 230 | op = ' OR ' |
| 231 | where = [ |
| 232 | ('(' + explicit_str + op + derived_str + ')', |
| 233 | explicit_args + derived_args)] |
| 234 | |
| 235 | return [], where, [] |
| 236 | |
| 237 | |
| 238 | def _ProcessOwnerLastVisitCond(cond, alias, _spare_alias, snapshot_mode): |
| 239 | """Convert an ownerlastvisit<timestamp cond to SQL.""" |
| 240 | # TODO(jeffcarp): It is possible to support this on snapshots. |
| 241 | if snapshot_mode: |
| 242 | return [], [], [cond] |
| 243 | |
| 244 | left_joins = [( |
| 245 | 'User AS {alias} ' |
| 246 | 'ON (Issue.owner_id = {alias}.user_id OR ' |
| 247 | 'Issue.derived_owner_id = {alias}.user_id)'.format(alias=alias), |
| 248 | [])] |
| 249 | where = [_Compare(alias, cond.op, tracker_pb2.FieldTypes.INT_TYPE, |
| 250 | 'last_visit_timestamp', cond.int_values)] |
| 251 | return left_joins, where, [] |
| 252 | |
| 253 | |
| 254 | def _ProcessIsOwnerBouncing(cond, alias, _spare_alias, snapshot_mode): |
| 255 | """Convert an is:ownerbouncing cond to SQL.""" |
| 256 | if snapshot_mode: |
| 257 | return [], [], [cond] |
| 258 | |
| 259 | left_joins = [( |
| 260 | 'User AS {alias} ' |
| 261 | 'ON (Issue.owner_id = {alias}.user_id OR ' |
| 262 | 'Issue.derived_owner_id = {alias}.user_id)'.format(alias=alias), |
| 263 | [])] |
| 264 | if cond.op == ast_pb2.QueryOp.EQ: |
| 265 | op = ast_pb2.QueryOp.IS_DEFINED |
| 266 | else: |
| 267 | op = ast_pb2.QueryOp.IS_NOT_DEFINED |
| 268 | |
| 269 | where = [_Compare(alias, op, tracker_pb2.FieldTypes.INT_TYPE, |
| 270 | 'email_bounce_timestamp', [])] |
| 271 | return left_joins, where, [] |
| 272 | |
| 273 | |
| 274 | def _ProcessReporterCond(cond, alias, _spare_alias, snapshot_mode): |
| 275 | """Convert a reporter:substring cond to SQL.""" |
| 276 | if snapshot_mode: |
| 277 | left_joins = [( |
| 278 | 'User AS {alias} ON IssueSnapshot.reporter_id = {alias}.user_id'.format( |
| 279 | alias=alias), [])] |
| 280 | else: |
| 281 | left_joins = [( |
| 282 | 'User AS {alias} ON Issue.reporter_id = {alias}.user_id'.format( |
| 283 | alias=alias), [])] |
| 284 | where = [_Compare(alias, cond.op, tracker_pb2.FieldTypes.STR_TYPE, 'email', |
| 285 | cond.str_values)] |
| 286 | |
| 287 | return left_joins, where, [] |
| 288 | |
| 289 | |
| 290 | def _ProcessReporterIDCond(cond, _alias, _spare_alias, snapshot_mode): |
| 291 | """Convert a reporter_ID=user_id cond to SQL.""" |
| 292 | field_type, field_values = _GetFieldTypeAndValues(cond) |
| 293 | |
| 294 | if snapshot_mode: |
| 295 | where = [_Compare( |
| 296 | 'IssueSnapshot', cond.op, field_type, 'reporter_id', field_values)] |
| 297 | else: |
| 298 | where = [_Compare( |
| 299 | 'Issue', cond.op, field_type, 'reporter_id', field_values)] |
| 300 | return [], where, [] |
| 301 | |
| 302 | |
| 303 | def _ProcessCcCond(cond, alias, user_alias, snapshot_mode): |
| 304 | """Convert a cc:substring cond to SQL.""" |
| 305 | email_cond_str, email_cond_args = _Compare( |
| 306 | user_alias, ast_pb2.QueryOp.TEXT_HAS, tracker_pb2.FieldTypes.STR_TYPE, |
| 307 | 'email', cond.str_values) |
| 308 | |
| 309 | if snapshot_mode: |
| 310 | left_joins = [( |
| 311 | '(IssueSnapshot2Cc AS {alias} JOIN User AS {user_alias} ' |
| 312 | 'ON {alias}.cc_id = {user_alias}.user_id AND {email_cond}) ' |
| 313 | 'ON IssueSnapshot.id = {alias}.issuesnapshot_id'.format( |
| 314 | alias=alias, user_alias=user_alias, email_cond=email_cond_str), |
| 315 | email_cond_args)] |
| 316 | else: |
| 317 | # Note: email_cond_str will have parens, if needed. |
| 318 | left_joins = [( |
| 319 | '(Issue2Cc AS {alias} JOIN User AS {user_alias} ' |
| 320 | 'ON {alias}.cc_id = {user_alias}.user_id AND {email_cond}) ' |
| 321 | 'ON Issue.id = {alias}.issue_id AND ' |
| 322 | 'Issue.shard = {alias}.issue_shard'.format( |
| 323 | alias=alias, user_alias=user_alias, email_cond=email_cond_str), |
| 324 | email_cond_args)] |
| 325 | where = [_CompareAlreadyJoined(user_alias, cond.op, 'email')] |
| 326 | |
| 327 | return left_joins, where, [] |
| 328 | |
| 329 | |
| 330 | def _ProcessCcIDCond(cond, alias, _spare_alias, snapshot_mode): |
| 331 | """Convert a cc_id=user_id cond to SQL.""" |
| 332 | if snapshot_mode: |
| 333 | join_str = ( |
| 334 | 'IssueSnapshot2Cc AS {alias} ' |
| 335 | 'ON IssueSnapshot.id = {alias}.issuesnapshot_id'.format(alias=alias)) |
| 336 | else: |
| 337 | join_str = ( |
| 338 | 'Issue2Cc AS {alias} ON Issue.id = {alias}.issue_id AND ' |
| 339 | 'Issue.shard = {alias}.issue_shard'.format( |
| 340 | alias=alias)) |
| 341 | if cond.op in (ast_pb2.QueryOp.IS_DEFINED, ast_pb2.QueryOp.IS_NOT_DEFINED): |
| 342 | left_joins = [(join_str, [])] |
| 343 | else: |
| 344 | field_type, field_values = _GetFieldTypeAndValues(cond) |
| 345 | cond_str, cond_args = _Compare( |
| 346 | alias, ast_pb2.QueryOp.EQ, field_type, 'cc_id', field_values) |
| 347 | left_joins = [(join_str + ' AND ' + cond_str, cond_args)] |
| 348 | |
| 349 | where = [_CompareAlreadyJoined(alias, cond.op, 'cc_id')] |
| 350 | return left_joins, where, [] |
| 351 | |
| 352 | |
| 353 | def _ProcessStarredByCond(cond, alias, user_alias, snapshot_mode): |
| 354 | """Convert a starredby:substring cond to SQL.""" |
| 355 | if snapshot_mode: |
| 356 | return [], [], [cond] |
| 357 | |
| 358 | email_cond_str, email_cond_args = _Compare( |
| 359 | user_alias, cond.op, tracker_pb2.FieldTypes.STR_TYPE, 'email', |
| 360 | cond.str_values) |
| 361 | # Note: email_cond_str will have parens, if needed. |
| 362 | left_joins = [( |
| 363 | '(IssueStar AS {alias} JOIN User AS {user_alias} ' |
| 364 | 'ON {alias}.user_id = {user_alias}.user_id AND {email_cond}) ' |
| 365 | 'ON Issue.id = {alias}.issue_id'.format( |
| 366 | alias=alias, user_alias=user_alias, email_cond=email_cond_str), |
| 367 | email_cond_args)] |
| 368 | where = [_CompareAlreadyJoined(user_alias, cond.op, 'email')] |
| 369 | |
| 370 | return left_joins, where, [] |
| 371 | |
| 372 | |
| 373 | def _ProcessStarredByIDCond(cond, alias, _spare_alias, snapshot_mode): |
| 374 | """Convert a starredby_id=user_id cond to SQL.""" |
| 375 | if snapshot_mode: |
| 376 | return [], [], [cond] |
| 377 | |
| 378 | join_str = 'IssueStar AS {alias} ON Issue.id = {alias}.issue_id'.format( |
| 379 | alias=alias) |
| 380 | if cond.op in (ast_pb2.QueryOp.IS_DEFINED, ast_pb2.QueryOp.IS_NOT_DEFINED): |
| 381 | left_joins = [(join_str, [])] |
| 382 | else: |
| 383 | field_type, field_values = _GetFieldTypeAndValues(cond) |
| 384 | cond_str, cond_args = _Compare( |
| 385 | alias, ast_pb2.QueryOp.EQ, field_type, 'user_id', field_values) |
| 386 | left_joins = [(join_str + ' AND ' + cond_str, cond_args)] |
| 387 | |
| 388 | where = [_CompareAlreadyJoined(alias, cond.op, 'user_id')] |
| 389 | return left_joins, where, [] |
| 390 | |
| 391 | |
| 392 | def _ProcessCommentByCond(cond, alias, user_alias, snapshot_mode): |
| 393 | """Convert a commentby:substring cond to SQL.""" |
| 394 | if snapshot_mode: |
| 395 | return [], [], [cond] |
| 396 | |
| 397 | email_cond_str, email_cond_args = _Compare( |
| 398 | user_alias, ast_pb2.QueryOp.TEXT_HAS, tracker_pb2.FieldTypes.STR_TYPE, |
| 399 | 'email', cond.str_values) |
| 400 | # Note: email_cond_str will have parens, if needed. |
| 401 | left_joins = [( |
| 402 | '(Comment AS {alias} JOIN User AS {user_alias} ' |
| 403 | 'ON {alias}.commenter_id = {user_alias}.user_id AND {email_cond}) ' |
| 404 | 'ON Issue.id = {alias}.issue_id AND ' |
| 405 | '{alias}.deleted_by IS NULL'.format( |
| 406 | alias=alias, user_alias=user_alias, email_cond=email_cond_str), |
| 407 | email_cond_args)] |
| 408 | where = [_CompareAlreadyJoined(user_alias, cond.op, 'email')] |
| 409 | |
| 410 | return left_joins, where, [] |
| 411 | |
| 412 | |
| 413 | def _ProcessCommentByIDCond(cond, alias, _spare_alias, snapshot_mode): |
| 414 | """Convert a commentby_id=user_id cond to SQL.""" |
| 415 | if snapshot_mode: |
| 416 | return [], [], [cond] |
| 417 | |
| 418 | field_type, field_values = _GetFieldTypeAndValues(cond) |
| 419 | commenter_cond_str, commenter_cond_args = _Compare( |
| 420 | alias, ast_pb2.QueryOp.EQ, field_type, 'commenter_id', field_values) |
| 421 | left_joins = [( |
| 422 | 'Comment AS {alias} ON Issue.id = {alias}.issue_id AND ' |
| 423 | '{commenter_cond} AND ' |
| 424 | '{alias}.deleted_by IS NULL'.format( |
| 425 | alias=alias, commenter_cond=commenter_cond_str), |
| 426 | commenter_cond_args)] |
| 427 | where = [_CompareAlreadyJoined(alias, cond.op, 'commenter_id')] |
| 428 | |
| 429 | return left_joins, where, [] |
| 430 | |
| 431 | |
| 432 | def _ProcessStatusIDCond(cond, _alias, _spare_alias, snapshot_mode): |
| 433 | """Convert a status_id=ID cond to SQL.""" |
| 434 | field_type, field_values = _GetFieldTypeAndValues(cond) |
| 435 | if snapshot_mode: |
| 436 | explicit_str, explicit_args = _Compare( |
| 437 | 'IssueSnapshot', cond.op, field_type, 'status_id', field_values) |
| 438 | where = [(explicit_str, explicit_args)] |
| 439 | else: |
| 440 | explicit_str, explicit_args = _Compare( |
| 441 | 'Issue', cond.op, field_type, 'status_id', field_values) |
| 442 | derived_str, derived_args = _Compare( |
| 443 | 'Issue', cond.op, field_type, 'derived_status_id', field_values) |
| 444 | if cond.op in (ast_pb2.QueryOp.IS_NOT_DEFINED, ast_pb2.QueryOp.NE): |
| 445 | where = [(explicit_str, explicit_args), (derived_str, derived_args)] |
| 446 | else: |
| 447 | where = [ |
| 448 | ('(' + explicit_str + ' OR ' + derived_str + ')', |
| 449 | explicit_args + derived_args)] |
| 450 | |
| 451 | return [], where, [] |
| 452 | |
| 453 | |
| 454 | def _ProcessSummaryCond(cond, alias, _spare_alias, snapshot_mode): |
| 455 | """Convert a summary="exact string" cond to SQL.""" |
| 456 | left_joins = [] |
| 457 | where = [] |
| 458 | field_type, field_values = _GetFieldTypeAndValues(cond) |
| 459 | if snapshot_mode: |
| 460 | return [], [], [cond] |
| 461 | elif cond.op in (ast_pb2.QueryOp.EQ, ast_pb2.QueryOp.NE, |
| 462 | ast_pb2.QueryOp.GT, ast_pb2.QueryOp.LT, |
| 463 | ast_pb2.QueryOp.GE, ast_pb2.QueryOp.LE, |
| 464 | ast_pb2.QueryOp.IS_DEFINED, ast_pb2.QueryOp.IS_NOT_DEFINED): |
| 465 | summary_cond_str, summary_cond_args = _Compare( |
| 466 | alias, cond.op, field_type, 'summary', field_values) |
| 467 | left_joins = [( |
| 468 | 'IssueSummary AS {alias} ON Issue.id = {alias}.issue_id AND ' |
| 469 | '{summary_cond}'.format( |
| 470 | alias=alias, summary_cond=summary_cond_str), |
| 471 | summary_cond_args)] |
| 472 | where = [_CompareAlreadyJoined(alias, ast_pb2.QueryOp.EQ, 'issue_id')] |
| 473 | |
| 474 | return left_joins, where, [] |
| 475 | |
| 476 | |
| 477 | def _ProcessLabelIDCond(cond, alias, _spare_alias, snapshot_mode): |
| 478 | """Convert a label_id=ID cond to SQL.""" |
| 479 | if snapshot_mode: |
| 480 | join_str = ( |
| 481 | 'IssueSnapshot2Label AS {alias} ' |
| 482 | 'ON IssueSnapshot.id = {alias}.issuesnapshot_id'.format(alias=alias)) |
| 483 | else: |
| 484 | join_str = ( |
| 485 | 'Issue2Label AS {alias} ON Issue.id = {alias}.issue_id AND ' |
| 486 | 'Issue.shard = {alias}.issue_shard'.format(alias=alias)) |
| 487 | |
| 488 | field_type, field_values = _GetFieldTypeAndValues(cond) |
| 489 | if not field_values and cond.op == ast_pb2.QueryOp.NE: |
| 490 | return [], [], [] |
| 491 | cond_str, cond_args = _Compare( |
| 492 | alias, ast_pb2.QueryOp.EQ, field_type, 'label_id', field_values) |
| 493 | left_joins = [(join_str + ' AND ' + cond_str, cond_args)] |
| 494 | where = [_CompareAlreadyJoined(alias, cond.op, 'label_id')] |
| 495 | return left_joins, where, [] |
| 496 | |
| 497 | |
| 498 | def _ProcessComponentIDCond(cond, alias, _spare_alias, snapshot_mode): |
| 499 | """Convert a component_id=ID cond to SQL.""" |
| 500 | # This is a built-in field, so it shadows any other fields w/ the same name. |
| 501 | if snapshot_mode: |
| 502 | join_str = ( |
| 503 | 'IssueSnapshot2Component AS {alias} ' |
| 504 | 'ON IssueSnapshot.id = {alias}.issuesnapshot_id'.format(alias=alias)) |
| 505 | else: |
| 506 | join_str = ( |
| 507 | 'Issue2Component AS {alias} ON Issue.id = {alias}.issue_id AND ' |
| 508 | 'Issue.shard = {alias}.issue_shard'.format(alias=alias)) |
| 509 | if cond.op in (ast_pb2.QueryOp.IS_DEFINED, ast_pb2.QueryOp.IS_NOT_DEFINED): |
| 510 | left_joins = [(join_str, [])] |
| 511 | else: |
| 512 | field_type, field_values = _GetFieldTypeAndValues(cond) |
| 513 | cond_str, cond_args = _Compare( |
| 514 | alias, ast_pb2.QueryOp.EQ, field_type, 'component_id', field_values) |
| 515 | left_joins = [(join_str + ' AND ' + cond_str, cond_args)] |
| 516 | |
| 517 | where = [_CompareAlreadyJoined(alias, cond.op, 'component_id')] |
| 518 | return left_joins, where, [] |
| 519 | |
| 520 | |
| 521 | # TODO(jojang): monorail:3819, check for cond.phase_name and process |
| 522 | # appropriately so users can search 'Canary.UXReview-status:Approved' |
| 523 | def _ProcessApprovalFieldCond(cond, alias, user_alias, snapshot_mode): |
| 524 | """Convert a custom approval field cond to SQL.""" |
| 525 | if snapshot_mode: |
| 526 | return [], [], [cond] |
| 527 | |
| 528 | approval_fd = cond.field_defs[0] |
| 529 | left_joins = [] |
| 530 | |
| 531 | join_str_tmpl = ( |
| 532 | '{tbl_name} AS {alias} ON Issue.id = {alias}.issue_id AND ' |
| 533 | '{alias}.approval_id = %s') |
| 534 | |
| 535 | join_args = [approval_fd.field_id] |
| 536 | |
| 537 | val_type, values = _GetFieldTypeAndValues(cond) |
| 538 | if val_type is tracker_pb2.FieldTypes.STR_TYPE: |
| 539 | values = [val.lower() for val in values] |
| 540 | # TODO(jojwang):monorail:3809, check if there is a cond.key_suffx. |
| 541 | # status, approver should always have a value, so 'has:UXReview-approver' |
| 542 | # should return the same issues as 'has:UXReview'. |
| 543 | # There will not always be values approval.setter_id and approval.set_on |
| 544 | # and the current code would not process 'has:UXReview-by' correctly. |
| 545 | if cond.op in ( |
| 546 | ast_pb2.QueryOp.IS_DEFINED, ast_pb2.QueryOp.IS_NOT_DEFINED): |
| 547 | join_str = join_str_tmpl.format( |
| 548 | tbl_name='Issue2ApprovalValue', alias=alias) |
| 549 | left_joins = [(join_str, join_args)] |
| 550 | else: |
| 551 | op = cond.op |
| 552 | if op == ast_pb2.QueryOp.NE: |
| 553 | op = ast_pb2.QueryOp.EQ # Negation is done in WHERE clause. |
| 554 | elif op == ast_pb2.QueryOp.NOT_TEXT_HAS: |
| 555 | op = ast_pb2.QueryOp.TEXT_HAS |
| 556 | |
| 557 | if (not cond.key_suffix) or cond.key_suffix == query2ast.STATUS_SUFFIX: |
| 558 | tbl_str = 'Issue2ApprovalValue' |
| 559 | cond_str, cond_args = _Compare( |
| 560 | alias, op, val_type, 'status', values) |
| 561 | elif cond.key_suffix == query2ast.SET_ON_SUFFIX: |
| 562 | tbl_str = 'Issue2ApprovalValue' |
| 563 | cond_str, cond_args = _Compare( |
| 564 | alias, op, val_type, 'set_on', values) |
| 565 | elif cond.key_suffix in [ |
| 566 | query2ast.APPROVER_SUFFIX, query2ast.SET_BY_SUFFIX]: |
| 567 | if cond.key_suffix == query2ast.SET_BY_SUFFIX: |
| 568 | tbl_str = 'Issue2ApprovalValue' |
| 569 | col_name = 'setter_id' |
| 570 | else: |
| 571 | tbl_str = 'IssueApproval2Approver' |
| 572 | col_name = 'approver_id' |
| 573 | |
| 574 | if val_type == tracker_pb2.FieldTypes.INT_TYPE: |
| 575 | cond_str, cond_args = _Compare( |
| 576 | alias, op, val_type, col_name, values) |
| 577 | else: |
| 578 | email_cond_str, email_cond_args = _Compare( |
| 579 | user_alias, op, val_type, 'email', values) |
| 580 | left_joins.append(( |
| 581 | 'User AS {user_alias} ON {email_cond}'.format( |
| 582 | user_alias=user_alias, email_cond=email_cond_str), |
| 583 | email_cond_args)) |
| 584 | |
| 585 | cond_str = '{alias}.{col_name} = {user_alias}.user_id'.format( |
| 586 | alias=alias, col_name=col_name, user_alias=user_alias) |
| 587 | cond_args = [] |
| 588 | if cond_str or cond_args: |
| 589 | join_str = join_str_tmpl.format(tbl_name=tbl_str, alias=alias) |
| 590 | join_str += ' AND ' + cond_str |
| 591 | join_args.extend(cond_args) |
| 592 | left_joins.append((join_str, join_args)) |
| 593 | |
| 594 | where = [_CompareAlreadyJoined(alias, cond.op, 'approval_id')] |
| 595 | return left_joins, where, [] |
| 596 | |
| 597 | |
| 598 | def _ProcessCustomFieldCond( |
| 599 | cond, alias, user_alias, phase_alias, snapshot_mode): |
| 600 | """Convert a custom field cond to SQL.""" |
| 601 | if snapshot_mode: |
| 602 | return [], [], [cond] |
| 603 | |
| 604 | # TODO(jrobbins): handle ambiguous field names that map to multiple |
| 605 | # field definitions, especially for cross-project search. |
| 606 | field_def = cond.field_defs[0] |
| 607 | field_type = field_def.field_type |
| 608 | left_joins = [] |
| 609 | |
| 610 | join_str = ( |
| 611 | 'Issue2FieldValue AS {alias} ON Issue.id = {alias}.issue_id AND ' |
| 612 | 'Issue.shard = {alias}.issue_shard AND ' |
| 613 | '{alias}.field_id = %s'.format(alias=alias)) |
| 614 | join_args = [field_def.field_id] |
| 615 | |
| 616 | if cond.op not in ( |
| 617 | ast_pb2.QueryOp.IS_DEFINED, ast_pb2.QueryOp.IS_NOT_DEFINED): |
| 618 | op = cond.op |
| 619 | if op == ast_pb2.QueryOp.NE: |
| 620 | op = ast_pb2.QueryOp.EQ # Negation is done in WHERE clause. |
| 621 | if field_type == tracker_pb2.FieldTypes.INT_TYPE: |
| 622 | cond_str, cond_args = _Compare( |
| 623 | alias, op, field_type, 'int_value', cond.int_values) |
| 624 | elif field_type == tracker_pb2.FieldTypes.STR_TYPE: |
| 625 | cond_str, cond_args = _Compare( |
| 626 | alias, op, field_type, 'str_value', cond.str_values) |
| 627 | elif field_type == tracker_pb2.FieldTypes.USER_TYPE: |
| 628 | if cond.int_values: |
| 629 | cond_str, cond_args = _Compare( |
| 630 | alias, op, field_type, 'user_id', cond.int_values) |
| 631 | else: |
| 632 | email_cond_str, email_cond_args = _Compare( |
| 633 | user_alias, op, field_type, 'email', cond.str_values) |
| 634 | left_joins.append(( |
| 635 | 'User AS {user_alias} ON {email_cond}'.format( |
| 636 | user_alias=user_alias, email_cond=email_cond_str), |
| 637 | email_cond_args)) |
| 638 | cond_str = '{alias}.user_id = {user_alias}.user_id'.format( |
| 639 | alias=alias, user_alias=user_alias) |
| 640 | cond_args = [] |
| 641 | elif field_type == tracker_pb2.FieldTypes.URL_TYPE: |
| 642 | cond_str, cond_args = _Compare( |
| 643 | alias, op, field_type, 'url_value', cond.str_values) |
| 644 | if field_type == tracker_pb2.FieldTypes.DATE_TYPE: |
| 645 | cond_str, cond_args = _Compare( |
| 646 | alias, op, field_type, 'date_value', cond.int_values) |
| 647 | if cond_str or cond_args: |
| 648 | join_str += ' AND ' + cond_str |
| 649 | join_args.extend(cond_args) |
| 650 | |
| 651 | if cond.phase_name: |
| 652 | phase_cond_str, phase_cond_args = _Compare( |
| 653 | phase_alias, ast_pb2.QueryOp.EQ, tracker_pb2.FieldTypes.STR_TYPE, |
| 654 | 'name', [cond.phase_name]) |
| 655 | left_joins.append(( |
| 656 | 'IssuePhaseDef AS {phase_alias} ON {phase_cond}'.format( |
| 657 | phase_alias=phase_alias, phase_cond=phase_cond_str), |
| 658 | phase_cond_args)) |
| 659 | cond_str = '{alias}.phase_id = {phase_alias}.id'.format( |
| 660 | alias=alias, phase_alias=phase_alias) |
| 661 | cond_args = [] |
| 662 | join_str += ' AND ' + cond_str |
| 663 | join_args.extend(cond_args) |
| 664 | |
| 665 | left_joins.append((join_str, join_args)) |
| 666 | where = [_CompareAlreadyJoined(alias, cond.op, 'field_id')] |
| 667 | return left_joins, where, [] |
| 668 | |
| 669 | |
| 670 | def _ProcessAttachmentCond(cond, alias, _spare_alias, snapshot_mode): |
| 671 | """Convert has:attachment and -has:attachment cond to SQL.""" |
| 672 | if snapshot_mode: |
| 673 | return [], [], [cond] |
| 674 | |
| 675 | if cond.op in (ast_pb2.QueryOp.IS_DEFINED, ast_pb2.QueryOp.IS_NOT_DEFINED): |
| 676 | left_joins = [] |
| 677 | where = [_Compare('Issue', cond.op, tracker_pb2.FieldTypes.INT_TYPE, |
| 678 | 'attachment_count', cond.int_values)] |
| 679 | else: |
| 680 | field_def = cond.field_defs[0] |
| 681 | field_type = field_def.field_type |
| 682 | left_joins = [ |
| 683 | ('Attachment AS {alias} ON Issue.id = {alias}.issue_id AND ' |
| 684 | '{alias}.deleted = %s'.format(alias=alias), |
| 685 | [False])] |
| 686 | where = [_Compare(alias, cond.op, field_type, 'filename', cond.str_values)] |
| 687 | |
| 688 | return left_joins, where, [] |
| 689 | |
| 690 | |
| 691 | def _ProcessHotlistIDCond(cond, alias, _spare_alias, snapshot_mode): |
| 692 | """Convert hotlist_id=IDS cond to SQL.""" |
| 693 | if snapshot_mode: |
| 694 | join_str = ( |
| 695 | 'IssueSnapshot2Hotlist AS {alias} ' |
| 696 | 'ON IssueSnapshot.id = {alias}.issuesnapshot_id'.format(alias=alias)) |
| 697 | else: |
| 698 | join_str = ( |
| 699 | 'Hotlist2Issue AS {alias} ON Issue.id = {alias}.issue_id'.format( |
| 700 | alias=alias)) |
| 701 | |
| 702 | field_type, field_values = _GetFieldTypeAndValues(cond) |
| 703 | if not field_values and cond.op == ast_pb2.QueryOp.NE: |
| 704 | return [], [], [] |
| 705 | cond_str, cond_args = _Compare( |
| 706 | alias, ast_pb2.QueryOp.EQ, field_type, 'hotlist_id', field_values) |
| 707 | left_joins = [(join_str + ' AND ' + cond_str, cond_args)] |
| 708 | where = [_CompareAlreadyJoined(alias, cond.op, 'hotlist_id')] |
| 709 | |
| 710 | return left_joins, where, [] |
| 711 | |
| 712 | |
| 713 | def _ProcessHotlistCond(cond, alias, _spare_alias, snapshot_mode): |
| 714 | """Convert hotlist=user:hotlist-name to SQL""" |
| 715 | # hotlist conditions that reach this function definitely have invalid |
| 716 | # user_name/id/email. This validity was determined in |
| 717 | # ast2ast._PreprocessHotlistCond. Any possible user identification is ignored. |
| 718 | hotlist_substrings = [] |
| 719 | for val in cond.str_values: |
| 720 | substring = val.split(':')[-1] |
| 721 | if substring: |
| 722 | hotlist_substrings.append(substring) |
| 723 | hotlist_cond_str, hotlist_cond_args = _Compare( |
| 724 | alias, ast_pb2.QueryOp.TEXT_HAS, tracker_pb2.FieldTypes.STR_TYPE, |
| 725 | 'name', hotlist_substrings) |
| 726 | if snapshot_mode: |
| 727 | left_joins = [( |
| 728 | '(IssueSnapshot2Hotlist JOIN Hotlist AS {alias} ' |
| 729 | 'ON IssueSnapshot2Hotlist.hotlist_id = {alias}.id AND {hotlist_cond}) ' |
| 730 | 'ON IssueSnapshot.id = IssueSnapshot2Hotlist.issuesnapshot_id'.format( |
| 731 | alias=alias, hotlist_cond=hotlist_cond_str), hotlist_cond_args)] |
| 732 | else: |
| 733 | left_joins = [( |
| 734 | '(Hotlist2Issue JOIN Hotlist AS {alias} ' |
| 735 | 'ON Hotlist2Issue.hotlist_id = {alias}.id AND {hotlist_cond}) ' |
| 736 | 'ON Issue.id = Hotlist2Issue.issue_id'.format( |
| 737 | alias=alias, hotlist_cond=hotlist_cond_str), hotlist_cond_args)] |
| 738 | where = [_CompareAlreadyJoined(alias, cond.op, 'name')] |
| 739 | |
| 740 | return left_joins, where, [] |
| 741 | |
| 742 | |
| 743 | def _ProcessPhaseCond(cond, alias, phase_alias, _snapshot_mode): |
| 744 | """Convert gate:<phase_name> to SQL.""" |
| 745 | |
| 746 | op = cond.op |
| 747 | if cond.op == ast_pb2.QueryOp.NE: |
| 748 | op = ast_pb2.QueryOp.EQ |
| 749 | elif cond.op == ast_pb2.QueryOp.NOT_TEXT_HAS: |
| 750 | op = ast_pb2.QueryOp.TEXT_HAS |
| 751 | |
| 752 | cond_str, cond_args = _Compare( |
| 753 | phase_alias, op, tracker_pb2.FieldTypes.STR_TYPE, |
| 754 | 'name', cond.str_values) |
| 755 | left_joins = [( |
| 756 | '(Issue2ApprovalValue AS {alias} JOIN IssuePhaseDef AS {phase_alias} ' |
| 757 | 'ON {alias}.phase_id = {phase_alias}.id AND {name_cond}) ' |
| 758 | 'ON Issue.id = {alias}.issue_id'.format( |
| 759 | alias=alias, phase_alias=phase_alias, name_cond=cond_str), |
| 760 | cond_args)] |
| 761 | where = [_CompareAlreadyJoined(phase_alias, cond.op, 'name')] |
| 762 | |
| 763 | return left_joins, where, [] |
| 764 | |
| 765 | |
| 766 | _PROCESSORS = { |
| 767 | 'owner': _ProcessOwnerCond, |
| 768 | 'owner_id': _ProcessOwnerIDCond, |
| 769 | 'ownerlastvisit': _ProcessOwnerLastVisitCond, |
| 770 | 'ownerbouncing': _ProcessIsOwnerBouncing, |
| 771 | 'reporter': _ProcessReporterCond, |
| 772 | 'reporter_id': _ProcessReporterIDCond, |
| 773 | 'cc': _ProcessCcCond, |
| 774 | 'cc_id': _ProcessCcIDCond, |
| 775 | 'starredby': _ProcessStarredByCond, |
| 776 | 'starredby_id': _ProcessStarredByIDCond, |
| 777 | 'commentby': _ProcessCommentByCond, |
| 778 | 'commentby_id': _ProcessCommentByIDCond, |
| 779 | 'status_id': _ProcessStatusIDCond, |
| 780 | 'summary': _ProcessSummaryCond, |
| 781 | 'label_id': _ProcessLabelIDCond, |
| 782 | 'component_id': _ProcessComponentIDCond, |
| 783 | 'blockedon_id': _ProcessBlockedOnIDCond, |
| 784 | 'blocking_id': _ProcessBlockingIDCond, |
| 785 | 'mergedinto_id': _ProcessMergedIntoIDCond, |
| 786 | 'attachment': _ProcessAttachmentCond, |
| 787 | 'hotlist_id': _ProcessHotlistIDCond, |
| 788 | 'hotlist': _ProcessHotlistCond, |
| 789 | } |
| 790 | |
| 791 | |
| 792 | def _ProcessCond(cond_num, cond, snapshot_mode): |
| 793 | """Translate one term of the user's search into an SQL query. |
| 794 | |
| 795 | Args: |
| 796 | cond_num: integer cond number used to make distinct local variable names. |
| 797 | cond: user query cond parsed by query2ast.py. |
| 798 | |
| 799 | Returns: |
| 800 | A pair of lists (left_joins, where) to use when building the SQL SELECT |
| 801 | statement. Each of them is a list of (str, [val, ...]) pairs. |
| 802 | """ |
| 803 | alias = 'Cond%d' % cond_num |
| 804 | spare_alias = 'Spare%d' % cond_num |
| 805 | # Note: a condition like [x=y] has field_name "x", there may be multiple |
| 806 | # field definitions that match "x", but they will all have field_name "x". |
| 807 | field_def = cond.field_defs[0] |
| 808 | assert all(field_def.field_name == fd.field_name for fd in cond.field_defs) |
| 809 | |
| 810 | if field_def.field_name in NATIVE_SEARCHABLE_FIELDS: |
| 811 | # TODO(jeffcarp): Support local_id search here. |
| 812 | if snapshot_mode: |
| 813 | return [], [], [cond] |
| 814 | else: |
| 815 | col = NATIVE_SEARCHABLE_FIELDS[field_def.field_name] |
| 816 | where = [_Compare( |
| 817 | 'Issue', cond.op, field_def.field_type, col, |
| 818 | cond.str_values or cond.int_values)] |
| 819 | return [], where, [] |
| 820 | |
| 821 | elif field_def.field_name in _PROCESSORS: |
| 822 | proc = _PROCESSORS[field_def.field_name] |
| 823 | return proc(cond, alias, spare_alias, snapshot_mode) |
| 824 | |
| 825 | # Any phase conditions use the sql.SHORTHAND['phase_cond'], which expects a |
| 826 | # 'Phase' alias. 'phase_cond' cannot expect a 'Spare' alias because |
| 827 | # _ProcessCustomFieldCond also creates a phase_cond string where it uses the |
| 828 | # 'Phase' alias because it needs the 'Spare' alias for other conditions. |
| 829 | elif field_def.field_name == 'gate': |
| 830 | phase_alias = 'Phase%d' % cond_num |
| 831 | return _ProcessPhaseCond(cond, alias, phase_alias, snapshot_mode) |
| 832 | |
| 833 | elif field_def.field_id: # it is a search on a custom field |
| 834 | phase_alias = 'Phase%d' % cond_num |
| 835 | if field_def.field_type == tracker_pb2.FieldTypes.APPROVAL_TYPE: |
| 836 | return _ProcessApprovalFieldCond(cond, alias, spare_alias, snapshot_mode) |
| 837 | return _ProcessCustomFieldCond( |
| 838 | cond, alias, spare_alias, phase_alias, snapshot_mode) |
| 839 | |
| 840 | elif (cond.op in (ast_pb2.QueryOp.TEXT_HAS, ast_pb2.QueryOp.NOT_TEXT_HAS) and |
| 841 | (field_def.field_name in tracker_fulltext.ISSUE_FULLTEXT_FIELDS or |
| 842 | field_def.field_name == 'any_field')): |
| 843 | if snapshot_mode: |
| 844 | return [], [], [cond] |
| 845 | # This case handled by full-text search. |
| 846 | |
| 847 | else: |
| 848 | logging.error('untranslated search cond %r', cond) |
| 849 | |
| 850 | return [], [], [] |
| 851 | |
| 852 | |
| 853 | def _Compare(alias, op, val_type, col, vals): |
| 854 | """Return an SQL comparison for the given values. For use in WHERE or ON. |
| 855 | |
| 856 | Args: |
| 857 | alias: String name of the table or alias defined in a JOIN clause. |
| 858 | op: One of the operators defined in ast_pb2.py. |
| 859 | val_type: One of the value types defined in ast_pb2.py. |
| 860 | col: string column name to compare to vals. |
| 861 | vals: list of values that the user is searching for. |
| 862 | |
| 863 | Returns: |
| 864 | (cond_str, cond_args) where cond_str is a SQL condition that may contain |
| 865 | some %s placeholders, and cond_args is the list of values that fill those |
| 866 | placeholders. If the condition string contains any AND or OR operators, |
| 867 | the whole expression is put inside parens. |
| 868 | |
| 869 | Raises: |
| 870 | NoPossibleResults: The user's query is impossible to ever satisfy, e.g., |
| 871 | it requires matching an empty set of labels. |
| 872 | """ |
| 873 | vals_ph = sql.PlaceHolders(vals) |
| 874 | if col in ['label', 'status', 'email', 'name']: |
| 875 | alias_col = 'LOWER(%s.%s)' % (alias, col) |
| 876 | else: |
| 877 | alias_col = '%s.%s' % (alias, col) |
| 878 | |
| 879 | def Fmt(cond_str): |
| 880 | return cond_str.format(alias_col=alias_col, vals_ph=vals_ph) |
| 881 | |
| 882 | no_value = (0 if val_type in [tracker_pb2.FieldTypes.DATE_TYPE, |
| 883 | tracker_pb2.FieldTypes.INT_TYPE] else '') |
| 884 | if op == ast_pb2.QueryOp.IS_DEFINED: |
| 885 | return Fmt('({alias_col} IS NOT NULL AND {alias_col} != %s)'), [no_value] |
| 886 | if op == ast_pb2.QueryOp.IS_NOT_DEFINED: |
| 887 | return Fmt('({alias_col} IS NULL OR {alias_col} = %s)'), [no_value] |
| 888 | |
| 889 | if val_type in [tracker_pb2.FieldTypes.DATE_TYPE, |
| 890 | tracker_pb2.FieldTypes.INT_TYPE]: |
| 891 | if op == ast_pb2.QueryOp.TEXT_HAS: |
| 892 | op = ast_pb2.QueryOp.EQ |
| 893 | if op == ast_pb2.QueryOp.NOT_TEXT_HAS: |
| 894 | op = ast_pb2.QueryOp.NE |
| 895 | |
| 896 | if op == ast_pb2.QueryOp.EQ: |
| 897 | if not vals: |
| 898 | raise NoPossibleResults('Column %s has no possible value' % alias_col) |
| 899 | elif len(vals) == 1: |
| 900 | cond_str = Fmt('{alias_col} = %s') |
| 901 | else: |
| 902 | cond_str = Fmt('{alias_col} IN ({vals_ph})') |
| 903 | return cond_str, vals |
| 904 | |
| 905 | if op == ast_pb2.QueryOp.NE: |
| 906 | if not vals: |
| 907 | return 'TRUE', [] # a no-op that matches every row. |
| 908 | elif len(vals) == 1: |
| 909 | comp = Fmt('{alias_col} != %s') |
| 910 | else: |
| 911 | comp = Fmt('{alias_col} NOT IN ({vals_ph})') |
| 912 | return '(%s IS NULL OR %s)' % (alias_col, comp), vals |
| 913 | |
| 914 | wild_vals = ['%%%s%%' % val for val in vals] |
| 915 | if op == ast_pb2.QueryOp.TEXT_HAS: |
| 916 | cond_str = ' OR '.join(Fmt('{alias_col} LIKE %s') for v in vals) |
| 917 | return ('(%s)' % cond_str), wild_vals |
| 918 | if op == ast_pb2.QueryOp.NOT_TEXT_HAS: |
| 919 | cond_str = (Fmt('{alias_col} IS NULL OR ') + |
| 920 | ' AND '.join(Fmt('{alias_col} NOT LIKE %s') for v in vals)) |
| 921 | return ('(%s)' % cond_str), wild_vals |
| 922 | |
| 923 | |
| 924 | # Note: These operators do not support quick-OR |
| 925 | val = vals[0] |
| 926 | |
| 927 | if op == ast_pb2.QueryOp.GT: |
| 928 | return Fmt('{alias_col} > %s'), [val] |
| 929 | if op == ast_pb2.QueryOp.LT: |
| 930 | return Fmt('{alias_col} < %s'), [val] |
| 931 | if op == ast_pb2.QueryOp.GE: |
| 932 | return Fmt('{alias_col} >= %s'), [val] |
| 933 | if op == ast_pb2.QueryOp.LE: |
| 934 | return Fmt('{alias_col} <= %s'), [val] |
| 935 | |
| 936 | logging.error('unknown op: %r', op) |
| 937 | |
| 938 | |
| 939 | def _CompareAlreadyJoined(alias, op, col): |
| 940 | """Return a WHERE clause comparison that checks that a join succeeded.""" |
| 941 | def Fmt(cond_str): |
| 942 | return cond_str.format(alias_col='%s.%s' % (alias, col)) |
| 943 | |
| 944 | if op in (ast_pb2.QueryOp.NE, ast_pb2.QueryOp.NOT_TEXT_HAS, |
| 945 | ast_pb2.QueryOp.IS_NOT_DEFINED): |
| 946 | return Fmt('{alias_col} IS NULL'), [] |
| 947 | else: |
| 948 | return Fmt('{alias_col} IS NOT NULL'), [] |
| 949 | |
| 950 | |
| 951 | class Error(Exception): |
| 952 | """Base class for errors from this module.""" |
| 953 | |
| 954 | |
| 955 | class NoPossibleResults(Error): |
| 956 | """The query could never match any rows from the database, so don't try..""" |