diff --git a/ConfigGenerators/MsSqlCommands.txt b/ConfigGenerators/MsSqlCommands.txt
index f2882bb2ac..f8e7801224 100644
--- a/ConfigGenerators/MsSqlCommands.txt
+++ b/ConfigGenerators/MsSqlCommands.txt
@@ -23,6 +23,7 @@ add Notebook --config "dab-config.MsSql.json" --source "notebooks" --permissions
add Journal --config "dab-config.MsSql.json" --source "journals" --rest true --graphql true --permissions "policy_tester_noupdate:create,delete"
add ArtOfWar --config "dab-config.MsSql.json" --source "aow" --rest true --permissions "anonymous:*"
add series --config "dab-config.MsSql.json" --source "series" --permissions "anonymous:*"
+add Sales --config "dab-config.MsSql.json" --source "sales" --permissions "anonymous:*" --rest true --graphql true
add GetBooks --config "dab-config.MsSql.json" --source "get_books" --source.type "stored-procedure" --permissions "anonymous:read" --rest true --graphql false
add GetBook --config "dab-config.MsSql.json" --source "get_book_by_id" --source.type "stored-procedure" --permissions "anonymous:read" --rest true --graphql false
update Publisher --config "dab-config.MsSql.json" --permissions "authenticated:create,read,update,delete" --rest true --graphql true --relationship books --target.entity Book --cardinality many
@@ -107,3 +108,4 @@ update Journal --config "dab-config.MsSql.json" --permissions "authorizationHand
update ArtOfWar --config "dab-config.MsSql.json" --permissions "authenticated:*" --map "DetailAssessmentAndPlanning:始計,WagingWar:作戰,StrategicAttack:謀攻,NoteNum:┬─┬ノ( º _ ºノ)"
update GetBook --config "dab-config.MsSql.json" --permissions "authenticated:*"
update GetBooks --config "dab-config.MsSql.json" --permissions "authenticated:*"
+update Sales --config "dab-config.MsSql.json" --permissions "authenticated:*"
diff --git a/ConfigGenerators/MySqlCommands.txt b/ConfigGenerators/MySqlCommands.txt
index 02582ec25f..c7c4b3ea4e 100644
--- a/ConfigGenerators/MySqlCommands.txt
+++ b/ConfigGenerators/MySqlCommands.txt
@@ -23,6 +23,7 @@ add Notebook --config "dab-config.MySql.json" --source "notebooks" --permissions
add Journal --config "dab-config.MySql.json" --source "journals" --rest true --graphql true --permissions "policy_tester_noupdate:create,delete"
add ArtOfWar --config "dab-config.MySql.json" --source "aow" --rest true --permissions "anonymous:*"
add series --config "dab-config.MySql.json" --source "series" --permissions "anonymous:*"
+add Sales --config "dab-config.MySql.json" --source "sales" --permissions "anonymous:*" --rest true --graphql true
update Publisher --config "dab-config.MySql.json" --permissions "authenticated:create,read,update,delete" --rest true --graphql true --relationship books --target.entity Book --cardinality many
update Publisher --config "dab-config.MySql.json" --permissions "policy_tester_01:create,delete"
update Publisher --config "dab-config.MySql.json" --permissions "policy_tester_01:update" --fields.include "*"
@@ -103,3 +104,4 @@ update Journal --config "dab-config.MySql.json" --permissions "policy_tester_upd
update Journal --config "dab-config.MySql.json" --permissions "policy_tester_update_noread:delete" --fields.include "*" --policy-database "@item.id eq 1"
update Journal --config "dab-config.MySql.json" --permissions "authorizationHandlerTester:read"
update ArtOfWar --config "dab-config.MySql.json" --permissions "authenticated:*" --map "DetailAssessmentAndPlanning:始計,WagingWar:作戰,StrategicAttack:謀攻,NoteNum:┬─┬ノ( º _ ºノ)"
+update Sales --config "dab-config.MySql.json" --permissions "authenticated:*"
diff --git a/ConfigGenerators/PostgreSqlCommands.txt b/ConfigGenerators/PostgreSqlCommands.txt
index dc1d01367a..b79abf31a6 100644
--- a/ConfigGenerators/PostgreSqlCommands.txt
+++ b/ConfigGenerators/PostgreSqlCommands.txt
@@ -23,6 +23,7 @@ add Notebook --config "dab-config.PostgreSql.json" --source "notebooks" --permis
add Journal --config "dab-config.PostgreSql.json" --source "journals" --rest true --graphql true --permissions "policy_tester_noupdate:create,delete"
add ArtOfWar --config "dab-config.PostgreSql.json" --source "aow" --rest true --permissions "anonymous:*"
add series --config "dab-config.PostgreSql.json" --source "series" --permissions "anonymous:*"
+add Sales --config "dab-config.PostgreSql.json" --source "sales" --permissions "anonymous:*" --rest true --graphql true
update Publisher --config "dab-config.PostgreSql.json" --permissions "authenticated:create,read,update,delete" --rest true --graphql true --relationship books --target.entity Book --cardinality many
update Publisher --config "dab-config.PostgreSql.json" --permissions "policy_tester_01:create,delete"
update Publisher --config "dab-config.PostgreSql.json" --permissions "policy_tester_01:update" --fields.include "*"
@@ -100,3 +101,4 @@ update Journal --config "dab-config.PostgreSql.json" --permissions "policy_teste
update Journal --config "dab-config.PostgreSql.json" --permissions "policy_tester_update_noread:delete" --fields.include "*" --policy-database "@item.id eq 1"
update Journal --config "dab-config.PostgreSql.json" --permissions "authorizationHandlerTester:read"
update ArtOfWar --config "dab-config.PostgreSql.json" --permissions "authenticated:*" --map "DetailAssessmentAndPlanning:始計,WagingWar:作戰,StrategicAttack:謀攻,NoteNum:┬─┬ノ( º _ ºノ)"
+update Sales --config "dab-config.PostgreSql.json" --permissions "authenticated:*"
diff --git a/ConfigGenerators/dab-config.sql.reference.json b/ConfigGenerators/dab-config.sql.reference.json
index 4d82461c78..43fa9b9290 100644
--- a/ConfigGenerators/dab-config.sql.reference.json
+++ b/ConfigGenerators/dab-config.sql.reference.json
@@ -945,6 +945,29 @@
"actions": [ "*" ]
}
]
+ },
+ "Sales": {
+ "source": {
+ "type": "table",
+ "object": "sales",
+ "key-fields": []
+ },
+ "rest": true,
+ "graphql": true,
+ "permissions": [
+ {
+ "role": "anonymous",
+ "actions": [
+ "*"
+ ]
+ },
+ {
+ "role": "authenticated",
+ "actions": [
+ "*"
+ ]
+ }
+ ]
}
}
}
diff --git a/src/Service.Tests/SqlTests/GraphQLMutationTests/GraphQLMutationTestBase.cs b/src/Service.Tests/SqlTests/GraphQLMutationTests/GraphQLMutationTestBase.cs
index 9f58d7a3c0..bc6c7d01f1 100644
--- a/src/Service.Tests/SqlTests/GraphQLMutationTests/GraphQLMutationTestBase.cs
+++ b/src/Service.Tests/SqlTests/GraphQLMutationTests/GraphQLMutationTestBase.cs
@@ -59,6 +59,32 @@ public async Task InsertMutationWithVariables(string dbQuery)
SqlTestHelper.PerformTestEqualJsonStrings(expected, actual.ToString());
}
+ ///
+ /// Do: Inserts new sale item into sales table that automatically calculates the total price
+ /// based on subtotal and tax.
+ /// Check: Calculated column is persisted successfully with correct calculated result.
+ ///
+ public async Task InsertMutationForComputedColumns(string dbQuery)
+ {
+ string graphQLMutationName = "createSales";
+ string graphQLMutation = @"
+ mutation{
+ createSales(item: {item_name: ""headphones"", subtotal: 195.00, tax: 10.33}) {
+ id
+ item_name
+ subtotal
+ tax
+ total
+ }
+ }
+ ";
+
+ JsonElement actual = await ExecuteGraphQLRequestAsync(graphQLMutation, graphQLMutationName, isAuthenticated: true);
+ string expected = await GetDatabaseResultAsync(dbQuery);
+
+ SqlTestHelper.PerformTestEqualJsonStrings(expected, actual.ToString());
+ }
+
///
/// Do: Inserts new review with default content for a Review and return its id and content
/// Check: If book with the given id is present in the database then
@@ -129,6 +155,31 @@ public async Task UpdateMutation(string dbQuery)
SqlTestHelper.PerformTestEqualJsonStrings(expected, actual.ToString());
}
+ ///
+ /// Do: Update Sales in database and return its updated fields
+ /// Check: The calculated column has successfully been updated after updating the other fields
+ ///
+ public async Task UpdateMutationForComputedColumns(string dbQuery)
+ {
+ string graphQLMutationName = "updateSales";
+ string graphQLMutation = @"
+ mutation{
+ updateSales(id: 2, item: {item_name: ""phone"", subtotal: 495.00, tax: 30.33}) {
+ id
+ item_name
+ subtotal
+ tax
+ total
+ }
+ }
+ ";
+
+ JsonElement actual = await ExecuteGraphQLRequestAsync(graphQLMutation, graphQLMutationName, isAuthenticated: true);
+ string expected = await GetDatabaseResultAsync(dbQuery);
+
+ SqlTestHelper.PerformTestEqualJsonStrings(expected, actual.ToString());
+ }
+
///
/// Do: Delete book by id
/// Check: if the mutation returned result is as expected and if book by that id has been deleted
diff --git a/src/Service.Tests/SqlTests/GraphQLMutationTests/MsSqlGraphQLMutationTests.cs b/src/Service.Tests/SqlTests/GraphQLMutationTests/MsSqlGraphQLMutationTests.cs
index 12d3901afc..25c85f9c6a 100644
--- a/src/Service.Tests/SqlTests/GraphQLMutationTests/MsSqlGraphQLMutationTests.cs
+++ b/src/Service.Tests/SqlTests/GraphQLMutationTests/MsSqlGraphQLMutationTests.cs
@@ -79,6 +79,35 @@ ORDER BY [id] asc
await InsertMutationWithVariables(msSqlQuery);
}
+ ///
+ /// Do: Inserts new sale item into sales table that automatically calculates the total price
+ /// based on subtotal and tax.
+ /// Check: Calculated column is persisted successfully with correct calculated result.
+ ///
+ [TestMethod]
+ public async Task InsertMutationForComputedColumns()
+ {
+ string msSqlQuery = @"
+ SELECT TOP 1 [table0].[id] AS [id],
+ [table0].[item_name] AS [item_name],
+ [table0].[subtotal] AS [subtotal],
+ [table0].[tax] AS [tax],
+ [table0].[total] AS [total]
+ FROM [sales] AS [table0]
+ WHERE [table0].[id] = 5001
+ AND [table0].[item_name] = 'headphones'
+ AND [table0].[subtotal] = 195.00
+ AND [table0].[tax] = 10.33
+ AND [table0].[total] = 205.33
+ ORDER BY [id] asc
+ FOR JSON PATH,
+ INCLUDE_NULL_VALUES,
+ WITHOUT_ARRAY_WRAPPER
+ ";
+
+ await InsertMutationForComputedColumns(msSqlQuery);
+ }
+
///
/// Do: Inserts new review with default content for a Review and return its id and content
/// Check: If book with the given id is present in the database then
@@ -146,6 +175,34 @@ ORDER BY [books].[id] asc
await UpdateMutation(msSqlQuery);
}
+ ///
+ /// Do: Update Sales in database and return its updated fields
+ /// Check: The calculated column has successfully been updated after updating the other fields
+ ///
+ [TestMethod]
+ public async Task UpdateMutationForComputedColumns()
+ {
+ string msSqlQuery = @"
+ SELECT TOP 1 [table0].[id] AS [id],
+ [table0].[item_name] AS [item_name],
+ [table0].[subtotal] AS [subtotal],
+ [table0].[tax] AS [tax],
+ [table0].[total] AS [total]
+ FROM [sales] AS [table0]
+ WHERE [table0].[id] = 2
+ AND [table0].[item_name] = 'phone'
+ AND [table0].[subtotal] = 495.00
+ AND [table0].[tax] = 30.33
+ AND [table0].[total] = 525.33
+ ORDER BY [id] asc
+ FOR JSON PATH,
+ INCLUDE_NULL_VALUES,
+ WITHOUT_ARRAY_WRAPPER
+ ";
+
+ await UpdateMutationForComputedColumns(msSqlQuery);
+ }
+
///
/// Do: Delete book by id
/// Check: if the mutation returned result is as expected and if book by that id has been deleted
diff --git a/src/Service.Tests/SqlTests/GraphQLMutationTests/MySqlGraphQLMutationTests.cs b/src/Service.Tests/SqlTests/GraphQLMutationTests/MySqlGraphQLMutationTests.cs
index 1736e201ac..43e05ac392 100644
--- a/src/Service.Tests/SqlTests/GraphQLMutationTests/MySqlGraphQLMutationTests.cs
+++ b/src/Service.Tests/SqlTests/GraphQLMutationTests/MySqlGraphQLMutationTests.cs
@@ -60,6 +60,39 @@ ORDER BY `id` asc LIMIT 1
await InsertMutation(mySqlQuery);
}
+ ///
+ /// Do: Inserts a new sale item into the sales table that automatically calculates the total price
+ /// based on subtotal and tax.
+ /// Check: Calculated column is persisted successfully with correct calculated result.
+ ///
+ [TestMethod]
+ public async Task InsertMutationForComputedColumns()
+ {
+ string mySqlQuery = @"
+ SELECT JSON_OBJECT(
+ 'id', `subq`.`id`, 'item_name', `subq`.`item_name`,
+ 'subtotal', `subq`.`subtotal`, 'tax', `subq`.`tax`,
+ 'total', `subq`.`total`
+ ) AS `data`
+ FROM (
+ SELECT `table0`.`id` AS `id`,
+ `table0`.`item_name` AS `item_name`,
+ `table0`.`subtotal` AS `subtotal`,
+ `table0`.`tax` AS `tax`,
+ `table0`.`total` AS `total`
+ FROM `sales` AS `table0`
+ WHERE `id` = 5001
+ AND `item_name` = 'headphones'
+ AND `subtotal` = 195.00
+ AND `tax` = 10.33
+ AND `total` = 205.33
+ ORDER BY `id` asc LIMIT 1
+ ) AS `subq`
+ ";
+
+ await InsertMutationForComputedColumns(mySqlQuery);
+ }
+
///
/// Do: Inserts new book using variables to set its title and publisher_id
/// Check: If book with the expected values of the new book is present in the database and
@@ -149,6 +182,36 @@ ORDER BY `table0`.`id` asc LIMIT 1
await UpdateMutation(mySqlQuery);
}
+ ///
+ /// Do: Update Sales in database and return its updated fields
+ /// Check: The calculated column has successfully been updated after updating the other fields
+ ///
+ [TestMethod]
+ // IGNORE FOR NOW, SEE: Issue #1001
+ [Ignore]
+ public async Task UpdateMutationForComputedColumns()
+ {
+ string mySqlQuery = @"
+ SELECT JSON_OBJECT(
+ 'id', `subq2`.`id`, 'item_name', `subq2`.`item_name`,
+ 'subtotal', `subq2`.`subtotal`, 'tax', `subq2`.`tax`,
+ 'total', `subq2`.`total`
+ ) AS `data`
+ FROM (
+ SELECT `table0`.`id` AS `id`,
+ `table0`.`item_name` AS `item_name`,
+ `table0`.`subtotal` AS `subtotal`,
+ `table0`.`tax` AS `tax`,
+ `table0`.`total` AS `total`
+ FROM `sales` AS `table0`
+ WHERE `id` = 2
+ ORDER BY `id` asc LIMIT 1
+ ) AS `subq2`
+ ";
+
+ await UpdateMutationForComputedColumns(mySqlQuery);
+ }
+
///
/// Do: Delete book by id
/// Check: if the mutation returned result is as expected and if book by that id has been deleted
diff --git a/src/Service.Tests/SqlTests/GraphQLMutationTests/PostgreSqlGraphQLMutationTests.cs b/src/Service.Tests/SqlTests/GraphQLMutationTests/PostgreSqlGraphQLMutationTests.cs
index f9a54367bf..740a1e0abc 100644
--- a/src/Service.Tests/SqlTests/GraphQLMutationTests/PostgreSqlGraphQLMutationTests.cs
+++ b/src/Service.Tests/SqlTests/GraphQLMutationTests/PostgreSqlGraphQLMutationTests.cs
@@ -59,6 +59,35 @@ ORDER BY id asc
await InsertMutation(postgresQuery);
}
+ ///
+ /// Do: Inserts new sale item into sales table that automatically calculates the total price
+ /// based on subtotal and tax.
+ /// Check: Calculated column is persisted successfully with correct calculated result.
+ ///
+ [TestMethod]
+ public async Task InsertMutationForComputedColumns()
+ {
+ string postgresQuery = @"
+ SELECT to_jsonb(subq) AS DATA
+ FROM
+ (SELECT table0.id AS id,
+ table0.item_name AS item_name,
+ table0.subtotal AS subtotal,
+ table0.tax AS tax,
+ table0.total AS total
+ FROM sales AS table0
+ WHERE id = 5001
+ AND item_name = 'headphones'
+ AND subtotal = 195.00
+ AND tax = 10.33
+ AND total = 205.33
+ ORDER BY id asc
+ LIMIT 1) AS subq
+ ";
+
+ await InsertMutationForComputedColumns(postgresQuery);
+ }
+
///
/// Do: Inserts new book using variables to set its title and publisher_id
/// Check: If book with the expected values of the new book is present in the database and
@@ -152,6 +181,34 @@ ORDER BY id asc
await UpdateMutation(postgresQuery);
}
+ ///
+ /// Do: Update Sales in database and return its updated fields
+ /// Check: The calculated column has successfully been updated after updating the other fields
+ ///
+ [TestMethod]
+ public async Task UpdateMutationForComputedColumns()
+ {
+ string postgresQuery = @"
+ SELECT to_jsonb(subq) AS DATA
+ FROM
+ (SELECT table0.id AS id,
+ table0.item_name AS item_name,
+ table0.subtotal AS subtotal,
+ table0.tax AS tax,
+ table0.total AS total
+ FROM sales AS table0
+ WHERE id = 2
+ AND item_name = 'phone'
+ AND subtotal = 495.00
+ AND tax = 30.33
+ AND total = 525.33
+ ORDER BY id asc
+ LIMIT 1) AS subq
+ ";
+
+ await UpdateMutationForComputedColumns(postgresQuery);
+ }
+
///
/// Do: Delete book by id
/// Check: if the mutation returned result is as expected and if book by that id has been deleted
diff --git a/src/Service.Tests/SqlTests/GraphQLQueryTests/GraphQLQueryTestBase.cs b/src/Service.Tests/SqlTests/GraphQLQueryTests/GraphQLQueryTestBase.cs
index e900b4e25c..3dc92cf814 100644
--- a/src/Service.Tests/SqlTests/GraphQLQueryTests/GraphQLQueryTestBase.cs
+++ b/src/Service.Tests/SqlTests/GraphQLQueryTests/GraphQLQueryTestBase.cs
@@ -54,6 +54,31 @@ public async Task MultipleResultQueryWithVariables(string dbQuery)
SqlTestHelper.PerformTestEqualJsonStrings(expected, actual.GetProperty("items").ToString());
}
+ ///
+ /// Gets array of results for querying a table containing computed columns.
+ ///
+ /// rows from sales table
+ public async Task MultipleResultQueryContainingComputedColumns(string dbQuery)
+ {
+ string graphQLQueryName = "sales";
+ string graphQLQuery = @"{
+ sales(first: 10) {
+ items {
+ id
+ item_name
+ subtotal
+ tax
+ total
+ }
+ }
+ }";
+
+ JsonElement actual = await ExecuteGraphQLRequestAsync(graphQLQuery, graphQLQueryName, isAuthenticated: false);
+ string expected = await GetDatabaseResultAsync(dbQuery);
+
+ SqlTestHelper.PerformTestEqualJsonStrings(expected, actual.GetProperty("items").ToString());
+ }
+
///
/// Gets array of results for querying more than one item.
///
diff --git a/src/Service.Tests/SqlTests/GraphQLQueryTests/MsSqlGraphQLQueryTests.cs b/src/Service.Tests/SqlTests/GraphQLQueryTests/MsSqlGraphQLQueryTests.cs
index 6d3f593dc6..b382bef79c 100644
--- a/src/Service.Tests/SqlTests/GraphQLQueryTests/MsSqlGraphQLQueryTests.cs
+++ b/src/Service.Tests/SqlTests/GraphQLQueryTests/MsSqlGraphQLQueryTests.cs
@@ -31,6 +31,26 @@ public async Task MultipleResultQuery()
await MultipleResultQuery(msSqlQuery);
}
+ ///
+ /// Gets array of results for querying a table containing computed columns.
+ ///
+ /// rows from sales table
+ [TestMethod]
+ public async Task MultipleResultQueryContainingComputedColumns()
+ {
+ string msSqlQuery = @"
+ SELECT
+ id,
+ item_name,
+ ROUND(subtotal,2) AS subtotal,
+ ROUND(tax,2) AS tax,
+ ROUND(total,2) AS total
+ FROM
+ sales
+ ORDER BY id asc FOR JSON PATH, INCLUDE_NULL_VALUES";
+ await MultipleResultQueryContainingComputedColumns(msSqlQuery);
+ }
+
[TestMethod]
public async Task MultipleResultQueryWithVariables()
{
diff --git a/src/Service.Tests/SqlTests/GraphQLQueryTests/MySqlGraphQLQueryTests.cs b/src/Service.Tests/SqlTests/GraphQLQueryTests/MySqlGraphQLQueryTests.cs
index 2935396bd1..d23f8890fc 100644
--- a/src/Service.Tests/SqlTests/GraphQLQueryTests/MySqlGraphQLQueryTests.cs
+++ b/src/Service.Tests/SqlTests/GraphQLQueryTests/MySqlGraphQLQueryTests.cs
@@ -34,6 +34,35 @@ ORDER BY `table0`.`id` asc
await MultipleResultQuery(mySqlQuery);
}
+ ///
+ /// Gets array of results for querying a table containing computed columns.
+ ///
+ /// rows from sales table
+ [TestMethod]
+ public async Task MultipleResultQueryContainingComputedColumns()
+ {
+ string mySqlQuery = @"
+ SELECT COALESCE(JSON_ARRAYAGG(JSON_OBJECT(
+ 'id', `subq1`.`id`,
+ 'item_name', `subq1`.`item_name`,
+ 'subtotal', `subq1`.`subtotal`,
+ 'tax', `subq1`.`tax`,
+ 'total', `subq1`.`total`
+ )), '[]') AS `data`
+ FROM
+ (SELECT `table0`.`id` AS `id`,
+ `table0`.`item_name` AS `item_name`,
+ `table0`.`subtotal` AS `subtotal`,
+ `table0`.`tax` AS `tax`,
+ `table0`.`total` AS `total`
+ FROM `sales` AS `table0`
+ WHERE 1 = 1
+ ORDER BY `table0`.`id` asc
+ LIMIT 100) AS `subq1`";
+
+ await MultipleResultQueryContainingComputedColumns(mySqlQuery);
+ }
+
[TestMethod]
public async Task MultipleResultQueryWithVariables()
{
diff --git a/src/Service.Tests/SqlTests/GraphQLQueryTests/PostgreSqlGraphQLQueryTests.cs b/src/Service.Tests/SqlTests/GraphQLQueryTests/PostgreSqlGraphQLQueryTests.cs
index 95248b98aa..df3030379b 100644
--- a/src/Service.Tests/SqlTests/GraphQLQueryTests/PostgreSqlGraphQLQueryTests.cs
+++ b/src/Service.Tests/SqlTests/GraphQLQueryTests/PostgreSqlGraphQLQueryTests.cs
@@ -25,6 +25,24 @@ public async Task MultipleResultQuery()
await MultipleResultQuery(postgresQuery);
}
+ ///
+ /// Gets array of results for querying a table containing computed columns.
+ ///
+ /// rows from sales table
+ [TestMethod]
+ public async Task MultipleResultQueryContainingComputedColumns()
+ {
+ string postgresQuery = @"SELECT json_agg(to_jsonb(table0)) FROM
+ (SELECT
+ id,
+ item_name,
+ subtotal,
+ tax,
+ total
+ FROM sales ORDER BY id asc LIMIT 100) as table0";
+ await MultipleResultQueryContainingComputedColumns(postgresQuery);
+ }
+
[TestMethod]
public async Task MultipleResultQueryWithVariables()
{
diff --git a/src/Service/MsSqlBooks.sql b/src/Service/MsSqlBooks.sql
index 6269092052..8f6b085f01 100644
--- a/src/Service/MsSqlBooks.sql
+++ b/src/Service/MsSqlBooks.sql
@@ -26,6 +26,7 @@ DROP TABLE IF EXISTS notebooks;
DROP TABLE IF EXISTS journals;
DROP TABLE IF EXISTS aow;
DROP TABLE IF EXISTS series;
+DROP TABLE IF EXISTS sales;
DROP SCHEMA IF EXISTS [foo];
COMMIT;
@@ -171,6 +172,13 @@ CREATE TABLE series (
[name] nvarchar(1000) NOT NULL
);
+CREATE TABLE sales (
+ id int NOT NULL IDENTITY(5001, 1) PRIMARY KEY,
+ item_name varchar(max) NOT NULL,
+ subtotal decimal(18,2) NOT NULL,
+ tax decimal(18,2) NOT NULL
+);
+
ALTER TABLE books
ADD CONSTRAINT book_publisher_fk
FOREIGN KEY (publisher_id)
@@ -219,6 +227,9 @@ FOREIGN KEY (series_id)
REFERENCES series(id)
ON DELETE CASCADE;
+ALTER TABLE sales
+ADD total AS (subtotal + tax) PERSISTED;
+
SET IDENTITY_INSERT publishers ON
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');
SET IDENTITY_INSERT publishers OFF
@@ -262,6 +273,10 @@ INSERT INTO type_table(id, byte_types, short_types, int_types, long_types, strin
(5, NULL, NULL, NULL, NULL, NULL, NULL, NULL, NULL, NULL, NULL, NULL);
SET IDENTITY_INSERT type_table OFF
+SET IDENTITY_INSERT sales ON
+INSERT INTO sales(id, item_name, subtotal, tax) VALUES (1, 'Watch', 249.00, 20.59), (2, 'Montior', 120.50, 11.12);
+SET IDENTITY_INSERT sales OFF
+
INSERT INTO notebooks(id, notebookname, color, ownername) VALUES (1, 'Notebook1', 'red', 'Sean'), (2, 'Notebook2', 'green', 'Ani'), (3, 'Notebook3', 'blue', 'Jarupat'), (4, 'Notebook4', 'yellow', 'Aaron');
INSERT INTO journals(id, journalname, color, ownername) VALUES (1, 'Journal1', 'red', 'Sean'), (2, 'Journal2', 'green', 'Ani'), (3, 'Journal3', 'blue', 'Jarupat'), (4, 'Journal4', 'yellow', 'Aaron');
diff --git a/src/Service/MySqlBooks.sql b/src/Service/MySqlBooks.sql
index 4d606fc9cf..4b900e7e33 100644
--- a/src/Service/MySqlBooks.sql
+++ b/src/Service/MySqlBooks.sql
@@ -23,6 +23,7 @@ DROP TABLE IF EXISTS notebooks;
DROP TABLE IF EXISTS journals;
DROP TABLE IF EXISTS aow;
DROP TABLE IF EXISTS series;
+DROP TABLE IF EXISTS sales;
CREATE TABLE publishers(
@@ -162,6 +163,14 @@ CREATE TABLE series (
name text NOT NULL
);
+CREATE TABLE sales (
+ id int AUTO_INCREMENT PRIMARY KEY,
+ item_name text NOT NULL,
+ subtotal decimal(18,2) NOT NULL,
+ tax decimal(18,2) NOT NULL,
+ total decimal(18,2) generated always as (subtotal + tax) stored
+);
+
ALTER TABLE books
ADD CONSTRAINT book_publisher_fk
FOREIGN KEY (publisher_id)
@@ -236,6 +245,7 @@ INSERT INTO notebooks(id, notebookname, color, ownername) VALUES (1, 'Notebook1'
INSERT INTO journals(id, journalname, color, ownername) VALUES (1, 'Journal1', 'red', 'Sean'), (2, 'Journal2', 'green', 'Ani'), (3, 'Journal3', 'blue', 'Jarupat'), (4, 'Journal4', 'yellow', 'Aaron');
INSERT INTO aow(NoteNum, DetailAssessmentAndPlanning, WagingWar, StrategicAttack) VALUES (1, 'chapter one notes: ', 'chapter two notes: ', 'chapter three notes: ');
+INSERT INTO sales(id, item_name, subtotal, tax) VALUES (1, 'Watch', 249.00, 20.59), (2, 'Montior', 120.50, 11.12);
-- Starting with id > 5000 is chosen arbitrarily so that the incremented id-s won't conflict with the manually inserted ids in this script
-- AUTO_INCREMENT is set to 5001 so the next autogenerated id will be 5001
@@ -246,6 +256,7 @@ ALTER TABLE authors AUTO_INCREMENT = 5001;
ALTER TABLE reviews AUTO_INCREMENT = 5001;
ALTER TABLE comics AUTO_INCREMENT = 5001;
ALTER TABLE type_table AUTO_INCREMENT = 5001;
+ALTER TABLE sales AUTO_INCREMENT = 5001;
prepare stmt1 from 'CREATE VIEW books_view_all AS SELECT * FROM books';
diff --git a/src/Service/PostgreSqlBooks.sql b/src/Service/PostgreSqlBooks.sql
index 041033033a..8f122df19b 100644
--- a/src/Service/PostgreSqlBooks.sql
+++ b/src/Service/PostgreSqlBooks.sql
@@ -23,6 +23,7 @@ DROP TABLE IF EXISTS aow;
DROP TABLE IF EXISTS notebooks;
DROP TABLE IF EXISTS journals;
DROP TABLE IF EXISTS series;
+DROP TABLE IF EXISTS sales;
DROP FUNCTION IF EXISTS insertCompositeView;
DROP SCHEMA IF EXISTS foo;
@@ -166,6 +167,14 @@ CREATE TABLE series (
name text NOT NULL
);
+CREATE TABLE sales (
+ id int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY,
+ item_name text NOT NULL,
+ subtotal float NOT NULL,
+ tax float NOT NULL,
+ total float generated always as (subtotal + tax) stored
+);
+
ALTER TABLE books
ADD CONSTRAINT book_publisher_fk
FOREIGN KEY (publisher_id)
@@ -239,6 +248,7 @@ INSERT INTO notebooks(id, noteBookName, color, ownerName) VALUES (1, 'Notebook1'
INSERT INTO journals(id, journalname, color, ownername) VALUES (1, 'Journal1', 'red', 'Sean'), (2, 'Journal2', 'green', 'Ani'), (3, 'Journal3', 'blue', 'Jarupat'), (4, 'Journal4', 'yellow', 'Aaron');
INSERT INTO aow("NoteNum", "DetailAssessmentAndPlanning", "WagingWar", "StrategicAttack") VALUES (1, 'chapter one notes: ', 'chapter two notes: ', 'chapter three notes: ');
+INSERT INTO sales(id, item_name, subtotal, tax) VALUES (1, 'Watch', 249.00, 20.59), (2, 'Montior', 120.50, 11.12);
--Starting with id > 5000 is chosen arbitrarily so that the incremented id-s won't conflict with the manually inserted ids in this script
--Sequence counter is set to 5000 so the next autogenerated id will be 5001
@@ -248,6 +258,7 @@ SELECT setval('publishers_id_seq', 5000);
SELECT setval('authors_id_seq', 5000);
SELECT setval('reviews_id_seq', 5000);
SELECT setval('type_table_id_seq', 5000);
+SELECT setval('sales_id_seq', 5000);
CREATE VIEW books_view_all AS SELECT * FROM books;
CREATE VIEW books_view_with_mapping AS SELECT * FROM books;