From 6f56fa9c3b0ee8e815b42d0b113f22086a390974 Mon Sep 17 00:00:00 2001 From: Jason Kulatunga Date: Mon, 14 Aug 2023 16:50:09 -0600 Subject: [PATCH] working aggregation code. added tests for sql generation. --- .../pkg/database/sqlite_repository_query.go | 110 ++++++- .../sqlite_repository_query_sql_test.go | 292 ++++++++++++++++++ backend/pkg/models/query_resource.go | 14 +- backend/pkg/models/query_resource_test.go | 4 + 4 files changed, 413 insertions(+), 7 deletions(-) create mode 100644 backend/pkg/database/sqlite_repository_query_sql_test.go diff --git a/backend/pkg/database/sqlite_repository_query.go b/backend/pkg/database/sqlite_repository_query.go index aad117f7..976c1729 100644 --- a/backend/pkg/database/sqlite_repository_query.go +++ b/backend/pkg/database/sqlite_repository_query.go @@ -24,8 +24,8 @@ const ( SearchParameterTypeToken SearchParameterType = "token" SearchParameterTypeReference SearchParameterType = "reference" SearchParameterTypeUri SearchParameterType = "uri" - SearchParameterTypeComposite SearchParameterType = "composite" SearchParameterTypeQuantity SearchParameterType = "quantity" + SearchParameterTypeComposite SearchParameterType = "composite" SearchParameterTypeSpecial SearchParameterType = "special" ) @@ -131,23 +131,67 @@ func (sr *SqliteRepository) sqlQueryResources(ctx context.Context, query models. //defaults selectClauses := []string{fmt.Sprintf("%s.*", TABLE_ALIAS)} groupClause := fmt.Sprintf("%s.id", TABLE_ALIAS) - orderClause := fmt.Sprintf("%s.sort_date asc", TABLE_ALIAS) + orderClause := fmt.Sprintf("%s.sort_date ASC", TABLE_ALIAS) if query.Aggregations != nil { - selectClauses = []string{} - groupClause = "" - orderClause = "" + //Handle Aggregations if len(query.Aggregations.CountBy) > 0 { //populate the group by and order by clause with the count by values + query.Aggregations.OrderBy = "count(*) DESC" + query.Aggregations.GroupBy = query.Aggregations.CountBy + } - //TODO: + //process order by clause + if len(query.Aggregations.OrderBy) > 0 { + orderAsc := true + if !strings.HasPrefix(query.Aggregations.OrderBy, "count(*)") { + orderAggregationParam, err := ProcessAggregationParameter(query.Aggregations.OrderBy, searchCodeToTypeLookup) + if err != nil { + return nil, err + } + orderAggregationFromClause, err := SearchCodeToFromClause(orderAggregationParam) + if err != nil { + return nil, err + } + fromClauses = append(fromClauses, orderAggregationFromClause) + + orderClause = AggregationParameterToClause(orderAggregationParam) + if orderAsc { + orderClause = fmt.Sprintf("%s ASC", orderClause) + } else { + orderClause = fmt.Sprintf("%s DESC", orderClause) + } + } else { + orderClause = query.Aggregations.OrderBy + } + } + + //process group by clause + if len(query.Aggregations.GroupBy) > 0 { + groupAggregationParam, err := ProcessAggregationParameter(query.Aggregations.GroupBy, searchCodeToTypeLookup) + if err != nil { + return nil, err + } + groupAggregationFromClause, err := SearchCodeToFromClause(groupAggregationParam) + if err != nil { + return nil, err + } + fromClauses = append(fromClauses, groupAggregationFromClause) + + groupClause = AggregationParameterToClause(groupAggregationParam) + selectClauses = []string{ + fmt.Sprintf("%s as %s", groupClause, "group_by"), + "count(*) as count", + } } } //ensure Where and From clauses are unique whereClauses = lo.Uniq(whereClauses) + whereClauses = lo.Compact(whereClauses) fromClauses = lo.Uniq(fromClauses) + fromClauses = lo.Compact(fromClauses) return sr.GormClient.WithContext(ctx). Select(strings.Join(selectClauses, ", ")). @@ -158,6 +202,7 @@ func (sr *SqliteRepository) sqlQueryResources(ctx context.Context, query models. } /// INTERNAL functionality. These functions are exported for testing, but are not available in the Interface +//TODO: dont export these, instead use casting to convert the interface to the SqliteRepository struct, then call ehese functions directly type SearchParameter struct { Name string @@ -499,3 +544,56 @@ func SearchCodeToFromClause(searchParam SearchParameter) (string, error) { } return "", nil } + +func AggregationParameterToClause(aggParameter SearchParameter) string { + switch aggParameter.Type { + case SearchParameterTypeQuantity, SearchParameterTypeToken, SearchParameterTypeString: + //setup the clause + return fmt.Sprintf("(%sJson.value ->> '$.%s')", aggParameter.Name, aggParameter.Modifier) + default: + return fmt.Sprintf("%s.%s", TABLE_ALIAS, aggParameter.Name) + } +} + +//ProcessAggregationParameter processes the aggregation parameters which are fields with optional properties: +// Fields that are primitive types (number, uri) must not have any property specified: +// eg. `probability` +// +// Fields that are complex types (token, quantity) must have a property specified: +// eg. `identifier:code` +// +// if the a property is specified, its set as the modifier, and used when generating the SQL query groupBy, orderBy, etc clause +func ProcessAggregationParameter(aggregationFieldWithProperty string, searchParamTypeLookup map[string]string) (SearchParameter, error) { + aggregationParameter := SearchParameter{} + + //determine the searchCode searchCodeModifier + //TODO: this is only applicable to string, token, reference and uri type (however unknown names & modifiers are ignored) + if aggregationFieldParts := strings.SplitN(aggregationFieldWithProperty, ":", 2); len(aggregationFieldParts) == 2 { + aggregationParameter.Name = aggregationFieldParts[0] + aggregationParameter.Modifier = aggregationFieldParts[1] + } else { + aggregationParameter.Name = aggregationFieldParts[0] + aggregationParameter.Modifier = "" + } + + //next, determine the searchCodeType for this Resource (or throw an error if it is unknown) + searchParamTypeStr, searchParamTypeOk := searchParamTypeLookup[aggregationParameter.Name] + if !searchParamTypeOk { + return aggregationParameter, fmt.Errorf("unknown search parameter: %s", aggregationParameter.Name) + } else { + aggregationParameter.Type = SearchParameterType(searchParamTypeStr) + } + + //primitive types should not have a modifier, we need to throw an error + if aggregationParameter.Type == SearchParameterTypeNumber || aggregationParameter.Type == SearchParameterTypeUri { + if len(aggregationParameter.Modifier) > 0 { + return aggregationParameter, fmt.Errorf("primitive aggregation parameter %s cannot have a property (%s)", aggregationParameter.Name, aggregationParameter.Modifier) + } + } else { + //complex types must have a modifier + if len(aggregationParameter.Modifier) == 0 { + return aggregationParameter, fmt.Errorf("complex aggregation parameter %s must have a property", aggregationParameter.Name) + } + } + return aggregationParameter, nil +} diff --git a/backend/pkg/database/sqlite_repository_query_sql_test.go b/backend/pkg/database/sqlite_repository_query_sql_test.go new file mode 100644 index 00000000..e4aacee4 --- /dev/null +++ b/backend/pkg/database/sqlite_repository_query_sql_test.go @@ -0,0 +1,292 @@ +package database + +import ( + "context" + "fmt" + "github.com/fastenhealth/fastenhealth-onprem/backend/pkg" + mock_config "github.com/fastenhealth/fastenhealth-onprem/backend/pkg/config/mock" + "github.com/fastenhealth/fastenhealth-onprem/backend/pkg/models" + "github.com/golang/mock/gomock" + "github.com/sirupsen/logrus" + "github.com/stretchr/testify/require" + "github.com/stretchr/testify/suite" + "gorm.io/gorm" + "io/ioutil" + "log" + "os" + "strings" + "testing" +) + +// Define the suite, and absorb the built-in basic suite +// functionality from testify - including a T() method which +// returns the current testing context +type RepositorySqlTestSuite struct { + suite.Suite + MockCtrl *gomock.Controller + TestDatabase *os.File + + TestRepository DatabaseRepository +} + +// BeforeTest has a function to be executed right before the test starts and receives the suite and test names as input +func (suite *RepositorySqlTestSuite) BeforeTest(suiteName, testName string) { + suite.MockCtrl = gomock.NewController(suite.T()) + + dbFile, err := ioutil.TempFile("", fmt.Sprintf("%s.*.db", testName)) + if err != nil { + log.Fatal(err) + } + suite.TestDatabase = dbFile + + fakeConfig := mock_config.NewMockInterface(suite.MockCtrl) + fakeConfig.EXPECT().GetString("database.location").Return(suite.TestDatabase.Name()).AnyTimes() + fakeConfig.EXPECT().GetString("log.level").Return("INFO").AnyTimes() + dbRepo, err := NewRepository(fakeConfig, logrus.WithField("test", suite.T().Name())) + require.NoError(suite.T(), err) + suite.TestRepository = dbRepo + userModel := &models.User{ + Username: "test_username", + Password: "testpassword", + Email: "test@test.com", + } + err = suite.TestRepository.CreateUser(context.Background(), userModel) + require.NoError(suite.T(), err) + +} + +// AfterTest has a function to be executed right after the test finishes and receives the suite and test names as input +func (suite *RepositorySqlTestSuite) AfterTest(suiteName, testName string) { + suite.MockCtrl.Finish() + os.Remove(suite.TestDatabase.Name()) +} + +// In order for 'go test' to run this suite, we need to create +// a normal test function and pass our suite to suite.Run +func TestRepositorySqlTestSuite(t *testing.T) { + suite.Run(t, new(RepositorySqlTestSuite)) + +} + +func (suite *RepositorySqlTestSuite) TestQueryResources_SQL() { + //setup + sqliteRepo := suite.TestRepository.(*SqliteRepository) + sqliteRepo.GormClient = sqliteRepo.GormClient.Session(&gorm.Session{DryRun: true}) + + //test + authContext := context.WithValue(context.Background(), pkg.ContextKeyTypeAuthUsername, "test_username") + + sqlQuery, err := sqliteRepo.sqlQueryResources(authContext, models.QueryResource{ + Select: []string{}, + Where: map[string]interface{}{ + "code": "test_code", + }, + From: "Observation", + }) + require.NoError(suite.T(), err) + var results []map[string]interface{} + statement := sqlQuery.Find(&results).Statement + sqlString := statement.SQL.String() + sqlParams := statement.Vars + + //assert + require.NoError(suite.T(), err) + require.Equal(suite.T(), + strings.Join([]string{ + "SELECT fhir.*", + "FROM fhir_observation as fhir, json_each(fhir.code) as codeJson", + "WHERE ((codeJson.value ->> '$.code' = ?)) AND (user_id = ?)", + "GROUP BY `fhir`.`id`", + "ORDER BY fhir.sort_date ASC", + }, " "), + sqlString) + require.Equal(suite.T(), sqlParams, []interface{}{ + "test_code", "00000000-0000-0000-0000-000000000000", + }) +} + +func (suite *RepositorySqlTestSuite) TestQueryResources_SQL_WithMultipleWhereConditions() { + //setup + sqliteRepo := suite.TestRepository.(*SqliteRepository) + sqliteRepo.GormClient = sqliteRepo.GormClient.Session(&gorm.Session{DryRun: true}) + + //test + authContext := context.WithValue(context.Background(), pkg.ContextKeyTypeAuthUsername, "test_username") + + sqlQuery, err := sqliteRepo.sqlQueryResources(authContext, models.QueryResource{ + Select: []string{}, + Where: map[string]interface{}{ + "code": "test_code", + "category": "12345", + }, + From: "Observation", + }) + require.NoError(suite.T(), err) + var results []map[string]interface{} + statement := sqlQuery.Find(&results).Statement + sqlString := statement.SQL.String() + sqlParams := statement.Vars + + //assert + require.NoError(suite.T(), err) + require.Equal(suite.T(), + strings.Join([]string{ + "SELECT fhir.*", + "FROM fhir_observation as fhir, json_each(fhir.code) as codeJson", + "WHERE ((codeJson.value ->> '$.code' = ?)) AND (user_id = ?)", + "GROUP BY `fhir`.`id`", + "ORDER BY fhir.sort_date ASC", + }, " "), + sqlString) + require.Equal(suite.T(), sqlParams, []interface{}{ + "test_code", "00000000-0000-0000-0000-000000000000", + }) +} + +func (suite *RepositorySqlTestSuite) TestQueryResources_SQL_WithPrimitiveOrderByAggregation() { + //setup + sqliteRepo := suite.TestRepository.(*SqliteRepository) + sqliteRepo.GormClient = sqliteRepo.GormClient.Session(&gorm.Session{DryRun: true}) + + //test + authContext := context.WithValue(context.Background(), pkg.ContextKeyTypeAuthUsername, "test_username") + + sqlQuery, err := sqliteRepo.sqlQueryResources(authContext, models.QueryResource{ + Select: []string{}, + Where: map[string]interface{}{ + "code": "test_code", + }, + From: "Observation", + Aggregations: &models.QueryResourceAggregations{OrderBy: "sourceUri"}, + }) + require.NoError(suite.T(), err) + var results []map[string]interface{} + statement := sqlQuery.Find(&results).Statement + sqlString := statement.SQL.String() + sqlParams := statement.Vars + + //assert + require.NoError(suite.T(), err) + require.Equal(suite.T(), + strings.Join([]string{ + "SELECT fhir.*", + "FROM fhir_observation as fhir, json_each(fhir.code) as codeJson", + "WHERE ((codeJson.value ->> '$.code' = ?)) AND (user_id = ?)", + "GROUP BY `fhir`.`id`", + "ORDER BY fhir.sourceUri ASC", + }, " "), sqlString) + require.Equal(suite.T(), sqlParams, []interface{}{ + "test_code", "00000000-0000-0000-0000-000000000000", + }) +} + +func (suite *RepositorySqlTestSuite) TestQueryResources_SQL_WithComplexOrderByAggregation() { + //setup + sqliteRepo := suite.TestRepository.(*SqliteRepository) + sqliteRepo.GormClient = sqliteRepo.GormClient.Session(&gorm.Session{DryRun: true}) + + //test + authContext := context.WithValue(context.Background(), pkg.ContextKeyTypeAuthUsername, "test_username") + + sqlQuery, err := sqliteRepo.sqlQueryResources(authContext, models.QueryResource{ + Select: []string{}, + Where: map[string]interface{}{ + "code": "test_code", + }, + From: "Observation", + Aggregations: &models.QueryResourceAggregations{OrderBy: "valueString:value"}, + }) + require.NoError(suite.T(), err) + var results []map[string]interface{} + statement := sqlQuery.Find(&results).Statement + sqlString := statement.SQL.String() + sqlParams := statement.Vars + + //assert + require.NoError(suite.T(), err) + require.Equal(suite.T(), + strings.Join([]string{ + "SELECT fhir.*", + "FROM fhir_observation as fhir, json_each(fhir.code) as codeJson, json_each(fhir.valueString) as valueStringJson", + "WHERE ((codeJson.value ->> '$.code' = ?)) AND (user_id = ?)", + "GROUP BY `fhir`.`id`", + "ORDER BY (valueStringJson.value ->> '$.value') ASC", + }, " "), sqlString) + require.Equal(suite.T(), sqlParams, []interface{}{ + "test_code", "00000000-0000-0000-0000-000000000000", + }) +} + +func (suite *RepositorySqlTestSuite) TestQueryResources_SQL_WithPrimitiveCountByAggregation() { + //setup + sqliteRepo := suite.TestRepository.(*SqliteRepository) + sqliteRepo.GormClient = sqliteRepo.GormClient.Session(&gorm.Session{DryRun: true}) + + //test + authContext := context.WithValue(context.Background(), pkg.ContextKeyTypeAuthUsername, "test_username") + + sqlQuery, err := sqliteRepo.sqlQueryResources(authContext, models.QueryResource{ + Select: []string{}, + Where: map[string]interface{}{ + "code": "test_code", + }, + From: "Observation", + Aggregations: &models.QueryResourceAggregations{CountBy: "sourceUri"}, + }) + require.NoError(suite.T(), err) + var results []map[string]interface{} + statement := sqlQuery.Find(&results).Statement + sqlString := statement.SQL.String() + sqlParams := statement.Vars + + //assert + require.NoError(suite.T(), err) + require.Equal(suite.T(), + strings.Join([]string{ + "SELECT fhir.sourceUri as group_by, count(*) as count", + "FROM fhir_observation as fhir, json_each(fhir.code) as codeJson", + "WHERE ((codeJson.value ->> '$.code' = ?)) AND (user_id = ?)", + "GROUP BY `fhir`.`sourceUri`", + "ORDER BY count(*) DESC", + }, " "), sqlString) + require.Equal(suite.T(), sqlParams, []interface{}{ + "test_code", "00000000-0000-0000-0000-000000000000", + }) +} + +func (suite *RepositorySqlTestSuite) TestQueryResources_SQL_WithComplexCountByAggregation() { + //setup + sqliteRepo := suite.TestRepository.(*SqliteRepository) + sqliteRepo.GormClient = sqliteRepo.GormClient.Session(&gorm.Session{DryRun: true}) + + //test + authContext := context.WithValue(context.Background(), pkg.ContextKeyTypeAuthUsername, "test_username") + + sqlQuery, err := sqliteRepo.sqlQueryResources(authContext, models.QueryResource{ + Select: []string{}, + Where: map[string]interface{}{ + "code": "test_code", + }, + From: "Observation", + Aggregations: &models.QueryResourceAggregations{CountBy: "code:code"}, + }) + require.NoError(suite.T(), err) + var results []map[string]interface{} + statement := sqlQuery.Find(&results).Statement + sqlString := statement.SQL.String() + sqlParams := statement.Vars + + //assert + require.NoError(suite.T(), err) + require.Equal(suite.T(), + strings.Join([]string{ + "SELECT (codeJson.value ->> '$.code') as group_by, count(*) as count", + "FROM fhir_observation as fhir, json_each(fhir.code) as codeJson", + "WHERE ((codeJson.value ->> '$.code' = ?)) AND (user_id = ?)", + "GROUP BY (codeJson.value ->> '$.code')", + "ORDER BY count(*) DESC", + }, " "), sqlString) + require.Equal(suite.T(), sqlParams, []interface{}{ + "test_code", "00000000-0000-0000-0000-000000000000", + }) +} diff --git a/backend/pkg/models/query_resource.go b/backend/pkg/models/query_resource.go index 542455ec..acad5118 100644 --- a/backend/pkg/models/query_resource.go +++ b/backend/pkg/models/query_resource.go @@ -1,6 +1,9 @@ package models -import "fmt" +import ( + "fmt" + "strings" +) // maps to frontend/src/app/models/widget/dashboard-widget-query.ts type QueryResource struct { @@ -44,6 +47,15 @@ func (q *QueryResource) Validate() error { if len(q.Aggregations.CountBy) == 0 && len(q.Aggregations.OrderBy) == 0 && len(q.Aggregations.GroupBy) == 0 { return fmt.Errorf("aggregations must have at least one of 'count_by', 'group_by', or 'order_by'") } + if strings.Contains(q.Aggregations.CountBy, " ") { + return fmt.Errorf("count_by cannot have spaces (or aliases)") + } + if strings.Contains(q.Aggregations.GroupBy, " ") { + return fmt.Errorf("group_by cannot have spaces (or aliases)") + } + if strings.Contains(q.Aggregations.OrderBy, " ") { + return fmt.Errorf("order_by cannot have spaces (or aliases)") + } } diff --git a/backend/pkg/models/query_resource_test.go b/backend/pkg/models/query_resource_test.go index 3f537972..55f99491 100644 --- a/backend/pkg/models/query_resource_test.go +++ b/backend/pkg/models/query_resource_test.go @@ -18,6 +18,10 @@ func TestQueryResource_Validate(t *testing.T) { {QueryResource{From: "test", Aggregations: &QueryResourceAggregations{CountBy: "test", GroupBy: "test"}}, "cannot use 'count_by' and 'group_by' together", true}, {QueryResource{From: "test", Aggregations: &QueryResourceAggregations{CountBy: "test", OrderBy: "test"}}, "cannot use 'count_by' and 'order_by' together", true}, {QueryResource{From: "test", Aggregations: &QueryResourceAggregations{}}, "aggregations must have at least one of 'count_by', 'group_by', or 'order_by'", true}, + {QueryResource{From: "test", Aggregations: &QueryResourceAggregations{CountBy: "test:property"}}, "", false}, + {QueryResource{From: "test", Aggregations: &QueryResourceAggregations{CountBy: "test:property as HELLO"}}, "count_by cannot have spaces", true}, + {QueryResource{From: "test", Aggregations: &QueryResourceAggregations{GroupBy: "test:property as HELLO"}}, "group_by cannot have spaces", true}, + {QueryResource{From: "test", Aggregations: &QueryResourceAggregations{OrderBy: "test:property as HELLO"}}, "order_by cannot have spaces", true}, } //test && assert