Skip to content

Commit

Permalink
Merge pull request #362 from biocore/st_dh_admin_queries
Browse files Browse the repository at this point in the history
Allows admins to query barcodes with sql where clauses
  • Loading branch information
wasade authored Aug 18, 2021
2 parents 92eb480 + 5147002 commit 36182fb
Show file tree
Hide file tree
Showing 5 changed files with 438 additions and 0 deletions.
98 changes: 98 additions & 0 deletions microsetta_private_api/admin/admin_impl.py
Original file line number Diff line number Diff line change
Expand Up @@ -27,6 +27,7 @@
post_daklapack_order, send_daklapack_hold_email
from microsetta_private_api import localization
from microsetta_private_api.admin.sample_summary import per_sample
from microsetta_private_api.util.query_builder_to_sql import build_condition
from werkzeug.exceptions import Unauthorized


Expand Down Expand Up @@ -493,3 +494,100 @@ def generate_activation_codes(body, token_info):
results = [{"email": email, "code": map[email]} for email in map]
t.commit()
return jsonify(results), 200


def list_barcode_query_fields(token_info):
validate_admin_access(token_info)

# Generates a json array declaring the filters
# that can be used for barcode queries
# Will be parseable by jQuery QueryBuilder
# to allow a user to modify queries.

# Barcode queries can filter on:
# - project (categorical, any project in our db)
# - sample_status (categorical, fixed list)
# - sample_type (categorical, fixed list)

# See examples https://querybuilder.js.org/demo.html
# https://querybuilder.js.org/assets/demo-import-export.js

with Transaction() as t:
admin_repo = AdminRepo(t)
projects_list = admin_repo.get_projects(False)

filter_fields = []
filter_fields.append(
{
'id': 'project_id',
'label': 'Project',
'type': 'integer',
'input': 'select',
'values': {
x.project_id: x.project_name for x in projects_list
},
'operators': ['equal', 'not_equal']
}
)
filter_fields.append(
{
'id': 'sample_status',
'label': 'Sample Status',
'type': 'string',
'input': 'select',
'values': {
"sample-is-valid": "Sample Is Valid",
"no-associated-source": "No Associated Source",
"no-registered-account": "No Registered Account",
"no-collection-info": "No Collection Info",
"sample-has-inconsistencies": "Sample Has Inconsistencies",
"received-unknown-validity": "Received Unknown Validity"
},
'operators': ['equal', 'not_equal']
}
)
filter_fields.append(
{
'id': 'site_sampled',
'label': 'Sample Site',
'type': 'string',
'input': 'select',
'values': {
"Blood (skin prick)": "Blood (skin prick)",
"Saliva": "Saliva",
"Ear wax": "Ear wax",
"Forehead": "Forehead",
"Fur": "Fur",
"Hair": "Hair",
"Left hand": "Left hand",
"Left leg": "Left leg",
"Mouth": "Mouth",
"Nares": "Nares",
"Nasal mucus": "Nasal mucus",
"Right hand": "Right hand",
"Right leg": "Right leg",
"Stool": "Stool",
"Tears": "Tears",
"Torso": "Torso",
"Vaginal mucus": "Vaginal mucus"
},
'operators': ['equal', 'not_equal']
}
)

return jsonify(filter_fields), 200


def barcode_query(body, token_info):
# Validating admin access is absolutely critical here
# Failing to do so enables sql query access
# to non admin users
validate_admin_access(token_info)

with Transaction() as t:
repo = AdminRepo(t)
cond, cond_params = build_condition(body)
barcodes = repo.search_barcode(cond, cond_params)
t.rollback() # Queries don't need to commit changes.

return jsonify(barcodes), 200
35 changes: 35 additions & 0 deletions microsetta_private_api/api/microsetta_private_api.yaml
Original file line number Diff line number Diff line change
Expand Up @@ -1590,6 +1590,41 @@ paths:
schema:
type: array

'/admin/barcode_query_fields':
get:
operationId: microsetta_private_api.admin.admin_impl.list_barcode_query_fields
tags:
- Admin
responses:
'200':
description: Returns array of fields, types and values
content:
application/json:
schema:
type: array

'/admin/barcode_query':
post:
operationId: microsetta_private_api.admin.admin_impl.barcode_query
tags:
- Admin
requestBody:
content:
application/json:
schema:
type: object
responses:
'200':
description: Returns array of barcodes
content:
application/json:
schema:
type: array
items:
# not using the defined schema for sample_barcode as it is
# readOnly
type: string

components:
parameters:
# path parameters
Expand Down
36 changes: 36 additions & 0 deletions microsetta_private_api/repo/admin_repo.py
Original file line number Diff line number Diff line change
Expand Up @@ -6,6 +6,8 @@
import psycopg2.extras
import json

from psycopg2 import sql

from microsetta_private_api.exceptions import RepoException

import microsetta_private_api.model.project as p
Expand Down Expand Up @@ -1096,6 +1098,40 @@ def scan_barcode(self, sample_barcode, scan_info):

return new_uuid

def search_barcode(self, sql_cond, cond_params):
# Security Note:
# Even with sql queries correctly escaped,
# exposing a conditional query oracle
# with unlimited queries grants full read access
# to all tables joined within the query
# That is, administrator users searching with
# this method can reconstruct
# project_barcode, ag_kit_barcodes and barcode_scans
# given enough queries, including columns
# that are not returned by the select
with self._transaction.cursor() as cur:
cur.execute(
sql.SQL(
"SELECT project_barcode.barcode FROM "
"project_barcode LEFT JOIN "
"ag_kit_barcodes USING (barcode) "
"LEFT JOIN barcodes.barcode_scans "
"USING (barcode) "
"LEFT JOIN ( "
"SELECT barcode, max(scan_timestamp) "
"AS scan_timestamp "
"FROM barcodes.barcode_scans "
"GROUP BY barcode "
") AS latest_scan "
"ON barcode_scans.barcode = latest_scan.barcode "
"AND barcode_scans.scan_timestamp = "
"latest_scan.scan_timestamp "
"WHERE {cond}"
).format(cond=sql_cond),
cond_params
)
return [r[0] for r in cur.fetchall()]

def get_survey_metadata(self, sample_barcode, survey_template_id=None):
ids = self._get_ids_relevant_to_barcode(sample_barcode)

Expand Down
88 changes: 88 additions & 0 deletions microsetta_private_api/util/query_builder_to_sql.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,88 @@
# Take model objects from the jquery query builder
# and convert them into escaped sql where clauses

from psycopg2 import sql
from microsetta_private_api.exceptions import RepoException

# If we ever implement remaining operators, be sure to
# check that parameterized arguments are generated in
# the correct order
supported_operators = {
'equal': '=',
'not_equal': '!=',
# in,
# not_in,
'less': "<",
'less_or_equal': "<=",
'greater': ">",
'greater_or_equal': ">=",
# between,
# not_between,
# begins_with,
# not_begins_with,
# contains,
# not_contains,
# ends_with,
# not_ends_with,
# is_empty,
# is_not_empty,
# is_null,
# is_not_null,
}


def build_condition(top_level_obj):
def build_condition_helper_group(root_obj, out_values, is_top_level=False):
condition = root_obj['condition']
rules = root_obj['rules']

if condition == 'AND':
join_str = " and "
elif condition == 'OR':
join_str = " or "
else:
raise RepoException("Unknown condition: " + str(condition))

cond = sql.SQL(join_str)\
.join([build_condition_helper(x, out_values) for x in rules])
if not is_top_level:
cond = sql.SQL('({cond})').format(cond=cond)
return cond

def build_condition_helper_rule(root_obj, out_values):
id = root_obj['id']
# field = root_obj['field']
# type = root_obj['type']
# input = root_obj['input']
operator = root_obj['operator']
value = root_obj['value']

if operator not in supported_operators:
raise RepoException("Unsupported query operator: " + str(operator))
cond = "{id} " + supported_operators[operator] + " {value}"

out_values.append(value)
return sql.SQL(cond).format(
id=sql.Identifier(id),
value=sql.Placeholder())

def build_condition_helper(root_obj, out_values, is_top_level=False):
if "condition" in root_obj:
return build_condition_helper_group(
root_obj,
out_values,
is_top_level=is_top_level)
else:
return build_condition_helper_rule(root_obj, out_values)

valid = top_level_obj['valid']

if not valid:
raise RepoException("Query is invalid")

out_values = []

return build_condition_helper(
top_level_obj,
out_values,
is_top_level=True), out_values
Loading

0 comments on commit 36182fb

Please sign in to comment.