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

[11.x] Add support for specifying schema name on SQL Server #49965

Merged
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
2 changes: 2 additions & 0 deletions src/Illuminate/Database/Schema/Grammars/PostgresGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -1093,6 +1093,8 @@ protected function modifyDefault(Blueprint $blueprint, Fluent $column)
if (! $column->autoIncrement || ! is_null($column->generatedAs)) {
return is_null($column->default) ? 'drop default' : 'set default '.$this->getDefaultValue($column->default);
}

return null;
}

if (! is_null($column->default)) {
Expand Down
35 changes: 21 additions & 14 deletions src/Illuminate/Database/Schema/Grammars/SqlServerGrammar.php
Original file line number Diff line number Diff line change
Expand Up @@ -73,7 +73,7 @@ public function compileDropDatabaseIfExists($name)
*/
public function compileTables()
{
return 'select t.name as name, SCHEMA_NAME(t.schema_id) as [schema], sum(u.total_pages) * 8 * 1024 as size '
return 'select t.name as name, schema_name(t.schema_id) as [schema], sum(u.total_pages) * 8 * 1024 as size '
.'from sys.tables as t '
.'join sys.partitions as p on p.object_id = t.object_id '
.'join sys.allocation_units as u on u.container_id = p.hobt_id '
Expand All @@ -88,18 +88,19 @@ public function compileTables()
*/
public function compileViews()
{
return 'select name, SCHEMA_NAME(v.schema_id) as [schema], definition from sys.views as v '
return 'select name, schema_name(v.schema_id) as [schema], definition from sys.views as v '
.'inner join sys.sql_modules as m on v.object_id = m.object_id '
.'order by name';
}

/**
* Compile the query to determine the columns.
*
* @param string $schema
* @param string $table
* @return string
*/
public function compileColumns($table)
public function compileColumns($schema, $table)
{
return sprintf(
'select col.name, type.name as type_name, '
Expand All @@ -113,19 +114,21 @@ public function compileColumns($table)
.'join sys.schemas as scm on obj.schema_id = scm.schema_id '
.'left join sys.default_constraints def on col.default_object_id = def.object_id and col.object_id = def.parent_object_id '
."left join sys.extended_properties as prop on obj.object_id = prop.major_id and col.column_id = prop.minor_id and prop.name = 'MS_Description' "
."where obj.type in ('U', 'V') and obj.name = %s and scm.name = SCHEMA_NAME() "
."where obj.type in ('U', 'V') and obj.name = %s and scm.name = %s "
.'order by col.column_id',
$this->quoteString($table),
$schema ? $this->quoteString($schema) : 'schema_name()',
);
}

/**
* Compile the query to determine the indexes.
*
* @param string $schema
* @param string $table
* @return string
*/
public function compileIndexes($table)
public function compileIndexes($schema, $table)
{
return sprintf(
"select idx.name as name, string_agg(col.name, ',') within group (order by idxcol.key_ordinal) as columns, "
Expand All @@ -135,19 +138,21 @@ public function compileIndexes($table)
.'join sys.schemas as scm on tbl.schema_id = scm.schema_id '
.'join sys.index_columns as idxcol on idx.object_id = idxcol.object_id and idx.index_id = idxcol.index_id '
.'join sys.columns as col on idxcol.object_id = col.object_id and idxcol.column_id = col.column_id '
.'where tbl.name = %s and scm.name = SCHEMA_NAME() '
.'where tbl.name = %s and scm.name = %s '
.'group by idx.name, idx.type_desc, idx.is_unique, idx.is_primary_key',
$this->quoteString($table),
$schema ? $this->quoteString($schema) : 'schema_name()',
);
}

/**
* Compile the query to determine the foreign keys.
*
* @param string $schema
* @param string $table
* @return string
*/
public function compileForeignKeys($table)
public function compileForeignKeys($schema, $table)
{
return sprintf(
'select fk.name as name, '
Expand All @@ -164,9 +169,10 @@ public function compileForeignKeys($table)
.'join sys.tables as ft on ft.object_id = fk.referenced_object_id '
.'join sys.schemas as fs on ft.schema_id = fs.schema_id '
.'join sys.columns as fc on fkc.referenced_object_id = fc.object_id and fkc.referenced_column_id = fc.column_id '
.'where lt.name = %s and ls.name = SCHEMA_NAME() '
.'where lt.name = %s and ls.name = %s '
.'group by fk.name, fs.name, ft.name, fk.update_referential_action_desc, fk.delete_referential_action_desc',
$this->quoteString($table)
$this->quoteString($table),
$schema ? $this->quoteString($schema) : 'schema_name()',
);
}

Expand Down Expand Up @@ -351,8 +357,8 @@ public function compileDrop(Blueprint $blueprint, Fluent $command)
*/
public function compileDropIfExists(Blueprint $blueprint, Fluent $command)
{
return sprintf('if exists (select * from sys.sysobjects where id = object_id(%s, \'U\')) drop table %s',
"'".str_replace("'", "''", $this->getTablePrefix().$blueprint->getTable())."'",
return sprintf('if object_id(%s, \'U\') is not null drop table %s',
$this->quoteString($this->getTablePrefix().$blueprint->getTable()),
$this->wrapTable($blueprint)
);
}
Expand Down Expand Up @@ -396,12 +402,13 @@ public function compileDropDefaultConstraint(Blueprint $blueprint, Fluent $comma
? "'".collect($blueprint->getChangedColumns())->pluck('name')->implode("','")."'"
: "'".implode("','", $command->columns)."'";

$tableName = $this->getTablePrefix().$blueprint->getTable();
$table = $this->wrapTable($blueprint);
$tableName = $this->quoteString($this->getTablePrefix().$blueprint->getTable());

$sql = "DECLARE @sql NVARCHAR(MAX) = '';";
$sql .= "SELECT @sql += 'ALTER TABLE [dbo].[{$tableName}] DROP CONSTRAINT ' + OBJECT_NAME([default_object_id]) + ';' ";
$sql .= "SELECT @sql += 'ALTER TABLE $table DROP CONSTRAINT ' + OBJECT_NAME([default_object_id]) + ';' ";
$sql .= 'FROM sys.columns ';
$sql .= "WHERE [object_id] = OBJECT_ID('[dbo].[{$tableName}]') AND [name] in ({$columns}) AND [default_object_id] <> 0;";
$sql .= "WHERE [object_id] = OBJECT_ID($tableName) AND [name] in ($columns) AND [default_object_id] <> 0;";
$sql .= 'EXEC(@sql)';

return $sql;
Expand Down
24 changes: 23 additions & 1 deletion src/Illuminate/Database/Schema/PostgresBuilder.php
Original file line number Diff line number Diff line change
Expand Up @@ -59,6 +59,28 @@ public function hasTable($table)
return false;
}

/**
* Determine if the given view exists.
*
* @param string $view
* @return bool
*/
public function hasView($view)
{
[$schema, $view] = $this->parseSchemaAndTable($view);

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

foreach ($this->getViews() as $value) {
if (strtolower($view) === strtolower($value['name'])
&& strtolower($schema) === strtolower($value['schema'])) {
return true;
}
}

return false;
}

/**
* Get the user-defined types that belong to the database.
*
Expand Down Expand Up @@ -239,7 +261,7 @@ protected function parseSchemaAndTable($reference)
if (count($parts) > 2) {
$database = $parts[0];

throw new InvalidArgumentException("Using 3-parts reference is not supported, you may use `Schema::connection('$database')` instead.");
throw new InvalidArgumentException("Using three-part reference is not supported, you may use `Schema::connection('$database')` instead.");
}

// We will use the default schema unless the schema has been specified in the
Expand Down
116 changes: 116 additions & 0 deletions src/Illuminate/Database/Schema/SqlServerBuilder.php
Original file line number Diff line number Diff line change
Expand Up @@ -30,6 +30,50 @@ public function dropDatabaseIfExists($name)
);
}

/**
* Determine if the given table exists.
*
* @param string $table
* @return bool
*/
public function hasTable($table)
{
[$schema, $table] = $this->parseSchemaAndTable($table);

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

foreach ($this->getTables() as $value) {
if (strtolower($table) === strtolower($value['name'])
&& strtolower($schema) === strtolower($value['schema'])) {
return true;
}
}

return false;
}

/**
* Determine if the given view exists.
*
* @param string $view
* @return bool
*/
public function hasView($view)
{
[$schema, $view] = $this->parseSchemaAndTable($view);

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

foreach ($this->getViews() as $value) {
if (strtolower($view) === strtolower($value['name'])
&& strtolower($schema) === strtolower($value['schema'])) {
return true;
}
}

return false;
}

/**
* Drop all tables from the database.
*
Expand All @@ -51,4 +95,76 @@ public function dropAllViews()
{
$this->connection->statement($this->grammar->compileDropAllViews());
}

/**
* 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;

$results = $this->connection->selectFromWriteConnection(
$this->grammar->compileColumns($schema, $table)
);

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

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

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

return $this->connection->getPostProcessor()->processIndexes(
$this->connection->selectFromWriteConnection($this->grammar->compileIndexes($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 = array_pad(explode('.', $reference, 2), -2, 'dbo');

if (str_contains($parts[1], '.')) {
$database = $parts[0];

throw new InvalidArgumentException("Using three-part reference is not supported, you may use `Schema::connection('$database')` instead.");
}

return $parts;
}
}
8 changes: 4 additions & 4 deletions tests/Database/DatabaseSqlServerSchemaGrammarTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -83,14 +83,14 @@ public function testDropTableIfExists()
$statements = $blueprint->toSql($this->getConnection(), $this->getGrammar());

$this->assertCount(1, $statements);
$this->assertSame('if exists (select * from sys.sysobjects where id = object_id(\'users\', \'U\')) drop table "users"', $statements[0]);
$this->assertSame('if object_id(N\'users\', \'U\') is not null drop table "users"', $statements[0]);

$blueprint = new Blueprint('users');
$blueprint->dropIfExists();
$statements = $blueprint->toSql($this->getConnection(), $this->getGrammar()->setTablePrefix('prefix_'));

$this->assertCount(1, $statements);
$this->assertSame('if exists (select * from sys.sysobjects where id = object_id(\'prefix_users\', \'U\')) drop table "prefix_users"', $statements[0]);
$this->assertSame('if object_id(N\'prefix_users\', \'U\') is not null drop table "prefix_users"', $statements[0]);
}

public function testDropColumn()
Expand Down Expand Up @@ -124,7 +124,7 @@ public function testDropColumnDropsCreatesSqlToDropDefaultConstraints()
$statements = $blueprint->toSql($this->getConnection(), $this->getGrammar());

$this->assertCount(1, $statements);
$this->assertSame("DECLARE @sql NVARCHAR(MAX) = '';SELECT @sql += 'ALTER TABLE [dbo].[foo] DROP CONSTRAINT ' + OBJECT_NAME([default_object_id]) + ';' FROM sys.columns WHERE [object_id] = OBJECT_ID('[dbo].[foo]') AND [name] in ('bar') AND [default_object_id] <> 0;EXEC(@sql);alter table \"foo\" drop column \"bar\"", $statements[0]);
$this->assertSame("DECLARE @sql NVARCHAR(MAX) = '';SELECT @sql += 'ALTER TABLE \"foo\" DROP CONSTRAINT ' + OBJECT_NAME([default_object_id]) + ';' FROM sys.columns WHERE [object_id] = OBJECT_ID(N'foo') AND [name] in ('bar') AND [default_object_id] <> 0;EXEC(@sql);alter table \"foo\" drop column \"bar\"", $statements[0]);
}

public function testDropPrimary()
Expand Down Expand Up @@ -185,7 +185,7 @@ public function testDropConstrainedForeignId()

$this->assertCount(2, $statements);
$this->assertSame('alter table "users" drop constraint "users_foo_foreign"', $statements[0]);
$this->assertSame('DECLARE @sql NVARCHAR(MAX) = \'\';SELECT @sql += \'ALTER TABLE [dbo].[users] DROP CONSTRAINT \' + OBJECT_NAME([default_object_id]) + \';\' FROM sys.columns WHERE [object_id] = OBJECT_ID(\'[dbo].[users]\') AND [name] in (\'foo\') AND [default_object_id] <> 0;EXEC(@sql);alter table "users" drop column "foo"', $statements[1]);
$this->assertSame('DECLARE @sql NVARCHAR(MAX) = \'\';SELECT @sql += \'ALTER TABLE "users" DROP CONSTRAINT \' + OBJECT_NAME([default_object_id]) + \';\' FROM sys.columns WHERE [object_id] = OBJECT_ID(N\'users\') AND [name] in (\'foo\') AND [default_object_id] <> 0;EXEC(@sql);alter table "users" drop column "foo"', $statements[1]);
}

public function testDropTimestamps()
Expand Down
10 changes: 5 additions & 5 deletions tests/Integration/Database/DatabaseSchemaBlueprintTest.php
Original file line number Diff line number Diff line change
Expand Up @@ -190,7 +190,7 @@ public function testNativeColumnModifyingOnSqlServer()
});

$this->assertEquals([
"DECLARE @sql NVARCHAR(MAX) = '';SELECT @sql += 'ALTER TABLE [dbo].[users] DROP CONSTRAINT ' + OBJECT_NAME([default_object_id]) + ';' FROM sys.columns WHERE [object_id] = OBJECT_ID('[dbo].[users]') AND [name] in ('added_at') AND [default_object_id] <> 0;EXEC(@sql)",
"DECLARE @sql NVARCHAR(MAX) = '';SELECT @sql += 'ALTER TABLE \"users\" DROP CONSTRAINT ' + OBJECT_NAME([default_object_id]) + ';' FROM sys.columns WHERE [object_id] = OBJECT_ID(N'users') AND [name] in ('added_at') AND [default_object_id] <> 0;EXEC(@sql)",
'alter table "users" alter column "added_at" datetime2(4) not null',
'alter table "users" add default CURRENT_TIMESTAMP for "added_at"',
], $blueprint->toSql($connection, new SqlServerGrammar));
Expand All @@ -200,7 +200,7 @@ public function testNativeColumnModifyingOnSqlServer()
});

$this->assertEquals([
"DECLARE @sql NVARCHAR(MAX) = '';SELECT @sql += 'ALTER TABLE [dbo].[users] DROP CONSTRAINT ' + OBJECT_NAME([default_object_id]) + ';' FROM sys.columns WHERE [object_id] = OBJECT_ID('[dbo].[users]') AND [name] in ('name') AND [default_object_id] <> 0;EXEC(@sql)",
"DECLARE @sql NVARCHAR(MAX) = '';SELECT @sql += 'ALTER TABLE \"users\" DROP CONSTRAINT ' + OBJECT_NAME([default_object_id]) + ';' FROM sys.columns WHERE [object_id] = OBJECT_ID(N'users') AND [name] in ('name') AND [default_object_id] <> 0;EXEC(@sql)",
'alter table "users" alter column "name" nchar(40) collate unicode null',
'alter table "users" add default \'easy\' for "name"',
], $blueprint->toSql($connection, new SqlServerGrammar));
Expand All @@ -210,7 +210,7 @@ public function testNativeColumnModifyingOnSqlServer()
});

$this->assertEquals([
"DECLARE @sql NVARCHAR(MAX) = '';SELECT @sql += 'ALTER TABLE [dbo].[users] DROP CONSTRAINT ' + OBJECT_NAME([default_object_id]) + ';' FROM sys.columns WHERE [object_id] = OBJECT_ID('[dbo].[users]') AND [name] in ('foo') AND [default_object_id] <> 0;EXEC(@sql)",
"DECLARE @sql NVARCHAR(MAX) = '';SELECT @sql += 'ALTER TABLE \"users\" DROP CONSTRAINT ' + OBJECT_NAME([default_object_id]) + ';' FROM sys.columns WHERE [object_id] = OBJECT_ID(N'users') AND [name] in ('foo') AND [default_object_id] <> 0;EXEC(@sql)",
'alter table "users" alter column "foo" int not null',
], $blueprint->toSql($connection, new SqlServerGrammar));
}
Expand Down Expand Up @@ -448,7 +448,7 @@ public function testAddUniqueIndexWithoutNameWorks()
$queries = $blueprintSqlServer->toSql(DB::connection(), new SqlServerGrammar);

$expected = [
"DECLARE @sql NVARCHAR(MAX) = '';SELECT @sql += 'ALTER TABLE [dbo].[users] DROP CONSTRAINT ' + OBJECT_NAME([default_object_id]) + ';' FROM sys.columns WHERE [object_id] = OBJECT_ID('[dbo].[users]') AND [name] in ('name') AND [default_object_id] <> 0;EXEC(@sql)",
"DECLARE @sql NVARCHAR(MAX) = '';SELECT @sql += 'ALTER TABLE \"users\" DROP CONSTRAINT ' + OBJECT_NAME([default_object_id]) + ';' FROM sys.columns WHERE [object_id] = OBJECT_ID(N'users') AND [name] in ('name') AND [default_object_id] <> 0;EXEC(@sql)",
'alter table "users" alter column "name" nvarchar(255) null',
'create unique index "users_name_unique" on "users" ("name")',
];
Expand Down Expand Up @@ -512,7 +512,7 @@ public function testAddUniqueIndexWithNameWorks()
$queries = $blueprintSqlServer->toSql(DB::connection(), new SqlServerGrammar);

$expected = [
"DECLARE @sql NVARCHAR(MAX) = '';SELECT @sql += 'ALTER TABLE [dbo].[users] DROP CONSTRAINT ' + OBJECT_NAME([default_object_id]) + ';' FROM sys.columns WHERE [object_id] = OBJECT_ID('[dbo].[users]') AND [name] in ('name') AND [default_object_id] <> 0;EXEC(@sql)",
"DECLARE @sql NVARCHAR(MAX) = '';SELECT @sql += 'ALTER TABLE \"users\" DROP CONSTRAINT ' + OBJECT_NAME([default_object_id]) + ';' FROM sys.columns WHERE [object_id] = OBJECT_ID(N'users') AND [name] in ('name') AND [default_object_id] <> 0;EXEC(@sql)",
'alter table "users" alter column "name" int null',
'create unique index "index1" on "users" ("name")',
];
Expand Down
Loading