Skip to content
This repository has been archived by the owner on Nov 13, 2023. It is now read-only.

Commit

Permalink
Fixes phpmyadmin#14658 - Regression on multi table query (phpmyadmin#…
Browse files Browse the repository at this point in the history
…14681)

Added functionality to generate SELECT query with JOINs of requested tables. It was mentioned that it's just a bug and it was working in previous versions, but I did not see any code fragments that would make it possible. Please, feel free to suggest any better solution if you don't like that one.

Fixes phpmyadmin#14658

Signed-off-by: Aleš Buľko <ales.bulko@student.tuke.sk>
  • Loading branch information
ales-bulko authored and MauricioFauth committed Nov 26, 2018
1 parent 416bf94 commit 23ce7ce
Show file tree
Hide file tree
Showing 7 changed files with 249 additions and 84 deletions.
8 changes: 8 additions & 0 deletions db_multi_table_query.php
Original file line number Diff line number Diff line change
Expand Up @@ -18,13 +18,21 @@
$_REQUEST['db'],
$pmaThemeImage
);
} if (isset($_GET['tables'])) {
$constrains = $GLOBALS['dbi']->getForeignKeyConstrains(
$_REQUEST['db'],
$_GET['tables']
);
$response = Response::getInstance();
$response->addJSON('foreignKeyConstrains',$constrains);
} else {
$response = Response::getInstance();

$header = $response->getHeader();
$scripts = $header->getScripts();
$scripts->addFile('vendor/jquery/jquery.md5.js');
$scripts->addFile('db_multi_table_query.js');
$scripts->addFile('db_query_generator.js');

$queryInstance = new MultiTableQuery($GLOBALS['dbi'], $db);

Expand Down
122 changes: 38 additions & 84 deletions js/db_multi_table_query.js
Original file line number Diff line number Diff line change
Expand Up @@ -6,6 +6,7 @@
* @requires jQuery
* @requires jQueryUI
* @requires js/functions.js
* @requires js/db_query_generator.js
*
*/

Expand Down Expand Up @@ -33,129 +34,82 @@ AJAX.registerOnload('db_multi_table_query.js', function () {
PMA_init_slider();
addNewColumnCallbacks();

function escapeBacktick (s) {
return s.replace('`', '``');
}

function escapeSingleQuote (s) {
return s.replace('\\', '\\\\').replace('\'', '\\\'');
}

$('#update_query_button').on('click', function () {
var columns = [];
var table_aliases = {};
var tableAliases = {};
$('.tableNameSelect').each(function () {
$show = $(this).siblings('.show_col').first();
if ($(this).val() !== '' && $show.prop('checked')) {
var table_alias = $(this).siblings('.table_alias').first().val();
var column_alias = $(this).siblings('.col_alias').first().val();
var tableAlias = $(this).siblings('.table_alias').first().val();
var columnAlias = $(this).siblings('.col_alias').first().val();

if (table_alias !== '') {
columns.push([table_alias, $(this).siblings('.columnNameSelect').first().val()]);
if (tableAlias !== '') {
columns.push([tableAlias, $(this).siblings('.columnNameSelect').first().val()]);
} else {
columns.push([$(this).val(), $(this).siblings('.columnNameSelect').first().val()]);
}

columns[columns.length - 1].push(column_alias);
columns[columns.length - 1].push(columnAlias);

if ($(this).val() in table_aliases) {
if (!(table_aliases[$(this).val()].includes(table_alias))) {
table_aliases[$(this).val()].push(table_alias);
if ($(this).val() in tableAliases) {
if (!(tableAliases[$(this).val()].includes(tableAlias))) {
tableAliases[$(this).val()].push(tableAlias);
}
} else {
table_aliases[$(this).val()] = [table_alias];
tableAliases[$(this).val()] = [tableAlias];
}
}
});
if (Object.keys(table_aliases).length === 0) {
if (Object.keys(tableAliases).length === 0) {
PMA_ajaxShowMessage('Nothing selected', false, 'error');
return;
}

query = 'SELECT ';
var foreignKeys;
$.ajax({
type: 'GET',
async: false,
url: 'db_multi_table_query.php',
data: {
'server': sessionStorage.server,
'db': $('#db_name').val(),
'tables': Object.keys(tableAliases),
'ajax_request': '1',
'token': PMA_commonParams.get('token')
},
success: function (response) {
foreignKeys = response.foreignKeyConstrains;
}
});

query = 'SELECT ' + '`' + escapeBacktick(columns[0][0]) + '`.';
if (columns[0][1] === '*') {
query += '`' + escapeBacktick(columns[0][0]) + '`.' + escapeBacktick(columns[0][1]) + '';
query += '*';
} else {
query += '`' + escapeBacktick(columns[0][0]) + '`.`' + escapeBacktick(columns[0][1]) + '`';
query += '`' + escapeBacktick(columns[0][1]) + '`';
}
if (columns[0][2] !== '') {
query += ' AS ' + columns[0][2];
}
for (var i = 1; i < columns.length; i++) {
query += ', `' + escapeBacktick(columns[i][0]) + '`.';
if (columns[i][1] === '*') {
query += ', `' + escapeBacktick(columns[i][0]) + '`.' + escapeBacktick(columns[i][1]) + '';
query += '*';
} else {
query += ', `' + escapeBacktick(columns[i][0]) + '`.`' + escapeBacktick(columns[i][1]) + '`';
query += '`' + escapeBacktick(columns[i][1]) + '`';
}
if (columns[i][2] !== '') {
query += ' AS `' + escapeBacktick(columns[0][2]) + '`';
}
}
query += '\nFROM ';
var table_count = 0;
for (var table in table_aliases) {
for (var i = 0; i < table_aliases[table].length; i++) {
if (table_count > 0) {
query += ', ';
}
query += '`' + escapeBacktick(table) + '`';
if (table_aliases[table][i] !== '') {
query += ' AS `' + escapeBacktick(table_aliases[table][i]) + '`';
}
table_count++;
}
}

query += generateFromBlock(tableAliases, foreignKeys);

$criteria_col_count = $('.criteria_col:checked').length;
if ($criteria_col_count > 0) {
query += '\nWHERE ';

var logical_ops = [];

var count = 0;

$('.tableNameSelect').each(function () {
$criteria_div = $(this).siblings('.slide-wrapper').first();
$use_criteria = $(this).siblings('.criteria_col').first();
if ($(this).val() !== '' && $use_criteria.prop('checked')) {
if (count > 0) {
$criteria_div.find('input.logical_op').each(function () {
if ($(this).prop('checked')) {
query += ' ' + $(this).val() + ' ';
}
});
}
formats_text = {
'=' : ' = \'%s\'',
'>' : ' > \'%s\'',
'>=' : ' >= \'%s\'',
'<' : ' < \'%s\'',
'<=' : ' <= \'%s\'',
'!=' : ' != \'%s\'',
'LIKE' : ' LIKE \'%s\'',
'LIKE \%...\%' : ' LIKE \'%%%s%%\'',
'NOT LIKE' : ' NOT LIKE \'%s\'',
'BETWEEN' : ' BETWEEN \'%s\'',
'NOT BETWEEN' : ' NOT BETWEEN \'%s\'',
'IS NULL' : ' \'%s\' IS NULL',
'IS NOT NULL' : ' \'%s\' IS NOT NULL',
'REGEXP' : ' REGEXP \'%s\'',
'REGEXP ^...$' : ' REGEXP \'^%s$\'',
'NOT REGEXP' : ' NOT REGEXP \'%s\''
};
query += '`' + escapeBacktick($(this).val()) + '`.';
query += '`' + escapeBacktick($(this).siblings('.columnNameSelect').first().val()) + '`';
if ($criteria_div.find('.criteria_rhs').first().val() === 'text') {
// query += " '" + $criteria_div.find('.rhs_text_val').first().val() + "'";
query += sprintf(formats_text[$criteria_div.find('.criteria_op').first().val()], escapeSingleQuote($criteria_div.find('.rhs_text_val').first().val()));
} else {
query += ' ' + $criteria_div.find('.criteria_op').first().val();
query += ' `' + escapeBacktick($criteria_div.find('.tableNameSelect').first().val()) + '`.';
query += '`' + escapeBacktick($criteria_div.find('.columnNameSelect').first().val()) + '`';
}
count++;
}
});
query += generateWhereBlock();
}

query += ';';
Expand Down
127 changes: 127 additions & 0 deletions js/db_query_generator.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,127 @@
/* vim: set expandtab sw=4 ts=4 sts=4: */
/**
* @fileoverview function used in QBE for DB
* @name Database Operations
*
* @requires jQuery
* @requires jQueryUI
* @requires js/functions.js
*
*/

function getFormatsText () {
return {
'=': ' = \'%s\'',
'>': ' > \'%s\'',
'>=': ' >= \'%s\'',
'<': ' < \'%s\'',
'<=': ' <= \'%s\'',
'!=': ' != \'%s\'',
'LIKE': ' LIKE \'%s\'',
'LIKE \%...\%': ' LIKE \'%%%s%%\'',
'NOT LIKE': ' NOT LIKE \'%s\'',
'BETWEEN': ' BETWEEN \'%s\'',
'NOT BETWEEN': ' NOT BETWEEN \'%s\'',
'IS NULL': ' \'%s\' IS NULL',
'IS NOT NULL': ' \'%s\' IS NOT NULL',
'REGEXP': ' REGEXP \'%s\'',
'REGEXP ^...$': ' REGEXP \'^%s$\'',
'NOT REGEXP': ' NOT REGEXP \'%s\''
};
}

function generateCondition (criteriaDiv, table) {
query = '`' + escapeBacktick(table.val()) + '`.';
query += '`' + escapeBacktick(table.siblings('.columnNameSelect').first().val()) + '`';
if (criteriaDiv.find('.criteria_rhs').first().val() === 'text') {
formatsText = getFormatsText();
query += sprintf(formatsText[criteriaDiv.find('.criteria_op').first().val()], escapeSingleQuote(criteriaDiv.find('.rhs_text_val').first().val()));
} else {
query += ' ' + criteriaDiv.find('.criteria_op').first().val();
query += ' `' + escapeBacktick(criteriaDiv.find('.tableNameSelect').first().val()) + '`.';
query += '`' + escapeBacktick(criteriaDiv.find('.columnNameSelect').first().val()) + '`';
}
return query;
}

function generateWhereBlock () {
var count = 0;
var query = '';
$('.tableNameSelect').each(function () {
var criteriaDiv = $(this).siblings('.slide-wrapper').first();
var useCriteria = $(this).siblings('.criteria_col').first();
if ($(this).val() !== '' && useCriteria.prop('checked')) {
if (count > 0) {
criteriaDiv.find('input.logical_op').each(function () {
if ($(this).prop('checked')) {
query += ' ' + $(this).val() + ' ';
}
});
}
query += generateCondition(criteriaDiv, $(this));
count++;
}
});
return query;
}

function generateJoin (newTable, tableAliases, fk) {
query = '';
query += ' \n\tLEFT JOIN ' + '`' + escapeBacktick(newTable) + '`';
if (tableAliases[fk.TABLE_NAME][0] !== '') {
query += ' AS `' + escapeBacktick(tableAliases[newTable][0]) + '`';
query += ' ON `' + escapeBacktick(tableAliases[fk.TABLE_NAME][0]) + '`';
} else {
query += ' ON `' + escapeBacktick(fk.TABLE_NAME) + '`';
}
query += '.`' + fk.COLUMN_NAME + '`';
if (tableAliases[fk.REFERENCED_TABLE_NAME][0] !== '') {
query += ' = `' + escapeBacktick(tableAliases[fk.REFERENCED_TABLE_NAME][0]) + '`';
} else {
query += ' = `' + escapeBacktick(fk.REFERENCED_TABLE_NAME) + '`';
}
query += '.`' + fk.REFERENCED_COLUMN_NAME + '`';
return query;
}

function existReference (table, fk, usedTables) {
var isReferredBy = fk.TABLE_NAME === table && usedTables.includes(fk.REFERENCED_TABLE_NAME);
var isReferencedBy = fk.REFERENCED_TABLE_NAME === table && usedTables.includes(fk.TABLE_NAME);
return isReferredBy || isReferencedBy;
}

function tryJoinTable (table, tableAliases, usedTables, foreignKeys) {
for (var i = 0; i < foreignKeys.length; i++) {
var fk = foreignKeys[i];
if (existReference(table, fk, usedTables)) {
return generateJoin(table, tableAliases, fk);
}
}
return '';
}

function appendTable (table, tableAliases, usedTables, foreignKeys) {
var query = tryJoinTable (table, tableAliases, usedTables, foreignKeys);
if (query === '') {
if (usedTables.length > 0) {
query += '\n\t, ';
}
query += '`' + escapeBacktick(table) + '`';
if (tableAliases[table][0] !== '') {
query += ' AS `' + escapeBacktick(tableAliases[table][0]) + '`';
}
}
usedTables.push(table);
return query;
}

function generateFromBlock (tableAliases, foreignKeys) {
var usedTables = [];
query = '';
for (var table in tableAliases) {
if (tableAliases.hasOwnProperty(table)) {
query += appendTable(table, tableAliases, usedTables, foreignKeys);
}
}
return query;
}
9 changes: 9 additions & 0 deletions js/functions.js
Original file line number Diff line number Diff line change
Expand Up @@ -383,6 +383,15 @@ function escapeJsString (unsafe) {
}
}


function escapeBacktick (s) {
return s.replace('`', '``');
}

function escapeSingleQuote (s) {
return s.replace('\\', '\\\\').replace('\'', '\\\'');
}

function PMA_sprintf () {
return sprintf.apply(this, arguments);
}
Expand Down
37 changes: 37 additions & 0 deletions libraries/classes/DatabaseInterface.php
Original file line number Diff line number Diff line change
Expand Up @@ -390,6 +390,43 @@ public function getTables(string $database, $link = DatabaseInterface::CONNECT_U
return $tables;
}


/**
* returns
*
* @param string $database name of database
* @param array $tables list of tables to search for for relations
* @param int $link mysql link resource|object
*
* @return array array of found foreign keys
*/
public function getForeignKeyConstrains(string $database, array $tables, $link = DatabaseInterface::CONNECT_USER): array
{
$tablesListForQuery = '';
foreach($tables as $table){
$tablesListForQuery .= "'" . $this->escapeString($table) . "',";
}
$tablesListForQuery = rtrim($tablesListForQuery, ',');

$foreignKeyConstrains = $this->fetchResult(
"SELECT"
. " TABLE_NAME,"
. " COLUMN_NAME,"
. " REFERENCED_TABLE_NAME,"
. " REFERENCED_COLUMN_NAME"
. " FROM information_schema.key_column_usage"
. " WHERE referenced_table_name IS NOT NULL"
. " AND TABLE_SCHEMA = '" . $this->escapeString($database) . "'"
. " AND TABLE_NAME IN (" . $tablesListForQuery . ")"
. " AND REFERENCED_TABLE_NAME IN (" . $tablesListForQuery . ");",
null,
null,
$link,
self::QUERY_STORE
);
return $foreignKeyConstrains;
}

/**
* returns a segment of the SQL WHERE clause regarding table name and type
*
Expand Down

0 comments on commit 23ce7ce

Please sign in to comment.