Skip to content

Commit

Permalink
removed processing of pgsql unique index with expressions; added find…
Browse files Browse the repository at this point in the history
…UniqueIndexes for oci and mssql; cleaned up oci and mssql schema
  • Loading branch information
nineinchnick authored and Jan Was committed Mar 30, 2015
1 parent 62a35cd commit 0b7bb1d
Show file tree
Hide file tree
Showing 3 changed files with 148 additions and 83 deletions.
57 changes: 50 additions & 7 deletions framework/db/mssql/Schema.php
Original file line number Diff line number Diff line change
Expand Up @@ -283,10 +283,12 @@ protected function findColumns($table)
}

/**
* Collects the primary key column details for the given table.
* @param TableSchema $table the table metadata
* Collects the constraint details for the given table and constraint type.
* @param TableSchema $table
* @param string $type either PRIMARY KEY or UNIQUE
* @return array each entry contains index_name and field_name
*/
protected function findPrimaryKeys($table)
protected function findTableConstraints($table, $type)
{
$keyColumnUsageTableName = 'INFORMATION_SCHEMA.KEY_COLUMN_USAGE';
$tableConstraintsTableName = 'INFORMATION_SCHEMA.TABLE_CONSTRAINTS';
Expand All @@ -299,20 +301,38 @@ protected function findPrimaryKeys($table)

$sql = <<<SQL
SELECT
[kcu].[constraint_name] AS [index_name],
[kcu].[column_name] AS [field_name]
FROM {$keyColumnUsageTableName} AS [kcu]
LEFT JOIN {$tableConstraintsTableName} AS [tc] ON
[kcu].[table_name] = [tc].[table_name] AND
[kcu].[constraint_name] = [tc].[constraint_name]
WHERE
[tc].[constraint_type] = 'PRIMARY KEY' AND
[tc].[constraint_type] = :type AND
[kcu].[table_name] = :tableName AND
[kcu].[table_schema] = :schemaName
SQL;

$table->primaryKey = $this->db
->createCommand($sql, [':tableName' => $table->name, ':schemaName' => $table->schemaName])
->queryColumn();
return $this->db
->createCommand($sql, [
':tableName' => $table->name,
':schemaName' => $table->schemaName,
':type' => $type,
])
->queryAll();
}

/**
* Collects the primary key column details for the given table.
* @param TableSchema $table the table metadata
*/
protected function findPrimaryKeys($table)
{
$result = [];
foreach ($this->findTableConstraints($table, 'PRIMARY KEY') as $row) {
$result[] = $row['field_name'];
}
$table->primaryKey = $result;
}

/**
Expand Down Expand Up @@ -376,4 +396,27 @@ protected function findTableNames($schema = '')

return $this->db->createCommand($sql, [':schema' => $schema])->queryColumn();
}

/**
* Returns all unique indexes for the given table.
* Each array element is of the following structure:
*
* ~~~
* [
* 'IndexName1' => ['col1' [, ...]],
* 'IndexName2' => ['col2' [, ...]],
* ]
* ~~~
*
* @param TableSchema $table the table metadata
* @return array all unique indexes for the given table.
*/
public function findUniqueIndexes($table)
{
$result = [];
foreach ($this->findTableConstraints($table, 'UNIQUE') as $row) {
$result[$row['index_name']][] = $row['field_name'];
}
return $result;
}
}
140 changes: 89 additions & 51 deletions framework/db/oci/Schema.php
Original file line number Diff line number Diff line change
Expand Up @@ -110,10 +110,7 @@ protected function resolveTableNames($table, $name)
*/
protected function findColumns($table)
{
$schemaName = $table->schemaName;
$tableName = $table->name;

$sql = <<<EOD
$sql = <<<SQL
SELECT a.column_name, a.data_type, a.data_precision, a.data_scale, a.data_length,
a.nullable, a.data_default,
( SELECT D.constraint_type
Expand All @@ -128,14 +125,17 @@ protected function findColumns($table)
inner join ALL_OBJECTS B ON b.owner = a.owner and ltrim(B.OBJECT_NAME) = ltrim(A.TABLE_NAME)
LEFT JOIN all_col_comments com ON (A.owner = com.owner AND A.table_name = com.table_name AND A.column_name = com.column_name)
WHERE
a.owner = '{$schemaName}'
and (b.object_type = 'TABLE' or b.object_type = 'VIEW')
and b.object_name = '{$tableName}'
a.owner = :schemaName
and (b.object_type IN ('TABLE', 'VIEW'))
and b.object_name = :tableName
ORDER by a.column_id
EOD;
SQL;

try {
$columns = $this->db->createCommand($sql)->queryAll();
$columns = $this->db->createCommand($sql, [
':tableName' => $table->name,
':schemaName' => $table->schemaName,
])->queryAll();
} catch (\Exception $e) {
return false;
}
Expand All @@ -161,19 +161,22 @@ protected function findColumns($table)
/**
* Sequence name of table
*
* @param $tablename
* @param $tableName
* @internal param \yii\db\TableSchema $table ->name the table schema
* @return string whether the sequence exists
*/
protected function getTableSequenceName($tablename)
protected function getTableSequenceName($tableName)
{
$seq_name_sql="select ud.referenced_name as sequence_name
from user_dependencies ud
join user_triggers ut on (ut.trigger_name = ud.name)
where ut.table_name='{$tablename}'
and ud.type='TRIGGER'
and ud.referenced_type='SEQUENCE'";
$sequenceName = $this->db->createCommand($seq_name_sql)->queryScalar();

$seq_name_sql = <<<SQL
SELECT ud.referenced_name as sequence_name
FROM user_dependencies ud
JOIN user_triggers ut on (ut.trigger_name = ud.name)
WHERE ut.table_name = :tableName
AND ud.type='TRIGGER'
AND ud.referenced_type='SEQUENCE'
SQL;
$sequenceName = $this->db->createCommand($seq_name_sql, [':tableName' => $tableName])->queryScalar();
return $sequenceName === false ? null : $sequenceName;
}

Expand Down Expand Up @@ -249,35 +252,35 @@ protected function createColumn($column)
*/
protected function findConstraints($table)
{
$sql = <<<EOD
SELECT D.constraint_type as CONSTRAINT_TYPE, C.COLUMN_NAME, C.position, D.constraint_name, D.r_constraint_name,
E.table_name as table_ref, f.column_name as column_ref,
C.table_name
FROM ALL_CONS_COLUMNS C
inner join ALL_constraints D on D.OWNER = C.OWNER and D.constraint_name = C.constraint_name
left join ALL_constraints E on E.OWNER = D.r_OWNER and E.constraint_name = D.r_constraint_name
left join ALL_cons_columns F on F.OWNER = E.OWNER and F.constraint_name = E.constraint_name and F.position = c.position
WHERE C.OWNER = '{$table->schemaName}'
and C.table_name = '{$table->name}'
and D.constraint_type <> 'P'
order by d.constraint_name, c.position
EOD;
$command = $this->db->createCommand($sql);
$constraints = [];
$sql = <<<SQL
SELECT D.constraint_type as CONSTRAINT_TYPE, C.COLUMN_NAME, C.position, D.r_constraint_name,
E.table_name as table_ref, f.column_name as column_ref,
C.table_name
FROM ALL_CONS_COLUMNS C
INNER JOIN ALL_constraints D on D.OWNER = C.OWNER and D.constraint_name = C.constraint_name
LEFT JOIN ALL_constraints E on E.OWNER = D.r_OWNER and E.constraint_name = D.r_constraint_name
LEFT JOIN ALL_cons_columns F on F.OWNER = E.OWNER and F.constraint_name = E.constraint_name and F.position = c.position
WHERE C.OWNER = :schemaName
AND C.table_name = :tableName
AND D.constraint_type = 'R'
ORDER BY d.constraint_name, c.position
SQL;
$command = $this->db->createCommand($sql, [
':tableName' => $table->name,
':schemaName' => $table->schemaName,
]);
foreach ($command->queryAll() as $row) {
if ($this->db->slavePdo->getAttribute(\PDO::ATTR_CASE) === \PDO::CASE_LOWER) {
$row = array_change_key_case($row, CASE_UPPER);
}
if ($row['CONSTRAINT_TYPE'] === 'R') {
$name = $row['CONSTRAINT_NAME'];
if (!isset($constraints[$name])) {
$constraints[$name] = [
'tableName' => $row["TABLE_REF"],
'columns' => [],
];
}
$constraints[$name]['columns'][$row["COLUMN_NAME"]] = $row["COLUMN_REF"];
$name = $row['CONSTRAINT_NAME'];
if (!isset($constraints[$name])) {
$constraints[$name] = [
'tableName' => $row["TABLE_REF"],
'columns' => [],
];
}
$constraints[$name]['columns'][$row["COLUMN_NAME"]] = $row["COLUMN_REF"];
}
foreach ($constraints as $constraint) {
$table->foreignKeys[] = array_merge([$constraint['tableName']], $constraint['columns']);
Expand All @@ -290,17 +293,17 @@ protected function findConstraints($table)
protected function findTableNames($schema = '')
{
if ($schema === '') {
$sql = <<<EOD
SELECT table_name, '{$schema}' as table_schema FROM user_tables
EOD;
$sql = <<<SQL
SELECT table_name FROM user_tables
SQL;
$command = $this->db->createCommand($sql);
} else {
$sql = <<<EOD
SELECT object_name as table_name, owner as table_schema FROM all_objects
$sql = <<<SQL
SELECT object_name as table_name
FROM all_objects
WHERE object_type = 'TABLE' AND owner=:schema
EOD;
$command = $this->db->createCommand($sql);
$command->bindParam(':schema', $schema);
SQL;
$command = $this->db->createCommand($sql, [':schema' => $schema]);
}

$rows = $command->queryAll();
Expand All @@ -311,10 +314,45 @@ protected function findTableNames($schema = '')
}
$names[] = $row['TABLE_NAME'];
}

return $names;
}

/**
* Returns all unique indexes for the given table.
* Each array element is of the following structure:
*
* ~~~
* [
* 'IndexName1' => ['col1' [, ...]],
* 'IndexName2' => ['col2' [, ...]],
* ]
* ~~~
*
* @param TableSchema $table the table metadata
* @return array all unique indexes for the given table.
*/
public function findUniqueIndexes($table)
{
$query = <<<SQL
SELECT dic.INDEX_NAME, dic.COLUMN_NAME
FROM ALL_INDEXES di
INNER JOIN ALL_IND_COLUMNS dic ON di.TABLE_NAME = dic.TABLE_NAME AND di.INDEX_NAME = dic.INDEX_NAME
WHERE di.UNIQUENESS = 'UNIQUE'
AND dic.TABLE_OWNER = :schemaName
AND dic.TABLE_NAME = :tableName
ORDER BY dic.TABLE_NAME, dic.INDEX_NAME, dic.COLUMN_POSITION
SQL;
$result = [];
$command = $this->db->createCommand($query, [
':tableName' => $table->name,
':schemaName' => $table->schemaName,
]);
foreach ($command->queryAll() as $row) {
$result[$row['INDEX_NAME']][] = $row['COLUMN_NAME'];
}
return $result;
}

/**
* Extracts the data types for the given column
* @param ColumnSchema $column
Expand Down
34 changes: 9 additions & 25 deletions framework/db/pgsql/Schema.php
Original file line number Diff line number Diff line change
Expand Up @@ -243,7 +243,7 @@ protected function findConstraints($table)
/**
* Gets information about given table unique indexes.
* @param TableSchema $table the table metadata
* @return array with index names, columns and if it is an expression tree
* @return array with index and column names
*/
protected function getUniqueIndexInformation($table)
{
Expand All @@ -253,21 +253,15 @@ protected function getUniqueIndexInformation($table)
$sql = <<<SQL
SELECT
i.relname as indexname,
ARRAY(
SELECT pg_get_indexdef(idx.indexrelid, k + 1, True)
FROM generate_subscripts(idx.indkey, 1) AS k
ORDER BY k
) AS indexcolumns,
idx.indexprs IS NOT NULL AS indexprs
pg_get_indexdef(idx.indexrelid, k + 1, TRUE) AS columnname
FROM pg_index idx
INNER JOIN generate_subscripts(idx.indkey, 1) AS k ON 1=1
INNER JOIN pg_class i ON i.oid = idx.indexrelid
INNER JOIN pg_class c ON c.oid = idx.indrelid
INNER JOIN pg_namespace ns ON c.relnamespace = ns.oid
WHERE idx.indisprimary != True
AND idx.indisunique = True
AND c.relname = {$tableName}
AND ns.nspname = {$tableSchema}
;
WHERE idx.indisprimary = FALSE AND idx.indisunique = TRUE
AND c.relname = {$tableName} AND ns.nspname = {$tableSchema}
ORDER BY i.relname, k
SQL;

return $this->db->createCommand($sql)->queryAll();
Expand All @@ -289,21 +283,11 @@ protected function getUniqueIndexInformation($table)
*/
public function findUniqueIndexes($table)
{
$indexes = $this->getUniqueIndexInformation($table);
$uniqueIndexes = [];

foreach ($indexes as $index) {
$indexName = $index['indexname'];

if ($index['indexprs']) {
// Index is an expression like "lower(colname::text)"
$indexColumns = preg_replace("/.*\(([^\:]+).*/mi", "$1", $index['indexcolumns']);
} else {
$indexColumns = array_map('trim', explode(',', str_replace(['{', '}', '"', '\\'], '', $index['indexcolumns'])));
}

$uniqueIndexes[$indexName] = $indexColumns;

$rows = $this->getUniqueIndexInformation($table);
foreach ($rows as $row) {
$uniqueIndexes[$row['indexname']][] = $row['columnname'];
}

return $uniqueIndexes;
Expand Down

0 comments on commit 0b7bb1d

Please sign in to comment.