Skip to content

Commit f17a206

Browse files
[11.x] Add support for specifying schema name on SQL Server (#49965)
* fix parsing schema name on sqlsrv and pgsql * fix tests * fix tests
1 parent bad4256 commit f17a206

File tree

6 files changed

+171
-24
lines changed

6 files changed

+171
-24
lines changed

src/Illuminate/Database/Schema/Grammars/PostgresGrammar.php

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1093,6 +1093,8 @@ protected function modifyDefault(Blueprint $blueprint, Fluent $column)
10931093
if (! $column->autoIncrement || ! is_null($column->generatedAs)) {
10941094
return is_null($column->default) ? 'drop default' : 'set default '.$this->getDefaultValue($column->default);
10951095
}
1096+
1097+
return null;
10961098
}
10971099

10981100
if (! is_null($column->default)) {

src/Illuminate/Database/Schema/Grammars/SqlServerGrammar.php

Lines changed: 21 additions & 14 deletions
Original file line numberDiff line numberDiff line change
@@ -73,7 +73,7 @@ public function compileDropDatabaseIfExists($name)
7373
*/
7474
public function compileTables()
7575
{
76-
return 'select t.name as name, SCHEMA_NAME(t.schema_id) as [schema], sum(u.total_pages) * 8 * 1024 as size '
76+
return 'select t.name as name, schema_name(t.schema_id) as [schema], sum(u.total_pages) * 8 * 1024 as size '
7777
.'from sys.tables as t '
7878
.'join sys.partitions as p on p.object_id = t.object_id '
7979
.'join sys.allocation_units as u on u.container_id = p.hobt_id '
@@ -88,18 +88,19 @@ public function compileTables()
8888
*/
8989
public function compileViews()
9090
{
91-
return 'select name, SCHEMA_NAME(v.schema_id) as [schema], definition from sys.views as v '
91+
return 'select name, schema_name(v.schema_id) as [schema], definition from sys.views as v '
9292
.'inner join sys.sql_modules as m on v.object_id = m.object_id '
9393
.'order by name';
9494
}
9595

9696
/**
9797
* Compile the query to determine the columns.
9898
*
99+
* @param string $schema
99100
* @param string $table
100101
* @return string
101102
*/
102-
public function compileColumns($table)
103+
public function compileColumns($schema, $table)
103104
{
104105
return sprintf(
105106
'select col.name, type.name as type_name, '
@@ -113,19 +114,21 @@ public function compileColumns($table)
113114
.'join sys.schemas as scm on obj.schema_id = scm.schema_id '
114115
.'left join sys.default_constraints def on col.default_object_id = def.object_id and col.object_id = def.parent_object_id '
115116
."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' "
116-
."where obj.type in ('U', 'V') and obj.name = %s and scm.name = SCHEMA_NAME() "
117+
."where obj.type in ('U', 'V') and obj.name = %s and scm.name = %s "
117118
.'order by col.column_id',
118119
$this->quoteString($table),
120+
$schema ? $this->quoteString($schema) : 'schema_name()',
119121
);
120122
}
121123

122124
/**
123125
* Compile the query to determine the indexes.
124126
*
127+
* @param string $schema
125128
* @param string $table
126129
* @return string
127130
*/
128-
public function compileIndexes($table)
131+
public function compileIndexes($schema, $table)
129132
{
130133
return sprintf(
131134
"select idx.name as name, string_agg(col.name, ',') within group (order by idxcol.key_ordinal) as columns, "
@@ -135,19 +138,21 @@ public function compileIndexes($table)
135138
.'join sys.schemas as scm on tbl.schema_id = scm.schema_id '
136139
.'join sys.index_columns as idxcol on idx.object_id = idxcol.object_id and idx.index_id = idxcol.index_id '
137140
.'join sys.columns as col on idxcol.object_id = col.object_id and idxcol.column_id = col.column_id '
138-
.'where tbl.name = %s and scm.name = SCHEMA_NAME() '
141+
.'where tbl.name = %s and scm.name = %s '
139142
.'group by idx.name, idx.type_desc, idx.is_unique, idx.is_primary_key',
140143
$this->quoteString($table),
144+
$schema ? $this->quoteString($schema) : 'schema_name()',
141145
);
142146
}
143147

144148
/**
145149
* Compile the query to determine the foreign keys.
146150
*
151+
* @param string $schema
147152
* @param string $table
148153
* @return string
149154
*/
150-
public function compileForeignKeys($table)
155+
public function compileForeignKeys($schema, $table)
151156
{
152157
return sprintf(
153158
'select fk.name as name, '
@@ -164,9 +169,10 @@ public function compileForeignKeys($table)
164169
.'join sys.tables as ft on ft.object_id = fk.referenced_object_id '
165170
.'join sys.schemas as fs on ft.schema_id = fs.schema_id '
166171
.'join sys.columns as fc on fkc.referenced_object_id = fc.object_id and fkc.referenced_column_id = fc.column_id '
167-
.'where lt.name = %s and ls.name = SCHEMA_NAME() '
172+
.'where lt.name = %s and ls.name = %s '
168173
.'group by fk.name, fs.name, ft.name, fk.update_referential_action_desc, fk.delete_referential_action_desc',
169-
$this->quoteString($table)
174+
$this->quoteString($table),
175+
$schema ? $this->quoteString($schema) : 'schema_name()',
170176
);
171177
}
172178

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

399-
$tableName = $this->getTablePrefix().$blueprint->getTable();
405+
$table = $this->wrapTable($blueprint);
406+
$tableName = $this->quoteString($this->getTablePrefix().$blueprint->getTable());
400407

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

407414
return $sql;

src/Illuminate/Database/Schema/PostgresBuilder.php

Lines changed: 23 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -59,6 +59,28 @@ public function hasTable($table)
5959
return false;
6060
}
6161

62+
/**
63+
* Determine if the given view exists.
64+
*
65+
* @param string $view
66+
* @return bool
67+
*/
68+
public function hasView($view)
69+
{
70+
[$schema, $view] = $this->parseSchemaAndTable($view);
71+
72+
$view = $this->connection->getTablePrefix().$view;
73+
74+
foreach ($this->getViews() as $value) {
75+
if (strtolower($view) === strtolower($value['name'])
76+
&& strtolower($schema) === strtolower($value['schema'])) {
77+
return true;
78+
}
79+
}
80+
81+
return false;
82+
}
83+
6284
/**
6385
* Get the user-defined types that belong to the database.
6486
*
@@ -239,7 +261,7 @@ protected function parseSchemaAndTable($reference)
239261
if (count($parts) > 2) {
240262
$database = $parts[0];
241263

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

245267
// We will use the default schema unless the schema has been specified in the

src/Illuminate/Database/Schema/SqlServerBuilder.php

Lines changed: 116 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -30,6 +30,50 @@ public function dropDatabaseIfExists($name)
3030
);
3131
}
3232

33+
/**
34+
* Determine if the given table exists.
35+
*
36+
* @param string $table
37+
* @return bool
38+
*/
39+
public function hasTable($table)
40+
{
41+
[$schema, $table] = $this->parseSchemaAndTable($table);
42+
43+
$table = $this->connection->getTablePrefix().$table;
44+
45+
foreach ($this->getTables() as $value) {
46+
if (strtolower($table) === strtolower($value['name'])
47+
&& strtolower($schema) === strtolower($value['schema'])) {
48+
return true;
49+
}
50+
}
51+
52+
return false;
53+
}
54+
55+
/**
56+
* Determine if the given view exists.
57+
*
58+
* @param string $view
59+
* @return bool
60+
*/
61+
public function hasView($view)
62+
{
63+
[$schema, $view] = $this->parseSchemaAndTable($view);
64+
65+
$view = $this->connection->getTablePrefix().$view;
66+
67+
foreach ($this->getViews() as $value) {
68+
if (strtolower($view) === strtolower($value['name'])
69+
&& strtolower($schema) === strtolower($value['schema'])) {
70+
return true;
71+
}
72+
}
73+
74+
return false;
75+
}
76+
3377
/**
3478
* Drop all tables from the database.
3579
*
@@ -51,4 +95,76 @@ public function dropAllViews()
5195
{
5296
$this->connection->statement($this->grammar->compileDropAllViews());
5397
}
98+
99+
/**
100+
* Get the columns for a given table.
101+
*
102+
* @param string $table
103+
* @return array
104+
*/
105+
public function getColumns($table)
106+
{
107+
[$schema, $table] = $this->parseSchemaAndTable($table);
108+
109+
$table = $this->connection->getTablePrefix().$table;
110+
111+
$results = $this->connection->selectFromWriteConnection(
112+
$this->grammar->compileColumns($schema, $table)
113+
);
114+
115+
return $this->connection->getPostProcessor()->processColumns($results);
116+
}
117+
118+
/**
119+
* Get the indexes for a given table.
120+
*
121+
* @param string $table
122+
* @return array
123+
*/
124+
public function getIndexes($table)
125+
{
126+
[$schema, $table] = $this->parseSchemaAndTable($table);
127+
128+
$table = $this->connection->getTablePrefix().$table;
129+
130+
return $this->connection->getPostProcessor()->processIndexes(
131+
$this->connection->selectFromWriteConnection($this->grammar->compileIndexes($schema, $table))
132+
);
133+
}
134+
135+
/**
136+
* Get the foreign keys for a given table.
137+
*
138+
* @param string $table
139+
* @return array
140+
*/
141+
public function getForeignKeys($table)
142+
{
143+
[$schema, $table] = $this->parseSchemaAndTable($table);
144+
145+
$table = $this->connection->getTablePrefix().$table;
146+
147+
return $this->connection->getPostProcessor()->processForeignKeys(
148+
$this->connection->selectFromWriteConnection($this->grammar->compileForeignKeys($schema, $table))
149+
);
150+
}
151+
152+
/**
153+
* Parse the database object reference and extract the schema and table.
154+
*
155+
* @param string $reference
156+
* @return array
157+
*/
158+
protected function parseSchemaAndTable($reference)
159+
{
160+
$parts = array_pad(explode('.', $reference, 2), -2, 'dbo');
161+
162+
if (str_contains($parts[1], '.')) {
163+
$database = $parts[0];
164+
165+
throw new InvalidArgumentException("Using three-part reference is not supported, you may use `Schema::connection('$database')` instead.");
166+
}
167+
168+
return $parts;
169+
}
54170
}

tests/Database/DatabaseSqlServerSchemaGrammarTest.php

Lines changed: 4 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -83,14 +83,14 @@ public function testDropTableIfExists()
8383
$statements = $blueprint->toSql($this->getConnection(), $this->getGrammar());
8484

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

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

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

9696
public function testDropColumn()
@@ -124,7 +124,7 @@ public function testDropColumnDropsCreatesSqlToDropDefaultConstraints()
124124
$statements = $blueprint->toSql($this->getConnection(), $this->getGrammar());
125125

126126
$this->assertCount(1, $statements);
127-
$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]);
127+
$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]);
128128
}
129129

130130
public function testDropPrimary()
@@ -185,7 +185,7 @@ public function testDropConstrainedForeignId()
185185

186186
$this->assertCount(2, $statements);
187187
$this->assertSame('alter table "users" drop constraint "users_foo_foreign"', $statements[0]);
188-
$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]);
188+
$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]);
189189
}
190190

191191
public function testDropTimestamps()

tests/Integration/Database/DatabaseSchemaBlueprintTest.php

Lines changed: 5 additions & 5 deletions
Original file line numberDiff line numberDiff line change
@@ -190,7 +190,7 @@ public function testNativeColumnModifyingOnSqlServer()
190190
});
191191

192192
$this->assertEquals([
193-
"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)",
193+
"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)",
194194
'alter table "users" alter column "added_at" datetime2(4) not null',
195195
'alter table "users" add default CURRENT_TIMESTAMP for "added_at"',
196196
], $blueprint->toSql($connection, new SqlServerGrammar));
@@ -200,7 +200,7 @@ public function testNativeColumnModifyingOnSqlServer()
200200
});
201201

202202
$this->assertEquals([
203-
"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)",
203+
"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)",
204204
'alter table "users" alter column "name" nchar(40) collate unicode null',
205205
'alter table "users" add default \'easy\' for "name"',
206206
], $blueprint->toSql($connection, new SqlServerGrammar));
@@ -210,7 +210,7 @@ public function testNativeColumnModifyingOnSqlServer()
210210
});
211211

212212
$this->assertEquals([
213-
"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)",
213+
"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)",
214214
'alter table "users" alter column "foo" int not null',
215215
], $blueprint->toSql($connection, new SqlServerGrammar));
216216
}
@@ -448,7 +448,7 @@ public function testAddUniqueIndexWithoutNameWorks()
448448
$queries = $blueprintSqlServer->toSql(DB::connection(), new SqlServerGrammar);
449449

450450
$expected = [
451-
"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)",
451+
"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)",
452452
'alter table "users" alter column "name" nvarchar(255) null',
453453
'create unique index "users_name_unique" on "users" ("name")',
454454
];
@@ -512,7 +512,7 @@ public function testAddUniqueIndexWithNameWorks()
512512
$queries = $blueprintSqlServer->toSql(DB::connection(), new SqlServerGrammar);
513513

514514
$expected = [
515-
"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)",
515+
"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)",
516516
'alter table "users" alter column "name" int null',
517517
'create unique index "index1" on "users" ("name")',
518518
];

0 commit comments

Comments
 (0)