From 675ecc148585e173f18fa38f643fce64c612ef7f Mon Sep 17 00:00:00 2001 From: Jake Owen Date: Fri, 19 Jan 2024 16:06:15 -0500 Subject: [PATCH] Add SELECT FOR JSON AUTO support in Babelfish (#2243) (#2270) This change adds SELECT FOR JSON AUTO support to Babelfish which nests JSON objects based on the structure of the Select statement. Task: BABEL-3668 Signed-off-by: Jake Owen --- contrib/babelfishpg_tds/error_mapping.txt | 3 + contrib/babelfishpg_tsql/src/err_handler.c | 1 + contrib/babelfishpg_tsql/src/err_handler.h | 1 + contrib/babelfishpg_tsql/src/pl_handler.c | 243 +++++++++ .../babelfishpg_tsql/src/tsql_for/forjson.c | 488 +++++++++++++++++- .../expected/TestErrorHelperFunctions.out | 2 + ...tErrorHelperFunctionsUpgrade-vu-verify.out | 7 +- test/JDBC/expected/forjsonauto-vu-cleanup.out | 84 +++ test/JDBC/expected/forjsonauto-vu-prepare.out | 197 +++++++ test/JDBC/expected/forjsonauto-vu-verify.out | 177 +++++++ .../input/forjson/forjsonauto-vu-cleanup.sql | 84 +++ .../input/forjson/forjsonauto-vu-prepare.sql | 183 +++++++ .../input/forjson/forjsonauto-vu-verify.sql | 62 +++ test/JDBC/upgrade/latest/schedule | 1 + test/JDBC/upgrade/master/schedule | 1 + 15 files changed, 1524 insertions(+), 10 deletions(-) create mode 100644 test/JDBC/expected/forjsonauto-vu-cleanup.out create mode 100644 test/JDBC/expected/forjsonauto-vu-prepare.out create mode 100644 test/JDBC/expected/forjsonauto-vu-verify.out create mode 100644 test/JDBC/input/forjson/forjsonauto-vu-cleanup.sql create mode 100644 test/JDBC/input/forjson/forjsonauto-vu-prepare.sql create mode 100644 test/JDBC/input/forjson/forjsonauto-vu-verify.sql diff --git a/contrib/babelfishpg_tds/error_mapping.txt b/contrib/babelfishpg_tds/error_mapping.txt index cf9453b044..442f490f70 100644 --- a/contrib/babelfishpg_tds/error_mapping.txt +++ b/contrib/babelfishpg_tds/error_mapping.txt @@ -184,3 +184,6 @@ XX000 ERRCODE_INTERNAL_ERROR "The table-valued parameter \"%s\" must be declared 22023 ERRCODE_INVALID_PARAMETER_VALUE "\'%s\' is not a recognized %s option" SQL_ERROR_155 15 22023 ERRCODE_INVALID_PARAMETER_VALUE "The datepart %s is not supported by date function %s for data type %s." SQL_ERROR_9810 16 22008 ERRCODE_DATETIME_VALUE_OUT_OF_RANGE "Adding a value to a \'%s\' column caused an overflow." SQL_ERROR_517 16 +42P01 ERRCODE_UNDEFINED_TABLE "FOR JSON AUTO requires at least one table for generating JSON objects. Use FOR JSON PATH or add a FROM clause with a table name." SQL_ERROR_13600 16 +42P01 ERRCODE_FEATURE_NOT_SUPPORTED "Values for json auto is not currently supported." SQL_ERROR_13600 16 + diff --git a/contrib/babelfishpg_tsql/src/err_handler.c b/contrib/babelfishpg_tsql/src/err_handler.c index 631745e6dc..6eac541e57 100644 --- a/contrib/babelfishpg_tsql/src/err_handler.c +++ b/contrib/babelfishpg_tsql/src/err_handler.c @@ -135,6 +135,7 @@ is_ignorable_error(int pg_error_code, uint8_t override_flag) case SQL_ERROR_155: case SQL_ERROR_9810: case SQL_ERROR_535: + case SQL_ERROR_13600: case SQL_ERROR_15003: { elog(DEBUG1, "TSQL TXN is_ignorable_error %d", latest_error_code); diff --git a/contrib/babelfishpg_tsql/src/err_handler.h b/contrib/babelfishpg_tsql/src/err_handler.h index 1e4c6049b7..a0311aaf8a 100644 --- a/contrib/babelfishpg_tsql/src/err_handler.h +++ b/contrib/babelfishpg_tsql/src/err_handler.h @@ -152,6 +152,7 @@ uint8_t override_txn_behaviour(PLtsql_stmt *stmt); #define SQL_ERROR_11708 11708 #define SQL_ERROR_11709 11709 #define SQL_ERROR_11717 11717 +#define SQL_ERROR_13600 13600 #define SQL_ERROR_16915 16915 #define SQL_ERROR_16948 16948 #define SQL_ERROR_16950 16950 diff --git a/contrib/babelfishpg_tsql/src/pl_handler.c b/contrib/babelfishpg_tsql/src/pl_handler.c index 207f16656a..26b6b0312f 100644 --- a/contrib/babelfishpg_tsql/src/pl_handler.c +++ b/contrib/babelfishpg_tsql/src/pl_handler.c @@ -169,6 +169,17 @@ static void bbf_ExecDropStmt(DropStmt *stmt); static int isolation_to_int(char *isolation_level); static void bbf_set_tran_isolation(char *new_isolation_level_str); +typedef struct { + int oid; + char *alias; + int nestLevel; +} forjson_table; + +static bool handleForJsonAuto(Query *query); +static bool isJsonAuto(List* target); +static bool check_json_auto_walker(Node *node, ParseState *pstate); +static TargetEntry* buildJsonEntry(forjson_table *table, TargetEntry* te); + extern bool pltsql_ansi_defaults; extern bool pltsql_quoted_identifier; extern bool pltsql_concat_null_yields_null; @@ -868,6 +879,7 @@ pltsql_pre_parse_analyze(ParseState *pstate, RawStmt *parseTree) static void pltsql_post_parse_analyze(ParseState *pstate, Query *query, JumbleState *jstate) { + if (prev_post_parse_analyze_hook) prev_post_parse_analyze_hook(pstate, query, jstate); @@ -876,6 +888,9 @@ pltsql_post_parse_analyze(ParseState *pstate, Query *query, JumbleState *jstate) if (sql_dialect != SQL_DIALECT_TSQL) return; + + (void) check_json_auto_walker((Node*) query, pstate); + if (query->commandType == CMD_INSERT) { ListCell *lc; @@ -1330,6 +1345,234 @@ pltsql_post_parse_analyze(ParseState *pstate, Query *query, JumbleState *jstate) } } +static bool +handleForJsonAuto(Query *query) +{ + Query* subq; + List* target = query->targetList; + List* rtable; + List* subqRtable; + ListCell* lc; + ListCell* lc2; + RangeTblEntry* rte; + RangeTblEntry* subqRte; + RangeTblEntry* queryRte; + Alias *colnameAlias; + forjson_table **tableInfoArr; + int numTables = 0; + int currTables = 0; + int currMax = 0; + int i = 0; + + if(!isJsonAuto(target)) + return false; + + // Modify query to be of the form "JSONAUTOALIAS.[nest_level].[table_alias]" + rtable = (List*) query->rtable; + if(rtable != NULL && list_length(rtable) > 0) { + rte = linitial_node(RangeTblEntry, rtable); + if(rte != NULL) { + subq = (Query*) rte->subquery; + if(subq != NULL && (subq->cteList == NULL || list_length(subq->cteList) == 0)) { + subqRtable = (List*) subq->rtable; + if(subqRtable != NULL && list_length(subqRtable) > 0) { + foreach(lc, subqRtable) { + subqRte = castNode(RangeTblEntry, lfirst(lc)); + if(subqRte->rtekind == RTE_RELATION) { + numTables++; + } else if(subqRte->rtekind == RTE_SUBQUERY) { + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("Values for json auto is not currently supported "))); + } + } + + if(numTables == 0) { + ereport(ERROR, + (errcode(ERRCODE_UNDEFINED_TABLE), + errmsg("FOR JSON AUTO requires at least one table for generating JSON objects. Use FOR JSON PATH or add a FROM clause with a table name."))); + } + + tableInfoArr = malloc(numTables * sizeof(forjson_table)); + queryRte = linitial_node(RangeTblEntry, query->rtable); + colnameAlias = (Alias*) queryRte->eref; + + foreach(lc, subqRtable) { + subqRte = castNode(RangeTblEntry, lfirst(lc)); + if(subqRte->rtekind == RTE_RELATION) { + forjson_table *table = palloc(sizeof(forjson_table)); + Alias* a = (Alias*) subqRte->eref; + table->oid = subqRte->relid; + table->nestLevel = -1; + table->alias = a->aliasname; + tableInfoArr[currTables] = table; + currTables++; + } + } + + foreach(lc, subq->targetList) { + TargetEntry* te = castNode(TargetEntry, lfirst(lc)); + int oid = te->resorigtbl; + for(int j = 0; j < numTables; j++) { + if(tableInfoArr[j]->oid == oid) { + // build entry + String* s = castNode(String, lfirst(list_nth_cell(colnameAlias->colnames, i))); + if(tableInfoArr[j]->nestLevel == -1) { + currMax++; + tableInfoArr[j]->nestLevel = currMax; + } + te = buildJsonEntry(tableInfoArr[j], te); + s->sval = te->resname; + break; + } + } + i++; + } + free(tableInfoArr); + return true; + } + } else if(subq->cteList != NULL && list_length(subq->cteList) > 0) { + Query* ctequery; + CommonTableExpr* cte; + foreach(lc, subq->cteList) { + cte = castNode(CommonTableExpr, lfirst(lc)); + ctequery = (Query*) cte->ctequery; + foreach(lc2, ctequery->rtable) { + subqRte = castNode(RangeTblEntry, lfirst(lc2)); + if(subqRte->rtekind == RTE_RELATION) + numTables++; + } + } + + if(numTables == 0) { + forjson_table *table = palloc(sizeof(forjson_table)); + tableInfoArr = malloc(sizeof(forjson_table)); + table->oid = 0; + table->nestLevel = -1; + table->alias = "cteplaceholder"; + tableInfoArr[numTables] = table; + numTables++; + } else { + tableInfoArr = malloc(numTables * sizeof(forjson_table)); + } + queryRte = linitial_node(RangeTblEntry, query->rtable); + colnameAlias = (Alias*) queryRte->eref; + + foreach(lc, subq->cteList) { + cte = castNode(CommonTableExpr, lfirst(lc)); + ctequery = (Query*) cte->ctequery; + foreach(lc2, ctequery->rtable) { + subqRte = castNode(RangeTblEntry, lfirst(lc2)); + if(subqRte->rtekind == RTE_RELATION) { + forjson_table *table = palloc(sizeof(forjson_table)); + Alias* a = (Alias*) subqRte->eref; + table->oid = subqRte->relid; + table->nestLevel = -1; + table->alias = a->aliasname; + tableInfoArr[currTables] = table; + currTables++; + } + } + } + + foreach(lc, subq->targetList) { + TargetEntry* te = castNode(TargetEntry, lfirst(lc)); + int oid = te->resorigtbl; + for(int j = 0; j < numTables; j++) { + if(tableInfoArr[j]->oid == oid) { + // build entry + String* s = castNode(String, lfirst(list_nth_cell(colnameAlias->colnames, i))); + if(tableInfoArr[j]->nestLevel == -1) { + currMax++; + tableInfoArr[j]->nestLevel = currMax; + } + te = buildJsonEntry(tableInfoArr[j], te); + s->sval = te->resname; + break; + } + } + i++; + } + free(tableInfoArr); + return true; + } + } + } + + ereport(ERROR, + (errcode(ERRCODE_UNDEFINED_TABLE), + errmsg("FOR JSON AUTO requires at least one table for generating JSON objects. Use FOR JSON PATH or add a FROM clause with a table name."))); + return true; +} + +static bool +isJsonAuto(List* target) +{ + if(target != NULL && list_length(target) > 0) { + ListCell* lc = list_nth_cell(target, 0); + if(lc != NULL && nodeTag(lfirst(lc)) == T_TargetEntry) { + TargetEntry* te = lfirst_node(TargetEntry, lc); + if(te && strcmp(te->resname, "json") == 0 && te->expr != NULL && nodeTag(te->expr) == T_FuncExpr) { + List* args = ((FuncExpr*) te->expr)->args; + if(args != NULL && nodeTag(linitial(args)) == T_Aggref) { + Aggref* agg = linitial_node(Aggref, args); + List* aggargs = agg->args; + if(aggargs != NULL && list_length(aggargs) > 1 && nodeTag(lsecond(aggargs)) == T_TargetEntry) { + TargetEntry* te2 = lsecond_node(TargetEntry, aggargs); + if(te2->expr != NULL && nodeTag(te2->expr) == T_Const) { + Const* c = (Const*) te2->expr; + if(c->constvalue == 0) + return true; + } + } + } + } + } + } + return false; +} + +static TargetEntry* +buildJsonEntry(forjson_table *table, TargetEntry* te) +{ + char nest[NAMEDATALEN]; // check size appropriate + StringInfo new_resname = makeStringInfo(); + sprintf(nest, "%d", table->nestLevel); + // Adding JSONAUTOALIAS prevents us from modifying + // a column more than once + if(!strcmp(te->resname, "\?column\?")) { + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("column expressions and data sources without names or aliases cannot be formatted as JSON text using FOR JSON clause. Add alias to the unnamed column or table"))); + } + if(!strncmp(te->resname, "JSONAUTOALIAS", 13)) + return te; + appendStringInfoString(new_resname, "JSONAUTOALIAS."); + appendStringInfoString(new_resname, nest); + appendStringInfoChar(new_resname, '.'); + appendStringInfoString(new_resname, table->alias); + appendStringInfoChar(new_resname, '.'); + appendStringInfoString(new_resname, te->resname); + te->resname = new_resname->data; + return te; +} + +static bool check_json_auto_walker(Node *node, ParseState *pstate) { + if (node == NULL) + return false; + if (IsA(node, Query)) { + if(handleForJsonAuto((Query*) node)) + return true; + else { + return query_tree_walker((Query*) node, + check_json_auto_walker, + (void *) pstate, 0); + } + } + return expression_tree_walker(node, check_json_auto_walker, + (void *) pstate); +} + /* * transformReturningList - * handle a RETURNING clause in INSERT/UPDATE/DELETE diff --git a/contrib/babelfishpg_tsql/src/tsql_for/forjson.c b/contrib/babelfishpg_tsql/src/tsql_for/forjson.c index 1f1228d33f..e908c2fd3a 100644 --- a/contrib/babelfishpg_tsql/src/tsql_for/forjson.c +++ b/contrib/babelfishpg_tsql/src/tsql_for/forjson.c @@ -45,14 +45,26 @@ typedef struct { static void tsql_row_to_json(JsonbValue* jsonbArray, Datum record, bool include_null_values); +static void tsql_auto_row_to_json(JsonbValue* jsonbArray, Datum record, bool include_null_values); + static char** determine_parts(const char* str, int *num); +char* remove_index_and_alias(const char* str); + static char* build_key(char **parts, int currentIdx); static JsonbValue* create_json(char *part, JsonbValue* val, int *idx); +static JsonbValue* create_json_array(char *arrayKey, char* pairKey, JsonbValue* pairVal, int *idx); + static void insert_existing_json(JsonbValue *exists, JsonbValue* parent, JsonbValue *val, int idx, char *key); +static void insert_existing_json_to_obj(JsonbValue *exists, JsonbValue* parent, JsonbValue *val, int idx, char *key); + +static void checkForDuplicateRows(JsonbValue *jsonbArray, JsonbValue* row, int maxDepth, int currDepth, int* minInsertDepth); + +static int compareNumeric(Numeric a, Numeric b); + PG_FUNCTION_INFO_V1(tsql_query_to_json_sfunc); Datum @@ -113,15 +125,7 @@ tsql_query_to_json_sfunc(PG_FUNCTION_ARGS) switch (mode) { case TSQL_FORJSON_AUTO: - - /* - * TODO FOR JSON AUTO: if there are joined tables, we need to know - * which table a particular column came from, but that is - * currently not accessible within the aggregate function. - */ - ereport(ERROR, - (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), - errmsg("AUTO mode is not supported"))); + tsql_auto_row_to_json(jsonbArray, record, include_null_values); break; case TSQL_FORJSON_PATH: /* FOR JSON PATH */ /* add the current row to the state */ @@ -138,6 +142,267 @@ tsql_query_to_json_sfunc(PG_FUNCTION_ARGS) PG_RETURN_POINTER(state); } +// Main row to json function. +// Creates a Jsonb row object, processes the row, determines if it should be inserted as a nested json object +// inserts json object to row and then into the main jsonbArray. +static void +tsql_auto_row_to_json(JsonbValue* jsonbArray, Datum record, bool include_null_values) +{ + // HashTable + HTAB *jsonbHash; + HASHCTL ct; + + // JsonbValue for the row + JsonbValue *jsonbRow; + + HeapTupleHeader td; + Oid tupType; + int32 tupTypmod; + TupleDesc tupdesc; + HeapTupleData tmptup; + HeapTuple tuple; + int maxDepth = -1; + int minInsertDepth; + + td = DatumGetHeapTupleHeader(record); + + /* Extract rowtype info and find a tupdesc */ + tupType = HeapTupleHeaderGetTypeId(td); + tupTypmod = HeapTupleHeaderGetTypMod(td); + tupdesc = lookup_rowtype_tupdesc(tupType, tupTypmod); + + /* Build a temporary HeapTuple control structure */ + tmptup.t_len = HeapTupleHeaderGetDatumLength(td); + tmptup.t_data = td; + tuple = &tmptup; + + // Initialize the JsonbValue for the row + jsonbRow = palloc(sizeof(JsonbValue)); + jsonbRow->type = jbvObject; + jsonbRow->val.object.nPairs = 0; + jsonbRow->val.object.pairs = palloc(sizeof(JsonbPair) * tupdesc->natts); + + // Initialize the hashTable to hold information regarding the nested json objects within the row + memset(&ct, 0, sizeof(ct)); + ct.keysize = NAMEDATALEN; + ct.entrysize = sizeof(JsonbEntry); + jsonbHash = hash_create("JsonbHash", TABLE_SIZE, &ct, HASH_ELEM | HASH_STRINGS); + + /* process the tuple into key/value pairs */ + for (int i = 0; i < tupdesc->natts; i++) + { + // Pair object that holds key-value + JsonbValue *key; + JsonbValue *value; + JsonbPair *jsonbPair; + + // Used for nested json Objects + JsonbEntry *hashEntry; + JsonbValue *nestedVal; + JsonbValue *current; + char **parts; + int num; + bool found; + char *hashKey; + + char *colname; + Datum colval; + bool isnull; + Oid datatype_oid; + Oid nspoid; + Oid tsql_datatype_oid; + char *typename; + + Form_pg_attribute att = TupleDescAttr(tupdesc, i); + + if (att->attisdropped) + continue; + + colname = NameStr(att->attname); + + if (!strcmp(colname, "\?column\?")) /* When column name or alias is + * not provided */ + { + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("column expressions and data sources without names or aliases cannot be formatted as JSON text using FOR JSON clause. Add alias to the unnamed column or table"))); + } + + colval = heap_getattr(tuple, i + 1, tupdesc, &isnull); + + if (isnull && !include_null_values) + continue; + + /* + * Below is a workaround for is_tsql_x_datatype() which does not work + * as expected. We compare the datatype oid of the columns with the + * tsql_datatype_oid and then specially handle some TSQL-specific + * datatypes. + */ + datatype_oid = att->atttypid; + typename = SPI_gettype(tupdesc, i + 1); + nspoid = get_namespace_oid("sys", true); + Assert(nspoid != InvalidOid); + + tsql_datatype_oid = GetSysCacheOid2(TYPENAMENSP, Anum_pg_type_oid, CStringGetDatum(typename), ObjectIdGetDatum(nspoid)); + + /* + * tsql_datatype_oid can be different from datatype_oid when there are + * datatypes in different namespaces but with the same name. Examples: + * bigint, int, etc. + */ + if (tsql_datatype_oid == datatype_oid) + { + /* binary datatypes are not supported */ + if (strcmp(typename, "binary") == 0 || + strcmp(typename, "varbinary") == 0 || + strcmp(typename, "image") == 0 || + strcmp(typename, "timestamp") == 0 || + strcmp(typename, "rowversion") == 0) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("binary types are not supported with FOR JSON"))); + /* check for bit datatype, and if so, change type to BOOL */ + if (strcmp(typename, "bit") == 0) + { + datatype_oid = BOOLOID; + } + + /* + * convert datetime, smalldatetime, and datetime2 to appropriate + * text values, as T-SQL has a different text conversion than + * postgres. + */ + else if (strcmp(typename, "datetime") == 0 || + strcmp(typename, "smalldatetime") == 0 || + strcmp(typename, "datetime2") == 0) + { + char *val = SPI_getvalue(tuple, tupdesc, i + 1); + StringInfo format_output = makeStringInfo(); + + tsql_for_datetime_format(format_output, val); + colval = CStringGetDatum(format_output->data); + + datatype_oid = CSTRINGOID; + } + + /* + * datetimeoffset has two behaviors: if offset is 0, just return + * the datetime with 'Z' at the end otherwise, append the offset + */ + else if (strcmp(typename, "datetimeoffset") == 0) + { + char *val = SPI_getvalue(tuple, tupdesc, i + 1); + StringInfo format_output = makeStringInfo(); + + tsql_for_datetimeoffset_format(format_output, val); + colval = CStringGetDatum(format_output->data); + + datatype_oid = CSTRINGOID; + } + /* convert money and smallmoney to numeric */ + else if (strcmp(typename, "money") == 0 || + strcmp(typename, "smallmoney") == 0) + { + char *val = SPI_getvalue(tuple, tupdesc, i + 1); + + colval = DirectFunctionCall3(numeric_in, CStringGetDatum(val), ObjectIdGetDatum(InvalidOid), Int32GetDatum(-1)); + datatype_oid = NUMERICOID; + } + } + + // Check for NULL + if (isnull && include_null_values) { + value = palloc(sizeof(JsonbValue)); + value->type=jbvNull; + } + else { + // Extract the colummn value in the correct format + value = palloc(sizeof(JsonbValue)); + jsonb_get_value(colval, isnull, value, datatype_oid); + value = &value->val.array.elems[0]; + } + + // Determine if the value should be inserted as a nested json object + parts = determine_parts(colname, &num); + colname = remove_index_and_alias(colname); + nestedVal = value; + + found = false; + + sscanf(parts[1], "%d", &num); + + maxDepth = (num > maxDepth) ? num : maxDepth; + + if (num > 1) { + hashKey = parts[1]; + + hashEntry = (JsonbEntry *) hash_search(jsonbHash, hashKey, HASH_FIND, &found); + + // If it exists, we insert the value into the existing JsonbValue and break out of the loop + if (hashEntry) { + // function call + current = hashEntry->value; + insert_existing_json_to_obj(current, hashEntry->parent, nestedVal, hashEntry->idx, colname); + pfree(hashKey); + } else { + hashEntry = (JsonbEntry *) hash_search(jsonbHash, (void *) hashKey, HASH_ENTER, NULL); + strlcpy(hashEntry->path, hashKey, NAMEDATALEN); + nestedVal = create_json_array(parts[2], colname, nestedVal, &hashEntry->idx); + hashEntry->value = nestedVal; + + // if the nested json is not at the jsonbRow level + if (num > 2) { + hashEntry->parent = nestedVal; + // insert new array into existing obj for nest + sprintf(hashKey, "%d", num - 1); + hashEntry = (JsonbEntry *) hash_search(jsonbHash, hashKey, HASH_FIND, &found); + current = hashEntry->value; + insert_existing_json_to_obj(current, hashEntry->parent, &(nestedVal->val.object.pairs[0].value), hashEntry->idx, parts[2]); + } + else { + hashEntry->parent = jsonbRow; + hashEntry->idx = jsonbRow->val.object.nPairs; + } + + pfree(hashKey); + + // Already inserted into existing json object (nested) + if (found) + continue; + + // JsonbValue was created in loop, insert and update structure. + jsonbRow->val.object.pairs[jsonbRow->val.object.nPairs] = nestedVal->val.object.pairs[0]; + jsonbRow->val.object.nPairs++; + } + } + else { + // Increment nPairs in the row if it isnt inserted into an already existing json object. + jsonbRow->val.object.nPairs++; + + // Allocate memory for key and create it + key = palloc(sizeof(JsonbValue)); + key->type = jbvString; + key->val.string.len = strlen(colname); + key->val.string.val = pstrdup(colname); + + // Create JsonbPair + jsonbPair = palloc(sizeof(JsonbPair)); + jsonbPair->key = *key; + jsonbPair->value = *nestedVal; + + // Assign it to the JsonbValue Row + jsonbRow->val.object.pairs[jsonbRow->val.object.nPairs - 1] = *jsonbPair; + } + } + + // Add the jsonb row to the jsonbArray + minInsertDepth = 1; + checkForDuplicateRows(jsonbArray, jsonbRow, maxDepth, 1, &minInsertDepth); + + ReleaseTupleDesc(tupdesc); +} + // Main row to json function. // Creates a Jsonb row object, processes the row, determines if it should be inserted as a nested json object // inserts json object to row and then into the main jsonbArray. @@ -538,6 +803,67 @@ create_json(char *part, JsonbValue* val, int *idx) } +// Creates a json array object of the form +// {arrayKey: [{pairkey: pairval}]} +static JsonbValue* +create_json_array(char *arrayKey, char* pairKey, JsonbValue* pairVal, int *idx) +{ + JsonbValue *obj; + JsonbValue *key; + JsonbValue *innerKey; + JsonbPair *pair; + JsonbValue *jsonbArray; + JsonbValue *innerObj; + JsonbPair *innerPair; + + // Create keys + key = palloc(sizeof(JsonbValue)); + key->type = jbvString; + key->val.string.len = strlen(arrayKey); + key->val.string.val = pstrdup(arrayKey); + + innerKey = palloc(sizeof(JsonbValue)); + innerKey->type = jbvString; + innerKey->val.string.len = strlen(pairKey); + innerKey->val.string.val = pstrdup(pairKey); + + // Create Val + jsonbArray = palloc(sizeof(JsonbValue)); + jsonbArray->type = jbvArray; + jsonbArray->val.array.nElems = 1; + jsonbArray->val.array.rawScalar = false; + jsonbArray->val.array.elems = (JsonbValue *) palloc(sizeof(JsonbValue)); + + // Create pair to hold key and value + innerPair = palloc(sizeof(JsonbPair)); + innerPair->key = *innerKey; + innerPair->value = *pairVal; + + innerObj = palloc(sizeof(JsonbValue)); + innerObj->type = jbvObject; + innerObj->val.object.nPairs = 1; + innerObj->val.object.pairs = palloc(sizeof(JsonbPair)); + innerObj->val.object.pairs[innerObj->val.object.nPairs - 1] = *innerPair; + + jsonbArray->val.array.elems[0] = *innerObj; + + // Create pair to hold key and value + pair = palloc(sizeof(JsonbPair)); + pair->key = *key; + pair->value = *jsonbArray; + + // If we are not inserting into an already existing json object + obj = palloc(sizeof(JsonbValue)); + obj->type = jbvObject; + obj->val.object.nPairs = 1; + obj->val.object.pairs = palloc(sizeof(JsonbPair)); + + + obj->val.object.pairs[obj->val.object.nPairs - 1] = *pair; + *idx = obj->val.object.nPairs - 1; + return obj; +} + // Function to append into existing JsonbValue // Used when the path to insert a json object is already found in the HashTable. static void @@ -571,3 +897,147 @@ insert_existing_json(JsonbValue *current, JsonbValue* parent, JsonbValue *nested // update parent pointer parent->val.object.pairs[idx].value = *current; } + +// This function adds a json pair to a given array +static void +insert_existing_json_to_obj(JsonbValue *current, JsonbValue* parent, JsonbValue *nestedVal, int idx, char *key) +{ + JsonbValue *jsonbArray; + JsonbValue *jsonKey; + JsonbPair* newPair; + JsonbPair* currPairs; + JsonbPair* newPairs; + int numPairs; + + jsonKey = palloc(sizeof(JsonbValue)); + jsonKey->type = jbvString; + jsonKey->val.string.len = strlen(key); + jsonKey->val.string.val = pstrdup(key); + + newPair = palloc(sizeof(JsonbPair)); + newPair->key = *jsonKey; + newPair->value = *nestedVal; + + jsonbArray = (JsonbValue *) (((JsonbPair*) current->val.object.pairs)->value.val.array.elems); // Object within the array + currPairs = (JsonbPair*) jsonbArray->val.object.pairs; + numPairs = jsonbArray->val.object.nPairs; + + // Allocate space for the new pairs + newPairs = palloc(sizeof(JsonbPair) * (numPairs + 1)); + + for(int i = 0; i < numPairs; i++) + newPairs[i] = currPairs[i]; + newPairs[numPairs] = *newPair; + + jsonbArray->val.object.nPairs = numPairs + 1; + + jsonbArray->val.object.pairs = newPairs; + + parent->val.object.pairs[idx].value = ((JsonbPair*) current->val.object.pairs)->value; + + return; +} + +/* + * checkForDuplicateRows inserts the given row into the json array + * nested based on the root object + */ +static void +checkForDuplicateRows(JsonbValue *jsonbArray, JsonbValue* row, int maxDepth, int currDepth, int* minInsertDepth) +{ + JsonbPair *arrRowPairs; + JsonbPair *rowPairs; + if(currDepth == maxDepth) { + jsonbArray->val.array.nElems++; + jsonbArray->val.array.elems = (JsonbValue *) repalloc(jsonbArray->val.array.elems, sizeof(JsonbValue) * (jsonbArray->val.array.nElems)); + jsonbArray->val.array.elems[jsonbArray->val.array.nElems - 1] = *row; + *minInsertDepth = currDepth; + return; + } + else { + for(int i = 0; i < jsonbArray->val.array.nElems; i++) { + arrRowPairs = (jsonbArray->val.array.elems[i]).val.object.pairs; + // Assumes that last value will be the next nested array + for(int j = 0; j < (jsonbArray->val.array.elems[i]).val.object.nPairs - 1; j++) { + bool sameElem = false; + rowPairs = row->val.object.pairs; + if(arrRowPairs[j].value.type != rowPairs[j].value.type) + break; + switch(rowPairs[j].value.type) { + case jbvNull: + sameElem = true; + continue; + case jbvString: + sameElem = (strcmp(arrRowPairs[j].value.val.string.val, rowPairs[j].value.val.string.val) == 0); + break; + case jbvNumeric: + sameElem = (compareNumeric(arrRowPairs[j].value.val.numeric, rowPairs[j].value.val.numeric) == 0); + break; + case jbvBool: + sameElem = arrRowPairs[j].value.val.boolean == rowPairs[j].value.val.boolean; + break; + case jbvDatetime: + sameElem = true; + if(arrRowPairs[j].value.val.datetime.value != rowPairs[j].value.val.datetime.value) + sameElem = false; + if(arrRowPairs[j].value.val.datetime.typid != rowPairs[j].value.val.datetime.typid) + sameElem = false; + if(arrRowPairs[j].value.val.datetime.typmod != rowPairs[j].value.val.datetime.typmod) + sameElem = false; + if(arrRowPairs[j].value.val.datetime.tz != rowPairs[j].value.val.datetime.tz) + sameElem = false; + break; + default: + break; + } + if(!sameElem) + break; + if(sameElem && j == (jsonbArray->val.array.elems[i]).val.object.nPairs - 2) { + if(*minInsertDepth == 1) + *minInsertDepth = 2; + checkForDuplicateRows(&(arrRowPairs[(jsonbArray->val.array.elems[i]).val.object.nPairs - 1].value), (row->val.object.pairs[(jsonbArray->val.array.elems[i]).val.object.nPairs - 1].value).val.array.elems, maxDepth, currDepth + 1, minInsertDepth); + } + } + } + if(currDepth == *minInsertDepth) { + jsonbArray->val.array.nElems++; + jsonbArray->val.array.elems = (JsonbValue *) repalloc(jsonbArray->val.array.elems, sizeof(JsonbValue) * (jsonbArray->val.array.nElems)); + if(jsonbArray->val.array.nElems == 1) { + jsonbArray->val.array.elems[0] = *row; + } + else { + jsonbArray->val.array.elems[jsonbArray->val.array.nElems - 1] = jsonbArray->val.array.elems[jsonbArray->val.array.nElems - 2]; + jsonbArray->val.array.elems[jsonbArray->val.array.nElems - 2] = *row; + } + } + return; + } +} + +static int +compareNumeric(Numeric a, Numeric b) +{ + return DatumGetInt32(DirectFunctionCall2(numeric_cmp, + NumericGetDatum(a), + NumericGetDatum(b))); +} + +/* + * JSON AUTO columns are modified to be in the form + * JSONAUTOALIAS.[nest_level].[table_alias].[original_colname] + * this function returns the original column name + */ +char* +remove_index_and_alias(const char* str) +{ + int index = 0; + int num = 0; + for (int i = 0; str[i]; i++) { + if (str[i] == '.') + num++; + index++; + if(num == 3) + return (char*) (str + index); + } + return (char*) str; +} \ No newline at end of file diff --git a/test/JDBC/expected/TestErrorHelperFunctions.out b/test/JDBC/expected/TestErrorHelperFunctions.out index 012d319cf9..ee83dcc37a 100644 --- a/test/JDBC/expected/TestErrorHelperFunctions.out +++ b/test/JDBC/expected/TestErrorHelperFunctions.out @@ -207,6 +207,8 @@ XX000#!#The table-valued parameter "%s" must be declared with the READONLY optio 22023#!#'%s' is not a recognized %s option#!##!#155 22023#!#The datepart %s is not supported by date function %s for data type %s.#!##!#9810 22008#!#Adding a value to a '%s' column caused an overflow.#!##!#517 +42P01#!#FOR JSON AUTO requires at least one table for generating JSON objects. Use FOR JSON PATH or add a FROM clause with a table name.#!##!#13600 +42P01#!#Values for json auto is not currently supported.#!##!#13600 ~~END~~ diff --git a/test/JDBC/expected/TestErrorHelperFunctionsUpgrade-vu-verify.out b/test/JDBC/expected/TestErrorHelperFunctionsUpgrade-vu-verify.out index 902d262c0e..e72a0d8405 100644 --- a/test/JDBC/expected/TestErrorHelperFunctionsUpgrade-vu-verify.out +++ b/test/JDBC/expected/TestErrorHelperFunctionsUpgrade-vu-verify.out @@ -127,6 +127,7 @@ int 11708 11709 11717 +13600 15003 16901 16902 @@ -314,6 +315,8 @@ int 155 9810 517 +13600 +13600 ~~END~~ @@ -485,6 +488,8 @@ int 155 9810 517 +13600 +13600 ~~END~~ @@ -492,6 +497,6 @@ EXEC TestErrorHelperFunctionsUpgrade_VU_PREPARE_PROC GO ~~START~~ int -164 +166 ~~END~~ diff --git a/test/JDBC/expected/forjsonauto-vu-cleanup.out b/test/JDBC/expected/forjsonauto-vu-cleanup.out new file mode 100644 index 0000000000..deafc10a83 --- /dev/null +++ b/test/JDBC/expected/forjsonauto-vu-cleanup.out @@ -0,0 +1,84 @@ +DROP VIEW forjson_vu_v_1 +GO + +DROP VIEW forjson_vu_v_2 +GO + +DROP VIEW forjson_vu_v_3 +GO + +DROP VIEW forjson_vu_v_4 +GO + +DROP VIEW forjson_vu_v_5 +GO + +DROP VIEW forjson_vu_v_6 +GO + +DROP VIEW forjson_vu_v_7 +GO + +DROP VIEW forjson_vu_v_8 +GO + +DROP VIEW forjson_vu_v_9 +GO + +DROP VIEW forjson_vu_v_10 +GO + +DROP VIEW forjson_vu_v_11 +GO + +DROP VIEW forjson_vu_v_12 +GO + +DROP VIEW forjson_vu_v_13 +GO + +DROP VIEW forjson_vu_v_14 +GO + +DROP PROCEDURE forjson_vu_p_1 +GO + +DROP PROCEDURE forjson_vu_p_2 +GO + +DROP PROCEDURE forjson_vu_p_3 +GO + +DROP PROCEDURE forjson_vu_p_4 +GO + +DROP PROCEDURE forjson_vu_p_5 +GO + + +DROP FUNCTION forjson_vu_f_1() +GO + +drop trigger forjson_vu_trigger_1; +go + +drop trigger forjson_vu_trigger_2; +go + +DROP TABLE forjson_auto_vu_t_users +GO + +DROP TABLE forjson_auto_vu_t_orders +GO + +DROP TABLE forjson_auto_vu_t_products +GO + +DROP TABLE forjson_auto_vu_t_sales +GO + +DROP TABLE forjson_auto_vu_t_times +GO + +DROP TABLE t50 +GO diff --git a/test/JDBC/expected/forjsonauto-vu-prepare.out b/test/JDBC/expected/forjsonauto-vu-prepare.out new file mode 100644 index 0000000000..e310e29271 --- /dev/null +++ b/test/JDBC/expected/forjsonauto-vu-prepare.out @@ -0,0 +1,197 @@ + +CREATE TABLE forjson_auto_vu_t_users ([Id] int, [firstname] varchar(50), [lastname] varchar(50), [email] varchar(50)); +CREATE TABLE forjson_auto_vu_t_orders ([Id] int, [userid] int, [productid] int, [quantity] int, [orderdate] Date); +CREATE TABLE forjson_auto_vu_t_products ([Id] int, [name] varchar(50), [price] varchar (25)); +CREATE TABLE forjson_auto_vu_t_sales ([Id] int, [price] varchar(25), [totalSales] int); +CREATE TABLE forjson_auto_vu_t_times ([Id] int, [date] Date); +INSERT INTO forjson_auto_vu_t_users VALUES (1, 'j', 'o', 'testemail'), (1, 'e', 'l', 'testemail2'); +INSERT INTO forjson_auto_vu_t_orders VALUES (1, 1, 1, 5, '2023-06-25'), (2, 1, 1, 6, '2023-06-25'); +INSERT INTO forjson_auto_vu_t_products VALUES (1, 'A', 20), (1, 'B', 30); +INSERT INTO forjson_auto_vu_t_sales VALUES (1, 20, 50), (2, 30, 100); +INSERT INTO forjson_auto_vu_t_times VALUES (1, '2023-11-26'), (2, '2023-11-27'); +GO +~~ROW COUNT: 2~~ + +~~ROW COUNT: 2~~ + +~~ROW COUNT: 2~~ + +~~ROW COUNT: 2~~ + +~~ROW COUNT: 2~~ + + +CREATE VIEW forjson_vu_v_1 AS +SELECT ( + select U.Id AS "users.userid", O.productId AS "order.productId", O.Id AS "product.oid", P.price AS "product.price" FROM forjson_auto_vu_t_users U JOIN forjson_auto_vu_t_orders O ON (U.id = O.userid) JOIN forjson_auto_vu_t_products P ON (P.id = O.productid) FOR JSON AUTO +) c1 +GO + +CREATE VIEW forjson_vu_v_2 AS +SELECT ( + select U.Id AS "users.userid", + U.firstname as "firstname" + FROM forjson_auto_vu_t_users U FOR JSON AUTO +) c1 +GO + +CREATE VIEW forjson_vu_v_3 AS +SELECT ( + select U.Id AS "users.userid", + U.firstname as "firstname", + O.productId AS "order.productId" + FROM forjson_auto_vu_t_users U JOIN forjson_auto_vu_t_orders O ON (U.id = O.userid) FOR JSON AUTO +) c1 +GO + +CREATE VIEW forjson_vu_v_4 AS +SELECT ( + select U.Id AS "users.userid", O.productId AS "order.productId", O.Id AS "product.oid", P.price AS "product.price", S.totalSales AS "totalsales" FROM forjson_auto_vu_t_users U JOIN forjson_auto_vu_t_orders O ON (U.id = O.userid) JOIN forjson_auto_vu_t_products P ON (P.id = O.productid) JOIN forjson_auto_vu_t_sales S ON (P.price = S.price) FOR JSON AUTO +) c1 +GO + +CREATE VIEW forjson_vu_v_5 AS +SELECT ( + select forjson_auto_vu_t_users.Id, + firstname, + productId + FROM forjson_auto_vu_t_users JOIN forjson_auto_vu_t_orders ON (forjson_auto_vu_t_users.id = userid) FOR JSON AUTO +) c1 +GO + +CREATE VIEW forjson_vu_v_6 AS +SELECT ( + select Id, + firstname, + lastname + FROM forjson_auto_vu_t_users FOR JSON AUTO +) c1 +GO + +CREATE VIEW forjson_vu_v_7 AS +SELECT ( + select U.Id, + name, + price + FROM forjson_auto_vu_t_users U JOIN forjson_auto_vu_t_products P ON (U.Id = P.Id) FOR JSON AUTO +) c1 +GO + +CREATE PROCEDURE forjson_vu_p_1 AS +SELECT ( + select U.Id AS "users.userid", O.productId AS "order.productId", O.Id AS "product.oid", P.price AS "product.price", S.totalSales AS "totalsales" FROM forjson_auto_vu_t_users U JOIN forjson_auto_vu_t_orders O ON (U.id = O.userid) JOIN forjson_auto_vu_t_products P ON (P.id = O.productid) JOIN forjson_auto_vu_t_sales S ON (P.price = S.price) FOR JSON AUTO +) c1 +GO + +INSERT INTO forjson_auto_vu_t_sales VALUES (1, NULL, NULL), (2, NULL, NULL); +GO +~~ROW COUNT: 2~~ + + +CREATE VIEW forjson_vu_v_8 AS +SELECT ( + select U.Id AS "users.userid", O.productId AS "order.productId", O.Id AS "product.oid", P.price AS "product.price", S.totalSales AS "totalsales" FROM forjson_auto_vu_t_users U JOIN forjson_auto_vu_t_orders O ON (U.id = O.userid) JOIN forjson_auto_vu_t_products P ON (P.id = O.productid) JOIN forjson_auto_vu_t_sales S ON (P.price = S.price) FOR JSON AUTO +) c1 +GO + +CREATE VIEW forjson_vu_v_9 AS +SELECT ( + select U.Id AS "users.userid", O.productId AS "order.productId", O.Id AS "product.oid", P.price AS "product.price", S.totalSales AS "totalsales", T.date as "date" FROM forjson_auto_vu_t_users U JOIN forjson_auto_vu_t_orders O ON (U.id = O.userid) JOIN forjson_auto_vu_t_products P ON (P.id = O.productid) JOIN forjson_auto_vu_t_sales S ON (P.price = S.price) JOIN forjson_auto_vu_t_times T ON (S.Id = T.Id) FOR JSON AUTO +) c1 +GO + +-- tests unique characters +CREATE VIEW forjson_vu_v_10 AS +SELECT ( + select U.Id AS "users.userid", O.productId AS "өглөө", O.Id AS "product.oid", P.price AS "product.price", S.totalSales AS "totalsales" FROM forjson_auto_vu_t_users U JOIN forjson_auto_vu_t_orders O ON (U.id = O.userid) JOIN forjson_auto_vu_t_products P ON (P.id = O.productid) JOIN forjson_auto_vu_t_sales S ON (P.price = S.price) FOR JSON AUTO +) c1 +GO + +CREATE VIEW forjson_vu_v_11 AS +SELECT ( + select U.Id AS "users.ελπίδα", + U.firstname as "爱", + U.lastname as "كلب" + FROM forjson_auto_vu_t_users U FOR JSON AUTO +) c1 +GO + +CREATE VIEW forjson_vu_v_12 AS +SELECT ( + select totalSales FROM forjson_auto_vu_t_sales FOR JSON AUTO, INCLUDE_NULL_VALUES +) c1 +GO + +create table t50 (x nvarchar(20)) +insert into t50 values ('some string') +go +~~ROW COUNT: 1~~ + + +CREATE VIEW forjson_vu_v_13 AS +SELECT ( + select json_modify('{"a":"b"}', '$.a', x) from (select * from t50 for json auto) a ([x]) +) c1 +GO + +CREATE VIEW forjson_vu_v_14 AS +SELECT ( + select json_query((select U.Id AS "users.userid", O.productId AS "order.productId", O.Id AS "product.oid", P.price AS "product.price", S.totalSales AS "totalsales" FROM forjson_auto_vu_t_users U JOIN forjson_auto_vu_t_orders O ON (U.id = O.userid) JOIN forjson_auto_vu_t_products P ON (P.id = O.productid) JOIN forjson_auto_vu_t_sales S ON (P.price = S.price) JOIN forjson_auto_vu_t_times T ON (S.Id = T.Id) FOR JSON AUTO)) AS [data] +) c1 +GO + +CREATE PROCEDURE forjson_vu_p_2 AS +BEGIN + CREATE TABLE users ([Id] int, [firstname] varchar(50)); + CREATE TABLE orders ([Id] int, [productid] int, [quantity] int, [orderdate] Date); + INSERT INTO users VALUES (1, 'j'), (2, 'k'), (3, 'l') + INSERT INTO orders VALUES (1, 1, 100, '01-01-2024'), (2, 2, 500, '01-01-2024') + select U.Id AS "users.userid", U.firstname as "firstname" FROM users U JOIN orders O ON (U.id = O.Id) FOR JSON AUTO + DROP TABLE users + DROP TABLE orders +END +GO + +CREATE FUNCTION forjson_vu_f_1() +RETURNS sys.NVARCHAR(5000) AS +BEGIN +RETURN (select U.Id AS "users.userid", O.productId AS "өглөө", O.Id AS "product.oid", P.price AS "product.price", S.totalSales AS "totalsales" FROM forjson_auto_vu_t_users U JOIN forjson_auto_vu_t_orders O ON (U.id = O.userid) JOIN forjson_auto_vu_t_products P ON (P.id = O.productid) JOIN forjson_auto_vu_t_sales S ON (P.price = S.price) FOR JSON AUTO) +END +GO + +CREATE PROCEDURE forjson_vu_p_3 AS +BEGIN + with cte as (select 1 as Id), cte2 as (select 1 as Id) select U.Id, O.Id from cte U JOIN cte2 O on (U.Id = O.Id) for json auto +END +GO + +CREATE PROCEDURE forjson_vu_p_4 AS +BEGIN + with cte as (select Id, firstname from forjson_auto_vu_t_users), cte2 as (select Id, productid from forjson_auto_vu_t_orders) + select U.Id, O.productId from cte U JOIN cte2 O ON (U.Id = O.Id) for JSON AUTO +END +GO + +CREATE PROCEDURE forjson_vu_p_5 AS +BEGIN + SELECT x.Val, y.Val ValY FROM (VALUES (1)) AS x(Val) JOIN (SELECT Val FROM (VALUES (1)) AS _(Val)) y ON y.Val = x.Val for json auto +END +GO + +CREATE TRIGGER forjson_vu_trigger_1 on forjson_auto_vu_t_users for insert as +BEGIN + with cte (Id, firstname) as (select Id, firstname from forjson_auto_vu_t_users), cte2 (Id, firstname) as (select Id, firstname from cte) + select * from cte2 for JSON AUTO +END +GO + +CREATE TRIGGER forjson_vu_trigger_2 on forjson_auto_vu_t_users for insert as +begin + select U.Id AS "users.userid", + U.firstname as "firstname", + U.lastname as "lastname", + O.productId AS "order.productId" + FROM forjson_auto_vu_t_users U JOIN forjson_auto_vu_t_orders O ON (U.id = O.userid) FOR JSON AUTO +end; +go + diff --git a/test/JDBC/expected/forjsonauto-vu-verify.out b/test/JDBC/expected/forjsonauto-vu-verify.out new file mode 100644 index 0000000000..b907571f44 --- /dev/null +++ b/test/JDBC/expected/forjsonauto-vu-verify.out @@ -0,0 +1,177 @@ +SELECT * FROM forjson_vu_v_1 +GO +~~START~~ +nvarchar +[{"users.userid": 1, "o": [{"order.productId": 1, "product.oid": 2, "p": [{"product.price": "20"}, {"product.price": "20"}, {"product.price": "30"}, {"product.price": "30"}]}, {"order.productId": 1, "product.oid": 1, "p": [{"product.price": "20"}, {"product.price": "20"}, {"product.price": "30"}, {"product.price": "30"}]}]}] +~~END~~ + + +SELECT * FROM forjson_vu_v_2 +GO +~~START~~ +nvarchar +[{"users.userid": 1, "firstname": "j"}, {"users.userid": 1, "firstname": "e"}] +~~END~~ + + +SELECT * FROM forjson_vu_v_3 +GO +~~START~~ +nvarchar +[{"users.userid": 1, "firstname": "j", "o": [{"order.productId": 1}, {"order.productId": 1}]}, {"users.userid": 1, "firstname": "e", "o": [{"order.productId": 1}, {"order.productId": 1}]}] +~~END~~ + + +SELECT * FROM forjson_vu_v_4 +GO +~~START~~ +nvarchar +[{"users.userid": 1, "o": [{"order.productId": 1, "product.oid": 2, "p": [{"product.price": "20", "s": [{"totalsales": 50}, {"totalsales": 50}]}]}, {"order.productId": 1, "product.oid": 1, "p": [{"product.price": "30", "s": [{"totalsales": 100}, {"totalsales": 100}]}]}, {"order.productId": 1, "product.oid": 2, "p": [{"product.price": "30", "s": [{"totalsales": 100}, {"totalsales": 100}]}]}, {"order.productId": 1, "product.oid": 1, "p": [{"product.price": "20", "s": [{"totalsales": 50}, {"totalsales": 50}]}]}]}] +~~END~~ + + +SELECT * FROM forjson_vu_v_5 +GO +~~START~~ +nvarchar +[{"Id": 1, "firstname": "j", "forjson_auto_vu_t_orders": [{"productId": 1}, {"productId": 1}]}, {"Id": 1, "firstname": "e", "forjson_auto_vu_t_orders": [{"productId": 1}, {"productId": 1}]}] +~~END~~ + + +SELECT * FROM forjson_vu_v_6 +GO +~~START~~ +nvarchar +[{"Id": 1, "firstname": "j", "lastname": "o"}, {"Id": 1, "firstname": "e", "lastname": "l"}] +~~END~~ + + +SELECT * FROM forjson_vu_v_7 +GO +~~START~~ +nvarchar +[{"Id": 1, "p": [{"name": "A", "price": "20"}, {"name": "A", "price": "20"}, {"name": "B", "price": "30"}, {"name": "B", "price": "30"}]}] +~~END~~ + + +SELECT * FROM forjson_vu_v_8 +GO +~~START~~ +nvarchar +[{"users.userid": 1, "o": [{"order.productId": 1, "product.oid": 2, "p": [{"product.price": "20", "s": [{"totalsales": 50}, {"totalsales": 50}]}]}, {"order.productId": 1, "product.oid": 1, "p": [{"product.price": "30", "s": [{"totalsales": 100}, {"totalsales": 100}]}]}, {"order.productId": 1, "product.oid": 2, "p": [{"product.price": "30", "s": [{"totalsales": 100}, {"totalsales": 100}]}]}, {"order.productId": 1, "product.oid": 1, "p": [{"product.price": "20", "s": [{"totalsales": 50}, {"totalsales": 50}]}]}]}] +~~END~~ + + +SELECT * FROM forjson_vu_v_9 +GO +~~START~~ +nvarchar +[{"users.userid": 1, "o": [{"order.productId": 1, "product.oid": 2, "p": [{"product.price": "20", "s": [{"totalsales": 50, "t": [{"date": "2023-11-26"}, {"date": "2023-11-26"}]}]}]}, {"order.productId": 1, "product.oid": 1, "p": [{"product.price": "30", "s": [{"totalsales": 100, "t": [{"date": "2023-11-27"}, {"date": "2023-11-27"}]}]}]}, {"order.productId": 1, "product.oid": 2, "p": [{"product.price": "30", "s": [{"totalsales": 100, "t": [{"date": "2023-11-27"}, {"date": "2023-11-27"}]}]}]}, {"order.productId": 1, "product.oid": 1, "p": [{"product.price": "20", "s": [{"totalsales": 50, "t": [{"date": "2023-11-26"}, {"date": "2023-11-26"}]}]}]}]}] +~~END~~ + + +SELECT * FROM forjson_vu_v_10 +GO +~~START~~ +nvarchar +[{"users.userid": 1, "o": [{"өглөө": 1, "product.oid": 2, "p": [{"product.price": "20", "s": [{"totalsales": 50}, {"totalsales": 50}]}]}, {"өглөө": 1, "product.oid": 1, "p": [{"product.price": "30", "s": [{"totalsales": 100}, {"totalsales": 100}]}]}, {"өглөө": 1, "product.oid": 2, "p": [{"product.price": "30", "s": [{"totalsales": 100}, {"totalsales": 100}]}]}, {"өглөө": 1, "product.oid": 1, "p": [{"product.price": "20", "s": [{"totalsales": 50}, {"totalsales": 50}]}]}]}] +~~END~~ + + +SELECT * FROM forjson_vu_v_11 +GO +~~START~~ +nvarchar +[{"users.ελπίδα": 1, "爱": "j", "كلب": "o"}, {"users.ελπίδα": 1, "爱": "e", "كلب": "l"}] +~~END~~ + + +SELECT * FROM forjson_vu_v_12 +GO +~~START~~ +nvarchar +[{"totalSales": 50}, {"totalSales": 100}, {"totalSales": null}, {"totalSales": null}] +~~END~~ + + +SELECT * FROM forjson_vu_v_13 +GO +~~START~~ +nvarchar +{"a": "[{\"x\": \"some string\"}]"} +~~END~~ + + +SELECT * FROM forjson_vu_v_14 +GO +~~START~~ +nvarchar +[{"o": [{"p": [{"s": [{"totalsales": 50}, {"totalsales": 50}], "product.price": "20"}], "product.oid": 2, "order.productId": 1}, {"p": [{"s": [{"totalsales": 100}, {"totalsales": 100}], "product.price": "30"}], "product.oid": 1, "order.productId": 1}, {"p": [{"s": [{"totalsales": 100}, {"totalsales": 100}], "product.price": "30"}], "product.oid": 2, "order.productId": 1}, {"p": [{"s": [{"totalsales": 50}, {"totalsales": 50}], "product.price": "20"}], "product.oid": 1, "order.productId": 1}], "users.userid": 1}] +~~END~~ + + +EXECUTE forjson_vu_p_1 +GO +~~START~~ +nvarchar +[{"users.userid": 1, "o": [{"order.productId": 1, "product.oid": 2, "p": [{"product.price": "20", "s": [{"totalsales": 50}, {"totalsales": 50}]}]}, {"order.productId": 1, "product.oid": 1, "p": [{"product.price": "30", "s": [{"totalsales": 100}, {"totalsales": 100}]}]}, {"order.productId": 1, "product.oid": 2, "p": [{"product.price": "30", "s": [{"totalsales": 100}, {"totalsales": 100}]}]}, {"order.productId": 1, "product.oid": 1, "p": [{"product.price": "20", "s": [{"totalsales": 50}, {"totalsales": 50}]}]}]}] +~~END~~ + + +EXECUTE forjson_vu_p_2 +GO +~~ROW COUNT: 3~~ + +~~ROW COUNT: 2~~ + +~~START~~ +nvarchar +[{"users.userid": 1, "firstname": "j"}, {"users.userid": 2, "firstname": "k"}] +~~END~~ + + +EXECUTE forjson_vu_p_3 +GO +~~START~~ +nvarchar +[{"Id": 1, "Id": 1}] +~~END~~ + + +EXECUTE forjson_vu_p_4 +GO +~~START~~ +nvarchar +[{"Id": 1, "forjson_auto_vu_t_orders": [{"productId": 1}, {"productId": 1}]}] +~~END~~ + + +EXECUTE forjson_vu_p_5 +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Values for json auto is not currently supported )~~ + + +SELECT forjson_vu_f_1() +GO +~~START~~ +nvarchar +[{"users.userid": 1, "o": [{"өглөө": 1, "product.oid": 2, "p": [{"product.price": "20", "s": [{"totalsales": 50}, {"totalsales": 50}]}]}, {"өглөө": 1, "product.oid": 1, "p": [{"product.price": "30", "s": [{"totalsales": 100}, {"totalsales": 100}]}]}, {"өглөө": 1, "product.oid": 2, "p": [{"product.price": "30", "s": [{"totalsales": 100}, {"totalsales": 100}]}]}, {"өглөө": 1, "product.oid": 1, "p": [{"product.price": "20", "s": [{"totalsales": 50}, {"totalsales": 50}]}]}]}] +~~END~~ + + +INSERT INTO forjson_auto_vu_t_users VALUES (1, 'e', 'o', 'testemail3') +go +~~START~~ +nvarchar +[{"id": 1, "firstname": "j"}, {"id": 1, "firstname": "e"}, {"id": 1, "firstname": "e"}] +~~END~~ + +~~START~~ +nvarchar +[{"users.userid": 1, "firstname": "e", "lastname": "l", "o": [{"order.productId": 1}, {"order.productId": 1}]}, {"users.userid": 1, "firstname": "j", "lastname": "o", "o": [{"order.productId": 1}, {"order.productId": 1}]}, {"users.userid": 1, "firstname": "e", "lastname": "o", "o": [{"order.productId": 1}, {"order.productId": 1}]}] +~~END~~ + +~~ROW COUNT: 1~~ + diff --git a/test/JDBC/input/forjson/forjsonauto-vu-cleanup.sql b/test/JDBC/input/forjson/forjsonauto-vu-cleanup.sql new file mode 100644 index 0000000000..7ded18b1a8 --- /dev/null +++ b/test/JDBC/input/forjson/forjsonauto-vu-cleanup.sql @@ -0,0 +1,84 @@ +DROP VIEW forjson_vu_v_1 +GO + +DROP VIEW forjson_vu_v_2 +GO + +DROP VIEW forjson_vu_v_3 +GO + +DROP VIEW forjson_vu_v_4 +GO + +DROP VIEW forjson_vu_v_5 +GO + +DROP VIEW forjson_vu_v_6 +GO + +DROP VIEW forjson_vu_v_7 +GO + +DROP VIEW forjson_vu_v_8 +GO + +DROP VIEW forjson_vu_v_9 +GO + +DROP VIEW forjson_vu_v_10 +GO + +DROP VIEW forjson_vu_v_11 +GO + +DROP VIEW forjson_vu_v_12 +GO + +DROP VIEW forjson_vu_v_13 +GO + +DROP VIEW forjson_vu_v_14 +GO + +DROP PROCEDURE forjson_vu_p_1 +GO + +DROP PROCEDURE forjson_vu_p_2 +GO + +DROP PROCEDURE forjson_vu_p_3 +GO + +DROP PROCEDURE forjson_vu_p_4 +GO + +DROP PROCEDURE forjson_vu_p_5 +GO + + +DROP FUNCTION forjson_vu_f_1() +GO + +drop trigger forjson_vu_trigger_1; +go + +drop trigger forjson_vu_trigger_2; +go + +DROP TABLE forjson_auto_vu_t_users +GO + +DROP TABLE forjson_auto_vu_t_orders +GO + +DROP TABLE forjson_auto_vu_t_products +GO + +DROP TABLE forjson_auto_vu_t_sales +GO + +DROP TABLE forjson_auto_vu_t_times +GO + +DROP TABLE t50 +GO \ No newline at end of file diff --git a/test/JDBC/input/forjson/forjsonauto-vu-prepare.sql b/test/JDBC/input/forjson/forjsonauto-vu-prepare.sql new file mode 100644 index 0000000000..25f254eaa2 --- /dev/null +++ b/test/JDBC/input/forjson/forjsonauto-vu-prepare.sql @@ -0,0 +1,183 @@ +CREATE TABLE forjson_auto_vu_t_users ([Id] int, [firstname] varchar(50), [lastname] varchar(50), [email] varchar(50)); +CREATE TABLE forjson_auto_vu_t_orders ([Id] int, [userid] int, [productid] int, [quantity] int, [orderdate] Date); +CREATE TABLE forjson_auto_vu_t_products ([Id] int, [name] varchar(50), [price] varchar (25)); +CREATE TABLE forjson_auto_vu_t_sales ([Id] int, [price] varchar(25), [totalSales] int); +CREATE TABLE forjson_auto_vu_t_times ([Id] int, [date] Date); + +INSERT INTO forjson_auto_vu_t_users VALUES (1, 'j', 'o', 'testemail'), (1, 'e', 'l', 'testemail2'); +INSERT INTO forjson_auto_vu_t_orders VALUES (1, 1, 1, 5, '2023-06-25'), (2, 1, 1, 6, '2023-06-25'); +INSERT INTO forjson_auto_vu_t_products VALUES (1, 'A', 20), (1, 'B', 30); +INSERT INTO forjson_auto_vu_t_sales VALUES (1, 20, 50), (2, 30, 100); +INSERT INTO forjson_auto_vu_t_times VALUES (1, '2023-11-26'), (2, '2023-11-27'); +GO + +CREATE VIEW forjson_vu_v_1 AS +SELECT ( + select U.Id AS "users.userid", O.productId AS "order.productId", O.Id AS "product.oid", P.price AS "product.price" FROM forjson_auto_vu_t_users U JOIN forjson_auto_vu_t_orders O ON (U.id = O.userid) JOIN forjson_auto_vu_t_products P ON (P.id = O.productid) FOR JSON AUTO +) c1 +GO + +CREATE VIEW forjson_vu_v_2 AS +SELECT ( + select U.Id AS "users.userid", + U.firstname as "firstname" + FROM forjson_auto_vu_t_users U FOR JSON AUTO +) c1 +GO + +CREATE VIEW forjson_vu_v_3 AS +SELECT ( + select U.Id AS "users.userid", + U.firstname as "firstname", + O.productId AS "order.productId" + FROM forjson_auto_vu_t_users U JOIN forjson_auto_vu_t_orders O ON (U.id = O.userid) FOR JSON AUTO +) c1 +GO + +CREATE VIEW forjson_vu_v_4 AS +SELECT ( + select U.Id AS "users.userid", O.productId AS "order.productId", O.Id AS "product.oid", P.price AS "product.price", S.totalSales AS "totalsales" FROM forjson_auto_vu_t_users U JOIN forjson_auto_vu_t_orders O ON (U.id = O.userid) JOIN forjson_auto_vu_t_products P ON (P.id = O.productid) JOIN forjson_auto_vu_t_sales S ON (P.price = S.price) FOR JSON AUTO +) c1 +GO + +CREATE VIEW forjson_vu_v_5 AS +SELECT ( + select forjson_auto_vu_t_users.Id, + firstname, + productId + FROM forjson_auto_vu_t_users JOIN forjson_auto_vu_t_orders ON (forjson_auto_vu_t_users.id = userid) FOR JSON AUTO +) c1 +GO + +CREATE VIEW forjson_vu_v_6 AS +SELECT ( + select Id, + firstname, + lastname + FROM forjson_auto_vu_t_users FOR JSON AUTO +) c1 +GO + +CREATE VIEW forjson_vu_v_7 AS +SELECT ( + select U.Id, + name, + price + FROM forjson_auto_vu_t_users U JOIN forjson_auto_vu_t_products P ON (U.Id = P.Id) FOR JSON AUTO +) c1 +GO + +CREATE PROCEDURE forjson_vu_p_1 AS +SELECT ( + select U.Id AS "users.userid", O.productId AS "order.productId", O.Id AS "product.oid", P.price AS "product.price", S.totalSales AS "totalsales" FROM forjson_auto_vu_t_users U JOIN forjson_auto_vu_t_orders O ON (U.id = O.userid) JOIN forjson_auto_vu_t_products P ON (P.id = O.productid) JOIN forjson_auto_vu_t_sales S ON (P.price = S.price) FOR JSON AUTO +) c1 +GO + +INSERT INTO forjson_auto_vu_t_sales VALUES (1, NULL, NULL), (2, NULL, NULL); +GO + +CREATE VIEW forjson_vu_v_8 AS +SELECT ( + select U.Id AS "users.userid", O.productId AS "order.productId", O.Id AS "product.oid", P.price AS "product.price", S.totalSales AS "totalsales" FROM forjson_auto_vu_t_users U JOIN forjson_auto_vu_t_orders O ON (U.id = O.userid) JOIN forjson_auto_vu_t_products P ON (P.id = O.productid) JOIN forjson_auto_vu_t_sales S ON (P.price = S.price) FOR JSON AUTO +) c1 +GO + +CREATE VIEW forjson_vu_v_9 AS +SELECT ( + select U.Id AS "users.userid", O.productId AS "order.productId", O.Id AS "product.oid", P.price AS "product.price", S.totalSales AS "totalsales", T.date as "date" FROM forjson_auto_vu_t_users U JOIN forjson_auto_vu_t_orders O ON (U.id = O.userid) JOIN forjson_auto_vu_t_products P ON (P.id = O.productid) JOIN forjson_auto_vu_t_sales S ON (P.price = S.price) JOIN forjson_auto_vu_t_times T ON (S.Id = T.Id) FOR JSON AUTO +) c1 +GO + +-- tests unique characters +CREATE VIEW forjson_vu_v_10 AS +SELECT ( + select U.Id AS "users.userid", O.productId AS "өглөө", O.Id AS "product.oid", P.price AS "product.price", S.totalSales AS "totalsales" FROM forjson_auto_vu_t_users U JOIN forjson_auto_vu_t_orders O ON (U.id = O.userid) JOIN forjson_auto_vu_t_products P ON (P.id = O.productid) JOIN forjson_auto_vu_t_sales S ON (P.price = S.price) FOR JSON AUTO +) c1 +GO + +CREATE VIEW forjson_vu_v_11 AS +SELECT ( + select U.Id AS "users.ελπίδα", + U.firstname as "爱", + U.lastname as "كلب" + FROM forjson_auto_vu_t_users U FOR JSON AUTO +) c1 +GO + +CREATE VIEW forjson_vu_v_12 AS +SELECT ( + select totalSales FROM forjson_auto_vu_t_sales FOR JSON AUTO, INCLUDE_NULL_VALUES +) c1 +GO + +create table t50 (x nvarchar(20)) +insert into t50 values ('some string') +go + +CREATE VIEW forjson_vu_v_13 AS +SELECT ( + select json_modify('{"a":"b"}', '$.a', x) from (select * from t50 for json auto) a ([x]) +) c1 +GO + +CREATE VIEW forjson_vu_v_14 AS +SELECT ( + select json_query((select U.Id AS "users.userid", O.productId AS "order.productId", O.Id AS "product.oid", P.price AS "product.price", S.totalSales AS "totalsales" FROM forjson_auto_vu_t_users U JOIN forjson_auto_vu_t_orders O ON (U.id = O.userid) JOIN forjson_auto_vu_t_products P ON (P.id = O.productid) JOIN forjson_auto_vu_t_sales S ON (P.price = S.price) JOIN forjson_auto_vu_t_times T ON (S.Id = T.Id) FOR JSON AUTO)) AS [data] +) c1 +GO + +CREATE PROCEDURE forjson_vu_p_2 AS +BEGIN + CREATE TABLE users ([Id] int, [firstname] varchar(50)); + CREATE TABLE orders ([Id] int, [productid] int, [quantity] int, [orderdate] Date); + INSERT INTO users VALUES (1, 'j'), (2, 'k'), (3, 'l') + INSERT INTO orders VALUES (1, 1, 100, '01-01-2024'), (2, 2, 500, '01-01-2024') + select U.Id AS "users.userid", U.firstname as "firstname" FROM users U JOIN orders O ON (U.id = O.Id) FOR JSON AUTO + DROP TABLE users + DROP TABLE orders +END +GO + +CREATE FUNCTION forjson_vu_f_1() +RETURNS sys.NVARCHAR(5000) AS +BEGIN +RETURN (select U.Id AS "users.userid", O.productId AS "өглөө", O.Id AS "product.oid", P.price AS "product.price", S.totalSales AS "totalsales" FROM forjson_auto_vu_t_users U JOIN forjson_auto_vu_t_orders O ON (U.id = O.userid) JOIN forjson_auto_vu_t_products P ON (P.id = O.productid) JOIN forjson_auto_vu_t_sales S ON (P.price = S.price) FOR JSON AUTO) +END +GO + +CREATE PROCEDURE forjson_vu_p_3 AS +BEGIN + with cte as (select 1 as Id), cte2 as (select 1 as Id) select U.Id, O.Id from cte U JOIN cte2 O on (U.Id = O.Id) for json auto +END +GO + +CREATE PROCEDURE forjson_vu_p_4 AS +BEGIN + with cte as (select Id, firstname from forjson_auto_vu_t_users), cte2 as (select Id, productid from forjson_auto_vu_t_orders) + select U.Id, O.productId from cte U JOIN cte2 O ON (U.Id = O.Id) for JSON AUTO +END +GO + +CREATE PROCEDURE forjson_vu_p_5 AS +BEGIN + SELECT x.Val, y.Val ValY FROM (VALUES (1)) AS x(Val) JOIN (SELECT Val FROM (VALUES (1)) AS _(Val)) y ON y.Val = x.Val for json auto +END +GO + +CREATE TRIGGER forjson_vu_trigger_1 on forjson_auto_vu_t_users for insert as +BEGIN + with cte (Id, firstname) as (select Id, firstname from forjson_auto_vu_t_users), cte2 (Id, firstname) as (select Id, firstname from cte) + select * from cte2 for JSON AUTO +END +GO + +CREATE TRIGGER forjson_vu_trigger_2 on forjson_auto_vu_t_users for insert as +begin + select U.Id AS "users.userid", + U.firstname as "firstname", + U.lastname as "lastname", + O.productId AS "order.productId" + FROM forjson_auto_vu_t_users U JOIN forjson_auto_vu_t_orders O ON (U.id = O.userid) FOR JSON AUTO +end; +go + diff --git a/test/JDBC/input/forjson/forjsonauto-vu-verify.sql b/test/JDBC/input/forjson/forjsonauto-vu-verify.sql new file mode 100644 index 0000000000..6c56020438 --- /dev/null +++ b/test/JDBC/input/forjson/forjsonauto-vu-verify.sql @@ -0,0 +1,62 @@ +SELECT * FROM forjson_vu_v_1 +GO + +SELECT * FROM forjson_vu_v_2 +GO + +SELECT * FROM forjson_vu_v_3 +GO + +SELECT * FROM forjson_vu_v_4 +GO + +SELECT * FROM forjson_vu_v_5 +GO + +SELECT * FROM forjson_vu_v_6 +GO + +SELECT * FROM forjson_vu_v_7 +GO + +SELECT * FROM forjson_vu_v_8 +GO + +SELECT * FROM forjson_vu_v_9 +GO + +SELECT * FROM forjson_vu_v_10 +GO + +SELECT * FROM forjson_vu_v_11 +GO + +SELECT * FROM forjson_vu_v_12 +GO + +SELECT * FROM forjson_vu_v_13 +GO + +SELECT * FROM forjson_vu_v_14 +GO + +EXECUTE forjson_vu_p_1 +GO + +EXECUTE forjson_vu_p_2 +GO + +EXECUTE forjson_vu_p_3 +GO + +EXECUTE forjson_vu_p_4 +GO + +EXECUTE forjson_vu_p_5 +GO + +SELECT forjson_vu_f_1() +GO + +INSERT INTO forjson_auto_vu_t_users VALUES (1, 'e', 'o', 'testemail3') +go \ No newline at end of file diff --git a/test/JDBC/upgrade/latest/schedule b/test/JDBC/upgrade/latest/schedule index 12fa040bbc..f581ee193f 100644 --- a/test/JDBC/upgrade/latest/schedule +++ b/test/JDBC/upgrade/latest/schedule @@ -215,6 +215,7 @@ forjson forjson-datatypes forjson-subquery forjson-nesting +forjsonauto format format-dep forxml diff --git a/test/JDBC/upgrade/master/schedule b/test/JDBC/upgrade/master/schedule index 752970c809..3c0e95962b 100644 --- a/test/JDBC/upgrade/master/schedule +++ b/test/JDBC/upgrade/master/schedule @@ -167,6 +167,7 @@ dateadd datepart datetime2fromparts-after-15-2 forjson +forjsonauto forjson-datatypes forjson-subquery format