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

feat: Improve schema grammar #842

Merged
merged 1 commit into from
Apr 11, 2024
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
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
69 changes: 68 additions & 1 deletion src/Oci8/Query/Processors/OracleProcessor.php
Original file line number Diff line number Diff line change
Expand Up @@ -198,7 +198,74 @@ public function processColumnListing($results)
public function processColumns($results)
{
return array_map(function ($result) {
return (array) $result;
$result = (object) $result;

$type = strtolower($result->type);
$precision = (int) $result->precision;
$places = (int) $result->places;
$length = (int) $result->data_length;

switch ($typeName = strtolower($result->type_name)) {
case 'number':
if ($precision === 19 && $places === 0) {
$type = 'bigint';
} elseif ($precision === 10 && $places === 0) {
$type = 'int';
} elseif ($precision === 5 && $places === 0) {
$type = 'smallint';
} elseif ($precision === 1 && $places === 0) {
$type = 'boolean';
} elseif ($places > 0) {
$type = 'decimal';
}

break;

case 'varchar':
case 'varchar2':
case 'nvarchar2':
case 'char':
case 'nchar':
$length = (int) $result->char_length;
break;
default:
$type = $typeName;
}

return [
'name' => strtolower($result->name),
'type_name' => strtolower($result->type_name),
'type' => $type,
'nullable' => (bool) $result->nullable,
'default' => $result->default,
'auto_increment' => (bool) $result->auto_increment,
'comment' => $result->comment != '' ? $result->comment : null,
'length' => $length,
'precision' => $precision,
];
}, $results);
}

/**
* Process the results of a columns query.
*
* @param array $results
* @return array
*/
public function processForeignKeys($results)
{
return array_map(function ($result) {
$result = (object) $result;

return [
'name' => strtolower($result->name),
'columns' => explode(',', strtolower($result->columns)),
'foreign_schema' => strtolower($result->foreign_schema),
'foreign_table' => strtolower($result->foreign_table),
'foreign_columns' => explode(',', strtolower($result->foreign_columns)),
'on_update' => strtolower($result->on_update),
'on_delete' => $result->on_delete,
];
}, $results);
}
}
51 changes: 42 additions & 9 deletions src/Oci8/Schema/Grammars/OracleGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -214,17 +214,50 @@ public function compileColumnExists($database, $table)
* @param string $table
* @return string
*/
public function compileColumns($table)
public function compileColumns($schema, $table)
{
return "select column_name as name,
nvl(data_type_mod, data_type) as type_name,
return "
select
t.column_name as name,
nvl(t.data_type_mod, data_type) as type_name,
null as auto_increment,
data_type as type,
data_length as length,
nullable,
data_default as \"default\"
from all_tab_cols where upper(table_name) = upper('{$table}')
and owner = (select sys_context( 'userenv', 'current_schema' ) from dual)";
t.data_type as type,
t.data_length,
t.char_length,
t.data_precision as precision,
t.data_scale as places,
decode(t.nullable, 'Y', 1, 0) as nullable,
t.data_default as \"default\",
c.comments as \"comment\"
from all_tab_cols t
left join all_col_comments c on t.owner = c.owner and t.table_name = c.table_name AND t.column_name = c.column_name
where upper(t.table_name) = upper('{$table}')
and upper(t.owner) = upper('{$schema}')
order by
t.column_id
";
}

public function compileForeignKeys($schema, $table)
{
return "
select
kc.constraint_name as name,
LISTAGG(kc.column_name, ',') WITHIN GROUP (ORDER BY kc.position) as columns,
rc.r_owner as foreign_schema,
kcr.table_name as foreign_table,
LISTAGG(kcr.column_name, ',') WITHIN GROUP (ORDER BY kcr.position) as foreign_columns,
rc.delete_rule AS \"on_delete\",
null AS \"on_update\"
from all_cons_columns kc
inner join all_constraints rc ON kc.constraint_name = rc.constraint_name
inner join all_cons_columns kcr ON kcr.constraint_name = rc.r_constraint_name
where kc.table_name = upper('{$table}')
and kc.owner = upper('{$schema}')
and rc.constraint_type = 'R'
group by
kc.constraint_name, rc.r_owner, kcr.table_name, kc.constraint_name, rc.delete_rule
";
}

/**
Expand Down
57 changes: 57 additions & 0 deletions src/Oci8/Schema/OracleBuilder.php
Original file line number Diff line number Diff line change
Expand Up @@ -161,4 +161,61 @@ public function getColumnListing($table)

return $this->connection->getPostProcessor()->processColumnListing($results);
}

/**
* Get the columns for a given table.
*
* @param string $table
* @return array
*/
public function getColumns($table)
{
[$schema, $table] = $this->parseSchemaAndTable($table);

$table = $this->connection->getTablePrefix().$table;

return $this->connection->getPostProcessor()->processColumns(
$this->connection->selectFromWriteConnection($this->grammar->compileColumns($schema, $table))
);
}

/**
* Get the foreign keys for a given table.
*
* @param string $table
* @return array
*/
public function getForeignKeys($table)
{
[$schema, $table] = $this->parseSchemaAndTable($table);

$table = $this->connection->getTablePrefix().$table;

return $this->connection->getPostProcessor()->processForeignKeys(
$this->connection->selectFromWriteConnection($this->grammar->compileForeignKeys($schema, $table))
);
}

/**
* Parse the database object reference and extract the schema and table.
*
* @param string $reference
* @return array
*/
protected function parseSchemaAndTable($reference)
{
$parts = explode('.', $reference);

// We will use the default schema unless the schema has been specified in the
// query. If the schema has been specified in the query then we can use it
// instead of a default schema configured in the connection search path.
$schema = $this->connection->getConfig('username');

if (count($parts) === 2) {
$schema = $parts[0];
array_shift($parts);
}

return [$schema, $parts[0]];
}
}
54 changes: 54 additions & 0 deletions tests/Database/Oci8SchemaGrammarTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -299,6 +299,60 @@ public function testCompileColumnExistsMethod()
$this->assertEquals($expected, $sql);
}

public function testCompileColumnsMethod()
{
$grammar = $this->getGrammar();
$expected = '
select
t.column_name as name,
nvl(t.data_type_mod, data_type) as type_name,
null as auto_increment,
t.data_type as type,
t.data_length,
t.char_length,
t.data_precision as precision,
t.data_scale as places,
decode(t.nullable, \'Y\', 1, 0) as nullable,
t.data_default as "default",
c.comments as "comment"
from all_tab_cols t
left join all_col_comments c on t.owner = c.owner and t.table_name = c.table_name AND t.column_name = c.column_name
where upper(t.table_name) = upper(\'test_table\')
and upper(t.owner) = upper(\'schema\')
order by
t.column_id
';

$sql = $grammar->compileColumns('schema', 'test_table');
$this->assertEquals($expected, $sql);
}

public function testCompileForeignKeysMethod()
{
$grammar = $this->getGrammar();
$expected = '
select
kc.constraint_name as name,
LISTAGG(kc.column_name, \',\') WITHIN GROUP (ORDER BY kc.position) as columns,
rc.r_owner as foreign_schema,
kcr.table_name as foreign_table,
LISTAGG(kcr.column_name, \',\') WITHIN GROUP (ORDER BY kcr.position) as foreign_columns,
rc.delete_rule AS "on_delete",
null AS "on_update"
from all_cons_columns kc
inner join all_constraints rc ON kc.constraint_name = rc.constraint_name
inner join all_cons_columns kcr ON kcr.constraint_name = rc.r_constraint_name
where kc.table_name = upper(\'test_table\')
and kc.owner = upper(\'schema\')
and rc.constraint_type = \'R\'
group by
kc.constraint_name, rc.r_owner, kcr.table_name, kc.constraint_name, rc.delete_rule
';

$sql = $grammar->compileForeignKeys('schema', 'test_table');
$this->assertEquals($expected, $sql);
}

public function testDropTableWithPrefix()
{
$blueprint = new Blueprint('users');
Expand Down
Loading
Loading