Skip to content

Commit

Permalink
gh #8160 : Replacing invalid constraint query and tuning performance
Browse files Browse the repository at this point in the history
The original query was joining a pg view referential_constraints, that was returning multiple invalid rows. It has now been converted to use the pg_catalog tables and performance has been tuned to .2ms
  • Loading branch information
David Binney committed Mar 4, 2016
1 parent b2a62ae commit 1b72331
Showing 1 changed file with 24 additions and 37 deletions.
61 changes: 24 additions & 37 deletions src/Database/Schema/PostgresSchema.php
Expand Up @@ -276,40 +276,27 @@ protected function _convertConstraint($table, $name, $type, $row)
public function describeForeignKeySql($tableName, $config)
{
$sql = "SELECT
rc.constraint_name AS name,
tc.constraint_type AS type,
kcu.column_name,
rc.match_option AS match_type,
rc.update_rule AS on_update,
rc.delete_rule AS on_delete,
kc.table_name AS references_table,
kc.column_name AS references_field
FROM information_schema.referential_constraints rc
JOIN information_schema.table_constraints tc
ON tc.constraint_name = rc.constraint_name
AND tc.constraint_schema = rc.constraint_schema
AND tc.constraint_name = rc.constraint_name
AND tc.table_schema = rc.constraint_schema
JOIN information_schema.key_column_usage kcu
ON kcu.constraint_name = rc.constraint_name
AND kcu.constraint_schema = rc.constraint_schema
AND kcu.constraint_name = rc.constraint_name
AND kcu.constraint_schema = rc.constraint_schema
JOIN information_schema.key_column_usage kc
ON kc.ordinal_position = kcu.position_in_unique_constraint
AND kc.constraint_name = rc.unique_constraint_name
AND kc.constraint_schema = rc.constraint_schema
WHERE kcu.table_name = ?
AND rc.constraint_schema = ?
AND tc.constraint_type = 'FOREIGN KEY'
ORDER BY rc.constraint_name, kcu.ordinal_position";
c.conname AS name,
c.contype AS type,
a.attname AS column_name,
c.confmatchtype AS match_type,
c.confupdtype AS on_update,
c.confdeltype AS on_delete,
c.confrelid::regclass AS references_table,
ab.attname AS references_field
FROM pg_catalog.pg_namespace n, pg_catalog.pg_class cl, pg_catalog.pg_constraint c, pg_catalog.pg_attribute a, pg_catalog.pg_attribute ab
WHERE n.oid = c.connamespace
AND cl.oid = c.conrelid
AND c.conrelid::regclass = a.attrelid::regclass
AND c.conkey[1] = a.attnum
AND a.attrelid = cl.oid
AND ab.attrelid = cl.oid
AND a.attrelid = ab.attrelid
AND a.attnum = ab.attnum
AND c.conrelid = ?::regclass
AND c.contype='f'
AND n.nspname = ?
ORDER BY c.conname, a.attnum";

$schema = empty($config['schema']) ? 'public' : $config['schema'];
return [$sql, [$tableName, $schema]];
Expand All @@ -335,13 +322,13 @@ public function convertForeignKeyDescription(Table $table, $row)
*/
protected function _convertOnClause($clause)
{
if ($clause === 'RESTRICT') {
if ($clause === 'r') {
return Table::ACTION_RESTRICT;
}
if ($clause === 'NO ACTION') {
if ($clause === 'a') {
return Table::ACTION_NO_ACTION;
}
if ($clause === 'CASCADE') {
if ($clause === 'c') {
return Table::ACTION_CASCADE;
}
return Table::ACTION_SET_NULL;
Expand Down

0 comments on commit 1b72331

Please sign in to comment.