From f552fbe52c3931fda7c3a4e2bc78bba05a9e5acf Mon Sep 17 00:00:00 2001 From: Jake Owen Date: Tue, 17 Oct 2023 20:31:38 +0000 Subject: [PATCH] Refinement of FOR JSON PATH & Nested Functionality Signed-off-by: Jake Owen --- .../babelfishpg_tsql/src/tsql_for/forjson.c | 400 +++++++++++++++--- ...orjson-before-14_10-or-15_5-vu-cleanup.out | 63 +++ ...orjson-before-14_10-or-15_5-vu-prepare.out | 208 +++++++++ ...forjson-before-14_10-or-15_5-vu-verify.out | 157 +++++++ ...atypes-before-14_10-or-15_5-vu-cleanup.out | 74 ++++ ...atypes-before-14_10-or-15_5-vu-prepare.out | 182 ++++++++ ...tatypes-before-14_10-or-15_5-vu-verify.out | 135 ++++++ .../expected/forjson-datatypes-vu-verify.out | 24 +- .../expected/forjson-nesting-vu-cleanup.out | 45 ++ .../expected/forjson-nesting-vu-prepare.out | 176 ++++++++ .../expected/forjson-nesting-vu-verify.out | 110 +++++ ...bquery-before-14_10-or-15_5-vu-cleanup.out | 59 +++ ...bquery-before-14_10-or-15_5-vu-prepare.out | 151 +++++++ ...ubquery-before-14_10-or-15_5-vu-verify.out | 95 +++++ .../expected/forjson-subquery-vu-verify.out | 4 +- test/JDBC/expected/forjson-vu-verify.out | 32 +- ...orjson-before-14_10-or-15_5-vu-cleanup.sql | 63 +++ ...orjson-before-14_10-or-15_5-vu-prepare.sql | 198 +++++++++ ...forjson-before-14_10-or-15_5-vu-verify.sql | 63 +++ ...atypes-before-14_10-or-15_5-vu-cleanup.sql | 74 ++++ ...atypes-before-14_10-or-15_5-vu-prepare.sql | 172 ++++++++ ...tatypes-before-14_10-or-15_5-vu-verify.sql | 55 +++ .../forjson/forjson-nesting-vu-cleanup.sql | 45 ++ .../forjson/forjson-nesting-vu-prepare.sql | 168 ++++++++ .../forjson/forjson-nesting-vu-verify.sql | 43 ++ ...bquery-before-14_10-or-15_5-vu-cleanup.sql | 55 +++ ...bquery-before-14_10-or-15_5-vu-prepare.sql | 137 ++++++ ...ubquery-before-14_10-or-15_5-vu-verify.sql | 38 ++ test/JDBC/input/forjson/forjson-vu-verify.sql | 4 +- test/JDBC/upgrade/14_6/schedule | 4 +- test/JDBC/upgrade/latest/schedule | 1 + 31 files changed, 2950 insertions(+), 85 deletions(-) create mode 100644 test/JDBC/expected/forjson-before-14_10-or-15_5-vu-cleanup.out create mode 100644 test/JDBC/expected/forjson-before-14_10-or-15_5-vu-prepare.out create mode 100644 test/JDBC/expected/forjson-before-14_10-or-15_5-vu-verify.out create mode 100644 test/JDBC/expected/forjson-datatypes-before-14_10-or-15_5-vu-cleanup.out create mode 100644 test/JDBC/expected/forjson-datatypes-before-14_10-or-15_5-vu-prepare.out create mode 100644 test/JDBC/expected/forjson-datatypes-before-14_10-or-15_5-vu-verify.out create mode 100644 test/JDBC/expected/forjson-nesting-vu-cleanup.out create mode 100644 test/JDBC/expected/forjson-nesting-vu-prepare.out create mode 100644 test/JDBC/expected/forjson-nesting-vu-verify.out create mode 100644 test/JDBC/expected/forjson-subquery-before-14_10-or-15_5-vu-cleanup.out create mode 100644 test/JDBC/expected/forjson-subquery-before-14_10-or-15_5-vu-prepare.out create mode 100644 test/JDBC/expected/forjson-subquery-before-14_10-or-15_5-vu-verify.out create mode 100644 test/JDBC/input/forjson/forjson-before-14_10-or-15_5-vu-cleanup.sql create mode 100644 test/JDBC/input/forjson/forjson-before-14_10-or-15_5-vu-prepare.sql create mode 100644 test/JDBC/input/forjson/forjson-before-14_10-or-15_5-vu-verify.sql create mode 100644 test/JDBC/input/forjson/forjson-datatypes-before-14_10-or-15_5-vu-cleanup.sql create mode 100644 test/JDBC/input/forjson/forjson-datatypes-before-14_10-or-15_5-vu-prepare.sql create mode 100644 test/JDBC/input/forjson/forjson-datatypes-before-14_10-or-15_5-vu-verify.sql create mode 100644 test/JDBC/input/forjson/forjson-nesting-vu-cleanup.sql create mode 100644 test/JDBC/input/forjson/forjson-nesting-vu-prepare.sql create mode 100644 test/JDBC/input/forjson/forjson-nesting-vu-verify.sql create mode 100644 test/JDBC/input/forjson/forjson-subquery-before-14_10-or-15_5-vu-cleanup.sql create mode 100644 test/JDBC/input/forjson/forjson-subquery-before-14_10-or-15_5-vu-prepare.sql create mode 100644 test/JDBC/input/forjson/forjson-subquery-before-14_10-or-15_5-vu-verify.sql diff --git a/contrib/babelfishpg_tsql/src/tsql_for/forjson.c b/contrib/babelfishpg_tsql/src/tsql_for/forjson.c index b825037e06..360ae65d37 100644 --- a/contrib/babelfishpg_tsql/src/tsql_for/forjson.c +++ b/contrib/babelfishpg_tsql/src/tsql_for/forjson.c @@ -15,26 +15,57 @@ #include "parser/parser.h" #include "utils/builtins.h" #include "utils/json.h" +#include "utils/jsonb.h" #include "utils/syscache.h" #include "utils/typcache.h" +#include "utils/hsearch.h" #include "catalog/pg_type.h" #include "catalog/namespace.h" #include "tsql_for.h" -static void tsql_row_to_json(StringInfo state, Datum record, bool include_null_values); +#define TABLE_SIZE 100 + +// For holding information regarding the state of the FOR JSON call +// Necessary to pass information regarding root_name & without_array-wrappers +// to ffunc. +typedef struct { + bool without_array_wrapper; + char *root_name; + JsonbValue* jsonbArray; +} forjson_state; + +// Entry struct for use in HashTable +typedef struct { + char path[NAMEDATALEN]; + JsonbValue *value; + JsonbValue *parent; + int idx; +} JsonbEntry; + +static void tsql_row_to_json(JsonbValue* jsonbArray, Datum record, bool include_null_values); + +static char** determine_parts(const char* str, int *num); + +static char* build_key(char **parts, int currentIdx); + +static JsonbValue* create_json(char *part, JsonbValue* val, int *idx); + +static void insert_existing_json(JsonbValue *exists, JsonbValue* parent, JsonbValue *val, int idx, char *key); PG_FUNCTION_INFO_V1(tsql_query_to_json_sfunc); Datum tsql_query_to_json_sfunc(PG_FUNCTION_ARGS) { - StringInfo state; + forjson_state *state; + JsonbValue *jsonbArray; + Datum record; - int mode; + int mode; bool include_null_values; bool without_array_wrapper; - char *root_name; + char *root_name; MemoryContext agg_context; MemoryContext old_context; @@ -58,25 +89,27 @@ tsql_query_to_json_sfunc(PG_FUNCTION_ARGS) include_null_values = PG_GETARG_BOOL(3); if (PG_ARGISNULL(0)) { - /* first time setup */ - state = makeStringInfo(); + // First time setup for struct & JsonBValue + state = (forjson_state *) palloc(sizeof(forjson_state)); + + jsonbArray = palloc(sizeof(JsonbValue)); + jsonbArray->type = jbvArray; + jsonbArray->val.array.nElems = 0; + jsonbArray->val.array.rawScalar = false; + jsonbArray->val.array.elems = (JsonbValue *) palloc(sizeof(JsonbValue)); + + // Populate the struct without_array_wrapper = PG_GETARG_BOOL(4); root_name = PG_ARGISNULL(5) ? NULL : text_to_cstring(PG_GETARG_TEXT_PP(5)); - /* If root_name is present then WITHOUT_ARRAY_WRAPPER will be FALSE */ - if (root_name) - /* - * we need to add an extra token to the beginning so that the - * finalfunc knows to append "]}" to the end - */ - appendStringInfo(state, "<{\"%s\":[", root_name); - else if (!without_array_wrapper) - appendStringInfoChar(state, '['); + state->jsonbArray = jsonbArray; + state->without_array_wrapper = without_array_wrapper; + state->root_name = root_name; } else { - state = (StringInfo) PG_GETARG_POINTER(0); - appendStringInfoChar(state, ','); + state = (forjson_state*) PG_GETARG_POINTER(0); + jsonbArray = state->jsonbArray; } switch (mode) { @@ -93,7 +126,7 @@ tsql_query_to_json_sfunc(PG_FUNCTION_ARGS) break; case TSQL_FORJSON_PATH: /* FOR JSON PATH */ /* add the current row to the state */ - tsql_row_to_json(state, record, include_null_values); + tsql_row_to_json(jsonbArray, record, include_null_values); break; default: /* Invalid mode, should not happen, report internal error */ @@ -103,45 +136,28 @@ tsql_query_to_json_sfunc(PG_FUNCTION_ARGS) } MemoryContextSwitchTo(old_context); - PG_RETURN_POINTER(state); } -PG_FUNCTION_INFO_V1(tsql_query_to_json_ffunc); - -Datum -tsql_query_to_json_ffunc(PG_FUNCTION_ARGS) +// 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_row_to_json(JsonbValue* jsonbArray, Datum record, bool include_null_values) { - StringInfo res = makeStringInfo(); - char *state = ((StringInfo) PG_GETARG_POINTER(0))->data; + // HashTable + HTAB *jsonbHash; + HASHCTL ct; - if (state[0] == '[') /* check for array wrapper */ - { - appendStringInfoString(res, state); - appendStringInfoChar(res, ']'); - } - else if (state[0] == '<') /* '<' indicates that root was specified */ - { - appendStringInfoString(res, state + 1); - appendStringInfoString(res, "]}"); - } - else - { - appendStringInfoString(res, state); - } - PG_RETURN_TEXT_P(cstring_to_text_with_len(res->data, res->len)); -} + // JsonbValue for the row + JsonbValue *jsonbRow; -static void -tsql_row_to_json(StringInfo state, Datum record, bool include_null_values) -{ HeapTupleHeader td; Oid tupType; int32 tupTypmod; TupleDesc tupdesc; HeapTupleData tmptup; HeapTuple tuple; - char *sep = ""; td = DatumGetHeapTupleHeader(record); @@ -155,12 +171,35 @@ tsql_row_to_json(StringInfo state, Datum record, bool include_null_values) tmptup.t_data = td; tuple = &tmptup; - /* each tuple is its own object */ - appendStringInfoChar(state, '{'); + // 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; @@ -168,6 +207,7 @@ tsql_row_to_json(StringInfo state, Datum record, bool include_null_values) Oid nspoid; Oid tsql_datatype_oid; char *typename; + Form_pg_attribute att = TupleDescAttr(tupdesc, i); if (att->attisdropped) @@ -265,12 +305,270 @@ tsql_row_to_json(StringInfo state, Datum record, bool include_null_values) 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); + nestedVal = value; + + found = false; + if (num > 1) { + for (int i = num - 1; i >= 0; i--) { + hashKey = build_key(parts, i); + + // Check if the current key exists in the hashTable + 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(current, hashEntry->parent, nestedVal, hashEntry->idx, colname); + pfree(hashKey); + break; + } + + // If it does not exist + hashEntry = (JsonbEntry *) hash_search(jsonbHash, (void *) hashKey, HASH_ENTER, NULL); + strlcpy(hashEntry->path, hashKey, NAMEDATALEN); + hashEntry->value = nestedVal; + nestedVal = create_json(parts[i], nestedVal, &hashEntry->idx); + + // if the nested json is not at the jsonbRow level + if (i != 0) + hashEntry->parent = nestedVal; + 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++; + colname = parts[0]; - appendStringInfoString(state, sep); - sep = ","; - tsql_json_build_object(state, CStringGetDatum(colname), colval, datatype_oid, isnull); + // 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; + } } - appendStringInfoChar(state, '}'); + + // Add the jsonb row to the jsonbArray + 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] = *jsonbRow; + ReleaseTupleDesc(tupdesc); } + +PG_FUNCTION_INFO_V1(tsql_query_to_json_ffunc); + +Datum +tsql_query_to_json_ffunc(PG_FUNCTION_ARGS) +{ + forjson_state *state; + JsonbValue *res; + Jsonb *jsonOut; + StringInfo resStr; + + // Only used if a root_name is given + JsonbValue *root; + JsonbValue *key; + + // Get the processed JsonbValue array + state = (forjson_state*) PG_GETARG_POINTER(0); + resStr = makeStringInfo(); + + if (state->root_name) { + + // Key jsonBValue to store the root name + key = palloc(sizeof(JsonbValue)); + key->type = jbvString; + key->val.string.len = strlen(state->root_name); + key->val.string.val = state->root_name; + + // Root JsonbValue where the key is the root name and value is the processed jsonbVal array + root = palloc(sizeof(JsonbValue)); + root->type = jbvObject; + root->val.object.nPairs = 1; + root->val.object.pairs = (JsonbPair *) palloc(sizeof(JsonbPair)); + root->val.object.pairs[0].key = *key; + root->val.object.pairs[0].value = *state->jsonbArray; + + // Update the processed jsonbArray + state->jsonbArray = root; + } + + // Convert JsonbValue to StringInfo for array wrapper check and to return + res = state->jsonbArray; + jsonOut = JsonbValueToJsonb(res); + JsonbToCString(resStr, &jsonOut->root, 0); + + // if without array wrappers is true, remove the array wrappers + if (state->without_array_wrapper) { + if (resStr->data[0] == '[') { + resStr->data++; + resStr->len--; + } + if (resStr->data[resStr->len - 1] == ']') { + resStr->data[resStr->len - 1] = '\0'; + resStr->len--; + } + } + + PG_RETURN_TEXT_P(cstring_to_text_with_len(resStr->data, resStr->len)); +} + +// Function to determine how many nested json objects a column requires +// Splits a string into an array of strings by the "." +static char** +determine_parts(const char* str, int* num) +{ + int i; + char **parts; + char *copy_str; + char *token; + + // Determine how many parts there are (words seperated by ".") + *num = 1; + for (i = 0; str[i]; i++) { + if (str[i] == '.') + (*num)++; + } + + // Create a string array to hold each indiviual word + parts = (char **) palloc(sizeof(char *) * (*num + 1)); + copy_str = pstrdup(str); + token = strtok(copy_str, "."); + i = 0; + while (token != NULL) { + parts[i++] = pstrdup(token); + token = strtok(NULL, "."); + } + + parts[i] = NULL; + pfree(copy_str); + return parts; + +} + +// Function to build a key to use to search in the Hashtable +// Uses the parts** created from determine_parts to build a string +// that is used as a key/path. +static char* +build_key(char **parts, int currentIdx) +{ + StringInfo str; + str = makeStringInfo(); + + // Build a string up to the current path + for (int i = 0; i <= currentIdx; i++) { + appendStringInfoString(str, parts[i]); + if (i < currentIdx) { + appendStringInfoChar(str, '.'); + } + } + + return str->data; +} + +// Function to create the nested json output for a col if required +// Used when created nested json objects +static JsonbValue* +create_json(char *part, JsonbValue* val, int *idx) +{ + JsonbValue *obj; + JsonbValue *key; + JsonbPair *pair; + + // Create key + key = palloc(sizeof(JsonbValue)); + key->type = jbvString; + key->val.string.len = strlen(part); + key->val.string.val = pstrdup(part); + + // Create pair to hold key and value + pair = palloc(sizeof(JsonbPair)); + pair->key = *key; + pair->value = *val; + + // 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 +insert_existing_json(JsonbValue *current, JsonbValue* parent, JsonbValue *nestedVal, int idx, char *key) +{ + JsonbPair* newPairs; + // Make sure both current and nestedVal are non-null and are objects + if (!current || !nestedVal || current->type != jbvObject || nestedVal->type != jbvObject) { + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("Property %s cannot be generated in JSON output due to a conflict with another column name or alias. Use different names and aliases for each column in SELECT list.", key))); + } + + // Allocate space for the new pairs + newPairs = (JsonbPair *) repalloc( + current->val.object.pairs, + sizeof(JsonbPair) * (current->val.object.nPairs + nestedVal->val.object.nPairs) + ); + + // Append the pairs from nestedVal to the new pair array + for (int i = 0; i < nestedVal->val.object.nPairs; i++) { + newPairs[current->val.object.nPairs + i] = nestedVal->val.object.pairs[i]; + } + + // Point the current's pairs to the newPairs + current->val.object.pairs = newPairs; + + // Update the pair count + current->val.object.nPairs += nestedVal->val.object.nPairs; + + // update parent pointer + parent->val.object.pairs[idx].value = *current; +} diff --git a/test/JDBC/expected/forjson-before-14_10-or-15_5-vu-cleanup.out b/test/JDBC/expected/forjson-before-14_10-or-15_5-vu-cleanup.out new file mode 100644 index 0000000000..4d1247a5c1 --- /dev/null +++ b/test/JDBC/expected/forjson-before-14_10-or-15_5-vu-cleanup.out @@ -0,0 +1,63 @@ +-- FOR JSON PATH clause without nested support +DROP VIEW forjson_vu_v_people +GO + +DROP VIEW forjson_vu_v_countries +GO + +-- Multiple tables without nested support +DROP VIEW forjson_vu_v_join +GO + +-- ROOT directive without specifying value +DROP VIEW forjson_vu_v_root +GO + +-- ROOT directive with specifying ROOT value +DROP VIEW forjson_vu_v_root_value +GO + +-- ROOT directive with specifying ROOT value with empty string +DROP VIEW forjson_vu_v_empty_root +GO + +-- WITHOUT_ARRAY_WRAPPERS directive +DROP VIEW forjson_vu_v_without_array_wrapper +GO + +-- INCLUDE_NULL_VALUES directive +DROP VIEW forjson_vu_v_include_null_values +GO + +-- Multiple Directives +DROP VIEW forjson_vu_v_root_include_null_values +GO + +DROP VIEW forjson_vu_v_without_array_wrapper_include_null_values +GO + + +-- Test case with parameters +DROP PROCEDURE forjson_vu_p_params1 +GO + +DROP PROCEDURE forjson_vu_p_params2 +GO + +-- All null values test +DROP VIEW forjson_vu_v_nulls +GO + +-- Test for all parser rules +DROP VIEW forjson_vu_v_order_by +GO + +-- Display Table Contents +DROP TABLE forjson_vu_t_people +GO + +DROP TABLE forjson_vu_t_countries +GO + +DROP TABLE forjson_vu_t_values +GO diff --git a/test/JDBC/expected/forjson-before-14_10-or-15_5-vu-prepare.out b/test/JDBC/expected/forjson-before-14_10-or-15_5-vu-prepare.out new file mode 100644 index 0000000000..486838fe84 --- /dev/null +++ b/test/JDBC/expected/forjson-before-14_10-or-15_5-vu-prepare.out @@ -0,0 +1,208 @@ +CREATE TABLE forjson_vu_t_people ( +[Id] INT, +[FirstName] VARCHAR(25), +[LastName] VARCHAR(25), +[State] VARCHAR(25) ) +GO + +INSERT INTO forjson_vu_t_people values +(1,'Divya','Kumar',NULL), +(2,NULL,'Khanna','Bengaluru'), +(3,'Tom','Mehta','Kolkata'), +(4,'Kane',NULL,'Delhi') +GO +~~ROW COUNT: 4~~ + + +CREATE TABLE forjson_vu_t_countries ( +[Id] INT, +[Age] INT, +[Country] VARCHAR(25)) +GO + +INSERT INTO forjson_vu_t_countries values +(1,25, 'India'), +(2,40, 'USA'), +(3,30, 'India'), +(4,20, NULL), +(5,10, 'USA') +GO +~~ROW COUNT: 5~~ + + +CREATE TABLE forjson_vu_t_values ( +[Id] INT, +[value] VARCHAR(25) ) +GO + +INSERT INTO forjson_vu_t_values values +(1,NULL), +(2,NULL), +(3,NULL) +GO +~~ROW COUNT: 3~~ + + +-- FOR JSON PATH clause without nested support +CREATE VIEW forjson_vu_v_people AS +SELECT ( + SELECT Id AS EmpId, + FirstName AS "Name.FirstName", + LastName AS "Name.LastName", + State + FROM forjson_vu_t_people + FOR JSON PATH +) c1 +GO + +CREATE VIEW forjson_vu_v_countries AS +SELECT ( + SELECT Id, + Age, + Country + FROM forjson_vu_t_countries + FOR JSON PATH +) c1 +GO + +-- Multiple tables without nested support +CREATE VIEW forjson_vu_v_join AS +SELECT ( + SELECT E.FirstName AS 'Person.Name', + E.LastName AS 'Person.Surname', + D.Age AS 'Employee.Price', + D.Country AS 'Employee.Quantity' + FROM forjson_vu_t_people E + INNER JOIN forjson_vu_t_countries D + ON E.Id = D.Id + FOR JSON PATH +) c1 +GO + +-- ROOT directive without specifying value +CREATE VIEW forjson_vu_v_root AS +SELECT ( + SELECT FirstName, + LastName + FROM forjson_vu_t_people + FOR JSON PATH, ROOT +) c1 +GO + +-- ROOT directive with specifying ROOT value +CREATE VIEW forjson_vu_v_root_value AS +SELECT ( + SELECT FirstName, + LastName + FROM forjson_vu_t_people + FOR JSON PATH, ROOT('Employee') +) c1 +GO + +-- ROOT directive with specifying ROOT value with empty string +CREATE VIEW forjson_vu_v_empty_root AS +SELECT ( + SELECT FirstName, + LastName + FROM forjson_vu_t_people + FOR JSON PATH, ROOT('') +) c1 +GO + +-- WITHOUT_ARRAY_WRAPPERS directive +CREATE VIEW forjson_vu_v_without_array_wrapper AS +SELECT ( + SELECT FirstName, + LastName + FROM forjson_vu_t_people + FOR JSON PATH, WITHOUT_ARRAY_WRAPPER +) c1 +GO + +-- INCLUDE_NULL_VALUES directive +CREATE VIEW forjson_vu_v_include_null_values AS +SELECT ( + SELECT FirstName, + LastName + FROM forjson_vu_t_people + FOR JSON PATH, INCLUDE_NULL_VALUES +) c1 +GO + +-- Multiple Directives +CREATE VIEW forjson_vu_v_root_include_null_values AS +SELECT ( + SELECT Id, + Age, + Country + FROM forjson_vu_t_countries + FOR JSON PATH, ROOT('Employee'), INCLUDE_NULL_VALUES +) c1 +GO + +CREATE VIEW forjson_vu_v_without_array_wrapper_include_null_values AS +SELECT ( + SELECT Id, + Age, + Country + FROM forjson_vu_t_countries + FOR JSON PATH, WITHOUT_ARRAY_WRAPPER, INCLUDE_NULL_VALUES +) c1 +GO + +-- Throws error as ROOT and WITHOUT_ARRAY_WRAPPER cannot be used together +CREATE VIEW forjson_vu_v_root_and_without_array_wrapper AS +SELECT ( + SELECT Id, + Age, + Country + FROM forjson_vu_t_countries + FOR JSON PATH, ROOT, WITHOUT_ARRAY_WRAPPER +) c1 +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: ROOT option and WITHOUT_ARRAY_WRAPPER option cannot be used together in FOR JSON. Remove one of these options)~~ + + +-- Test case with parameters +CREATE PROCEDURE forjson_vu_p_params1 @id int AS +SELECT ( + SELECT Firstname AS [Name], + State + FROM forjson_vu_t_people + WHERE Id = @id + FOR JSON PATH +) c1 +GO + +CREATE PROCEDURE forjson_vu_p_params2 @id int AS +SELECT ( + SELECT Firstname AS [nam"@e], + State AS [State"@] + FROM forjson_vu_t_people + WHERE Id = @id + FOR JSON PATH +) c1 +GO + +-- All null values test +CREATE VIEW forjson_vu_v_nulls AS +SELECT ( + SELECT value + FROM forjson_vu_t_values + FOR JSON PATH +) c1 +GO + +-- Test for all parser rules +CREATE VIEW forjson_vu_v_order_by AS +SELECT ( + SELECT Id, + Age, + Country + FROM forjson_vu_t_countries + ORDER BY Age + FOR JSON PATH +) C1 +GO diff --git a/test/JDBC/expected/forjson-before-14_10-or-15_5-vu-verify.out b/test/JDBC/expected/forjson-before-14_10-or-15_5-vu-verify.out new file mode 100644 index 0000000000..9b5f226477 --- /dev/null +++ b/test/JDBC/expected/forjson-before-14_10-or-15_5-vu-verify.out @@ -0,0 +1,157 @@ +-- Display Table Contents +SELECT * FROM forjson_vu_t_people +GO +~~START~~ +int#!#varchar#!#varchar#!#varchar +1#!#Divya#!#Kumar#!# +2#!##!#Khanna#!#Bengaluru +3#!#Tom#!#Mehta#!#Kolkata +4#!#Kane#!##!#Delhi +~~END~~ + + +SELECT * FROM forjson_vu_t_countries +GO +~~START~~ +int#!#int#!#varchar +1#!#25#!#India +2#!#40#!#USA +3#!#30#!#India +4#!#20#!# +5#!#10#!#USA +~~END~~ + + +SELECT * FROM forjson_vu_t_values +GO +~~START~~ +int#!#varchar +1#!# +2#!# +3#!# +~~END~~ + + +-- FOR JSON PATH clause without nested support +SELECT * FROM forjson_vu_v_people +GO +~~START~~ +nvarchar +[{"EmpId":1,"Name.FirstName":"Divya","Name.LastName":"Kumar"},{"EmpId":2,"Name.LastName":"Khanna","State":"Bengaluru"},{"EmpId":3,"Name.FirstName":"Tom","Name.LastName":"Mehta","State":"Kolkata"},{"EmpId":4,"Name.FirstName":"Kane","State":"Delhi"}] +~~END~~ + + +SELECT * FROM forjson_vu_v_countries +GO +~~START~~ +nvarchar +[{"Id":1,"Age":25,"Country":"India"},{"Id":2,"Age":40,"Country":"USA"},{"Id":3,"Age":30,"Country":"India"},{"Id":4,"Age":20},{"Id":5,"Age":10,"Country":"USA"}] +~~END~~ + + +-- Multiple tables without nested support +SELECT * FROM forjson_vu_v_join +GO +~~START~~ +nvarchar +[{"Person.Name":"Divya","Person.Surname":"Kumar","Employee.Price":25,"Employee.Quantity":"India"},{"Person.Surname":"Khanna","Employee.Price":40,"Employee.Quantity":"USA"},{"Person.Name":"Tom","Person.Surname":"Mehta","Employee.Price":30,"Employee.Quantity":"India"},{"Person.Name":"Kane","Employee.Price":20}] +~~END~~ + + +-- ROOT directive without specifying value +SELECT * FROM forjson_vu_v_root +GO +~~START~~ +nvarchar +{"root":[{"FirstName":"Divya","LastName":"Kumar"},{"LastName":"Khanna"},{"FirstName":"Tom","LastName":"Mehta"},{"FirstName":"Kane"}]} +~~END~~ + + +-- ROOT directive with specifying ROOT value +SELECT * FROM forjson_vu_v_root_value +GO +~~START~~ +nvarchar +{"Employee":[{"FirstName":"Divya","LastName":"Kumar"},{"LastName":"Khanna"},{"FirstName":"Tom","LastName":"Mehta"},{"FirstName":"Kane"}]} +~~END~~ + + +-- ROOT directive with specifying ROOT value with empty string +SELECT * FROM forjson_vu_v_empty_root +GO +~~START~~ +nvarchar +{"":[{"FirstName":"Divya","LastName":"Kumar"},{"LastName":"Khanna"},{"FirstName":"Tom","LastName":"Mehta"},{"FirstName":"Kane"}]} +~~END~~ + + +-- WITHOUT_ARRAY_WRAPPERS directive +SELECT * FROM forjson_vu_v_without_array_wrapper +GO +~~START~~ +nvarchar +{"FirstName":"Divya","LastName":"Kumar"},{"LastName":"Khanna"},{"FirstName":"Tom","LastName":"Mehta"},{"FirstName":"Kane"} +~~END~~ + + +-- INCLUDE_NULL_VALUES directive +SELECT * FROM forjson_vu_v_include_null_values +GO +~~START~~ +nvarchar +[{"FirstName":"Divya","LastName":"Kumar"},{"FirstName":null,"LastName":"Khanna"},{"FirstName":"Tom","LastName":"Mehta"},{"FirstName":"Kane","LastName":null}] +~~END~~ + + +-- Multiple Directives +SELECT * FROM forjson_vu_v_root_include_null_values +GO +~~START~~ +nvarchar +{"Employee":[{"Id":1,"Age":25,"Country":"India"},{"Id":2,"Age":40,"Country":"USA"},{"Id":3,"Age":30,"Country":"India"},{"Id":4,"Age":20,"Country":null},{"Id":5,"Age":10,"Country":"USA"}]} +~~END~~ + + +SELECT * FROM forjson_vu_v_without_array_wrapper_include_null_values +GO +~~START~~ +nvarchar +{"Id":1,"Age":25,"Country":"India"},{"Id":2,"Age":40,"Country":"USA"},{"Id":3,"Age":30,"Country":"India"},{"Id":4,"Age":20,"Country":null},{"Id":5,"Age":10,"Country":"USA"} +~~END~~ + + + +-- Test case with parameters +EXECUTE forjson_vu_p_params1 @id = 2 +GO +~~START~~ +nvarchar +[{"State": "Bengaluru"}] +~~END~~ + + +EXECUTE forjson_vu_p_params2 @id = 3 +GO +~~START~~ +nvarchar +[{"nam\"@e": "Tom", "State\"@": "Kolkata"}] +~~END~~ + + +-- All null values test +SELECT * FROM forjson_vu_v_nulls +GO +~~START~~ +nvarchar +[{},{},{}] +~~END~~ + + +-- Test for all parser rules +SELECT * FROM forjson_vu_v_order_by +GO +~~START~~ +nvarchar +[{"Id":5,"Age":10,"Country":"USA"},{"Id":4,"Age":20},{"Id":1,"Age":25,"Country":"India"},{"Id":3,"Age":30,"Country":"India"},{"Id":2,"Age":40,"Country":"USA"}] +~~END~~ + diff --git a/test/JDBC/expected/forjson-datatypes-before-14_10-or-15_5-vu-cleanup.out b/test/JDBC/expected/forjson-datatypes-before-14_10-or-15_5-vu-cleanup.out new file mode 100644 index 0000000000..859f23a74e --- /dev/null +++ b/test/JDBC/expected/forjson-datatypes-before-14_10-or-15_5-vu-cleanup.out @@ -0,0 +1,74 @@ +-- DIFFERENT CASES TO CHECK DATATYPES +-- Exact Numerics +DROP VIEW forjson_datatypes_vu_v_numerics +GO + +DROP VIEW forjson_datatypes_vu_v_bit +GO + +DROP VIEW forjson_datatypes_vu_v_money +GO + +DROP VIEW forjson_datatypes_vu_v_smallmoney +GO + +-- Approximate numerics +DROP VIEW forjson_datatypes_vu_v_approx_numerics +GO + +-- Date and time +DROP VIEW forjson_datatypes_vu_v_time_date +GO + +DROP VIEW forjson_datatypes_vu_v_smalldatetime +GO + +DROP VIEW forjson_datatypes_vu_v_datetime +GO + +DROP VIEW forjson_datatypes_vu_v_datetime2 +GO + +DROP VIEW forjson_datatypes_vu_v_datetimeoffset +GO + +-- Character strings +DROP VIEW forjson_datatypes_vu_v_strings +GO + +-- Unicode character strings +DROP VIEW forjson_datatypes_vu_v_unicode_strings +GO + +-- NULL datetimes +DROP VIEW forjson_datatypes_vu_v_nulldatetime; +go + +DROP VIEW forjson_datatypes_vu_v_nullsmalldatetime; +go + +DROP VIEW forjson_datatypes_vu_v_nulldatetime2; +go + +DROP VIEW forjson_datatypes_vu_v_nulldatetimeoffset; +go + +-- DROP TABLE +DROP TABLE forjson_datatypes_vu_t_exact_numerics +GO + +-- Approximate numerics +DROP TABLE forjson_datatypes_vu_t_approx_numerics +GO + +-- Date and time +DROP TABLE forjson_datatypes_vu_t_date_and_time +GO + +-- Character strings +DROP TABLE forjson_datatypes_vu_t_strings +GO + +-- Unicode character strings +DROP TABLE forjson_datatypes_vu_t_unicode_strings +GO diff --git a/test/JDBC/expected/forjson-datatypes-before-14_10-or-15_5-vu-prepare.out b/test/JDBC/expected/forjson-datatypes-before-14_10-or-15_5-vu-prepare.out new file mode 100644 index 0000000000..0f84cd53da --- /dev/null +++ b/test/JDBC/expected/forjson-datatypes-before-14_10-or-15_5-vu-prepare.out @@ -0,0 +1,182 @@ +-- DIFFERENT CASES TO CHECK DATATYPES +-- Exact Numerics +CREATE TABLE forjson_datatypes_vu_t_exact_numerics(abigint bigint, abit bit, adecimal decimal, aint int, amoney money, anumeric numeric, asmallint smallint, asmallmoney smallmoney, atinyint tinyint) +GO +INSERT forjson_datatypes_vu_t_exact_numerics VALUES(9223372036854775807, 1, 123.2, 2147483647, 3148.29, 12345.12, 32767, 3148.29, 255) +GO +~~ROW COUNT: 1~~ + + +-- Approximate numerics +CREATE TABLE forjson_datatypes_vu_t_approx_numerics(afloat float, areal real) +GO +INSERT forjson_datatypes_vu_t_approx_numerics VALUES(12.05, 120.53) +GO +~~ROW COUNT: 1~~ + + +-- Date and time +CREATE TABLE forjson_datatypes_vu_t_date_and_time(atime time, adate date, asmalldatetime smalldatetime, adatetime datetime, adatetime2 datetime2, adatetimeoffset datetimeoffset, adatetimeoffset_2 datetimeoffset) +GO +INSERT forjson_datatypes_vu_t_date_and_time VALUES('2022-11-11 23:17:08.560','2022-11-11 23:17:08.560','2022-11-11 23:17:08.560','2022-11-11 23:17:08.560','2022-11-11 23:17:08.560','2022-11-11 23:17:08.560', '2012-10-12 12:34:56 +02:30') +GO +~~ROW COUNT: 1~~ + + +-- Character strings +CREATE TABLE forjson_datatypes_vu_t_strings(achar char, avarchar varchar(3), atext text) +GO +INSERT forjson_datatypes_vu_t_strings VALUES('a','abc','abc') +GO +~~ROW COUNT: 1~~ + + +-- Unicode character strings +CREATE TABLE forjson_datatypes_vu_t_unicode_strings(anchar nchar(5), anvarchar nvarchar(5), antext ntext) +GO +INSERT forjson_datatypes_vu_t_unicode_strings VALUES('abc','abc','abc') +GO +~~ROW COUNT: 1~~ + + +-- T-SQL does not allow raw scalars as the output of a view, so surround the FOR JSON call with a SELECT to avoid a syntax error +-- Exact Numerics +CREATE VIEW forjson_datatypes_vu_v_numerics AS +SELECT +( + SELECT abigint, adecimal, aint, anumeric, asmallint, atinyint + FROM forjson_datatypes_vu_t_exact_numerics + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_bit AS +SELECT +( + SELECT abit + FROM forjson_datatypes_vu_t_exact_numerics + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_money AS +SELECT +( + SELECT amoney + FROM forjson_datatypes_vu_t_exact_numerics + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_smallmoney AS +SELECT +( + SELECT asmallmoney + FROM forjson_datatypes_vu_t_exact_numerics + FOR JSON PATH +) as c1; +GO + +-- Approximate numerics +CREATE VIEW forjson_datatypes_vu_v_approx_numerics AS +SELECT +( + SELECT * + FROM forjson_datatypes_vu_t_approx_numerics + FOR JSON PATH +) as c1; +GO + +-- Date and time +CREATE VIEW forjson_datatypes_vu_v_time_date AS +SELECT +( + SELECT atime,adate + FROM forjson_datatypes_vu_t_date_and_time + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_smalldatetime AS +SELECT +( + SELECT asmalldatetime + FROM forjson_datatypes_vu_t_date_and_time + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_datetime AS +SELECT +( + SELECT adatetime + FROM forjson_datatypes_vu_t_date_and_time + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_datetime2 AS +SELECT +( + SELECT adatetime2 + FROM forjson_datatypes_vu_t_date_and_time + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_datetimeoffset AS +SELECT +( + SELECT adatetimeoffset, adatetimeoffset_2 + FROM forjson_datatypes_vu_t_date_and_time + FOR JSON PATH +) as c1; +GO + +-- Character strings +CREATE VIEW forjson_datatypes_vu_v_strings AS +SELECT +( + SELECT * + FROM forjson_datatypes_vu_t_strings + FOR JSON PATH +) as c1; +GO + +-- Unicode character strings +CREATE VIEW forjson_datatypes_vu_v_unicode_strings AS +SELECT +( + SELECT * + FROM forjson_datatypes_vu_t_unicode_strings + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_nulldatetime AS +SELECT +( + select cast(null as datetime) for JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_nullsmalldatetime AS +SELECT +( + select cast(null as smalldatetime) for JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_nulldatetime2 AS +SELECT +( + select cast(null as datetime2) for JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_nulldatetimeoffset AS +SELECT +( + select cast(null as datetimeoffset) for JSON PATH +) as c1; +GO diff --git a/test/JDBC/expected/forjson-datatypes-before-14_10-or-15_5-vu-verify.out b/test/JDBC/expected/forjson-datatypes-before-14_10-or-15_5-vu-verify.out new file mode 100644 index 0000000000..81d555646a --- /dev/null +++ b/test/JDBC/expected/forjson-datatypes-before-14_10-or-15_5-vu-verify.out @@ -0,0 +1,135 @@ +-- DIFFERENT CASES TO CHECK DATATYPES +-- Exact Numerics +SELECT * FROM forjson_datatypes_vu_v_numerics +GO +~~START~~ +nvarchar +[{"abigint":9223372036854775807,"adecimal":123,"aint":2147483647,"anumeric":12345,"asmallint":32767,"atinyint":255}] +~~END~~ + + +SELECT * FROM forjson_datatypes_vu_v_bit +GO +~~START~~ +nvarchar +[{"abit":true}] +~~END~~ + + +SELECT * FROM forjson_datatypes_vu_v_money +GO +~~START~~ +nvarchar +[{"amoney":3148.2900}] +~~END~~ + + +SELECT * FROM forjson_datatypes_vu_v_smallmoney +GO +~~START~~ +nvarchar +[{"asmallmoney":3148.2900}] +~~END~~ + + +-- Approximate numerics +SELECT * FROM forjson_datatypes_vu_v_approx_numerics +GO +~~START~~ +nvarchar +[{"afloat":12.05,"areal":120.53}] +~~END~~ + + +-- Date and time +SELECT * FROM forjson_datatypes_vu_v_time_date +GO +~~START~~ +nvarchar +[{"atime":"23:17:08.56","adate":"2022-11-11"}] +~~END~~ + + +SELECT * FROM forjson_datatypes_vu_v_smalldatetime +GO +~~START~~ +nvarchar +[{"asmalldatetime":"2022-11-11T23:17:00"}] +~~END~~ + + +SELECT * FROM forjson_datatypes_vu_v_datetime +GO +~~START~~ +nvarchar +[{"adatetime":"2022-11-11T23:17:08.56"}] +~~END~~ + + +SELECT * FROM forjson_datatypes_vu_v_datetime2 +GO +~~START~~ +nvarchar +[{"adatetime2":"2022-11-11T23:17:08.56"}] +~~END~~ + + +SELECT * FROM forjson_datatypes_vu_v_datetimeoffset +GO +~~START~~ +nvarchar +[{"adatetimeoffset":"2022-11-11T23:17:08.56Z","adatetimeoffset_2":"2012-10-12T12:34:56+02:30"}] +~~END~~ + + +-- Character strings +SELECT * FROM forjson_datatypes_vu_v_strings +GO +~~START~~ +nvarchar +[{"achar":"a","avarchar":"abc","atext":"abc"}] +~~END~~ + + +-- Unicode character strings +SELECT * FROM forjson_datatypes_vu_v_unicode_strings +GO +~~START~~ +nvarchar +[{"anchar":"abc ","anvarchar":"abc","antext":"abc"}] +~~END~~ + + + +-- NULL datetime and datetimeoffset +SELECT * FROM forjson_datatypes_vu_v_nulldatetime +GO +~~START~~ +nvarchar +[{}] +~~END~~ + + +SELECT * FROM forjson_datatypes_vu_v_nullsmalldatetime +GO +~~START~~ +nvarchar +[{}] +~~END~~ + + +SELECT * FROM forjson_datatypes_vu_v_nulldatetime2 +GO +~~START~~ +nvarchar +[{}] +~~END~~ + + +SELECT * FROM forjson_datatypes_vu_v_nulldatetimeoffset +GO +~~START~~ +nvarchar +[{}] +~~END~~ + diff --git a/test/JDBC/expected/forjson-datatypes-vu-verify.out b/test/JDBC/expected/forjson-datatypes-vu-verify.out index 81d555646a..425eef8bbf 100644 --- a/test/JDBC/expected/forjson-datatypes-vu-verify.out +++ b/test/JDBC/expected/forjson-datatypes-vu-verify.out @@ -4,7 +4,7 @@ SELECT * FROM forjson_datatypes_vu_v_numerics GO ~~START~~ nvarchar -[{"abigint":9223372036854775807,"adecimal":123,"aint":2147483647,"anumeric":12345,"asmallint":32767,"atinyint":255}] +[{"abigint": 9223372036854775807, "adecimal": 123, "aint": 2147483647, "anumeric": 12345, "asmallint": 32767, "atinyint": 255}] ~~END~~ @@ -12,7 +12,7 @@ SELECT * FROM forjson_datatypes_vu_v_bit GO ~~START~~ nvarchar -[{"abit":true}] +[{"abit": true}] ~~END~~ @@ -20,7 +20,7 @@ SELECT * FROM forjson_datatypes_vu_v_money GO ~~START~~ nvarchar -[{"amoney":3148.2900}] +[{"amoney": 3148.2900}] ~~END~~ @@ -28,7 +28,7 @@ SELECT * FROM forjson_datatypes_vu_v_smallmoney GO ~~START~~ nvarchar -[{"asmallmoney":3148.2900}] +[{"asmallmoney": 3148.2900}] ~~END~~ @@ -37,7 +37,7 @@ SELECT * FROM forjson_datatypes_vu_v_approx_numerics GO ~~START~~ nvarchar -[{"afloat":12.05,"areal":120.53}] +[{"afloat": 12.05, "areal": 120.53}] ~~END~~ @@ -46,7 +46,7 @@ SELECT * FROM forjson_datatypes_vu_v_time_date GO ~~START~~ nvarchar -[{"atime":"23:17:08.56","adate":"2022-11-11"}] +[{"atime": "23:17:08.56", "adate": "2022-11-11"}] ~~END~~ @@ -54,7 +54,7 @@ SELECT * FROM forjson_datatypes_vu_v_smalldatetime GO ~~START~~ nvarchar -[{"asmalldatetime":"2022-11-11T23:17:00"}] +[{"asmalldatetime": "2022-11-11T23:17:00"}] ~~END~~ @@ -62,7 +62,7 @@ SELECT * FROM forjson_datatypes_vu_v_datetime GO ~~START~~ nvarchar -[{"adatetime":"2022-11-11T23:17:08.56"}] +[{"adatetime": "2022-11-11T23:17:08.56"}] ~~END~~ @@ -70,7 +70,7 @@ SELECT * FROM forjson_datatypes_vu_v_datetime2 GO ~~START~~ nvarchar -[{"adatetime2":"2022-11-11T23:17:08.56"}] +[{"adatetime2": "2022-11-11T23:17:08.56"}] ~~END~~ @@ -78,7 +78,7 @@ SELECT * FROM forjson_datatypes_vu_v_datetimeoffset GO ~~START~~ nvarchar -[{"adatetimeoffset":"2022-11-11T23:17:08.56Z","adatetimeoffset_2":"2012-10-12T12:34:56+02:30"}] +[{"adatetimeoffset": "2022-11-11T23:17:08.56Z", "adatetimeoffset_2": "2012-10-12T12:34:56+02:30"}] ~~END~~ @@ -87,7 +87,7 @@ SELECT * FROM forjson_datatypes_vu_v_strings GO ~~START~~ nvarchar -[{"achar":"a","avarchar":"abc","atext":"abc"}] +[{"achar": "a", "avarchar": "abc", "atext": "abc"}] ~~END~~ @@ -96,7 +96,7 @@ SELECT * FROM forjson_datatypes_vu_v_unicode_strings GO ~~START~~ nvarchar -[{"anchar":"abc ","anvarchar":"abc","antext":"abc"}] +[{"anchar": "abc ", "anvarchar": "abc", "antext": "abc"}] ~~END~~ diff --git a/test/JDBC/expected/forjson-nesting-vu-cleanup.out b/test/JDBC/expected/forjson-nesting-vu-cleanup.out new file mode 100644 index 0000000000..202343737b --- /dev/null +++ b/test/JDBC/expected/forjson-nesting-vu-cleanup.out @@ -0,0 +1,45 @@ +-- FOR JSON PATH CLAUSE with nested json support for existing objects +DROP VIEW forjson_nesting_vu_v_users +GO + +DROP VIEW forjson_nesting_vu_v_products +GO + +DROP VIEW forjson_nesting_vu_v_orders +GO + +-- FOR JSON PATH support for multiple layers of nested JSON objects +DROP VIEW forjson_nesting_vu_v_deep +GO + +-- FOR JSON PATH support for multiple layers of nested JSON objects w/ join +DROP VIEW forjson_nesting_vu_v_join_deep +GO + +-- FOR JSON PATH Support for key-values being inserted into mid layer of multi-layered JSON object +DROP VIEW forjson_nesting_vu_v_layered_insert +GO + +-- Error related to inserting value at Json object location +DROP VIEW forjson_nesting_vu_v_error +GO + +-- Queries that check NULL nested json object insert +DROP VIEW forjson_nesting_vu_v_no_null +GO + +DROP VIEW forjson_nesting_vu_v_with_null +GO + +-- DROP Tables +DROP TABLE forjson_nesting_vu_t_users +GO + +DROP TABLE forjson_nesting_vu_t_products +GO + +DROP TABLE forjson_nesting_vu_t_orders +GO + +DROP TABLE forjson_nesting_vu_t_null_users +GO diff --git a/test/JDBC/expected/forjson-nesting-vu-prepare.out b/test/JDBC/expected/forjson-nesting-vu-prepare.out new file mode 100644 index 0000000000..4f4f1ea1f3 --- /dev/null +++ b/test/JDBC/expected/forjson-nesting-vu-prepare.out @@ -0,0 +1,176 @@ +CREATE TABLE forjson_nesting_vu_t_users ( + [Id] int, + [firstname] varchar(50), + [lastname] varchar(50), + [email] varchar(50), +); +GO +CREATE TABLE forjson_nesting_vu_t_products ( + [Id] int, + [name] varchar(50), + [price] varchar (25) +); +GO +CREATE TABLE forjson_nesting_vu_t_orders ( + [Id] int, + [userid] int, + [productid] int, + [quantity] int, + [orderdate] Date +); +GO +CREATE TABLE forjson_nesting_vu_t_null_users ( + [Id] int, + [firstname] varchar(50), + [lastname] varchar(50), + [email] varchar(50), + [phone] varchar(25) +); +GO + +INSERT INTO forjson_nesting_vu_t_users +VALUES + (1, 'John', 'Doe', 'johndoe@gmail.com'), + (2, 'Jane', 'Smith', 'janesmith@yahoo.com'), + (3, 'Mike', 'Johnson', 'mikejohnson'); +GO +~~ROW COUNT: 3~~ + + +INSERT INTO forjson_nesting_vu_t_products +VALUES + (1, 'Product A', '10.99'), + (2, 'Product B', '19.99'), + (3, 'Product C', '5.99'); +GO +~~ROW COUNT: 3~~ + + +INSERT INTO forjson_nesting_vu_t_orders +VALUES + (1, 1, 1, 2, '2023-06-25'), + (2, 1, 2, 1, '2023-06-25'), + (3, 2, 3, 3, '2023-06-26'); +GO +~~ROW COUNT: 3~~ + + +INSERT INTO forjson_nesting_vu_t_null_users +VALUES + (1, 'John', 'Doe', 'johndoe@gmail.com', '123-456-7890'), + (2, 'Jane', 'Smith', 'janesmith@yahoo.com', NULL), + (3, NULL, NULL, 'mikejohnson@myspace.com', '098-765-4321'), + (4, 'Sergio', 'Giavanni', NULL, NULL); +GO +~~ROW COUNT: 4~~ + + +-- FOR JSON PATH CLAUSE with nested json support for existing objects +CREATE VIEW forjson_nesting_vu_v_users AS +SELECT ( + SELECT Id, + firstname AS "Name.first", + lastname AS "Name.last", + email + FROM forjson_nesting_vu_t_users + FOR JSON PATH +) c1 +GO + +CREATE VIEW forjson_nesting_vu_v_products AS +SELECT ( + SELECT Id, + name AS "Info.name", + price AS "Info.price" + FROM forjson_nesting_vu_t_products + FOR JSON PATH +) c1 +GO + +CREATE VIEW forjson_nesting_vu_v_orders AS +SELECT ( + SELECT Id AS "Id.orderid", + userid AS "Id.userid", + productid AS "Id.productid", + quantity AS "orderinfo.quantity", + orderdate AS "orderinfo.orderdate" + FROM forjson_nesting_vu_t_orders + FOR JSON PATH +) c1 +GO + +-- FOR JSON PATH support for multiple layers of nested JSON objects +CREATE VIEW forjson_nesting_vu_v_deep AS +SELECT ( + SELECT Id, + firstname AS "User.info.name.first", + lastname AS "User.info.name.last" + FROM forjson_nesting_vu_t_users + FOR JSON PATH +) c1 +GO + +-- FOR JSON PATH support for multiple layers of nested JSON objects w/ join +CREATE VIEW forjson_nesting_vu_v_join_deep AS +SELECT ( + SELECT U.Id "User.id", + O.quantity AS "User.order.info.quantity", + O.orderdate AS "User.order.info.orderdate" + FROM forjson_nesting_vu_t_users U + JOIN forjson_nesting_vu_t_orders O + ON (U.id = O.userid) + FOR JSON PATH +) c1 +GO + +-- FOR JSON PATH Support for key-values being inserted into mid layer of multi-layered JSON object +CREATE VIEW forjson_nesting_vu_v_layered_insert AS +SELECT ( + SELECT U.id, + O.id AS "Order.Orderid", + P.id AS "Order.Product.Productid", + O.orderdate AS "Order.date" + FROM forjson_nesting_vu_t_users U + JOIN forjson_nesting_vu_t_orders O + ON (U.id = O.userid) + JOIN forjson_nesting_vu_t_products P + ON (P.id = O.productid) + FOR JSON PATH +) c1 +GO + +-- Error related to inserting value at Json object location +CREATE VIEW forjson_nesting_vu_v_error AS +SELECT ( + SELECT id, + firstname AS "user.name", + lastname AS "user.name.last" + FROM forjson_nesting_vu_t_users + FOR JSON PATH +) +GO + +-- Queries that check NULL nested json object insert +CREATE VIEW forjson_nesting_vu_v_no_null AS +SELECT ( + SELECT id, + firstname AS "user.name.first", + lastname AS "user.name.last", + email AS "contact.email", + phone AS "contact.phone" + FROM forjson_nesting_vu_t_null_users + FOR JSON PATH +) +GO + +CREATE VIEW forjson_nesting_vu_v_with_null AS +SELECT ( + SELECT id, + firstname AS "user.name.first", + lastname AS "user.name.last", + email AS "contact.email", + phone AS "contact.phone" + FROM forjson_nesting_vu_t_null_users + FOR JSON PATH, INCLUDE_NULL_VALUES +) +GO diff --git a/test/JDBC/expected/forjson-nesting-vu-verify.out b/test/JDBC/expected/forjson-nesting-vu-verify.out new file mode 100644 index 0000000000..277e0bfb88 --- /dev/null +++ b/test/JDBC/expected/forjson-nesting-vu-verify.out @@ -0,0 +1,110 @@ +-- Display Table Contents +SELECT * FROM forjson_nesting_vu_t_users +GO +~~START~~ +int#!#varchar#!#varchar#!#varchar +1#!#John#!#Doe#!#johndoe@gmail.com +2#!#Jane#!#Smith#!#janesmith@yahoo.com +3#!#Mike#!#Johnson#!#mikejohnson +~~END~~ + + +SELECT * FROM forjson_nesting_vu_t_products +GO +~~START~~ +int#!#varchar#!#varchar +1#!#Product A#!#10.99 +2#!#Product B#!#19.99 +3#!#Product C#!#5.99 +~~END~~ + + +SELECT * FROM forjson_nesting_vu_t_orders +GO +~~START~~ +int#!#int#!#int#!#int#!#date +1#!#1#!#1#!#2#!#2023-06-25 +2#!#1#!#2#!#1#!#2023-06-25 +3#!#2#!#3#!#3#!#2023-06-26 +~~END~~ + + +-- FOR JSON PATH CLAUSE with nested json support for existing objects +SELECT * FROM forjson_nesting_vu_v_users +GO +~~START~~ +nvarchar +[{"Id": 1, "Name": {"first": "John", "last": "Doe"}, "email": "johndoe@gmail.com"}, {"Id": 2, "Name": {"first": "Jane", "last": "Smith"}, "email": "janesmith@yahoo.com"}, {"Id": 3, "Name": {"first": "Mike", "last": "Johnson"}, "email": "mikejohnson"}] +~~END~~ + + +SELECT * FROM forjson_nesting_vu_v_products +GO +~~START~~ +nvarchar +[{"Id": 1, "Info": {"name": "Product A", "price": "10.99"}}, {"Id": 2, "Info": {"name": "Product B", "price": "19.99"}}, {"Id": 3, "Info": {"name": "Product C", "price": "5.99"}}] +~~END~~ + + +SELECT * FROM forjson_nesting_vu_v_orders +GO +~~START~~ +nvarchar +[{"Id": {"orderid": 1, "userid": 1, "productid": 1}, "orderinfo": {"quantity": 2, "orderdate": "2023-06-25"}}, {"Id": {"orderid": 2, "userid": 1, "productid": 2}, "orderinfo": {"quantity": 1, "orderdate": "2023-06-25"}}, {"Id": {"orderid": 3, "userid": 2, "productid": 3}, "orderinfo": {"quantity": 3, "orderdate": "2023-06-26"}}] +~~END~~ + + +-- FOR JSON PATH support for multiple layers of nested JSON objects +SELECT * FROM forjson_nesting_vu_v_deep +GO +~~START~~ +nvarchar +[{"Id": 1, "User": {"info": {"name": {"first": "John", "last": "Doe"}}}}, {"Id": 2, "User": {"info": {"name": {"first": "Jane", "last": "Smith"}}}}, {"Id": 3, "User": {"info": {"name": {"first": "Mike", "last": "Johnson"}}}}] +~~END~~ + + +-- FOR JSON PATH support for multiple layers of nested JSON objects w/ join +SELECT * FROM forjson_nesting_vu_v_join_deep +GO +~~START~~ +nvarchar +[{"User": {"id": 1, "order": {"info": {"quantity": 2, "orderdate": "2023-06-25"}}}}, {"User": {"id": 1, "order": {"info": {"quantity": 1, "orderdate": "2023-06-25"}}}}, {"User": {"id": 2, "order": {"info": {"quantity": 3, "orderdate": "2023-06-26"}}}}] +~~END~~ + + +-- FOR JSON PATH Support for key-values being inserted into mid layer of multi-layered JSON object +SELECT * FROM forjson_nesting_vu_v_layered_insert +GO +~~START~~ +nvarchar +[{"id": 1, "Order": {"Orderid": 1, "Product": {"Productid": 1}, "date": "2023-06-25"}}, {"id": 1, "Order": {"Orderid": 2, "Product": {"Productid": 2}, "date": "2023-06-25"}}, {"id": 2, "Order": {"Orderid": 3, "Product": {"Productid": 3}, "date": "2023-06-26"}}] +~~END~~ + + +-- Error related to inserting value at Json object location +SELECT * FROM forjson_nesting_vu_v_error +GO +~~START~~ +nvarchar +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Property user.name.last cannot be generated in JSON output due to a conflict with another column name or alias. Use different names and aliases for each column in SELECT list.)~~ + + +-- Queries that check NULL nested json object insert +SELECT * FROM forjson_nesting_vu_v_no_null +GO +~~START~~ +nvarchar +[{"id": 1, "user": {"name": {"first": "John", "last": "Doe"}}, "contact": {"email": "johndoe@gmail.com", "phone": "123-456-7890"}}, {"id": 2, "user": {"name": {"first": "Jane", "last": "Smith"}}, "contact": {"email": "janesmith@yahoo.com"}}, {"id": 3, "contact": {"email": "mikejohnson@myspace.com", "phone": "098-765-4321"}}, {"id": 4, "user": {"name": {"first": "Sergio", "last": "Giavanni"}}}] +~~END~~ + + +SELECT * FROM forjson_nesting_vu_v_with_null +GO +~~START~~ +nvarchar +[{"id": 1, "user": {"name": {"first": "John", "last": "Doe"}}, "contact": {"email": "johndoe@gmail.com", "phone": "123-456-7890"}}, {"id": 2, "user": {"name": {"first": "Jane", "last": "Smith"}}, "contact": {"email": "janesmith@yahoo.com", "phone": null}}, {"id": 3, "user": {"name": {"first": null, "last": null}}, "contact": {"email": "mikejohnson@myspace.com", "phone": "098-765-4321"}}, {"id": 4, "user": {"name": {"first": "Sergio", "last": "Giavanni"}}, "contact": {"email": null, "phone": null}}] +~~END~~ + + diff --git a/test/JDBC/expected/forjson-subquery-before-14_10-or-15_5-vu-cleanup.out b/test/JDBC/expected/forjson-subquery-before-14_10-or-15_5-vu-cleanup.out new file mode 100644 index 0000000000..8cb72c506f --- /dev/null +++ b/test/JDBC/expected/forjson-subquery-before-14_10-or-15_5-vu-cleanup.out @@ -0,0 +1,59 @@ +-- FOR JSON AUTO clause not supported +DROP VIEW forjson_subquery_vu_v_auto +GO +~~ERROR (Code: 3701)~~ + +~~ERROR (Message: view "forjson_subquery_vu_v_auto" does not exist)~~ + + +-- Alias/colname is not present +DROP VIEW forjson_subquery_vu_v_no_alias +GO + +DROP VIEW forjson_subquery_vu_v_with +GO + +DROP VIEW forjson_subquery_vu_v_with_order_by +GO + +-- Binary strings +DROP VIEW forjson_subquery_vu_v_binary_strings +GO + +DROP VIEW forjson_subquery_vu_v_varbinary_strings +GO + +-- Rowversion and timestamp +DROP VIEW forjson_subquery_vu_v_rowversion +GO + +DROP VIEW forjson_subquery_vu_v_timestamp +GO + +-- BABEL-3569/BABEL-3690 return 0 rows for empty rowset +DROP PROCEDURE forjson_subquery_vu_p_empty +GO + +-- exercise tsql_select_for_json_result internal function +DROP VIEW forjson_subquery_vu_v_internal +GO + +DROP TABLE forjson_subquery_vu_t_countries +GO + +DROP TABLE forjson_subquery_vu_t1 +GO + +-- Binary strings +DROP TABLE forjson_subquery_vu_t_binary_strings +GO + +-- Rowversion and timestamp +DROP TABLE forjson_subquery_vu_t_rowversion +GO + +DROP TABLE forjson_subquery_vu_t_timestamp +GO + +EXEC sp_babelfish_configure 'babelfishpg_tsql.escape_hatch_rowversion', 'strict'; +GO diff --git a/test/JDBC/expected/forjson-subquery-before-14_10-or-15_5-vu-prepare.out b/test/JDBC/expected/forjson-subquery-before-14_10-or-15_5-vu-prepare.out new file mode 100644 index 0000000000..47f572490d --- /dev/null +++ b/test/JDBC/expected/forjson-subquery-before-14_10-or-15_5-vu-prepare.out @@ -0,0 +1,151 @@ + +-- 14.7 (aka extension version 2.4.0) has a major change to how FOR JSON +-- has been implemented, which slightly changes the behavior around some old error +-- messages as well, so we need to move those tests to a new test file that separately +-- exercises them outside of the pre-14.6 upgrade tests. +CREATE TABLE forjson_subquery_vu_t_countries ( +[Id] INT, +[Age] INT, +[Country] VARCHAR(25)) +GO + +INSERT INTO forjson_subquery_vu_t_countries values +(1,25, 'India'), +(2,40, 'USA'), +(3,30, 'India'), +(4,20, NULL), +(5,10, 'USA') +GO +~~ROW COUNT: 5~~ + + +create table forjson_subquery_vu_t1 (x int) +insert into forjson_subquery_vu_t1 values (1) +go +~~ROW COUNT: 1~~ + + +-- FOR JSON AUTO clause not supported +CREATE VIEW forjson_subquery_vu_v_auto AS +SELECT ( + SELECT Id, + State + FROM forjson_subquery_vu_t1 + FOR JSON AUTO +) c1 +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: column "id" does not exist)~~ + + +-- Alias/colname not present +CREATE VIEW forjson_subquery_vu_v_no_alias AS +SELECT ( + SELECT 2 + FOR JSON PATH +) c1 +GO + +CREATE VIEW forjson_subquery_vu_v_with AS +WITH forjson_subquery_vu_with1(avg_age) AS ( + SELECT avg(Age) + FROM forjson_subquery_vu_t_countries +) +SELECT ( + SELECT Id, Age, Country + FROM forjson_subquery_vu_t_countries, forjson_subquery_vu_with1 + WHERE Age >= forjson_subquery_vu_with1.avg_age + FOR JSON PATH +) C1 +GO + +CREATE VIEW forjson_subquery_vu_v_with_order_by AS +WITH forjson_subquery_vu_with2(avg_age) AS ( + SELECT avg(Age) + FROM forjson_subquery_vu_t_countries +) +SELECT ( + SELECT Id, Age, Country + FROM forjson_subquery_vu_t_countries, forjson_subquery_vu_with2 + WHERE Age >= forjson_subquery_vu_with2.avg_age + ORDER BY Country + FOR JSON PATH +) c1 +GO + +-- Binary strings +CREATE TABLE forjson_subquery_vu_t_binary_strings(abinary binary, avarbinary varbinary(10)) +GO +INSERT forjson_subquery_vu_t_binary_strings VALUES (123456,0x0a0b0c0d0e) +GO +~~ROW COUNT: 1~~ + + +-- Rowversion and timestamp +EXEC sp_babelfish_configure 'babelfishpg_tsql.escape_hatch_rowversion', 'ignore'; +GO + +CREATE TABLE forjson_subquery_vu_t_rowversion (myKey int, myValue int,RV rowversion); +GO +INSERT INTO forjson_subquery_vu_t_rowversion (myKey, myValue) VALUES (1, 0); +GO +~~ROW COUNT: 1~~ + + +CREATE TABLE forjson_subquery_vu_t_timestamp (myKey int, myValue int, timestamp); +GO +INSERT INTO forjson_subquery_vu_t_timestamp (myKey, myValue) VALUES (1, 0); +GO +~~ROW COUNT: 1~~ + + +-- Binary strings +CREATE VIEW forjson_subquery_vu_v_binary_strings AS +SELECT +( + SELECT abinary + FROM forjson_subquery_vu_t_binary_strings + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_subquery_vu_v_varbinary_strings AS +SELECT +( + SELECT avarbinary + FROM forjson_subquery_vu_t_binary_strings + FOR JSON PATH +) as c1; +GO + +-- Rowversion and timestamp +CREATE VIEW forjson_subquery_vu_v_rowversion AS +SELECT +( + SELECT * + FROM forjson_subquery_vu_t_rowversion + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_subquery_vu_v_timestamp AS +SELECT +( + SELECT * + FROM forjson_subquery_vu_t_timestamp + FOR JSON PATH +) as c1; +GO + +-- BABEL-3569/BABEL-3690 return 0 rows for empty rowset +CREATE PROCEDURE forjson_subquery_vu_p_empty AS +SELECT * FROM forjson_subquery_vu_t_countries + WHERE 1 = 0 + FOR JSON PATH +GO + +-- exercise tsql_select_for_json_result internal function +CREATE VIEW forjson_subquery_vu_v_internal AS +SELECT * FROM tsql_select_for_json_result('abcd') +GO diff --git a/test/JDBC/expected/forjson-subquery-before-14_10-or-15_5-vu-verify.out b/test/JDBC/expected/forjson-subquery-before-14_10-or-15_5-vu-verify.out new file mode 100644 index 0000000000..c4553b14cd --- /dev/null +++ b/test/JDBC/expected/forjson-subquery-before-14_10-or-15_5-vu-verify.out @@ -0,0 +1,95 @@ +-- FOR JSON AUTO clause not supported +SELECT * FROM forjson_subquery_vu_v_auto +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: relation "forjson_subquery_vu_v_auto" does not exist)~~ + + +-- Alias/colname is not present +SELECT * FROM forjson_subquery_vu_v_no_alias +GO +~~START~~ +nvarchar +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: 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)~~ + + +SELECT * FROM forjson_subquery_vu_v_with +GO +~~START~~ +nvarchar +[{"Id":1,"Age":25,"Country":"India"},{"Id":2,"Age":40,"Country":"USA"},{"Id":3,"Age":30,"Country":"India"}] +~~END~~ + + +SELECT * FROM forjson_subquery_vu_v_with_order_by +GO +~~START~~ +nvarchar +[{"Id":1,"Age":25,"Country":"India"},{"Id":3,"Age":30,"Country":"India"},{"Id":2,"Age":40,"Country":"USA"}] +~~END~~ + + +-- Binary strings +SELECT * FROM forjson_subquery_vu_v_binary_strings +GO +~~START~~ +nvarchar +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: binary types are not supported with FOR JSON)~~ + + +SELECT * FROM forjson_subquery_vu_v_varbinary_strings +GO +~~START~~ +nvarchar +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: binary types are not supported with FOR JSON)~~ + + +-- Rowversion and timestamp +SELECT * FROM forjson_subquery_vu_v_rowversion +GO +~~START~~ +nvarchar +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: binary types are not supported with FOR JSON)~~ + + +SELECT * FROM forjson_subquery_vu_v_timestamp +GO +~~START~~ +nvarchar +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: binary types are not supported with FOR JSON)~~ + + +-- BABEL-3569/BABEL-3690 return 0 rows for empty rowset +EXEC forjson_subquery_vu_p_empty +GO +~~START~~ +nvarchar +~~END~~ + + +SELECT @@rowcount +GO +~~START~~ +int +0 +~~END~~ + + +-- exercise tsql_select_for_json_result internal function +SELECT * FROM forjson_subquery_vu_v_internal +GO +~~START~~ +nvarchar +abcd +~~END~~ diff --git a/test/JDBC/expected/forjson-subquery-vu-verify.out b/test/JDBC/expected/forjson-subquery-vu-verify.out index 89f76f3dd5..e9e82cce6c 100644 --- a/test/JDBC/expected/forjson-subquery-vu-verify.out +++ b/test/JDBC/expected/forjson-subquery-vu-verify.out @@ -20,7 +20,7 @@ SELECT * FROM forjson_subquery_vu_v_with GO ~~START~~ nvarchar -[{"Id":1,"Age":25,"Country":"India"},{"Id":2,"Age":40,"Country":"USA"},{"Id":3,"Age":30,"Country":"India"}] +[{"Id": 1, "Age": 25, "Country": "India"}, {"Id": 2, "Age": 40, "Country": "USA"}, {"Id": 3, "Age": 30, "Country": "India"}] ~~END~~ @@ -28,7 +28,7 @@ SELECT * FROM forjson_subquery_vu_v_with_order_by GO ~~START~~ nvarchar -[{"Id":1,"Age":25,"Country":"India"},{"Id":3,"Age":30,"Country":"India"},{"Id":2,"Age":40,"Country":"USA"}] +[{"Id": 1, "Age": 25, "Country": "India"}, {"Id": 3, "Age": 30, "Country": "India"}, {"Id": 2, "Age": 40, "Country": "USA"}] ~~END~~ diff --git a/test/JDBC/expected/forjson-vu-verify.out b/test/JDBC/expected/forjson-vu-verify.out index 4f8a705dba..ce8d2391eb 100644 --- a/test/JDBC/expected/forjson-vu-verify.out +++ b/test/JDBC/expected/forjson-vu-verify.out @@ -32,12 +32,12 @@ int#!#varchar ~~END~~ --- FOR JSON PATH clause without nested support +-- FOR JSON PATH clause with nested support SELECT * FROM forjson_vu_v_people GO ~~START~~ nvarchar -[{"EmpId":1,"Name.FirstName":"Divya","Name.LastName":"Kumar"},{"EmpId":2,"Name.LastName":"Khanna","State":"Bengaluru"},{"EmpId":3,"Name.FirstName":"Tom","Name.LastName":"Mehta","State":"Kolkata"},{"EmpId":4,"Name.FirstName":"Kane","State":"Delhi"}] +[{"EmpId": 1, "Name": {"FirstName": "Divya", "LastName": "Kumar"}}, {"EmpId": 2, "Name": {"LastName": "Khanna"}, "State": "Bengaluru"}, {"EmpId": 3, "Name": {"FirstName": "Tom", "LastName": "Mehta"}, "State": "Kolkata"}, {"EmpId": 4, "Name": {"FirstName": "Kane"}, "State": "Delhi"}] ~~END~~ @@ -45,16 +45,16 @@ SELECT * FROM forjson_vu_v_countries GO ~~START~~ nvarchar -[{"Id":1,"Age":25,"Country":"India"},{"Id":2,"Age":40,"Country":"USA"},{"Id":3,"Age":30,"Country":"India"},{"Id":4,"Age":20},{"Id":5,"Age":10,"Country":"USA"}] +[{"Id": 1, "Age": 25, "Country": "India"}, {"Id": 2, "Age": 40, "Country": "USA"}, {"Id": 3, "Age": 30, "Country": "India"}, {"Id": 4, "Age": 20}, {"Id": 5, "Age": 10, "Country": "USA"}] ~~END~~ --- Multiple tables without nested support +-- Multiple tables with nested support SELECT * FROM forjson_vu_v_join GO ~~START~~ nvarchar -[{"Person.Name":"Divya","Person.Surname":"Kumar","Employee.Price":25,"Employee.Quantity":"India"},{"Person.Surname":"Khanna","Employee.Price":40,"Employee.Quantity":"USA"},{"Person.Name":"Tom","Person.Surname":"Mehta","Employee.Price":30,"Employee.Quantity":"India"},{"Person.Name":"Kane","Employee.Price":20}] +[{"Person": {"Name": "Divya", "Surname": "Kumar"}, "Employee": {"Price": 25, "Quantity": "India"}}, {"Person": {"Surname": "Khanna"}, "Employee": {"Price": 40, "Quantity": "USA"}}, {"Person": {"Name": "Tom", "Surname": "Mehta"}, "Employee": {"Price": 30, "Quantity": "India"}}, {"Person": {"Name": "Kane"}, "Employee": {"Price": 20}}] ~~END~~ @@ -63,7 +63,7 @@ SELECT * FROM forjson_vu_v_root GO ~~START~~ nvarchar -{"root":[{"FirstName":"Divya","LastName":"Kumar"},{"LastName":"Khanna"},{"FirstName":"Tom","LastName":"Mehta"},{"FirstName":"Kane"}]} +{"root": [{"FirstName": "Divya", "LastName": "Kumar"}, {"LastName": "Khanna"}, {"FirstName": "Tom", "LastName": "Mehta"}, {"FirstName": "Kane"}]} ~~END~~ @@ -72,7 +72,7 @@ SELECT * FROM forjson_vu_v_root_value GO ~~START~~ nvarchar -{"Employee":[{"FirstName":"Divya","LastName":"Kumar"},{"LastName":"Khanna"},{"FirstName":"Tom","LastName":"Mehta"},{"FirstName":"Kane"}]} +{"Employee": [{"FirstName": "Divya", "LastName": "Kumar"}, {"LastName": "Khanna"}, {"FirstName": "Tom", "LastName": "Mehta"}, {"FirstName": "Kane"}]} ~~END~~ @@ -81,7 +81,7 @@ SELECT * FROM forjson_vu_v_empty_root GO ~~START~~ nvarchar -{"":[{"FirstName":"Divya","LastName":"Kumar"},{"LastName":"Khanna"},{"FirstName":"Tom","LastName":"Mehta"},{"FirstName":"Kane"}]} +{"": [{"FirstName": "Divya", "LastName": "Kumar"}, {"LastName": "Khanna"}, {"FirstName": "Tom", "LastName": "Mehta"}, {"FirstName": "Kane"}]} ~~END~~ @@ -90,7 +90,7 @@ SELECT * FROM forjson_vu_v_without_array_wrapper GO ~~START~~ nvarchar -{"FirstName":"Divya","LastName":"Kumar"},{"LastName":"Khanna"},{"FirstName":"Tom","LastName":"Mehta"},{"FirstName":"Kane"} +{"FirstName": "Divya", "LastName": "Kumar"}, {"LastName": "Khanna"}, {"FirstName": "Tom", "LastName": "Mehta"}, {"FirstName": "Kane"} ~~END~~ @@ -99,7 +99,7 @@ SELECT * FROM forjson_vu_v_include_null_values GO ~~START~~ nvarchar -[{"FirstName":"Divya","LastName":"Kumar"},{"FirstName":null,"LastName":"Khanna"},{"FirstName":"Tom","LastName":"Mehta"},{"FirstName":"Kane","LastName":null}] +[{"FirstName": "Divya", "LastName": "Kumar"}, {"FirstName": null, "LastName": "Khanna"}, {"FirstName": "Tom", "LastName": "Mehta"}, {"FirstName": "Kane", "LastName": null}] ~~END~~ @@ -108,7 +108,7 @@ SELECT * FROM forjson_vu_v_root_include_null_values GO ~~START~~ nvarchar -{"Employee":[{"Id":1,"Age":25,"Country":"India"},{"Id":2,"Age":40,"Country":"USA"},{"Id":3,"Age":30,"Country":"India"},{"Id":4,"Age":20,"Country":null},{"Id":5,"Age":10,"Country":"USA"}]} +{"Employee": [{"Id": 1, "Age": 25, "Country": "India"}, {"Id": 2, "Age": 40, "Country": "USA"}, {"Id": 3, "Age": 30, "Country": "India"}, {"Id": 4, "Age": 20, "Country": null}, {"Id": 5, "Age": 10, "Country": "USA"}]} ~~END~~ @@ -116,7 +116,7 @@ SELECT * FROM forjson_vu_v_without_array_wrapper_include_null_values GO ~~START~~ nvarchar -{"Id":1,"Age":25,"Country":"India"},{"Id":2,"Age":40,"Country":"USA"},{"Id":3,"Age":30,"Country":"India"},{"Id":4,"Age":20,"Country":null},{"Id":5,"Age":10,"Country":"USA"} +{"Id": 1, "Age": 25, "Country": "India"}, {"Id": 2, "Age": 40, "Country": "USA"}, {"Id": 3, "Age": 30, "Country": "India"}, {"Id": 4, "Age": 20, "Country": null}, {"Id": 5, "Age": 10, "Country": "USA"} ~~END~~ @@ -126,7 +126,7 @@ EXECUTE forjson_vu_p_params1 @id = 2 GO ~~START~~ nvarchar -[{"State":"Bengaluru"}] +[{"State": "Bengaluru"}] ~~END~~ @@ -134,7 +134,7 @@ EXECUTE forjson_vu_p_params2 @id = 3 GO ~~START~~ nvarchar -[{"nam\"@e":"Tom","State\"@":"Kolkata"}] +[{"nam\"@e": "Tom", "State\"@": "Kolkata"}] ~~END~~ @@ -143,7 +143,7 @@ SELECT * FROM forjson_vu_v_nulls GO ~~START~~ nvarchar -[{},{},{}] +[{}, {}, {}] ~~END~~ @@ -152,6 +152,6 @@ SELECT * FROM forjson_vu_v_order_by GO ~~START~~ nvarchar -[{"Id":5,"Age":10,"Country":"USA"},{"Id":4,"Age":20},{"Id":1,"Age":25,"Country":"India"},{"Id":3,"Age":30,"Country":"India"},{"Id":2,"Age":40,"Country":"USA"}] +[{"Id": 5, "Age": 10, "Country": "USA"}, {"Id": 4, "Age": 20}, {"Id": 1, "Age": 25, "Country": "India"}, {"Id": 3, "Age": 30, "Country": "India"}, {"Id": 2, "Age": 40, "Country": "USA"}] ~~END~~ diff --git a/test/JDBC/input/forjson/forjson-before-14_10-or-15_5-vu-cleanup.sql b/test/JDBC/input/forjson/forjson-before-14_10-or-15_5-vu-cleanup.sql new file mode 100644 index 0000000000..5be5342d57 --- /dev/null +++ b/test/JDBC/input/forjson/forjson-before-14_10-or-15_5-vu-cleanup.sql @@ -0,0 +1,63 @@ +-- FOR JSON PATH clause without nested support +DROP VIEW forjson_vu_v_people +GO + +DROP VIEW forjson_vu_v_countries +GO + +-- Multiple tables without nested support +DROP VIEW forjson_vu_v_join +GO + +-- ROOT directive without specifying value +DROP VIEW forjson_vu_v_root +GO + +-- ROOT directive with specifying ROOT value +DROP VIEW forjson_vu_v_root_value +GO + +-- ROOT directive with specifying ROOT value with empty string +DROP VIEW forjson_vu_v_empty_root +GO + +-- WITHOUT_ARRAY_WRAPPERS directive +DROP VIEW forjson_vu_v_without_array_wrapper +GO + +-- INCLUDE_NULL_VALUES directive +DROP VIEW forjson_vu_v_include_null_values +GO + +-- Multiple Directives +DROP VIEW forjson_vu_v_root_include_null_values +GO + +DROP VIEW forjson_vu_v_without_array_wrapper_include_null_values +GO + + +-- Test case with parameters +DROP PROCEDURE forjson_vu_p_params1 +GO + +DROP PROCEDURE forjson_vu_p_params2 +GO + +-- All null values test +DROP VIEW forjson_vu_v_nulls +GO + +-- Test for all parser rules +DROP VIEW forjson_vu_v_order_by +GO + +-- Display Table Contents +DROP TABLE forjson_vu_t_people +GO + +DROP TABLE forjson_vu_t_countries +GO + +DROP TABLE forjson_vu_t_values +GO \ No newline at end of file diff --git a/test/JDBC/input/forjson/forjson-before-14_10-or-15_5-vu-prepare.sql b/test/JDBC/input/forjson/forjson-before-14_10-or-15_5-vu-prepare.sql new file mode 100644 index 0000000000..3947821204 --- /dev/null +++ b/test/JDBC/input/forjson/forjson-before-14_10-or-15_5-vu-prepare.sql @@ -0,0 +1,198 @@ +CREATE TABLE forjson_vu_t_people ( +[Id] INT, +[FirstName] VARCHAR(25), +[LastName] VARCHAR(25), +[State] VARCHAR(25) ) +GO + +INSERT INTO forjson_vu_t_people values +(1,'Divya','Kumar',NULL), +(2,NULL,'Khanna','Bengaluru'), +(3,'Tom','Mehta','Kolkata'), +(4,'Kane',NULL,'Delhi') +GO + +CREATE TABLE forjson_vu_t_countries ( +[Id] INT, +[Age] INT, +[Country] VARCHAR(25)) +GO + +INSERT INTO forjson_vu_t_countries values +(1,25, 'India'), +(2,40, 'USA'), +(3,30, 'India'), +(4,20, NULL), +(5,10, 'USA') +GO + +CREATE TABLE forjson_vu_t_values ( +[Id] INT, +[value] VARCHAR(25) ) +GO + +INSERT INTO forjson_vu_t_values values +(1,NULL), +(2,NULL), +(3,NULL) +GO + +-- FOR JSON PATH clause without nested support +CREATE VIEW forjson_vu_v_people AS +SELECT ( + SELECT Id AS EmpId, + FirstName AS "Name.FirstName", + LastName AS "Name.LastName", + State + FROM forjson_vu_t_people + FOR JSON PATH +) c1 +GO + +CREATE VIEW forjson_vu_v_countries AS +SELECT ( + SELECT Id, + Age, + Country + FROM forjson_vu_t_countries + FOR JSON PATH +) c1 +GO + +-- Multiple tables without nested support +CREATE VIEW forjson_vu_v_join AS +SELECT ( + SELECT E.FirstName AS 'Person.Name', + E.LastName AS 'Person.Surname', + D.Age AS 'Employee.Price', + D.Country AS 'Employee.Quantity' + FROM forjson_vu_t_people E + INNER JOIN forjson_vu_t_countries D + ON E.Id = D.Id + FOR JSON PATH +) c1 +GO + +-- ROOT directive without specifying value +CREATE VIEW forjson_vu_v_root AS +SELECT ( + SELECT FirstName, + LastName + FROM forjson_vu_t_people + FOR JSON PATH, ROOT +) c1 +GO + +-- ROOT directive with specifying ROOT value +CREATE VIEW forjson_vu_v_root_value AS +SELECT ( + SELECT FirstName, + LastName + FROM forjson_vu_t_people + FOR JSON PATH, ROOT('Employee') +) c1 +GO + +-- ROOT directive with specifying ROOT value with empty string +CREATE VIEW forjson_vu_v_empty_root AS +SELECT ( + SELECT FirstName, + LastName + FROM forjson_vu_t_people + FOR JSON PATH, ROOT('') +) c1 +GO + +-- WITHOUT_ARRAY_WRAPPERS directive +CREATE VIEW forjson_vu_v_without_array_wrapper AS +SELECT ( + SELECT FirstName, + LastName + FROM forjson_vu_t_people + FOR JSON PATH, WITHOUT_ARRAY_WRAPPER +) c1 +GO + +-- INCLUDE_NULL_VALUES directive +CREATE VIEW forjson_vu_v_include_null_values AS +SELECT ( + SELECT FirstName, + LastName + FROM forjson_vu_t_people + FOR JSON PATH, INCLUDE_NULL_VALUES +) c1 +GO + +-- Multiple Directives +CREATE VIEW forjson_vu_v_root_include_null_values AS +SELECT ( + SELECT Id, + Age, + Country + FROM forjson_vu_t_countries + FOR JSON PATH, ROOT('Employee'), INCLUDE_NULL_VALUES +) c1 +GO + +CREATE VIEW forjson_vu_v_without_array_wrapper_include_null_values AS +SELECT ( + SELECT Id, + Age, + Country + FROM forjson_vu_t_countries + FOR JSON PATH, WITHOUT_ARRAY_WRAPPER, INCLUDE_NULL_VALUES +) c1 +GO + +-- Throws error as ROOT and WITHOUT_ARRAY_WRAPPER cannot be used together +CREATE VIEW forjson_vu_v_root_and_without_array_wrapper AS +SELECT ( + SELECT Id, + Age, + Country + FROM forjson_vu_t_countries + FOR JSON PATH, ROOT, WITHOUT_ARRAY_WRAPPER +) c1 +GO + +-- Test case with parameters +CREATE PROCEDURE forjson_vu_p_params1 @id int AS +SELECT ( + SELECT Firstname AS [Name], + State + FROM forjson_vu_t_people + WHERE Id = @id + FOR JSON PATH +) c1 +GO + +CREATE PROCEDURE forjson_vu_p_params2 @id int AS +SELECT ( + SELECT Firstname AS [nam"@e], + State AS [State"@] + FROM forjson_vu_t_people + WHERE Id = @id + FOR JSON PATH +) c1 +GO + +-- All null values test +CREATE VIEW forjson_vu_v_nulls AS +SELECT ( + SELECT value + FROM forjson_vu_t_values + FOR JSON PATH +) c1 +GO + +-- Test for all parser rules +CREATE VIEW forjson_vu_v_order_by AS +SELECT ( + SELECT Id, + Age, + Country + FROM forjson_vu_t_countries + ORDER BY Age + FOR JSON PATH +) C1 +GO \ No newline at end of file diff --git a/test/JDBC/input/forjson/forjson-before-14_10-or-15_5-vu-verify.sql b/test/JDBC/input/forjson/forjson-before-14_10-or-15_5-vu-verify.sql new file mode 100644 index 0000000000..e0c3879c41 --- /dev/null +++ b/test/JDBC/input/forjson/forjson-before-14_10-or-15_5-vu-verify.sql @@ -0,0 +1,63 @@ +-- Display Table Contents +SELECT * FROM forjson_vu_t_people +GO + +SELECT * FROM forjson_vu_t_countries +GO + +SELECT * FROM forjson_vu_t_values +GO + +-- FOR JSON PATH clause without nested support +SELECT * FROM forjson_vu_v_people +GO + +SELECT * FROM forjson_vu_v_countries +GO + +-- Multiple tables without nested support +SELECT * FROM forjson_vu_v_join +GO + +-- ROOT directive without specifying value +SELECT * FROM forjson_vu_v_root +GO + +-- ROOT directive with specifying ROOT value +SELECT * FROM forjson_vu_v_root_value +GO + +-- ROOT directive with specifying ROOT value with empty string +SELECT * FROM forjson_vu_v_empty_root +GO + +-- WITHOUT_ARRAY_WRAPPERS directive +SELECT * FROM forjson_vu_v_without_array_wrapper +GO + +-- INCLUDE_NULL_VALUES directive +SELECT * FROM forjson_vu_v_include_null_values +GO + +-- Multiple Directives +SELECT * FROM forjson_vu_v_root_include_null_values +GO + +SELECT * FROM forjson_vu_v_without_array_wrapper_include_null_values +GO + + +-- Test case with parameters +EXECUTE forjson_vu_p_params1 @id = 2 +GO + +EXECUTE forjson_vu_p_params2 @id = 3 +GO + +-- All null values test +SELECT * FROM forjson_vu_v_nulls +GO + +-- Test for all parser rules +SELECT * FROM forjson_vu_v_order_by +GO \ No newline at end of file diff --git a/test/JDBC/input/forjson/forjson-datatypes-before-14_10-or-15_5-vu-cleanup.sql b/test/JDBC/input/forjson/forjson-datatypes-before-14_10-or-15_5-vu-cleanup.sql new file mode 100644 index 0000000000..1b793f1fca --- /dev/null +++ b/test/JDBC/input/forjson/forjson-datatypes-before-14_10-or-15_5-vu-cleanup.sql @@ -0,0 +1,74 @@ +-- DIFFERENT CASES TO CHECK DATATYPES +-- Exact Numerics +DROP VIEW forjson_datatypes_vu_v_numerics +GO + +DROP VIEW forjson_datatypes_vu_v_bit +GO + +DROP VIEW forjson_datatypes_vu_v_money +GO + +DROP VIEW forjson_datatypes_vu_v_smallmoney +GO + +-- Approximate numerics +DROP VIEW forjson_datatypes_vu_v_approx_numerics +GO + +-- Date and time +DROP VIEW forjson_datatypes_vu_v_time_date +GO + +DROP VIEW forjson_datatypes_vu_v_smalldatetime +GO + +DROP VIEW forjson_datatypes_vu_v_datetime +GO + +DROP VIEW forjson_datatypes_vu_v_datetime2 +GO + +DROP VIEW forjson_datatypes_vu_v_datetimeoffset +GO + +-- Character strings +DROP VIEW forjson_datatypes_vu_v_strings +GO + +-- Unicode character strings +DROP VIEW forjson_datatypes_vu_v_unicode_strings +GO + +-- NULL datetimes +DROP VIEW forjson_datatypes_vu_v_nulldatetime; +go + +DROP VIEW forjson_datatypes_vu_v_nullsmalldatetime; +go + +DROP VIEW forjson_datatypes_vu_v_nulldatetime2; +go + +DROP VIEW forjson_datatypes_vu_v_nulldatetimeoffset; +go + +-- DROP TABLE +DROP TABLE forjson_datatypes_vu_t_exact_numerics +GO + +-- Approximate numerics +DROP TABLE forjson_datatypes_vu_t_approx_numerics +GO + +-- Date and time +DROP TABLE forjson_datatypes_vu_t_date_and_time +GO + +-- Character strings +DROP TABLE forjson_datatypes_vu_t_strings +GO + +-- Unicode character strings +DROP TABLE forjson_datatypes_vu_t_unicode_strings +GO \ No newline at end of file diff --git a/test/JDBC/input/forjson/forjson-datatypes-before-14_10-or-15_5-vu-prepare.sql b/test/JDBC/input/forjson/forjson-datatypes-before-14_10-or-15_5-vu-prepare.sql new file mode 100644 index 0000000000..fcf3d1f0d2 --- /dev/null +++ b/test/JDBC/input/forjson/forjson-datatypes-before-14_10-or-15_5-vu-prepare.sql @@ -0,0 +1,172 @@ +-- DIFFERENT CASES TO CHECK DATATYPES +-- Exact Numerics +CREATE TABLE forjson_datatypes_vu_t_exact_numerics(abigint bigint, abit bit, adecimal decimal, aint int, amoney money, anumeric numeric, asmallint smallint, asmallmoney smallmoney, atinyint tinyint) +GO +INSERT forjson_datatypes_vu_t_exact_numerics VALUES(9223372036854775807, 1, 123.2, 2147483647, 3148.29, 12345.12, 32767, 3148.29, 255) +GO + +-- Approximate numerics +CREATE TABLE forjson_datatypes_vu_t_approx_numerics(afloat float, areal real) +GO +INSERT forjson_datatypes_vu_t_approx_numerics VALUES(12.05, 120.53) +GO + +-- Date and time +CREATE TABLE forjson_datatypes_vu_t_date_and_time(atime time, adate date, asmalldatetime smalldatetime, adatetime datetime, adatetime2 datetime2, adatetimeoffset datetimeoffset, adatetimeoffset_2 datetimeoffset) +GO +INSERT forjson_datatypes_vu_t_date_and_time VALUES('2022-11-11 23:17:08.560','2022-11-11 23:17:08.560','2022-11-11 23:17:08.560','2022-11-11 23:17:08.560','2022-11-11 23:17:08.560','2022-11-11 23:17:08.560', '2012-10-12 12:34:56 +02:30') +GO + +-- Character strings +CREATE TABLE forjson_datatypes_vu_t_strings(achar char, avarchar varchar(3), atext text) +GO +INSERT forjson_datatypes_vu_t_strings VALUES('a','abc','abc') +GO + +-- Unicode character strings +CREATE TABLE forjson_datatypes_vu_t_unicode_strings(anchar nchar(5), anvarchar nvarchar(5), antext ntext) +GO +INSERT forjson_datatypes_vu_t_unicode_strings VALUES('abc','abc','abc') +GO + +-- T-SQL does not allow raw scalars as the output of a view, so surround the FOR JSON call with a SELECT to avoid a syntax error +-- Exact Numerics +CREATE VIEW forjson_datatypes_vu_v_numerics AS +SELECT +( + SELECT abigint, adecimal, aint, anumeric, asmallint, atinyint + FROM forjson_datatypes_vu_t_exact_numerics + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_bit AS +SELECT +( + SELECT abit + FROM forjson_datatypes_vu_t_exact_numerics + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_money AS +SELECT +( + SELECT amoney + FROM forjson_datatypes_vu_t_exact_numerics + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_smallmoney AS +SELECT +( + SELECT asmallmoney + FROM forjson_datatypes_vu_t_exact_numerics + FOR JSON PATH +) as c1; +GO + +-- Approximate numerics +CREATE VIEW forjson_datatypes_vu_v_approx_numerics AS +SELECT +( + SELECT * + FROM forjson_datatypes_vu_t_approx_numerics + FOR JSON PATH +) as c1; +GO + +-- Date and time +CREATE VIEW forjson_datatypes_vu_v_time_date AS +SELECT +( + SELECT atime,adate + FROM forjson_datatypes_vu_t_date_and_time + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_smalldatetime AS +SELECT +( + SELECT asmalldatetime + FROM forjson_datatypes_vu_t_date_and_time + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_datetime AS +SELECT +( + SELECT adatetime + FROM forjson_datatypes_vu_t_date_and_time + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_datetime2 AS +SELECT +( + SELECT adatetime2 + FROM forjson_datatypes_vu_t_date_and_time + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_datetimeoffset AS +SELECT +( + SELECT adatetimeoffset, adatetimeoffset_2 + FROM forjson_datatypes_vu_t_date_and_time + FOR JSON PATH +) as c1; +GO + +-- Character strings +CREATE VIEW forjson_datatypes_vu_v_strings AS +SELECT +( + SELECT * + FROM forjson_datatypes_vu_t_strings + FOR JSON PATH +) as c1; +GO + +-- Unicode character strings +CREATE VIEW forjson_datatypes_vu_v_unicode_strings AS +SELECT +( + SELECT * + FROM forjson_datatypes_vu_t_unicode_strings + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_nulldatetime AS +SELECT +( + select cast(null as datetime) for JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_nullsmalldatetime AS +SELECT +( + select cast(null as smalldatetime) for JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_nulldatetime2 AS +SELECT +( + select cast(null as datetime2) for JSON PATH +) as c1; +GO + +CREATE VIEW forjson_datatypes_vu_v_nulldatetimeoffset AS +SELECT +( + select cast(null as datetimeoffset) for JSON PATH +) as c1; +GO \ No newline at end of file diff --git a/test/JDBC/input/forjson/forjson-datatypes-before-14_10-or-15_5-vu-verify.sql b/test/JDBC/input/forjson/forjson-datatypes-before-14_10-or-15_5-vu-verify.sql new file mode 100644 index 0000000000..fb02ca4b70 --- /dev/null +++ b/test/JDBC/input/forjson/forjson-datatypes-before-14_10-or-15_5-vu-verify.sql @@ -0,0 +1,55 @@ +-- DIFFERENT CASES TO CHECK DATATYPES +-- Exact Numerics +SELECT * FROM forjson_datatypes_vu_v_numerics +GO + +SELECT * FROM forjson_datatypes_vu_v_bit +GO + +SELECT * FROM forjson_datatypes_vu_v_money +GO + +SELECT * FROM forjson_datatypes_vu_v_smallmoney +GO + +-- Approximate numerics +SELECT * FROM forjson_datatypes_vu_v_approx_numerics +GO + +-- Date and time +SELECT * FROM forjson_datatypes_vu_v_time_date +GO + +SELECT * FROM forjson_datatypes_vu_v_smalldatetime +GO + +SELECT * FROM forjson_datatypes_vu_v_datetime +GO + +SELECT * FROM forjson_datatypes_vu_v_datetime2 +GO + +SELECT * FROM forjson_datatypes_vu_v_datetimeoffset +GO + +-- Character strings +SELECT * FROM forjson_datatypes_vu_v_strings +GO + +-- Unicode character strings +SELECT * FROM forjson_datatypes_vu_v_unicode_strings +GO + +-- NULL datetime and datetimeoffset + +SELECT * FROM forjson_datatypes_vu_v_nulldatetime +GO + +SELECT * FROM forjson_datatypes_vu_v_nullsmalldatetime +GO + +SELECT * FROM forjson_datatypes_vu_v_nulldatetime2 +GO + +SELECT * FROM forjson_datatypes_vu_v_nulldatetimeoffset +GO \ No newline at end of file diff --git a/test/JDBC/input/forjson/forjson-nesting-vu-cleanup.sql b/test/JDBC/input/forjson/forjson-nesting-vu-cleanup.sql new file mode 100644 index 0000000000..d91d5577e7 --- /dev/null +++ b/test/JDBC/input/forjson/forjson-nesting-vu-cleanup.sql @@ -0,0 +1,45 @@ +-- FOR JSON PATH CLAUSE with nested json support for existing objects +DROP VIEW forjson_nesting_vu_v_users +GO + +DROP VIEW forjson_nesting_vu_v_products +GO + +DROP VIEW forjson_nesting_vu_v_orders +GO + +-- FOR JSON PATH support for multiple layers of nested JSON objects +DROP VIEW forjson_nesting_vu_v_deep +GO + +-- FOR JSON PATH support for multiple layers of nested JSON objects w/ join +DROP VIEW forjson_nesting_vu_v_join_deep +GO + +-- FOR JSON PATH Support for key-values being inserted into mid layer of multi-layered JSON object +DROP VIEW forjson_nesting_vu_v_layered_insert +GO + +-- Error related to inserting value at Json object location +DROP VIEW forjson_nesting_vu_v_error +GO + +-- Queries that check NULL nested json object insert +DROP VIEW forjson_nesting_vu_v_no_null +GO + +DROP VIEW forjson_nesting_vu_v_with_null +GO + +-- DROP Tables +DROP TABLE forjson_nesting_vu_t_users +GO + +DROP TABLE forjson_nesting_vu_t_products +GO + +DROP TABLE forjson_nesting_vu_t_orders +GO + +DROP TABLE forjson_nesting_vu_t_null_users +GO \ No newline at end of file diff --git a/test/JDBC/input/forjson/forjson-nesting-vu-prepare.sql b/test/JDBC/input/forjson/forjson-nesting-vu-prepare.sql new file mode 100644 index 0000000000..013af8d17b --- /dev/null +++ b/test/JDBC/input/forjson/forjson-nesting-vu-prepare.sql @@ -0,0 +1,168 @@ +CREATE TABLE forjson_nesting_vu_t_users ( + [Id] int, + [firstname] varchar(50), + [lastname] varchar(50), + [email] varchar(50), +); +GO +CREATE TABLE forjson_nesting_vu_t_products ( + [Id] int, + [name] varchar(50), + [price] varchar (25) +); +GO +CREATE TABLE forjson_nesting_vu_t_orders ( + [Id] int, + [userid] int, + [productid] int, + [quantity] int, + [orderdate] Date +); +GO +CREATE TABLE forjson_nesting_vu_t_null_users ( + [Id] int, + [firstname] varchar(50), + [lastname] varchar(50), + [email] varchar(50), + [phone] varchar(25) +); +GO + +INSERT INTO forjson_nesting_vu_t_users +VALUES + (1, 'John', 'Doe', 'johndoe@gmail.com'), + (2, 'Jane', 'Smith', 'janesmith@yahoo.com'), + (3, 'Mike', 'Johnson', 'mikejohnson'); +GO + +INSERT INTO forjson_nesting_vu_t_products +VALUES + (1, 'Product A', '10.99'), + (2, 'Product B', '19.99'), + (3, 'Product C', '5.99'); +GO + +INSERT INTO forjson_nesting_vu_t_orders +VALUES + (1, 1, 1, 2, '2023-06-25'), + (2, 1, 2, 1, '2023-06-25'), + (3, 2, 3, 3, '2023-06-26'); +GO + +INSERT INTO forjson_nesting_vu_t_null_users +VALUES + (1, 'John', 'Doe', 'johndoe@gmail.com', '123-456-7890'), + (2, 'Jane', 'Smith', 'janesmith@yahoo.com', NULL), + (3, NULL, NULL, 'mikejohnson@myspace.com', '098-765-4321'), + (4, 'Sergio', 'Giavanni', NULL, NULL); +GO + +-- FOR JSON PATH CLAUSE with nested json support for existing objects +CREATE VIEW forjson_nesting_vu_v_users AS +SELECT ( + SELECT Id, + firstname AS "Name.first", + lastname AS "Name.last", + email + FROM forjson_nesting_vu_t_users + FOR JSON PATH +) c1 +GO + +CREATE VIEW forjson_nesting_vu_v_products AS +SELECT ( + SELECT Id, + name AS "Info.name", + price AS "Info.price" + FROM forjson_nesting_vu_t_products + FOR JSON PATH +) c1 +GO + +CREATE VIEW forjson_nesting_vu_v_orders AS +SELECT ( + SELECT Id AS "Id.orderid", + userid AS "Id.userid", + productid AS "Id.productid", + quantity AS "orderinfo.quantity", + orderdate AS "orderinfo.orderdate" + FROM forjson_nesting_vu_t_orders + FOR JSON PATH +) c1 +GO + +-- FOR JSON PATH support for multiple layers of nested JSON objects +CREATE VIEW forjson_nesting_vu_v_deep AS +SELECT ( + SELECT Id, + firstname AS "User.info.name.first", + lastname AS "User.info.name.last" + FROM forjson_nesting_vu_t_users + FOR JSON PATH +) c1 +GO + +-- FOR JSON PATH support for multiple layers of nested JSON objects w/ join +CREATE VIEW forjson_nesting_vu_v_join_deep AS +SELECT ( + SELECT U.Id "User.id", + O.quantity AS "User.order.info.quantity", + O.orderdate AS "User.order.info.orderdate" + FROM forjson_nesting_vu_t_users U + JOIN forjson_nesting_vu_t_orders O + ON (U.id = O.userid) + FOR JSON PATH +) c1 +GO + +-- FOR JSON PATH Support for key-values being inserted into mid layer of multi-layered JSON object +CREATE VIEW forjson_nesting_vu_v_layered_insert AS +SELECT ( + SELECT U.id, + O.id AS "Order.Orderid", + P.id AS "Order.Product.Productid", + O.orderdate AS "Order.date" + FROM forjson_nesting_vu_t_users U + JOIN forjson_nesting_vu_t_orders O + ON (U.id = O.userid) + JOIN forjson_nesting_vu_t_products P + ON (P.id = O.productid) + FOR JSON PATH +) c1 +GO + +-- Error related to inserting value at Json object location +CREATE VIEW forjson_nesting_vu_v_error AS +SELECT ( + SELECT id, + firstname AS "user.name", + lastname AS "user.name.last" + FROM forjson_nesting_vu_t_users + FOR JSON PATH +) +GO + +-- Queries that check NULL nested json object insert +CREATE VIEW forjson_nesting_vu_v_no_null AS +SELECT ( + SELECT id, + firstname AS "user.name.first", + lastname AS "user.name.last", + email AS "contact.email", + phone AS "contact.phone" + FROM forjson_nesting_vu_t_null_users + FOR JSON PATH +) +GO + +CREATE VIEW forjson_nesting_vu_v_with_null AS +SELECT ( + SELECT id, + firstname AS "user.name.first", + lastname AS "user.name.last", + email AS "contact.email", + phone AS "contact.phone" + FROM forjson_nesting_vu_t_null_users + FOR JSON PATH, INCLUDE_NULL_VALUES +) +GO diff --git a/test/JDBC/input/forjson/forjson-nesting-vu-verify.sql b/test/JDBC/input/forjson/forjson-nesting-vu-verify.sql new file mode 100644 index 0000000000..efb10e7cb2 --- /dev/null +++ b/test/JDBC/input/forjson/forjson-nesting-vu-verify.sql @@ -0,0 +1,43 @@ +-- Display Table Contents +SELECT * FROM forjson_nesting_vu_t_users +GO + +SELECT * FROM forjson_nesting_vu_t_products +GO + +SELECT * FROM forjson_nesting_vu_t_orders +GO + +-- FOR JSON PATH CLAUSE with nested json support for existing objects +SELECT * FROM forjson_nesting_vu_v_users +GO + +SELECT * FROM forjson_nesting_vu_v_products +GO + +SELECT * FROM forjson_nesting_vu_v_orders +GO + +-- FOR JSON PATH support for multiple layers of nested JSON objects +SELECT * FROM forjson_nesting_vu_v_deep +GO + +-- FOR JSON PATH support for multiple layers of nested JSON objects w/ join +SELECT * FROM forjson_nesting_vu_v_join_deep +GO + +-- FOR JSON PATH Support for key-values being inserted into mid layer of multi-layered JSON object +SELECT * FROM forjson_nesting_vu_v_layered_insert +GO + +-- Error related to inserting value at Json object location +SELECT * FROM forjson_nesting_vu_v_error +GO + +-- Queries that check NULL nested json object insert +SELECT * FROM forjson_nesting_vu_v_no_null +GO + +SELECT * FROM forjson_nesting_vu_v_with_null +GO + diff --git a/test/JDBC/input/forjson/forjson-subquery-before-14_10-or-15_5-vu-cleanup.sql b/test/JDBC/input/forjson/forjson-subquery-before-14_10-or-15_5-vu-cleanup.sql new file mode 100644 index 0000000000..e30cb1bd5b --- /dev/null +++ b/test/JDBC/input/forjson/forjson-subquery-before-14_10-or-15_5-vu-cleanup.sql @@ -0,0 +1,55 @@ +-- FOR JSON AUTO clause not supported +DROP VIEW forjson_subquery_vu_v_auto +GO + +-- Alias/colname is not present +DROP VIEW forjson_subquery_vu_v_no_alias +GO + +DROP VIEW forjson_subquery_vu_v_with +GO + +DROP VIEW forjson_subquery_vu_v_with_order_by +GO + +-- Binary strings +DROP VIEW forjson_subquery_vu_v_binary_strings +GO + +DROP VIEW forjson_subquery_vu_v_varbinary_strings +GO + +-- Rowversion and timestamp +DROP VIEW forjson_subquery_vu_v_rowversion +GO + +DROP VIEW forjson_subquery_vu_v_timestamp +GO + +-- BABEL-3569/BABEL-3690 return 0 rows for empty rowset +DROP PROCEDURE forjson_subquery_vu_p_empty +GO + +-- exercise tsql_select_for_json_result internal function +DROP VIEW forjson_subquery_vu_v_internal +GO + +DROP TABLE forjson_subquery_vu_t_countries +GO + +DROP TABLE forjson_subquery_vu_t1 +GO + +-- Binary strings +DROP TABLE forjson_subquery_vu_t_binary_strings +GO + +-- Rowversion and timestamp +DROP TABLE forjson_subquery_vu_t_rowversion +GO + +DROP TABLE forjson_subquery_vu_t_timestamp +GO + +EXEC sp_babelfish_configure 'babelfishpg_tsql.escape_hatch_rowversion', 'strict'; +GO \ No newline at end of file diff --git a/test/JDBC/input/forjson/forjson-subquery-before-14_10-or-15_5-vu-prepare.sql b/test/JDBC/input/forjson/forjson-subquery-before-14_10-or-15_5-vu-prepare.sql new file mode 100644 index 0000000000..9eeb1b1900 --- /dev/null +++ b/test/JDBC/input/forjson/forjson-subquery-before-14_10-or-15_5-vu-prepare.sql @@ -0,0 +1,137 @@ +-- 14.7 (aka extension version 2.4.0) has a major change to how FOR JSON +-- has been implemented, which slightly changes the behavior around some old error +-- messages as well, so we need to move those tests to a new test file that separately +-- exercises them outside of the pre-14.6 upgrade tests. + +CREATE TABLE forjson_subquery_vu_t_countries ( +[Id] INT, +[Age] INT, +[Country] VARCHAR(25)) +GO + +INSERT INTO forjson_subquery_vu_t_countries values +(1,25, 'India'), +(2,40, 'USA'), +(3,30, 'India'), +(4,20, NULL), +(5,10, 'USA') +GO + +create table forjson_subquery_vu_t1 (x int) +insert into forjson_subquery_vu_t1 values (1) +go + +-- FOR JSON AUTO clause not supported +CREATE VIEW forjson_subquery_vu_v_auto AS +SELECT ( + SELECT Id, + State + FROM forjson_subquery_vu_t1 + FOR JSON AUTO +) c1 +GO + +-- Alias/colname not present +CREATE VIEW forjson_subquery_vu_v_no_alias AS +SELECT ( + SELECT 2 + FOR JSON PATH +) c1 +GO + +CREATE VIEW forjson_subquery_vu_v_with AS +WITH forjson_subquery_vu_with1(avg_age) AS ( + SELECT avg(Age) + FROM forjson_subquery_vu_t_countries +) +SELECT ( + SELECT Id, Age, Country + FROM forjson_subquery_vu_t_countries, forjson_subquery_vu_with1 + WHERE Age >= forjson_subquery_vu_with1.avg_age + FOR JSON PATH +) C1 +GO + +CREATE VIEW forjson_subquery_vu_v_with_order_by AS +WITH forjson_subquery_vu_with2(avg_age) AS ( + SELECT avg(Age) + FROM forjson_subquery_vu_t_countries +) +SELECT ( + SELECT Id, Age, Country + FROM forjson_subquery_vu_t_countries, forjson_subquery_vu_with2 + WHERE Age >= forjson_subquery_vu_with2.avg_age + ORDER BY Country + FOR JSON PATH +) c1 +GO + +-- Binary strings +CREATE TABLE forjson_subquery_vu_t_binary_strings(abinary binary, avarbinary varbinary(10)) +GO +INSERT forjson_subquery_vu_t_binary_strings VALUES (123456,0x0a0b0c0d0e) +GO + +-- Rowversion and timestamp +EXEC sp_babelfish_configure 'babelfishpg_tsql.escape_hatch_rowversion', 'ignore'; +GO + +CREATE TABLE forjson_subquery_vu_t_rowversion (myKey int, myValue int,RV rowversion); +GO +INSERT INTO forjson_subquery_vu_t_rowversion (myKey, myValue) VALUES (1, 0); +GO + +CREATE TABLE forjson_subquery_vu_t_timestamp (myKey int, myValue int, timestamp); +GO +INSERT INTO forjson_subquery_vu_t_timestamp (myKey, myValue) VALUES (1, 0); +GO + +-- Binary strings +CREATE VIEW forjson_subquery_vu_v_binary_strings AS +SELECT +( + SELECT abinary + FROM forjson_subquery_vu_t_binary_strings + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_subquery_vu_v_varbinary_strings AS +SELECT +( + SELECT avarbinary + FROM forjson_subquery_vu_t_binary_strings + FOR JSON PATH +) as c1; +GO + +-- Rowversion and timestamp +CREATE VIEW forjson_subquery_vu_v_rowversion AS +SELECT +( + SELECT * + FROM forjson_subquery_vu_t_rowversion + FOR JSON PATH +) as c1; +GO + +CREATE VIEW forjson_subquery_vu_v_timestamp AS +SELECT +( + SELECT * + FROM forjson_subquery_vu_t_timestamp + FOR JSON PATH +) as c1; +GO + +-- BABEL-3569/BABEL-3690 return 0 rows for empty rowset +CREATE PROCEDURE forjson_subquery_vu_p_empty AS +SELECT * FROM forjson_subquery_vu_t_countries + WHERE 1 = 0 + FOR JSON PATH +GO + +-- exercise tsql_select_for_json_result internal function +CREATE VIEW forjson_subquery_vu_v_internal AS +SELECT * FROM tsql_select_for_json_result('abcd') +GO diff --git a/test/JDBC/input/forjson/forjson-subquery-before-14_10-or-15_5-vu-verify.sql b/test/JDBC/input/forjson/forjson-subquery-before-14_10-or-15_5-vu-verify.sql new file mode 100644 index 0000000000..eec0a9ad98 --- /dev/null +++ b/test/JDBC/input/forjson/forjson-subquery-before-14_10-or-15_5-vu-verify.sql @@ -0,0 +1,38 @@ +-- FOR JSON AUTO clause not supported +SELECT * FROM forjson_subquery_vu_v_auto +GO + +-- Alias/colname is not present +SELECT * FROM forjson_subquery_vu_v_no_alias +GO + +SELECT * FROM forjson_subquery_vu_v_with +GO + +SELECT * FROM forjson_subquery_vu_v_with_order_by +GO + +-- Binary strings +SELECT * FROM forjson_subquery_vu_v_binary_strings +GO + +SELECT * FROM forjson_subquery_vu_v_varbinary_strings +GO + +-- Rowversion and timestamp +SELECT * FROM forjson_subquery_vu_v_rowversion +GO + +SELECT * FROM forjson_subquery_vu_v_timestamp +GO + +-- BABEL-3569/BABEL-3690 return 0 rows for empty rowset +EXEC forjson_subquery_vu_p_empty +GO + +SELECT @@rowcount +GO + +-- exercise tsql_select_for_json_result internal function +SELECT * FROM forjson_subquery_vu_v_internal +GO \ No newline at end of file diff --git a/test/JDBC/input/forjson/forjson-vu-verify.sql b/test/JDBC/input/forjson/forjson-vu-verify.sql index e0c3879c41..b0fa58207a 100644 --- a/test/JDBC/input/forjson/forjson-vu-verify.sql +++ b/test/JDBC/input/forjson/forjson-vu-verify.sql @@ -8,14 +8,14 @@ GO SELECT * FROM forjson_vu_t_values GO --- FOR JSON PATH clause without nested support +-- FOR JSON PATH clause with nested support SELECT * FROM forjson_vu_v_people GO SELECT * FROM forjson_vu_v_countries GO --- Multiple tables without nested support +-- Multiple tables with nested support SELECT * FROM forjson_vu_v_join GO diff --git a/test/JDBC/upgrade/14_6/schedule b/test/JDBC/upgrade/14_6/schedule index 0cf2a2d539..ca3baf9175 100644 --- a/test/JDBC/upgrade/14_6/schedule +++ b/test/JDBC/upgrade/14_6/schedule @@ -135,8 +135,8 @@ BABEL-3748-before-14_7 BABEL-383 BABEL-405 BABEL-937 -forjson -forjson-datatypes +forjson-before-14_10-or-15_5 +forjson-datatypes-before-14_10-or-15_5 forxml BABEL-PROCID babel_trigger diff --git a/test/JDBC/upgrade/latest/schedule b/test/JDBC/upgrade/latest/schedule index 6be12d2792..3c4d151f2c 100644 --- a/test/JDBC/upgrade/latest/schedule +++ b/test/JDBC/upgrade/latest/schedule @@ -143,6 +143,7 @@ BABEL-937 forjson forjson-subquery forjson-datatypes +forjson-nesting forxml forxml-subquery BABEL-PROCID