Skip to content

Commit 33972a4

Browse files
authored
Add MySQL RESTAPI POST/PUT support and Tests (#260)
* Add upsert Support * Use a different way to get the updated rowid * Add tests to validate insert returns right JSON * Enable most REST API tests
1 parent db91a9f commit 33972a4

File tree

10 files changed

+144
-76
lines changed

10 files changed

+144
-76
lines changed

DataGateway.Service.Tests/SqlTests/MySqlRestApiTests.cs

Lines changed: 28 additions & 55 deletions
Original file line numberDiff line numberDiff line change
@@ -338,14 +338,36 @@ SELECT JSON_OBJECT('id', id) AS data
338338
{
339339
"PutOne_Insert_Test",
340340
@"
341-
SELECT JSON_OBJECT('id', id) AS data
341+
SELECT JSON_OBJECT('id', id, 'title', title, 'issueNumber', issueNumber ) AS data
342342
FROM (
343-
SELECT id, title, publisher_id
344-
FROM " + _integrationTableName + @"
345-
WHERE id > 5000 AND title = 'The Hobbit Returns to The Shire'
346-
AND publisher_id = 1234
343+
SELECT id, title, issueNumber
344+
FROM " + _integration_NonAutoGenPK_TableName + @"
345+
WHERE id > 5000 AND title = 'Batman Returns'
346+
AND issueNumber = 1234
347347
) AS subq
348348
"
349+
},
350+
{
351+
"PutOne_Insert_Nullable_Test",
352+
@"SELECT JSON_OBJECT('id', id, 'title', title, 'issueNumber', issueNumber ) AS data
353+
FROM (
354+
SELECT id, title, issueNumber
355+
FROM " + _integration_NonAutoGenPK_TableName + @"
356+
WHERE id = " + $"{STARTING_ID_FOR_TEST_INSERTS + 1}" + @" AND title = 'Times'
357+
AND issueNumber is NULL
358+
) as subq
359+
"
360+
},
361+
{
362+
"PutOne_Insert_AutoGenNonPK_Test",
363+
@"SELECT JSON_OBJECT('id', id, 'title', title, 'volume', volume ) AS data
364+
FROM (
365+
SELECT id, title, volume
366+
FROM " + _integration_AutoGenNonPK_TableName + @"
367+
WHERE id = " + $"{STARTING_ID_FOR_TEST_INSERTS}" + @" AND title = 'Star Trek'
368+
AND volume IS NOT NULL
369+
) as subq
370+
"
349371
}
350372
};
351373

@@ -376,60 +398,11 @@ public override string GetQuery(string key)
376398
return _queryMap[key];
377399
}
378400

379-
[TestMethod]
380-
[Ignore]
381-
public override Task InsertOneTest()
382-
{
383-
throw new NotImplementedException();
384-
}
385-
386-
[TestMethod]
387-
[Ignore]
388-
public override Task InsertOneInCompositeKeyTableTest()
389-
{
390-
throw new NotImplementedException();
391-
}
392-
393-
[TestMethod]
394-
[Ignore]
395-
public override Task PutOne_Update_Test()
396-
{
397-
throw new NotImplementedException();
398-
}
399-
400-
[TestMethod]
401-
[Ignore]
402-
public override Task PutOne_Insert_Test()
403-
{
404-
throw new NotImplementedException();
405-
}
406-
407-
[TestMethod]
408-
[Ignore]
409-
public override Task PutOne_Insert_BadReq_Test()
410-
{
411-
throw new NotImplementedException();
412-
}
413-
414-
[TestMethod]
415-
[Ignore]
416-
public override Task PutOne_Insert_BadReq_NonNullable_Test()
417-
{
418-
throw new NotImplementedException();
419-
}
420-
421401
[TestMethod]
422402
[Ignore]
423403
public override Task PutOne_Insert_PKAutoGen_Test()
424404
{
425-
throw new NotImplementedException();
426-
}
427-
428-
[TestMethod]
429-
[Ignore]
430-
public override Task PutOne_Insert_BadReq_AutoGen_NonNullable_Test()
431-
{
432-
throw new NotImplementedException();
405+
throw new NotImplementedException("Insert success");
433406
}
434407
}
435408
}

DataGateway.Service.Tests/SqlTests/SqlTestBase.cs

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -224,8 +224,8 @@ protected static async Task SetupAndRunRestApiTest(
224224
actionResult,
225225
expected,
226226
expectedStatusCode,
227-
expectedLocationHeader);
228-
227+
expectedLocationHeader,
228+
!exception);
229229
}
230230

231231
/// <summary>

DataGateway.Service.Tests/SqlTests/SqlTestHelper.cs

Lines changed: 11 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -128,7 +128,8 @@ public static void VerifyResult(
128128
IActionResult actionResult,
129129
string expected,
130130
HttpStatusCode expectedStatusCode,
131-
string expectedLocationHeader)
131+
string expectedLocationHeader,
132+
bool isJson = false)
132133
{
133134
string actual;
134135
switch (actionResult)
@@ -158,9 +159,15 @@ public static void VerifyResult(
158159
break;
159160
}
160161

161-
// if whitespaces are not consistent JsonStringDeepEquals should be used
162-
// this will require deserializing and then serializing the strings for JSON
163-
Assert.AreEqual(expected, actual);
162+
Console.WriteLine($"Expected: {expected}\nActual: {actual}");
163+
if (isJson && !string.IsNullOrEmpty(expected))
164+
{
165+
Assert.IsTrue(JsonStringsDeepEqual(expected, actual));
166+
}
167+
else
168+
{
169+
Assert.AreEqual(expected, actual);
170+
}
164171
}
165172
}
166173
}

DataGateway.Service/MySqlBooks.sql

Lines changed: 8 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -4,6 +4,7 @@ DROP TABLE IF EXISTS authors;
44
DROP TABLE IF EXISTS books;
55
DROP TABLE IF EXISTS publishers;
66
DROP TABLE IF EXISTS magazines;
7+
DROP TABLE IF EXISTS comics;
78

89
CREATE TABLE publishers(
910
id bigint AUTO_INCREMENT PRIMARY KEY,
@@ -43,6 +44,12 @@ CREATE TABLE magazines(
4344
issueNumber bigint NULL
4445
);
4546

47+
CREATE TABLE comics(
48+
id bigint PRIMARY KEY,
49+
title text NOT NULL,
50+
volume bigint AUTO_INCREMENT UNIQUE KEY
51+
);
52+
4653
ALTER TABLE books
4754
ADD CONSTRAINT book_publisher_fk
4855
FOREIGN KEY (publisher_id)
@@ -80,5 +87,5 @@ ALTER TABLE books AUTO_INCREMENT = 5001;
8087
ALTER TABLE publishers AUTO_INCREMENT = 5001;
8188
ALTER TABLE authors AUTO_INCREMENT = 5001;
8289
ALTER TABLE reviews AUTO_INCREMENT = 5001;
83-
90+
ALTER TABLE comics AUTO_INCREMENT = 5001
8491

DataGateway.Service/Resolvers/MySqlQueryBuilder.cs

Lines changed: 75 additions & 11 deletions
Original file line numberDiff line numberDiff line change
@@ -60,22 +60,25 @@ public string Build(SqlQueryStructure structure)
6060
/// <inheritdoc />
6161
public string Build(SqlInsertStructure structure)
6262
{
63-
// TODO: these should be put in a transcation
63+
// No need to put into transaction as LAST_INSERT_ID is session level variable
6464
return $"INSERT INTO {QuoteIdentifier(structure.TableName)} ({Build(structure.InsertColumns)}) " +
6565
$"VALUES ({string.Join(", ", (structure.Values))}); " +
66-
$"SELECT {MakeInsertSelections(structure)}";
66+
$" SET @ROWCOUNT=ROW_COUNT(); " +
67+
$"SELECT {MakeInsertSelections(structure)} WHERE @ROWCOUNT > 0;";
6768
}
6869

6970
/// <inheritdoc />
7071
public string Build(SqlUpdateStructure structure)
7172
{
72-
// TODO: these should be put in a transaction
73-
return $"UPDATE {QuoteIdentifier(structure.TableName)} " +
73+
(string sets, string updates, string select) = MakeStoreUpdatePK(structure.PrimaryKey());
74+
75+
return sets + ";\n" +
76+
$"UPDATE {QuoteIdentifier(structure.TableName)} " +
7477
$"SET {Build(structure.UpdateOperations, ", ")} " +
75-
$"WHERE {Build(structure.Predicates)}; " +
76-
$"SELECT {Build(structure.PrimaryKey())} " +
77-
$"FROM {QuoteIdentifier(structure.TableName)} " +
78-
$"WHERE {Build(structure.Predicates)}; ";
78+
", " + updates +
79+
$" WHERE {Build(structure.Predicates)}; " +
80+
$" SET @ROWCOUNT=ROW_COUNT(); " +
81+
$"SELECT " + select + $" WHERE @ROWCOUNT > 0;";
7982
}
8083

8184
/// <inheritdoc />
@@ -88,8 +91,36 @@ public string Build(SqlDeleteStructure structure)
8891
/// <inheritdoc />
8992
public string Build(SqlUpsertQueryStructure structure)
9093
{
91-
// TODO: these should be put in a transcation
92-
throw new NotImplementedException();
94+
(string sets, string updates, string select) = MakeStoreUpdatePK(structure.PrimaryKey());
95+
96+
string insert = $"INSERT INTO {QuoteIdentifier(structure.TableName)} ({Build(structure.InsertColumns)}) " +
97+
$"VALUES ({string.Join(", ", (structure.Values))}) ";
98+
99+
return sets + ";\n" +
100+
insert + " ON DUPLICATE KEY " +
101+
$"UPDATE {Build(structure.UpdateOperations, ", ")}" +
102+
$", " + updates + ";" +
103+
$" SET @ROWCOUNT=ROW_COUNT(); " +
104+
$"SELECT " + select + $" WHERE @ROWCOUNT != 1;" +
105+
$"SELECT {MakeUpsertSelections(structure)} WHERE @ROWCOUNT = 1;";
106+
}
107+
108+
/// <summary>
109+
/// Makes the query segments to store PK during an update
110+
/// </summary>
111+
private (string, string, string) MakeStoreUpdatePK(List<string> primaryKey)
112+
{
113+
// Create local variables to store the pk columns
114+
string sets = String.Join(";\n", primaryKey.Select((x, index) => $"SET {"@LU_" + index.ToString()} := 0"));
115+
116+
// Fetch the value to local variables
117+
string updates = String.Join(", ", primaryKey.Select((x, index) =>
118+
$"{QuoteIdentifier(x)} = (SELECT {"@LU_" + index.ToString()} := {QuoteIdentifier(x)})"));
119+
120+
// Select local variables and mapping to original column name
121+
string select = String.Join(", ", primaryKey.Select((x, index) => $"{"@LU_" + index.ToString()} AS {QuoteIdentifier(x)}"));
122+
123+
return (sets, updates, select);
93124
}
94125

95126
/// <summary>
@@ -126,8 +157,11 @@ private string MakeInsertSelections(SqlInsertStructure structure)
126157
{
127158
List<string> selections = new();
128159

160+
List<string> fields = structure.PrimaryKey()
161+
.Union(structure.InsertColumns).ToList();
162+
129163
int index = 0;
130-
foreach (string colName in structure.PrimaryKey())
164+
foreach (string colName in fields)
131165
{
132166
string quotedColName = QuoteIdentifier(colName);
133167
if (structure.InsertColumns.Contains(colName))
@@ -137,11 +171,41 @@ private string MakeInsertSelections(SqlInsertStructure structure)
137171
}
138172
else if (structure.GetColumnDefinition(colName).IsAutoGenerated)
139173
{
174+
//TODO: This assumes one column PK
140175
selections.Add($"LAST_INSERT_ID() AS {quotedColName}");
141176
}
142177
}
143178

144179
return string.Join(", ", selections);
145180
}
181+
182+
private string MakeUpsertSelections(SqlUpsertQueryStructure structure)
183+
{
184+
List<string> selections = new();
185+
186+
List<string> fields = structure.AllColumns();
187+
188+
int index = 0;
189+
foreach (string colName in fields)
190+
{
191+
string quotedColName = QuoteIdentifier(colName);
192+
193+
if (structure.InsertColumns.Contains(colName))
194+
{
195+
selections.Add($"{structure.Values[index]} AS {quotedColName}");
196+
index++;
197+
}
198+
else if (structure.GetColumnDefinition(colName).IsAutoGenerated)
199+
{
200+
selections.Add($"LAST_INSERT_ID() AS {quotedColName}");
201+
}
202+
else
203+
{
204+
selections.Add($"NULL AS {quotedColName}");
205+
}
206+
}
207+
208+
return string.Join(", ", selections);
209+
}
146210
}
147211
}

DataGateway.Service/Resolvers/Sql Query Structures/BaseSqlQueryStructure.cs

Lines changed: 9 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1,5 +1,6 @@
11
using System;
22
using System.Collections.Generic;
3+
using System.Linq;
34
using Azure.DataGateway.Service.Models;
45
using Azure.DataGateway.Services;
56
using HotChocolate.Language;
@@ -94,6 +95,14 @@ public List<string> PrimaryKey()
9495
return GetTableDefinition().PrimaryKey;
9596
}
9697

98+
/// <summary>
99+
/// get all columns of the table
100+
/// </summary>
101+
public List<string> AllColumns()
102+
{
103+
return GetTableDefinition().Columns.Select(col => col.Key).ToList();
104+
}
105+
97106
/// <summary>
98107
/// Add parameter to Parameters and return the name associated with it
99108
/// </summary>

DataGateway.Service/Resolvers/Sql Query Structures/SqlUpsertQueryStructure.cs

Lines changed: 8 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -80,6 +80,14 @@ public SqlUpsertQueryStructure(string tableName, IMetadataStoreProvider metadata
8080
}
8181
}
8282

83+
/// <summary>
84+
/// Get the definition of a column by name
85+
/// </summary>
86+
public ColumnDefinition GetColumnDefinition(string columnName)
87+
{
88+
return GetTableDefinition().Columns[columnName];
89+
}
90+
8391
private void PopulateColumns(
8492
IDictionary<string, object> mutationParams,
8593
TableDefinition tableDefinition)

DataGateway.Service/Resolvers/SqlMutationEngine.cs

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -124,7 +124,7 @@ await PerformMutationOperation(
124124
/// In MsSQL upsert:
125125
/// result set #1: result of the UPDATE operation.
126126
/// result set #2: result of the INSERT operation.
127-
if (await dbDataReader.NextResultAsync())
127+
if (await dbDataReader.NextResultAsync() && resultRecord == null)
128128
{
129129
// Since no first result set exists, we overwrite Dictionary here.
130130
resultRecord = await ExtractRowFromDbDataReader(dbDataReader);

DataGateway.Service/appsettings.MySql.json

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -3,7 +3,7 @@
33
"DatabaseType": "MySql",
44
"ResolverConfigFile": "sql-config.json",
55
"DatabaseConnection": {
6-
"ConnectionString": "server=localhost;database=graphql"
6+
"ConnectionString": "server=localhost;database=graphql;Allow User Variables=true;"
77
}
88
}
99
}
Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1,7 +1,7 @@
11
{
22
"DataGatewayConfig": {
33
"DatabaseConnection": {
4-
"ConnectionString": "server=localhost;database=datagatewaytest;uid=root;pwd=REPLACEME"
4+
"ConnectionString": "server=localhost;database=datagatewaytest;Allow User Variables=true;uid=root;pwd=REPLACEME"
55
}
66
}
77
}

0 commit comments

Comments
 (0)