Skip to content

Commit

Permalink
[DataQuery] New dataquery backend implementation (#8268)
Browse files Browse the repository at this point in the history
This implements the dataquery REST API schema defined in PR#8219.

This allows module's data to be queried programmatically without the usage of CouchDB. It currently only provides an API, but will be the basis of a new dataquery tool frontend.
  • Loading branch information
driusan authored Aug 30, 2023
1 parent b0a24a9 commit 0ae7a24
Show file tree
Hide file tree
Showing 18 changed files with 2,110 additions and 1 deletion.
65 changes: 65 additions & 0 deletions SQL/0000-00-00-schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2440,3 +2440,68 @@ CREATE TABLE `publication_users_edit_perm_rel` (
CONSTRAINT `FK_publication_users_edit_perm_rel_PublicationID` FOREIGN KEY (`PublicationID`) REFERENCES `publication` (`PublicationID`),
CONSTRAINT `FK_publication_users_edit_perm_rel_UserID` FOREIGN KEY (`UserID`) REFERENCES `users` (`ID`)
) ENGINE=InnoDB DEFAULT CHARSET='utf8';

CREATE TABLE dataquery_queries (
QueryID int(10) unsigned NOT NULL AUTO_INCREMENT,
Query JSON NOT NULL,
PRIMARY KEY (QueryID)
-- FOREIGN KEY (Owner) REFERENCES users(ID)
);

CREATE TABLE dataquery_query_names (
QueryID int(10) unsigned NOT NULL,
UserID int(10) unsigned NOT NULL,
Name varchar(255) NOT NULL,
PRIMARY KEY (QueryID, UserID),
FOREIGN KEY (QueryID) REFERENCES dataquery_queries(QueryID),
FOREIGN KEY (UserID) REFERENCES users(ID)
);

CREATE TABLE dataquery_run_queries (
RunID int(10) unsigned NOT NULL AUTO_INCREMENT,
QueryID int(10) unsigned,
UserID int(10) unsigned,
RunTime TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
PRIMARY KEY (RunID),
FOREIGN KEY (QueryID) REFERENCES dataquery_queries(QueryID),
FOREIGN KEY (UserID) REFERENCES users(ID)
);
CREATE TABLE dataquery_shared_queries_rel (
QueryID int(10) unsigned,
SharedBy int(10) unsigned,
FOREIGN KEY (QueryID) REFERENCES dataquery_queries(QueryID),
FOREIGN KEY (SharedBy) REFERENCES users(ID),
CONSTRAINT unique_share UNIQUE (QueryID, SharedBy)
);

CREATE TABLE dataquery_starred_queries_rel (
QueryID int(10) unsigned,
StarredBy int(10) unsigned,
FOREIGN KEY (QueryID) REFERENCES dataquery_queries(QueryID),
FOREIGN KEY (StarredBy) REFERENCES users(ID),
CONSTRAINT unique_pin UNIQUE (QueryID, StarredBy)
);

CREATE TABLE dataquery_run_results (
RunID int(10) unsigned NOT NULL AUTO_INCREMENT,
CandID int(6) NOT NULL,
-- JSON or same format that's streamed in?
RowData LONGTEXT DEFAULT NULL,

PRIMARY KEY (RunID, CandID),
FOREIGN KEY (CandID) REFERENCES candidate(CandID),
FOREIGN KEY (RunID) REFERENCES dataquery_run_queries(RunID)
);

CREATE TABLE dataquery_study_queries_rel (
QueryID int(10) unsigned,
PinnedBy int(10) unsigned,
-- A top query shows on the top of the dataquery tool similarly
-- to a saved query but is chosen by admins, a dashboard query
-- shows the number of matching results on the LORIS dashboard.
Name varchar(255) NOT NULL,
PinType enum('topquery', 'dashboard'),
FOREIGN KEY (QueryID) REFERENCES dataquery_queries(QueryID),
FOREIGN KEY (PinnedBy) REFERENCES users(ID),
CONSTRAINT unique_pin UNIQUE (QueryID, PinType)
);
1 change: 1 addition & 0 deletions SQL/0000-00-01-Modules.sql
Original file line number Diff line number Diff line change
Expand Up @@ -52,5 +52,6 @@ INSERT INTO modules (Name, Active) VALUES ('user_accounts', 'Y');
INSERT INTO modules (Name, Active) VALUES ('electrophysiology_browser', 'Y');
INSERT INTO modules (Name, Active) VALUES ('dqt', 'Y');
INSERT INTO modules (Name, Active) VALUES ('electrophysiology_uploader', 'Y');
INSERT INTO modules (Name, Active) VALUES ('dataquery', 'Y');

ALTER TABLE issues ADD CONSTRAINT `fk_issues_7` FOREIGN KEY (`module`) REFERENCES `modules` (`ID`);
8 changes: 8 additions & 0 deletions SQL/9999-99-99-drop_tables.sql
Original file line number Diff line number Diff line change
@@ -1,3 +1,11 @@
DROP TABLE IF EXISTS dataquery_study_queries_rel;
DROP TABLE IF EXISTS dataquery_run_results;
DROP TABLE IF EXISTS dataquery_starred_queries_rel;
DROP TABLE IF EXISTS dataquery_shared_queries_rel;
DROP TABLE IF EXISTS dataquery_run_queries;
DROP TABLE IF EXISTS dataquery_query_names;
DROP TABLE IF EXISTS dataquery_queries;

-- 0000-00-05-ElectrophysiologyTables.sql
DROP TABLE IF EXISTS `physiological_coord_system_electrode_rel`;
DROP TABLE IF EXISTS `physiological_coord_system_point_3d_rel`;
Expand Down
66 changes: 66 additions & 0 deletions SQL/New_patches/2022-09-29-NewestDQT.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,66 @@
CREATE TABLE dataquery_queries (
QueryID int(10) unsigned NOT NULL AUTO_INCREMENT,
Query JSON NOT NULL,
PRIMARY KEY (QueryID)
-- FOREIGN KEY (Owner) REFERENCES users(ID)
);

CREATE TABLE dataquery_query_names (
QueryID int(10) unsigned NOT NULL,
UserID int(10) unsigned NOT NULL,
Name varchar(255) NOT NULL,
PRIMARY KEY (QueryID, UserID),
FOREIGN KEY (QueryID) REFERENCES dataquery_queries(QueryID),
FOREIGN KEY (UserID) REFERENCES users(ID)
);

CREATE TABLE dataquery_run_queries (
RunID int(10) unsigned NOT NULL AUTO_INCREMENT,
QueryID int(10) unsigned,
UserID int(10) unsigned,
RunTime TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
PRIMARY KEY (RunID),
FOREIGN KEY (QueryID) REFERENCES dataquery_queries(QueryID),
FOREIGN KEY (UserID) REFERENCES users(ID)
);
CREATE TABLE dataquery_shared_queries_rel (
QueryID int(10) unsigned,
SharedBy int(10) unsigned,
FOREIGN KEY (QueryID) REFERENCES dataquery_queries(QueryID),
FOREIGN KEY (SharedBy) REFERENCES users(ID),
CONSTRAINT unique_share UNIQUE (QueryID, SharedBy)
);

CREATE TABLE dataquery_starred_queries_rel (
QueryID int(10) unsigned,
StarredBy int(10) unsigned,
FOREIGN KEY (QueryID) REFERENCES dataquery_queries(QueryID),
FOREIGN KEY (StarredBy) REFERENCES users(ID),
CONSTRAINT unique_pin UNIQUE (QueryID, StarredBy)
);

CREATE TABLE dataquery_run_results (
RunID int(10) unsigned NOT NULL AUTO_INCREMENT,
CandID int(6) NOT NULL,
-- JSON or same format that's streamed in?
RowData LONGTEXT DEFAULT NULL,

PRIMARY KEY (RunID, CandID),
FOREIGN KEY (CandID) REFERENCES candidate(CandID),
FOREIGN KEY (RunID) REFERENCES dataquery_run_queries(RunID)
);

CREATE TABLE dataquery_study_queries_rel (
QueryID int(10) unsigned,
PinnedBy int(10) unsigned,
-- A top query shows on the top of the dataquery tool similarly
-- to a saved query but is chosen by admins, a dashboard query
-- shows the number of matching results on the LORIS dashboard.
Name varchar(255) NOT NULL,
PinType enum('topquery', 'dashboard'),
FOREIGN KEY (QueryID) REFERENCES dataquery_queries(QueryID),
FOREIGN KEY (PinnedBy) REFERENCES users(ID),
CONSTRAINT unique_pin UNIQUE (QueryID, PinType)
);

INSERT INTO modules (Name, Active) VALUES ('dataquery', 'Y');
1 change: 1 addition & 0 deletions modules/dataquery/.gitignore
Original file line number Diff line number Diff line change
@@ -0,0 +1 @@
js/
153 changes: 153 additions & 0 deletions modules/dataquery/php/endpoints/queries.class.inc
Original file line number Diff line number Diff line change
@@ -0,0 +1,153 @@
<?php
namespace LORIS\dataquery\endpoints;

use \Psr\Http\Message\ServerRequestInterface;
use \Psr\Http\Message\ResponseInterface;
use \LORIS\Data\Filters\AccessibleResourceFilter;

/**
* Handles requests to queries under the /queries/* endpoint of
* the dataquery module.
*
* @license http://www.gnu.org/licenses/gpl-3.0.txt GPLv3
*/
class Queries extends \LORIS\Http\Endpoint
{
public $skipTemplate = true;

/**
* If the user has access to the module they can access this endpoint,
* specific queries permissions are checked (and filtered out) individually.
*
* @param \User $user The user whose access is being checked
*
* @return bool
*/
function _hasAccess(\User $user) : bool
{
return true;
}

/**
* {@inheritDoc}
*
* @param ServerRequestInterface $request The incoming PSR7 request
*
* @return ResponseInterface
*/
public function handle(ServerRequestInterface $request) : ResponseInterface
{
$user = $request->getAttribute('user');
switch ($request->getMethod()) {
case 'GET':
return new \LORIS\Http\Response\JSON\OK(
[
'queries' => iterator_to_array(
$this->getUserAccessibleQueries($user),
false, // do not preserve keys, stay an array
),
]
);
case 'POST':
$requestjson = (string) $request->getBody();
$requestdata = json_decode($requestjson, true);
if ($requestdata === false) {
return new \LORIS\Http\Response\JSON\BadRequest(
'Invalid JSON data'
);
}
if ($this->_validateQuery($requestdata, $user) === false) {
return new \LORIS\Http\Response\JSON\BadRequest(
'Invalid query'
);
}
$queryID = $this->_storeQuery($requestjson);
return new \LORIS\Http\Response\JSON\OK(
[
'QueryID' => $queryID
]
);
default:
return new \LORIS\Http\Response\JSON\MethodNotAllowed(['GET', 'POST']);
}
}

/**
* Validates that a query submitted is valid before storing it.
* Returns true if the query is valid, false otherwise.
*
* @param array $json The parsed JSON of the query
* @param \User $user The user trying to create the query
*
* @return bool
*/
private function _validateQuery(array $json, \User $user) : bool
{
if (($json['type'] ?? 'invalid') !== "candidates") {
return false;
}
if (!isset($json['fields'])
|| !is_array($json['fields'])
|| !array_is_list($json['fields'])
) {
return false;
}

// Validate all the fields used in the fields and filters
// are accessible by the current user.
$theQuery = new \LORIS\dataquery\Query(
loris: $this->loris,
queryID: -1,
query: $json,
);
return $theQuery->isAccessibleBy($user);
}

/**
* Store a query that was run in the database and return the QueryID.
* for it.
*
* @param string $requestjson The JSON of the query
*
* @return int
*/
private function _storeQuery(string $requestjson)
{
$DB = $this->loris->getDatabaseConnection();
$queryID = $DB->pselectOne(
"SELECT QueryID
FROM dataquery_queries
WHERE Query=:json",
[
'json' => $requestjson,
],
);
if ($queryID === null) {
// Dealing with JSON need to use the unsafe wrapper
$DB->unsafeInsert(
'dataquery_queries',
[
'Query' => $requestjson,
],
);
$queryID = $DB->getLastInsertId();
}
return intval($queryID);
}

/**
* Get a list of recent query runs for this user
*
* @param \User $user The user getting the queries.
*
* @return \Traversable
*/
public function getUserAccessibleQueries(\User $user) : iterable
{
return (new \LORIS\dataquery\provisioners\AllUserQueries(
$this->loris,
$user
))->filter(new AccessibleResourceFilter())
->execute($user);
}
}
Loading

0 comments on commit 0ae7a24

Please sign in to comment.