Skip to content

Commit

Permalink
GraphQL stored procedure support for DW (#2008)
Browse files Browse the repository at this point in the history
## Why make this change?
This change adds stored procedure execution support for Datawarehouse. 

## What is this change?
In this change, the definitions in DwSqlQueryBuilder are created to have
the dw queries to get result set information of the stored procedure and
to actually execute stored procedure queries.

In addition, for both mssql and dwsql the execution logic flows through
a single parser. It ensures that both mssql and dw sql use consistent
naming to ensure easy parsing of information.

## How was this tested?

- [ ] Integration Tests
1.Tested against a warehouse:

![image](https://github.com/Azure/data-api-builder/assets/124841904/fac592c5-d99e-4d12-ac31-7c3ee043c641)
2. Added Tests for stored procedure.
  • Loading branch information
rohkhann committed Feb 14, 2024
1 parent 302520d commit f557b4d
Show file tree
Hide file tree
Showing 11 changed files with 661 additions and 12 deletions.
19 changes: 18 additions & 1 deletion config-generators/dwsql-commands.txt
Original file line number Diff line number Diff line change
Expand Up @@ -26,6 +26,14 @@ add Notebook --config "dab-config.DwSql.json" --source "notebooks" --permissions
add Journal --config "dab-config.DwSql.json" --source "journals" --rest true --graphql true --permissions "policy_tester_noupdate:create,delete" --source.key-fields "id"
add ArtOfWar --config "dab-config.DwSql.json" --source "aow" --rest true --graphql false --permissions "anonymous:*" --source.key-fields "NoteNum"
add stocks_view_selected --config "dab-config.DwSql.json" --source stocks_view_selected --source.type "view" --source.key-fields "categoryid,pieceid" --permissions "anonymous:*" --rest true --graphql true
add GetBooks --config "dab-config.DwSql.json" --source "get_books" --source.type "stored-procedure" --permissions "anonymous:execute" --rest true --graphql true
add GetPublisher --config "dab-config.DwSql.json" --source "get_publisher_by_id" --source.type "stored-procedure" --permissions "anonymous:execute" --rest true --graphql true --graphql.operation "query"
add GetAuthorsHistoryByFirstName --config "dab-config.DwSql.json" --source "get_authors_history_by_first_name" --source.type "stored-procedure" --source.params "firstName:Aaron" --permissions "anonymous:execute" --rest true --graphql SearchAuthorByFirstName
add CountBooks --config "dab-config.DwSql.json" --source "count_books" --source.type "stored-procedure" --permissions "anonymous:execute" --rest true --graphql true
add InsertBook --config "dab-config.DwSql.json" --source "insert_book" --source.type "stored-procedure" --source.params "title:randomX,publisher_id:1234" --permissions "anonymous:execute" --rest true --graphql true
add DeleteLastInsertedBook --config "dab-config.DwSql.json" --source "delete_last_inserted_book" --source.type "stored-procedure" --permissions "anonymous:execute" --rest true --graphql true
add UpdateBookTitle --config "dab-config.DwSql.json" --source "update_book_title" --source.type "stored-procedure" --source.params "id:1,title:Testing Tonight" --permissions "anonymous:execute" --rest true --graphql true
add InsertAndDisplayAllBooksUnderGivenPublisher --config "dab-config.DwSql.json" --source "insert_and_display_all_books_for_given_publisher" --source.type "stored-procedure" --source.params "title:MyTitle,publisher_name:MyPublisher" --permissions "anonymous:execute" --rest true --graphql true
update stocks_price --config "dab-config.DwSql.json" --permissions "anonymous:read"
update stocks_price --config "dab-config.DwSql.json" --permissions "TestNestedFilterFieldIsNull_ColumnForbidden:read" --fields.exclude "price"
update stocks_price --config "dab-config.DwSql.json" --permissions "TestNestedFilterFieldIsNull_EntityReadForbidden:create"
Expand Down Expand Up @@ -136,4 +144,13 @@ update Journal --config "dab-config.DwSql.json" --permissions "policy_tester_upd
update Journal --config "dab-config.DwSql.json" --permissions "policy_tester_update_noread:delete" --fields.include "*" --policy-database "@item.id eq 1"
update Journal --config "dab-config.DwSql.json" --permissions "authorizationHandlerTester:read"
update ArtOfWar --config "dab-config.DwSql.json" --permissions "authenticated:*" --map "DetailAssessmentAndPlanning:始計,WagingWar:作戰,StrategicAttack:謀攻,NoteNum:┬─┬ノ( º _ ºノ)"
update stocks_view_selected --config "dab-config.DwSql.json" --permissions "authenticated:create,read,update,delete"
update stocks_view_selected --config "dab-config.DwSql.json" --permissions "authenticated:create,read,update,delete"
update InsertBook --config "dab-config.DwSql.json" --permissions "authenticated:execute"
update DeleteLastInsertedBook --config "dab-config.DwSql.json" --permissions "authenticated:execute"
update UpdateBookTitle --config "dab-config.DwSql.json" --permissions "authenticated:execute"
update InsertAndDisplayAllBooksUnderGivenPublisher --config "dab-config.DwSql.json" --permissions "authenticated:execute"
update GetPublisher --config "dab-config.DwSql.json" --permissions "authenticated:execute"
update GetBooks --config "dab-config.DwSql.json" --permissions "authenticated:execute" --graphql.operation "Query"
update CountBooks --config "dab-config.DwSql.json" --permissions "authenticated:execute"
update Sales --config "dab-config.DwSql.json" --permissions "authenticated:*"
update GetAuthorsHistoryByFirstName --config "dab-config.DwSql.json" --permissions "authenticated:execute"
3 changes: 3 additions & 0 deletions src/Core/Resolvers/BaseSqlQueryBuilder.cs
Original file line number Diff line number Diff line change
Expand Up @@ -20,6 +20,9 @@ public abstract class BaseSqlQueryBuilder
{
public const string SCHEMA_NAME_PARAM = "schemaName";
public const string TABLE_NAME_PARAM = "tableName";
public const string STOREDPROC_COLUMN_NAME = "name";
public const string STOREDPROC_COLUMN_SYSTEMTYPENAME = "system_type_name";
public const string STOREDPROC_COLUMN_ISNULLABLE = "is_nullable";

/// <summary>
/// Predicate added to the query when no other predicates exist.
Expand Down
24 changes: 22 additions & 2 deletions src/Core/Resolvers/DWSqlQueryBuilder.cs
Original file line number Diff line number Diff line change
Expand Up @@ -209,7 +209,8 @@ public string Build(SqlDeleteStructure structure)
/// <inheritdoc />
public string Build(SqlExecuteStructure structure)
{
throw new NotImplementedException("DataWarehouse sql currently does not support executes");
return $"EXECUTE {QuoteIdentifier(structure.DatabaseObject.SchemaName)}.{QuoteIdentifier(structure.DatabaseObject.Name)} " +
$"{BuildProcedureParameterList(structure.ProcedureParameters)}";
}

/// <inheritdoc />
Expand Down Expand Up @@ -306,7 +307,8 @@ private string WrappedColumns(SqlQueryStructure structure)
/// <inheritdoc />
public string BuildStoredProcedureResultDetailsQuery(string databaseObjectName)
{
throw new NotImplementedException("DataWarehouse sql currently does not support stored procedures");
string query = $"EXEC sp_describe_first_result_set @tsql = N'{databaseObjectName}';";
return query;
}

/// <summary>
Expand Down Expand Up @@ -338,5 +340,23 @@ public string BuildFetchEnabledTriggersQuery()

return query;
}

/// <summary>
/// Builds the parameter list for the stored procedure execute call
/// paramKeys are the user-generated procedure parameter names
/// paramValues are the auto-generated, parameterized values (@param0, @param1..)
/// </summary>
private static string BuildProcedureParameterList(Dictionary<string, object> procedureParameters)
{
StringBuilder sb = new();
foreach ((string paramKey, object paramValue) in procedureParameters)
{
sb.Append($"@{paramKey} = {paramValue}, ");
}

string parameterList = sb.ToString();
// If at least one parameter added, remove trailing comma and space, else return empty string
return parameterList.Length > 0 ? parameterList[..^2] : parameterList;
}
}
}
4 changes: 3 additions & 1 deletion src/Core/Resolvers/MsSqlQueryBuilder.cs
Original file line number Diff line number Diff line change
Expand Up @@ -472,8 +472,10 @@ private static string BuildProcedureParameterList(Dictionary<string, object> pro
/// </summary>
public string BuildStoredProcedureResultDetailsQuery(string databaseObjectName)
{
// The system type name column is aliased while the other columns are not to ensure
// names are consistent across different sql implementations as all go through same deserialization logic
string query = "SELECT " +
"name as result_field_name, TYPE_NAME(system_type_id) as result_type, is_nullable " +
$"{STOREDPROC_COLUMN_NAME}, TYPE_NAME(system_type_id) as {STOREDPROC_COLUMN_SYSTEMTYPENAME}, {STOREDPROC_COLUMN_ISNULLABLE} " +
"FROM " +
"sys.dm_exec_describe_first_result_set_for_object (" +
$"OBJECT_ID('{databaseObjectName}'), 0) " +
Expand Down
8 changes: 4 additions & 4 deletions src/Core/Services/MetadataProviders/SqlMetadataProvider.cs
Original file line number Diff line number Diff line change
Expand Up @@ -919,7 +919,7 @@ private async Task PopulateObjectDefinitionForEntities()
GetDatabaseObjectName(entityName),
GetStoredProcedureDefinition(entityName));

if (GetDatabaseType() == DatabaseType.MSSQL)
if (GetDatabaseType() == DatabaseType.MSSQL || GetDatabaseType() == DatabaseType.DWSQL)
{
await PopulateResultSetDefinitionsForStoredProcedureAsync(
GetSchemaName(entityName),
Expand Down Expand Up @@ -985,9 +985,9 @@ private async Task PopulateObjectDefinitionForEntities()
// one row in the result set.
foreach (JsonElement element in sqlResult.RootElement.EnumerateArray())
{
string resultFieldName = element.GetProperty("result_field_name").ToString();
Type resultFieldType = SqlToCLRType(element.GetProperty("result_type").ToString());
bool isResultFieldNullable = element.GetProperty("is_nullable").GetBoolean();
string resultFieldName = element.GetProperty(BaseSqlQueryBuilder.STOREDPROC_COLUMN_NAME).ToString();
Type resultFieldType = SqlToCLRType(element.GetProperty(BaseSqlQueryBuilder.STOREDPROC_COLUMN_SYSTEMTYPENAME).ToString());
bool isResultFieldNullable = element.GetProperty(BaseSqlQueryBuilder.STOREDPROC_COLUMN_ISNULLABLE).GetBoolean();

// Store the dictionary containing result set field with its type as Columns
storedProcedureDefinition.Columns.TryAdd(resultFieldName, new(resultFieldType) { IsNullable = isResultFieldNullable });
Expand Down
6 changes: 5 additions & 1 deletion src/Core/Services/TypeHelper.cs
Original file line number Diff line number Diff line change
Expand Up @@ -227,7 +227,11 @@ public static JsonDataType GetJsonDataTypeFromSystemType(Type type)
/// <exception>Failed type conversion.</exception>"
public static Type GetSystemTypeFromSqlDbType(string sqlDbTypeName)
{
if (Enum.TryParse(sqlDbTypeName, ignoreCase: true, out SqlDbType sqlDbType))
// Remove the length specifier from the type name if it exists.Example: varchar(50) -> varchar
int separatorIndex = sqlDbTypeName.IndexOf('(');
string baseType = separatorIndex == -1 ? sqlDbTypeName : sqlDbTypeName.Substring(0, separatorIndex);

if (Enum.TryParse(baseType, ignoreCase: true, out SqlDbType sqlDbType))
{
if (_sqlDbTypeToType.TryGetValue(sqlDbType, out Type? value))
{
Expand Down
77 changes: 77 additions & 0 deletions src/Service.Tests/DatabaseSchema-DwSql.sql
Original file line number Diff line number Diff line change
Expand Up @@ -30,6 +30,16 @@ DROP TABLE IF EXISTS GQLmappings;
DROP TABLE IF EXISTS bookmarks;
DROP TABLE IF EXISTS mappedbookmarks;
DROP TABLE IF EXISTS publishers;
DROP TABLE IF EXISTS authors_history;
DROP PROCEDURE IF EXISTS get_books;
DROP PROCEDURE IF EXISTS get_book_by_id;
DROP PROCEDURE IF EXISTS get_publisher_by_id;
DROP PROCEDURE IF EXISTS count_books;
DROP PROCEDURE IF EXISTS get_authors_history_by_first_name;
DROP PROCEDURE IF EXISTS insert_book;
DROP PROCEDURE IF EXISTS delete_last_inserted_book;
DROP PROCEDURE IF EXISTS update_book_title;
DROP PROCEDURE IF EXISTS insert_and_display_all_books_for_given_publisher;
DROP SCHEMA IF EXISTS [foo];
COMMIT;

Expand Down Expand Up @@ -196,8 +206,75 @@ CREATE TABLE type_table(
uuid_types uniqueidentifier
);

CREATE TABLE authors_history (
id int NOT NULL,
first_name varchar(100) NOT NULL,
middle_name varchar(100),
last_name varchar(100) NOT NULL,
year_of_publish int,
books_published int
);

EXEC('CREATE PROCEDURE get_publisher_by_id @id int AS
SELECT * FROM dbo.publishers
WHERE id = @id');
EXEC('CREATE PROCEDURE get_books AS
SELECT * FROM dbo.books');
EXEC('CREATE PROCEDURE get_book_by_id @id int AS
SELECT * FROM dbo.books
WHERE id = @id');
EXEC('CREATE PROCEDURE count_books AS
SELECT COUNT(*) AS total_books FROM dbo.books');
EXEC('CREATE PROCEDURE get_authors_history_by_first_name @firstName varchar(100) AS
BEGIN
SELECT
concat(first_name, '' '', (middle_name + '' ''), last_name) as author_name,
min(year_of_publish) as first_publish_year,
sum(books_published) as total_books_published
FROM
authors_history
WHERE
first_name=@firstName
GROUP BY
concat(first_name, '' '', (middle_name + '' ''), last_name)
END');
EXEC('CREATE PROCEDURE insert_book @book_id int, @title varchar(max), @publisher_id int AS
INSERT INTO dbo.books(id, title, publisher_id) VALUES (@book_id, @title, @publisher_id)');
EXEC('CREATE PROCEDURE delete_last_inserted_book AS
BEGIN
DELETE FROM dbo.books
WHERE
id = (select max(id) from dbo.books)
END');
EXEC('CREATE PROCEDURE update_book_title @id int, @title varchar(max) AS
BEGIN
UPDATE dbo.books SET title = @title WHERE id = @id
SELECT * from dbo.books WHERE id = @id
END');
EXEC('CREATE PROCEDURE insert_and_display_all_books_for_given_publisher @book_id int,@title varchar(max), @publisher_name varchar(max) AS
BEGIN
DECLARE @publisher_id AS INT;
SET @publisher_id = (SELECT id FROM dbo.publishers WHERE name = @publisher_name);
INSERT INTO dbo.books(id, title, publisher_id)
VALUES(@book_id, @title, @publisher_id);
SELECT * FROM dbo.books WHERE publisher_id = @publisher_id;
END');
INSERT INTO authors(id, name, birthdate) VALUES (123, 'Jelte', '2001-01-01'), (124, 'Aniruddh', '2002-02-02'), (125, 'Aniruddh', '2001-01-01'), (126, 'Aaron', '2001-01-01');

INSERT INTO authors_history(id, first_name, middle_name, last_name, year_of_publish, books_published)
VALUES
(1, 'Isaac', null, 'Asimov', 1993, 6),
(2, 'Robert', 'A.', 'Heinlein', 1886, null),
(3, 'Robert', null, 'Silvenberg', null, null),
(4, 'Dan', null, 'Simmons', 1759, 3),
(5, 'Isaac', null, 'Asimov', 2000, null),
(6, 'Robert', 'A.', 'Heinlein', 1899, 2),
(7, 'Isaac', null, 'Silvenberg', 1664, null),
(8, 'Dan', null, 'Simmons', 1799, 3),
(9, 'Aaron', null, 'Mitchells', 2001, 1),
(10, 'Aaron', 'F.', 'Burtle', null, null)

INSERT INTO GQLmappings(__column1, __column2, column3) VALUES (1, 'Incompatible GraphQL Name', 'Compatible GraphQL Name');
INSERT INTO GQLmappings(__column1, __column2, column3) VALUES (3, 'Old Value', 'Record to be Updated');
INSERT INTO GQLmappings(__column1, __column2, column3) VALUES (4, 'Lost Record', 'Record to be Deleted');
Expand Down

0 comments on commit f557b4d

Please sign in to comment.