Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Improve BaseConnection::getForeignKeyData() and Forge::addForeignKey() #6468

Merged
merged 41 commits into from
Sep 24, 2022
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
Show all changes
41 commits
Select commit Hold shift + click to select a range
44390dd
Normalize foreign Key name
sclubricants Sep 1, 2022
7819dcd
Update MySql Connection::_foreignKeyData()
sclubricants Sep 1, 2022
27a399b
Update Postgres Connection::_foreignKeyData()
sclubricants Sep 1, 2022
44e152f
Update Sqlite Connection::_foreignKeyData()
sclubricants Sep 1, 2022
3d312e2
Update SQLSRV Connection::_foreignKeyData()
sclubricants Sep 1, 2022
913759e
Update Oracle Connection::_foreignKeyData()
sclubricants Sep 1, 2022
1f15091
Fix Sqlite Array Index Error
sclubricants Sep 1, 2022
087a0ed
Fix Sqlite Table to work with new data structure _foreignKeyData()
sclubricants Sep 1, 2022
3423949
Fix AlterTableTest - use new data structure from _foreignKeyData()
sclubricants Sep 1, 2022
1fc411d
Fix Oracle Connection::_foreignKeyData() letter case
sclubricants Sep 1, 2022
a66dbe8
Update ForgeTest to work with new data structure of Connection::_fore…
sclubricants Sep 1, 2022
bd1e18c
Added Change Log Note
sclubricants Sep 1, 2022
9584fc7
Fix variable name $ind to $indexes
sclubricants Sep 2, 2022
f71705e
Refactor _foreignKeyData() by adding BaseConnection::foreignKeyDataTo…
sclubricants Sep 2, 2022
337b00d
Refactor _processForeignKeys() to remove duplicate code
sclubricants Sep 2, 2022
2b81be7
Change All DBMS to use fk_ prefix instead of _foreign suffix
sclubricants Sep 2, 2022
6813030
Refactor _processForeignKeys() to provide 30 byte name for Oracle < v…
sclubricants Sep 3, 2022
8513959
Revert _foreign suffix
sclubricants Sep 3, 2022
fb07056
Update documentation - upgrade instructions - and change logs
sclubricants Sep 3, 2022
8064d3e
Fix user guide syntax error
sclubricants Sep 3, 2022
3bc4347
Fix MySql _foreignKeyData() SQL upper case
sclubricants Sep 3, 2022
cf54786
Add DocBlock to _processForeignKeys()
sclubricants Sep 4, 2022
02b6cdf
Change Oracle Version Rule for Identifier length
sclubricants Sep 4, 2022
a5078ae
Add link to change log
sclubricants Sep 6, 2022
9d3368b
revert _processForeignKeys() parameters/structure
sclubricants Sep 6, 2022
251e9f9
Added breaking change
sclubricants Sep 8, 2022
6738d32
Change suffix to _fk for all DBMS
sclubricants Sep 13, 2022
1a6e59d
Update documentation
sclubricants Sep 13, 2022
0766b62
Add Custom Naming to foreign keys and test
sclubricants Sep 15, 2022
0c68216
Removed db prefix from dropForeignKey()
sclubricants Sep 15, 2022
2db2af4
Update documentation for custom named foreign keys
sclubricants Sep 15, 2022
5bcb3e3
Fix Rector issue
sclubricants Sep 15, 2022
2c418cd
Update user_guide_src/source/changelogs/v4.3.0.rst
sclubricants Sep 16, 2022
3c8a1a5
Added Note about SQLite to Forge Documentation
sclubricants Sep 16, 2022
9d9bc4c
Update forge.rst
sclubricants Sep 16, 2022
d205a5b
Revert suffix _fk to _foreign in all but OCI8
sclubricants Sep 17, 2022
73d0646
Revert Documentation
sclubricants Sep 17, 2022
ecc2553
Update user_guide_src/source/changelogs/v4.3.0.rst
sclubricants Sep 19, 2022
a6276e7
Update documentation
sclubricants Sep 19, 2022
240724b
Update upgrade_430.rst
sclubricants Sep 19, 2022
aa818d5
Add to changelog
sclubricants Sep 23, 2022
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
45 changes: 45 additions & 0 deletions system/Database/BaseConnection.php
Original file line number Diff line number Diff line change
Expand Up @@ -1541,6 +1541,51 @@ public function getForeignKeyData(string $table)
return $this->_foreignKeyData($this->protectIdentifiers($table, true, false, false));
}

/**
* Converts array of arrays generated by _foreignKeyData() to array of objects
*
* @return array[
* {constraint_name} =>
* stdClass[
* 'constraint_name' => string,
* 'table_name' => string,
* 'column_name' => string[],
* 'foreign_table_name' => string,
* 'foreign_column_name' => string[],
* 'on_delete' => string,
* 'on_update' => string,
* 'match' => string
* ]
* ]
*/
protected function foreignKeyDataToObjects(array $data)
{
$retVal = [];

foreach ($data as $row) {
$name = $row['constraint_name'];

// for sqlite generate name
if ($name === null) {
$name = $row['table_name'] . '_' . implode('_', $row['column_name']) . '_foreign';
}

$obj = new stdClass();
$obj->constraint_name = $name;
$obj->table_name = $row['table_name'];
$obj->column_name = $row['column_name'];
$obj->foreign_table_name = $row['foreign_table_name'];
$obj->foreign_column_name = $row['foreign_column_name'];
$obj->on_delete = $row['on_delete'];
$obj->on_update = $row['on_update'];
$obj->match = $row['match'];

$retVal[$name] = $obj;
}

return $retVal;
}

/**
* Disables foreign key checks temporarily.
*/
Expand Down
32 changes: 19 additions & 13 deletions system/Database/Forge.php
Original file line number Diff line number Diff line change
Expand Up @@ -176,6 +176,13 @@ class Forge
*/
protected $dropIndexStr = 'DROP INDEX %s ON %s';

/**
* Foreign Key Allowed Actions
*
* @var array
*/
protected $fkAllowActions = ['CASCADE', 'SET NULL', 'NO ACTION', 'RESTRICT', 'SET DEFAULT'];

/**
* Constructor.
*/
Expand Down Expand Up @@ -401,7 +408,7 @@ public function addField($field)
*
* @throws DatabaseException
*/
public function addForeignKey($fieldName = '', string $tableName = '', $tableField = '', string $onUpdate = '', string $onDelete = '')
public function addForeignKey($fieldName = '', string $tableName = '', $tableField = '', string $onUpdate = '', string $onDelete = '', string $fkName = '')
{
$fieldName = (array) $fieldName;
$tableField = (array) $tableField;
Expand All @@ -425,6 +432,7 @@ public function addForeignKey($fieldName = '', string $tableName = '', $tableFie
'referenceField' => $tableField,
'onDelete' => strtoupper($onDelete),
'onUpdate' => strtoupper($onUpdate),
'fkName' => $fkName,
];

return $this;
Expand Down Expand Up @@ -480,7 +488,7 @@ public function dropForeignKey(string $table, string $foreignName)
$sql = sprintf(
(string) $this->dropConstraintStr,
$this->db->escapeIdentifiers($this->db->DBPrefix . $table),
$this->db->escapeIdentifiers($this->db->DBPrefix . $foreignName)
$this->db->escapeIdentifiers($foreignName)
);

if ($sql === '') {
Expand Down Expand Up @@ -1055,20 +1063,18 @@ protected function _processIndexes(string $table)
return $sqls;
}

/**
* Generates SQL to process foreign keys
*/
protected function _processForeignKeys(string $table): string
{
$sql = '';

$allowActions = [
'CASCADE',
'SET NULL',
'NO ACTION',
'RESTRICT',
'SET DEFAULT',
];

foreach ($this->foreignKeys as $fkey) {
$nameIndex = $table . '_' . implode('_', $fkey['field']) . '_foreign';
$nameIndex = $fkey['fkName'] !== '' ?
$fkey['fkName'] :
$table . '_' . implode('_', $fkey['field']) . ($this->db->DBDriver === 'OCI8' ? '_fk' : '_foreign');

$nameIndexFilled = $this->db->escapeIdentifiers($nameIndex);
$foreignKeyFilled = implode(', ', $this->db->escapeIdentifiers($fkey['field']));
$referenceTableFilled = $this->db->escapeIdentifiers($this->db->DBPrefix . $fkey['referenceTable']);
Expand All @@ -1077,11 +1083,11 @@ protected function _processForeignKeys(string $table): string
$formatSql = ",\n\tCONSTRAINT %s FOREIGN KEY (%s) REFERENCES %s(%s)";
$sql .= sprintf($formatSql, $nameIndexFilled, $foreignKeyFilled, $referenceTableFilled, $referenceFieldFilled);

if ($fkey['onDelete'] !== false && in_array($fkey['onDelete'], $allowActions, true)) {
if ($fkey['onDelete'] !== false && in_array($fkey['onDelete'], $this->fkAllowActions, true)) {
$sql .= ' ON DELETE ' . $fkey['onDelete'];
}

if ($fkey['onUpdate'] !== false && in_array($fkey['onUpdate'], $allowActions, true)) {
if ($this->db->DBDriver !== 'OCI8' && $fkey['onUpdate'] !== false && in_array($fkey['onUpdate'], $this->fkAllowActions, true)) {
$sql .= ' ON UPDATE ' . $fkey['onUpdate'];
}
}
Expand Down
59 changes: 31 additions & 28 deletions system/Database/MySQLi/Connection.php
Original file line number Diff line number Diff line change
Expand Up @@ -482,43 +482,46 @@ protected function _indexData(string $table): array
protected function _foreignKeyData(string $table): array
{
$sql = '
SELECT
tc.CONSTRAINT_NAME,
tc.TABLE_NAME,
kcu.COLUMN_NAME,
rc.REFERENCED_TABLE_NAME,
kcu.REFERENCED_COLUMN_NAME
FROM information_schema.TABLE_CONSTRAINTS AS tc
INNER JOIN information_schema.REFERENTIAL_CONSTRAINTS AS rc
ON tc.CONSTRAINT_NAME = rc.CONSTRAINT_NAME
AND tc.CONSTRAINT_SCHEMA = rc.CONSTRAINT_SCHEMA
INNER JOIN information_schema.KEY_COLUMN_USAGE AS kcu
ON tc.CONSTRAINT_NAME = kcu.CONSTRAINT_NAME
AND tc.CONSTRAINT_SCHEMA = kcu.CONSTRAINT_SCHEMA
WHERE
tc.CONSTRAINT_TYPE = ' . $this->escape('FOREIGN KEY') . ' AND
tc.TABLE_SCHEMA = ' . $this->escape($this->database) . ' AND
tc.TABLE_NAME = ' . $this->escape($table);
SELECT
tc.CONSTRAINT_NAME,
tc.TABLE_NAME,
kcu.COLUMN_NAME,
rc.REFERENCED_TABLE_NAME,
kcu.REFERENCED_COLUMN_NAME,
rc.DELETE_RULE,
rc.UPDATE_RULE,
rc.MATCH_OPTION
FROM information_schema.table_constraints AS tc
INNER JOIN information_schema.referential_constraints AS rc
ON tc.constraint_name = rc.constraint_name
AND tc.constraint_schema = rc.constraint_schema
INNER JOIN information_schema.key_column_usage AS kcu
ON tc.constraint_name = kcu.constraint_name
AND tc.constraint_schema = kcu.constraint_schema
WHERE
tc.constraint_type = ' . $this->escape('FOREIGN KEY') . ' AND
tc.table_schema = ' . $this->escape($this->database) . ' AND
tc.table_name = ' . $this->escape($table);

if (($query = $this->query($sql)) === false) {
throw new DatabaseException(lang('Database.failGetForeignKeyData'));
}
$query = $query->getResultObject();

$retVal = [];
$query = $query->getResultObject();
$indexes = [];

foreach ($query as $row) {
$obj = new stdClass();
$obj->constraint_name = $row->CONSTRAINT_NAME;
$obj->table_name = $row->TABLE_NAME;
$obj->column_name = $row->COLUMN_NAME;
$obj->foreign_table_name = $row->REFERENCED_TABLE_NAME;
$obj->foreign_column_name = $row->REFERENCED_COLUMN_NAME;

$retVal[] = $obj;
$indexes[$row->CONSTRAINT_NAME]['constraint_name'] = $row->CONSTRAINT_NAME;
$indexes[$row->CONSTRAINT_NAME]['table_name'] = $row->TABLE_NAME;
$indexes[$row->CONSTRAINT_NAME]['column_name'][] = $row->COLUMN_NAME;
$indexes[$row->CONSTRAINT_NAME]['foreign_table_name'] = $row->REFERENCED_TABLE_NAME;
$indexes[$row->CONSTRAINT_NAME]['foreign_column_name'][] = $row->REFERENCED_COLUMN_NAME;
$indexes[$row->CONSTRAINT_NAME]['on_delete'] = $row->DELETE_RULE;
$indexes[$row->CONSTRAINT_NAME]['on_update'] = $row->UPDATE_RULE;
$indexes[$row->CONSTRAINT_NAME]['match'] = $row->MATCH_OPTION;
}

return $retVal;
return $this->foreignKeyDataToObjects($indexes);
}

/**
Expand Down
55 changes: 28 additions & 27 deletions system/Database/OCI8/Connection.php
Original file line number Diff line number Diff line change
Expand Up @@ -384,43 +384,44 @@ protected function _indexData(string $table): array
protected function _foreignKeyData(string $table): array
{
$sql = 'SELECT
acc.constraint_name,
acc.table_name,
acc.column_name,
ccu.table_name foreign_table_name,
accu.column_name foreign_column_name
FROM all_cons_columns acc
JOIN all_constraints ac
ON acc.owner = ac.owner
AND acc.constraint_name = ac.constraint_name
JOIN all_constraints ccu
ON ac.r_owner = ccu.owner
AND ac.r_constraint_name = ccu.constraint_name
JOIN all_cons_columns accu
ON accu.constraint_name = ccu.constraint_name
AND accu.table_name = ccu.table_name
WHERE ac.constraint_type = ' . $this->escape('R') . '
AND acc.table_name = ' . $this->escape($table);
acc.constraint_name,
acc.table_name,
acc.column_name,
ccu.table_name foreign_table_name,
accu.column_name foreign_column_name,
ac.delete_rule
FROM all_cons_columns acc
JOIN all_constraints ac ON acc.owner = ac.owner
AND acc.constraint_name = ac.constraint_name
JOIN all_constraints ccu ON ac.r_owner = ccu.owner
AND ac.r_constraint_name = ccu.constraint_name
JOIN all_cons_columns accu ON accu.constraint_name = ccu.constraint_name
AND accu.position = acc.position
AND accu.table_name = ccu.table_name
WHERE ac.constraint_type = ' . $this->escape('R') . '
AND acc.table_name = ' . $this->escape($table);

$query = $this->query($sql);

if ($query === false) {
throw new DatabaseException(lang('Database.failGetForeignKeyData'));
}
$query = $query->getResultObject();

$retVal = [];
$query = $query->getResultObject();
$indexes = [];

foreach ($query as $row) {
$obj = new stdClass();
$obj->constraint_name = $row->CONSTRAINT_NAME;
$obj->table_name = $row->TABLE_NAME;
$obj->column_name = $row->COLUMN_NAME;
$obj->foreign_table_name = $row->FOREIGN_TABLE_NAME;
$obj->foreign_column_name = $row->FOREIGN_COLUMN_NAME;
$retVal[] = $obj;
$indexes[$row->CONSTRAINT_NAME]['constraint_name'] = $row->CONSTRAINT_NAME;
$indexes[$row->CONSTRAINT_NAME]['table_name'] = $row->TABLE_NAME;
$indexes[$row->CONSTRAINT_NAME]['column_name'][] = $row->COLUMN_NAME;
$indexes[$row->CONSTRAINT_NAME]['foreign_table_name'] = $row->FOREIGN_TABLE_NAME;
$indexes[$row->CONSTRAINT_NAME]['foreign_column_name'][] = $row->FOREIGN_COLUMN_NAME;
$indexes[$row->CONSTRAINT_NAME]['on_delete'] = $row->DELETE_RULE;
$indexes[$row->CONSTRAINT_NAME]['on_update'] = null;
$indexes[$row->CONSTRAINT_NAME]['match'] = null;
}

return $retVal;
return $this->foreignKeyDataToObjects($indexes);
}

/**
Expand Down
35 changes: 7 additions & 28 deletions system/Database/OCI8/Forge.php
Original file line number Diff line number Diff line change
Expand Up @@ -83,6 +83,13 @@ class Forge extends BaseForge
*/
protected $dropConstraintStr = 'ALTER TABLE %s DROP CONSTRAINT %s';

/**
* Foreign Key Allowed Actions
*
* @var array
*/
protected $fkAllowActions = ['CASCADE', 'SET NULL', 'NO ACTION'];

/**
* ALTER TABLE
*
Expand Down Expand Up @@ -272,32 +279,4 @@ protected function _dropTable(string $table, bool $ifExists, bool $cascade)

return $sql;
}

protected function _processForeignKeys(string $table): string
{
$sql = '';

$allowActions = [
'CASCADE',
'SET NULL',
'NO ACTION',
];

foreach ($this->foreignKeys as $fkey) {
$nameIndex = $table . '_' . implode('_', $fkey['field']) . '_fk';
$nameIndexFilled = $this->db->escapeIdentifiers($nameIndex);
$foreignKeyFilled = implode(', ', $this->db->escapeIdentifiers($fkey['field']));
$referenceTableFilled = $this->db->escapeIdentifiers($this->db->DBPrefix . $fkey['referenceTable']);
$referenceFieldFilled = implode(', ', $this->db->escapeIdentifiers($fkey['referenceField']));

$formatSql = ",\n\tCONSTRAINT %s FOREIGN KEY (%s) REFERENCES %s(%s)";
$sql .= sprintf($formatSql, $nameIndexFilled, $foreignKeyFilled, $referenceTableFilled, $referenceFieldFilled);

if ($fkey['onDelete'] !== false && in_array($fkey['onDelete'], $allowActions, true)) {
$sql .= ' ON DELETE ' . $fkey['onDelete'];
}
}

return $sql;
}
}
50 changes: 27 additions & 23 deletions system/Database/Postgre/Connection.php
Original file line number Diff line number Diff line change
Expand Up @@ -326,38 +326,42 @@ protected function _indexData(string $table): array
*/
protected function _foreignKeyData(string $table): array
{
$sql = 'SELECT
tc.constraint_name, tc.table_name, kcu.column_name,
ccu.table_name AS foreign_table_name,
ccu.column_name AS foreign_column_name
FROM information_schema.table_constraints AS tc
JOIN information_schema.key_column_usage AS kcu
ON tc.constraint_name = kcu.constraint_name
JOIN information_schema.constraint_column_usage AS ccu
ON ccu.constraint_name = tc.constraint_name
WHERE constraint_type = ' . $this->escape('FOREIGN KEY') . ' AND
tc.table_name = ' . $this->escape($table);
$sql = 'SELECT c.constraint_name,
x.table_name,
x.column_name,
y.table_name as foreign_table_name,
y.column_name as foreign_column_name,
c.delete_rule,
c.update_rule,
c.match_option
FROM information_schema.referential_constraints c
JOIN information_schema.key_column_usage x
on x.constraint_name = c.constraint_name
JOIN information_schema.key_column_usage y
on y.ordinal_position = x.position_in_unique_constraint
and y.constraint_name = c.unique_constraint_name
WHERE x.table_name = ' . $this->escape($table) .
'order by c.constraint_name, x.ordinal_position';

if (($query = $this->query($sql)) === false) {
throw new DatabaseException(lang('Database.failGetForeignKeyData'));
}

$query = $query->getResultObject();
$retVal = [];
$query = $query->getResultObject();
$indexes = [];

foreach ($query as $row) {
$obj = new stdClass();

$obj->constraint_name = $row->constraint_name;
$obj->table_name = $row->table_name;
$obj->column_name = $row->column_name;
$obj->foreign_table_name = $row->foreign_table_name;
$obj->foreign_column_name = $row->foreign_column_name;

$retVal[] = $obj;
$indexes[$row->constraint_name]['constraint_name'] = $row->constraint_name;
$indexes[$row->constraint_name]['table_name'] = $table;
$indexes[$row->constraint_name]['column_name'][] = $row->column_name;
$indexes[$row->constraint_name]['foreign_table_name'] = $row->foreign_table_name;
$indexes[$row->constraint_name]['foreign_column_name'][] = $row->foreign_column_name;
$indexes[$row->constraint_name]['on_delete'] = $row->delete_rule;
$indexes[$row->constraint_name]['on_update'] = $row->update_rule;
$indexes[$row->constraint_name]['match'] = $row->match_option;
}

return $retVal;
return $this->foreignKeyDataToObjects($indexes);
}

/**
Expand Down
Loading