Skip to content

Commit fa419cd

Browse files
authored
Table name collision bug fix (#1990)
## Why make this change? Closes #1908 ## What is this change? We were previously filling the schema information for the entity data set but only using the table name. We add in the schema name to deconflict between two tables with the same name in different schemas. This means that we retrieve information from the entity data set by using schema and tablename when schema is available, and just the table name otherwise. The reason that we do not need to worry about collisions at the schema and table name level (eg. where we have the same schema and table names within different databases) is because this entity data set is a part of the SqlMetadataProvider, and we have a SqlMetadataProvider for each database (not database type but actual DBs). ## How was this tested? A regression test with a collision between table names in different schemas was added. We also update the unit test for SqlMetadatProvider. ## Sample Request(s) see #1908
1 parent 2115adf commit fa419cd

File tree

13 files changed

+164
-38
lines changed

13 files changed

+164
-38
lines changed

src/Core/Services/MetadataProviders/SqlMetadataProvider.cs

Lines changed: 25 additions & 21 deletions
Original file line numberDiff line numberDiff line change
@@ -1241,7 +1241,14 @@ private async Task<DataTable> GetTableWithSchemaFromDataSetAsync(
12411241
string schemaName,
12421242
string tableName)
12431243
{
1244-
DataTable? dataTable = EntitiesDataSet.Tables[tableName];
1244+
// Because we have an instance of SqlMetadataProvider for each individual database
1245+
// (note: this means each actual database not each database type), we do not
1246+
// need to worry about collisions beyond that schema, hence no database name is needed.
1247+
string tableNameWithSchemaPrefix = GetTableNameWithSchemaPrefix(
1248+
schemaName: schemaName,
1249+
tableName: tableName);
1250+
1251+
DataTable? dataTable = EntitiesDataSet.Tables[tableNameWithSchemaPrefix];
12451252
if (dataTable is null)
12461253
{
12471254
try
@@ -1361,43 +1368,40 @@ private async Task<DataTable> FillSchemaForTableAsync(
13611368
Connection = conn
13621369
};
13631370

1364-
string tablePrefix = GetTablePrefix(conn.Database, schemaName);
1365-
string queryPrefix = string.IsNullOrEmpty(tablePrefix) ? string.Empty : $"{tablePrefix}.";
1371+
string tableNameWithSchemaPrefix = GetTableNameWithSchemaPrefix(schemaName, tableName);
13661372
selectCommand.CommandText
1367-
= $"SELECT * FROM {queryPrefix}{SqlQueryBuilder.QuoteIdentifier(tableName)}";
1373+
= $"SELECT * FROM {tableNameWithSchemaPrefix}";
13681374
adapterForTable.SelectCommand = selectCommand;
13691375

1370-
DataTable[] dataTable = adapterForTable.FillSchema(EntitiesDataSet, SchemaType.Source, tableName);
1376+
DataTable[] dataTable = adapterForTable.FillSchema(EntitiesDataSet, SchemaType.Source, tableNameWithSchemaPrefix);
13711377
return dataTable[0];
13721378
}
13731379

1374-
internal string GetTablePrefix(string databaseName, string schemaName)
1380+
/// <summary>
1381+
/// Gets the correctly formatted table name with schema as prefix, if one exists.
1382+
/// A schema prefix is simply the correctly formatted and prefixed schema name that
1383+
/// is provided, separated from the table name by a ".". The formatting for both the
1384+
/// schema and table name is based on database type and may or may not include
1385+
/// [] quotes depending how the particular database type handles said format.
1386+
/// </summary>
1387+
/// <param name="schemaName">Name of schema the table belongs within.</param>
1388+
/// <param name="tableName">Name of the table.</param>
1389+
/// <returns>Properly formatted table name with schema prefix if it exists.</returns>
1390+
internal string GetTableNameWithSchemaPrefix(string schemaName, string tableName)
13751391
{
13761392
IQueryBuilder queryBuilder = GetQueryBuilder();
13771393
StringBuilder tablePrefix = new();
13781394

1379-
if (!string.IsNullOrEmpty(databaseName))
1380-
{
1381-
// Determine databaseName for prefix.
1382-
databaseName = queryBuilder.QuoteIdentifier(databaseName);
1383-
tablePrefix.Append(databaseName);
1384-
1385-
if (!string.IsNullOrEmpty(schemaName))
1386-
{
1387-
// Determine schemaName for prefix.
1388-
schemaName = queryBuilder.QuoteIdentifier(schemaName);
1389-
tablePrefix.Append($".{schemaName}");
1390-
}
1391-
}
1392-
else if (!string.IsNullOrEmpty(schemaName))
1395+
if (!string.IsNullOrEmpty(schemaName))
13931396
{
13941397
// Determine schemaName for prefix.
13951398
schemaName = queryBuilder.QuoteIdentifier(schemaName);
13961399
// Database name is empty we just need the schema name.
13971400
tablePrefix.Append(schemaName);
13981401
}
13991402

1400-
return tablePrefix.ToString();
1403+
string queryPrefix = string.IsNullOrEmpty(tablePrefix.ToString()) ? string.Empty : $"{tablePrefix}.";
1404+
return $"{queryPrefix}{SqlQueryBuilder.QuoteIdentifier(tableName)}";
14011405
}
14021406

14031407
/// <summary>

src/Service.Tests/Configuration/ConfigurationTests.cs

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1196,7 +1196,7 @@ public async Task TestSqlMetadataForInvalidConfigEntities()
11961196
Assert.AreEqual(2, configValidator.ConfigValidationExceptions.Count);
11971197
List<Exception> exceptionsList = configValidator.ConfigValidationExceptions;
11981198
Assert.AreEqual("Cannot obtain Schema for entity Book with underlying database "
1199-
+ "object source: dbo.bokos due to: Invalid object name 'master.dbo.bokos'.", exceptionsList[0].Message);
1199+
+ "object source: dbo.bokos due to: Invalid object name 'dbo.bokos'.", exceptionsList[0].Message);
12001200
Assert.AreEqual("No stored procedure definition found for the given database object publishers", exceptionsList[1].Message);
12011201
}
12021202

src/Service.Tests/DatabaseSchema-DwSql.sql

Lines changed: 11 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -13,6 +13,7 @@ DROP TABLE IF EXISTS book_website_placements;
1313
DROP TABLE IF EXISTS website_users;
1414
DROP TABLE IF EXISTS books;
1515
DROP TABLE IF EXISTS [foo].[magazines];
16+
DROP TABLE IF EXISTS [bar].[magazines];
1617
DROP TABLE IF EXISTS stocks_price;
1718
DROP TABLE IF EXISTS stocks;
1819
DROP TABLE IF EXISTS comics;
@@ -41,6 +42,7 @@ DROP PROCEDURE IF EXISTS delete_last_inserted_book;
4142
DROP PROCEDURE IF EXISTS update_book_title;
4243
DROP PROCEDURE IF EXISTS insert_and_display_all_books_for_given_publisher;
4344
DROP SCHEMA IF EXISTS [foo];
45+
DROP SCHEMA IF EXISTS [bar];
4446
COMMIT;
4547

4648
CREATE TABLE books(
@@ -85,6 +87,14 @@ CREATE TABLE [foo].[magazines](
8587
issue_number int NULL
8688
);
8789

90+
EXEC('CREATE SCHEMA [bar]');
91+
92+
CREATE TABLE [bar].[magazines](
93+
upc int NOT NULL,
94+
comic_name varchar(2048) NOT NULL,
95+
issue int NULL
96+
);
97+
8898
CREATE TABLE comics(
8999
id int,
90100
title varchar(2048) NOT NULL,
@@ -312,6 +322,7 @@ VALUES (1, 'Star Trek', 'SciFi', NULL), (2, 'Cinderella', 'Tales', 3001),(3,'Ún
312322
(5, 'Snow White', 'AnotherTales', 3001);
313323

314324
INSERT INTO [foo].[magazines](id, title, issue_number) VALUES (1, 'Vogue', 1234), (11, 'Sports Illustrated', NULL), (3, 'Fitness', NULL);
325+
INSERT INTO [bar].[magazines](upc, comic_name, issue) VALUES (0, 'NotVogue', 0);
315326
INSERT INTO brokers([ID Number], [First Name], [Last Name]) VALUES (1, 'Michael', 'Burry'), (2, 'Jordan', 'Belfort');
316327
INSERT INTO publishers(id, name) VALUES (1234, 'Big Company'), (2345, 'Small Town Publisher'), (2323, 'TBD Publishing One'), (2324, 'TBD Publishing Two Ltd'), (1940, 'Policy Publisher 01'), (1941, 'Policy Publisher 02'), (1156, 'The First Publisher');
317328
INSERT INTO book_author_link(book_id, author_id) VALUES (1, 123), (2, 124), (3, 123), (3, 124), (4, 123), (4, 124), (5, 126);

src/Service.Tests/DatabaseSchema-MsSql.sql

Lines changed: 11 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -28,6 +28,7 @@ DROP TABLE IF EXISTS players;
2828
DROP TABLE IF EXISTS clubs;
2929
DROP TABLE IF EXISTS publishers;
3030
DROP TABLE IF EXISTS [foo].[magazines];
31+
DROP TABLE IF EXISTS [bar].[magazines];
3132
DROP TABLE IF EXISTS stocks_price;
3233
DROP TABLE IF EXISTS stocks;
3334
DROP TABLE IF EXISTS comics;
@@ -52,6 +53,7 @@ DROP TABLE IF EXISTS intern_data;
5253
DROP TABLE IF EXISTS books_sold;
5354
DROP TABLE IF EXISTS default_with_function_table;
5455
DROP SCHEMA IF EXISTS [foo];
56+
DROP SCHEMA IF EXISTS [bar];
5557
COMMIT;
5658

5759
--Autogenerated id seed are set at 5001 for consistency with Postgres
@@ -118,6 +120,14 @@ CREATE TABLE [foo].[magazines](
118120
issue_number int NULL
119121
);
120122

123+
EXEC('CREATE SCHEMA [bar]');
124+
125+
CREATE TABLE [bar].[magazines](
126+
upc int PRIMARY KEY,
127+
comic_name varchar(max) NOT NULL,
128+
issue int NULL
129+
);
130+
121131
CREATE TABLE comics(
122132
id int PRIMARY KEY,
123133
title varchar(max) NOT NULL,
@@ -472,6 +482,7 @@ INSERT INTO journals(id, journalname, color, ownername) VALUES (1, 'Journal1', '
472482

473483
INSERT INTO website_users(id, username) VALUES (1, 'George'), (2, NULL), (3, ''), (4, 'book_lover_95'), (5, 'null');
474484
INSERT INTO [foo].[magazines](id, title, issue_number) VALUES (1, 'Vogue', 1234), (11, 'Sports Illustrated', NULL), (3, 'Fitness', NULL);
485+
INSERT INTO [bar].[magazines](upc, comic_name, issue) VALUES (0, 'NotVogue', 0);
475486
INSERT INTO brokers([ID Number], [First Name], [Last Name]) VALUES (1, 'Michael', 'Burry'), (2, 'Jordan', 'Belfort');
476487

477488
SET IDENTITY_INSERT series ON

src/Service.Tests/DatabaseSchema-PostgreSql.sql

Lines changed: 10 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -16,6 +16,7 @@ DROP TABLE IF EXISTS players;
1616
DROP TABLE IF EXISTS clubs;
1717
DROP TABLE IF EXISTS publishers;
1818
DROP TABLE IF EXISTS foo.magazines;
19+
DROP TABLE IF EXISTS bar.magazines;
1920
DROP TABLE IF EXISTS stocks_price;
2021
DROP TABLE IF EXISTS stocks;
2122
DROP TABLE IF EXISTS comics;
@@ -38,8 +39,10 @@ DROP TABLE IF EXISTS default_with_function_table;
3839
DROP FUNCTION IF EXISTS insertCompositeView;
3940

4041
DROP SCHEMA IF EXISTS foo;
42+
DROP SCHEMA IF EXISTS bar;
4143

4244
CREATE SCHEMA foo;
45+
CREATE SCHEMA bar;
4346

4447
CREATE TABLE publishers(
4548
id int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY,
@@ -100,6 +103,12 @@ CREATE TABLE foo.magazines(
100103
issue_number int NULL
101104
);
102105

106+
CREATE TABLE bar.magazines(
107+
upc int PRIMARY KEY,
108+
comic_name text NOT NULL,
109+
issue int NULL
110+
);
111+
103112
CREATE TABLE comics(
104113
id int PRIMARY KEY,
105114
title text NOT NULL,
@@ -341,6 +350,7 @@ INSERT INTO website_users(id, username) VALUES (1, 'George'), (2, NULL), (3, '')
341350
INSERT INTO book_author_link(book_id, author_id) VALUES (1, 123), (2, 124), (3, 123), (3, 124), (4, 123), (4, 124), (5, 126);;
342351
INSERT INTO reviews(id, book_id, content) VALUES (567, 1, 'Indeed a great book'), (568, 1, 'I loved it'), (569, 1, 'best book I read in years');
343352
INSERT INTO foo.magazines(id, title, issue_number) VALUES (1, 'Vogue', 1234), (11, 'Sports Illustrated', NULL), (3, 'Fitness', NULL);
353+
INSERT INTO bar.magazines(upc, comic_name, issue) VALUES (0, 'NotVogue', 0);
344354
INSERT INTO series(id, name) VALUES (3001, 'Foundation'), (3002, 'Hyperion Cantos');
345355
INSERT INTO comics(id, title, "categoryName", series_id)
346356
VALUES (1, 'Star Trek', 'SciFi', NULL), (2, 'Cinderella', 'Tales', 3001),(3,'Únknown','', 3002), (4, 'Alexander the Great', 'Historical', NULL);INSERT INTO stocks(categoryid, pieceid, "categoryName") VALUES (1, 1, 'SciFi'), (2, 1, 'Tales'),(0,1,''),(100, 99, 'Historical');

src/Service.Tests/SqlTests/RestApiTests/Find/DwSqlFindApiTests.cs

Lines changed: 5 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -37,6 +37,11 @@ public class DwSqlFindApiTests : FindApiTestBase
3737
$"SELECT * FROM { _integrationTableName } " +
3838
$"WHERE 1 != 1 FOR JSON PATH, INCLUDE_NULL_VALUES"
3939
},
40+
{
41+
"FindOnTableWithNamingCollision",
42+
$"SELECT upc, comic_name, issue FROM { _collisionTable } " +
43+
$"WHERE 1 = 1 FOR JSON PATH, INCLUDE_NULL_VALUES"
44+
},
4045
{
4146
"FindOnTableWithUniqueCharacters",
4247
$"SELECT [NoteNum] AS [┬─┬ノ( º _ ºノ)], [DetailAssessmentAndPlanning] AS [始計], " +

src/Service.Tests/SqlTests/RestApiTests/Find/FindApiTestBase.cs

Lines changed: 17 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -127,6 +127,23 @@ await SetupAndRunRestApiTest(
127127
sqlQuery: GetQuery("FindOnTableWithUniqueCharacters"));
128128
}
129129

130+
/// <summary>
131+
/// Tests the Rest Api to validate that queries work
132+
/// when there is the same table name in two different
133+
/// schemas. In this test we have two tables both
134+
/// named magazines but with one in the schema "foo" and
135+
/// the other in the schema "bar".
136+
/// </summary>
137+
[TestMethod]
138+
public virtual async Task FindOnTableWithNamingCollision()
139+
{
140+
await SetupAndRunRestApiTest(
141+
primaryKeyRoute: string.Empty,
142+
queryString: string.Empty,
143+
entityNameOrPath: _collisionEntity,
144+
sqlQuery: GetQuery("FindOnTableWithNamingCollision"));
145+
}
146+
130147
/// <summary>
131148
/// Validates that a Find request on a single item with $select with only non-PK fields
132149
/// returns only the selected fields and does not contain PK fields.

src/Service.Tests/SqlTests/RestApiTests/Find/MsSqlFindApiTests.cs

Lines changed: 6 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -50,6 +50,12 @@ public class MsSqlFindApiTests : FindApiTestBase
5050
$"[WagingWar] AS [作戰], [StrategicAttack] AS [謀攻] FROM { _integrationUniqueCharactersTable } " +
5151
$"FOR JSON PATH, INCLUDE_NULL_VALUES"
5252
},
53+
{
54+
"FindOnTableWithNamingCollision",
55+
$"SELECT [upc], [comic_name], [issue] " +
56+
$"FROM { _collisionTable } AS { _collisionEntity } " +
57+
$"WHERE 1 = 1 ORDER BY [upc] ASC FOR JSON PATH"
58+
},
5359
{
5460
"FindViewAll",
5561
$"SELECT * FROM { _simple_all_books } " +

src/Service.Tests/SqlTests/RestApiTests/Find/MySqlFindApiTests.cs

Lines changed: 15 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -1008,11 +1008,11 @@ public override string GetDefaultSchema()
10081008
}
10091009

10101010
/// <summary>
1011-
/// MySql does not a schema so it lacks
1011+
/// MySql does not have a schema so it lacks
10121012
/// the '.' between schema and table, we
10131013
/// return empty string here for this reason.
10141014
/// </summary>
1015-
/// <returns></returns>
1015+
/// <exception cref="NotImplementedException"></exception>
10161016
public override string GetDefaultSchemaForEdmModel()
10171017
{
10181018
return string.Empty;
@@ -1023,6 +1023,19 @@ public override string GetQuery(string key)
10231023
return _queryMap[key];
10241024
}
10251025

1026+
/// <summary>
1027+
/// MySql does not have a schema and so this test
1028+
/// which validates we de-conflict the same table
1029+
/// name in different schemas is not valid.
1030+
/// </summary>
1031+
/// <exception cref="NotImplementedException"></exception>
1032+
[TestMethod]
1033+
[Ignore]
1034+
public override Task FindOnTableWithNamingCollision()
1035+
{
1036+
throw new NotImplementedException();
1037+
}
1038+
10261039
// Pending Stored Procedure Support
10271040
[TestMethod]
10281041
[Ignore]

src/Service.Tests/SqlTests/RestApiTests/Find/PostgreSqlFindApiTests.cs

Lines changed: 10 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -170,6 +170,16 @@ SELECT to_jsonb(subq) AS data
170170
WHERE 1 <> 1
171171
) AS subq"
172172
},
173+
{
174+
"FindOnTableWithNamingCollision",
175+
@"
176+
SELECT to_jsonb(subq) AS data
177+
FROM (
178+
SELECT upc, comic_name, issue
179+
FROM " + _collisionTable + @"
180+
WHERE 1 = 1
181+
) AS subq"
182+
},
173183
{
174184
"FindTestWithQueryStringOneField",
175185
@"

0 commit comments

Comments
 (0)