diff --git a/contrib/babelfishpg_tsql/src/backend_parser/gram-tsql-epilogue.y.c b/contrib/babelfishpg_tsql/src/backend_parser/gram-tsql-epilogue.y.c index 4a2423507b..d3e4317fa7 100644 --- a/contrib/babelfishpg_tsql/src/backend_parser/gram-tsql-epilogue.y.c +++ b/contrib/babelfishpg_tsql/src/backend_parser/gram-tsql-epilogue.y.c @@ -2072,6 +2072,8 @@ tsql_unpivot_debug_transformation(List *components) //List *unpivot_cols; char *measure_colname; char *dim_colname; + char *inner_alias_name; + /* Extract components */ @@ -2155,7 +2157,8 @@ tsql_unpivot_debug_transformation(List *components) strcmp(strVal(linitial(prev_unpivot)), "UNPIVOT") == 0) { /* Use the alias from previous UNPIVOT */ - source_alias = strVal(list_nth(prev_unpivot, 4)); + //source_alias = strVal(list_nth(prev_unpivot, 1)); + source_alias = strVal(list_nth(prev_unpivot, 1)); /* Use the transformed node as our left arg */ //n->larg = (Node *)list_nth(prev_unpivot, 5); @@ -2174,7 +2177,8 @@ tsql_unpivot_debug_transformation(List *components) errmsg("Invalid source structure for UNPIVOT operation"))); } n->larg = table_ref; - /* Build VALUES list from source columns */ + + /* Build VALUES list from source columns */ foreach(lc, source_cols) { String *col_name = (String *)lfirst(lc); @@ -2203,37 +2207,28 @@ tsql_unpivot_debug_transformation(List *components) values_subquery->valuesLists = values_list; rarg->subquery = (Node *)values_subquery; - /* Handle alias for VALUES clause */ - /* TODO: can remove check or add error: UNPIVOT table alias cannot be NULL - throw error in parser rule body if alias is NULL */ + /* Handle alias for Join-Values (RangeSubSelect) clause */ + inner_alias_name = psprintf("%s_1", alias->aliasname); if (alias != NULL) { - rarg->alias = alias; - /* Add column names if not specified */ - /* TODO: alias->colnames wont exist in the alias object of UNPIVOT stmt so can remove check*/ - if (rarg->alias->colnames == NIL) - { - rarg->alias->colnames = list_make2( - makeString(measure_colname), - makeString(dim_colname) - ); - } + rarg->alias = makeAlias(inner_alias_name, list_make2( + makeString(measure_colname), + makeString(dim_colname) + ) + ); } else { - /* Create default alias if none provided */ - rarg->alias = makeAlias( - "unpvt", - list_make2( - makeString(measure_colname), - makeString(dim_colname) - ) - ); + ereport(ERROR, + (errcode(ERRCODE_SYNTAX_ERROR), + errmsg("Alias for UNPIVOT operation is required."))); } n->rarg = (Node *)rarg; n->usingClause = NIL; n->quals = NULL; + /* Rewrite by adding unpivot alias as the complete Join operation alias */ + n->alias = alias; elog(DEBUG1, "Final transformed node: %s", nodeToString((Node *)n)); @@ -2249,7 +2244,7 @@ tsql_unpivot_debug_transformation(List *components) /* Create result info list */ result_info = list_make5( makeString("UNPIVOT"), - makeString(rarg->alias->aliasname), /* unpivot alias and its columns: */ + makeString(alias->aliasname), /* unpivot alias and its columns: */ makeString(dim_colname), /* dimension column */ makeString(measure_colname), /* measure column */ makeString(source_alias) /* source table/query alias */ diff --git a/contrib/babelfishpg_tsql/src/hooks.c b/contrib/babelfishpg_tsql/src/hooks.c index 95c21b4ac4..5c51c0c958 100644 --- a/contrib/babelfishpg_tsql/src/hooks.c +++ b/contrib/babelfishpg_tsql/src/hooks.c @@ -139,7 +139,7 @@ static SortByNulls unique_constraint_nulls_ordering(ConstrType constraint_type, SortByDir ordering); static void transform_pivot_clause(ParseState *pstate, SelectStmt *stmt); static void transform_unpivot_clause(ParseState *pstate, SelectStmt *stmt); -static void transform_unpivot_clause_recursive(Node **node, Node **where_clause); +static void transform_unpivot_clause_recursive(Node **node, Node **where_clause, List **dim_cols, char **outer_alias); /***************************************** * Commands Hooks *****************************************/ @@ -5325,181 +5325,66 @@ transform_pivot_clause(ParseState *pstate, SelectStmt *stmt) wrapperSelect_RangeFunction->functions = list_make1(list_make2((Node *) pivot_func, NIL)); } -// static List * -// handle_unpivot_star_expansion(ParseState *pstate, SelectStmt *stmt, -// List *source_cols, char *unpivot_alias, -// char *measure_colname, char *dim_colname, -// char *source_table_alias) -// { -// Query *temp_src_query; -// List *temp_src_targetlist; -// List *new_targetlist = NIL; -// List *used_names = NIL; -// bool has_ambiguous_refs = false; - -// /* First analyze the source query to get correct target list */ -// temp_src_query = parse_sub_analyze((Node *) stmt->srcSql, pstate, NULL, -// false, false); -// temp_src_targetlist = temp_src_query->targetList; - -// /* First pass: check for ambiguous references */ -// for (int i = 0; i < temp_src_targetlist->length; i++) -// { -// TargetEntry *tempEntry = list_nth_node(TargetEntry, temp_src_targetlist, i); -// char *colName = tempEntry->resname; -// ListCell *lc; - -// foreach(lc, used_names) -// { -// if (strcmp(colName, strVal(lfirst(lc))) == 0) -// { -// has_ambiguous_refs = true; -// break; -// } -// } -// used_names = lappend(used_names, makeString(colName)); -// } - -// /* Get the targetList of the source table excluding unpivot columns */ -// for (int i = 0; i < temp_src_targetlist->length; i++) -// { -// ResTarget *tempResTarget; -// TargetEntry *tempEntry = list_nth_node(TargetEntry, temp_src_targetlist, i); -// char *colName = tempEntry->resname; -// bool skip_column = false; -// ListCell *source_lc; -// List *col_fields = NIL; - -// /* Skip if column is in source_cols list */ -// foreach(source_lc, source_cols) -// { -// String *source_col = (String *) lfirst(source_lc); -// if (strcmp(colName, strVal(source_col)) == 0) -// { -// skip_column = true; -// break; -// } -// } - -// if (!skip_column) -// { -// /* Handle ambiguous references by qualifying with table alias */ -// if (has_ambiguous_refs && source_table_alias) -// { -// col_fields = list_make2( -// makeString(source_table_alias), -// makeString(colName) -// ); -// } -// else -// { -// col_fields = list_make1(makeString(colName)); -// } - -// /* prepare target list entry */ -// tempResTarget = make_restarget_from_cstr_list(col_fields); - -// /* Set explicit column name to avoid ambiguity in output */ -// if (has_ambiguous_refs && source_table_alias) -// { -// tempResTarget->name = psprintf("%s_%s", -// source_table_alias, -// colName); -// } - -// new_targetlist = lappend(new_targetlist, tempResTarget); -// } -// } - -// /* Add measure and dimension columns */ -// { -// ResTarget *measure_res = makeNode(ResTarget); -// ResTarget *dim_res = makeNode(ResTarget); -// ColumnRef *measure_cref = makeNode(ColumnRef); -// ColumnRef *dim_cref = makeNode(ColumnRef); - -// /* Add measure column with explicit alias */ -// measure_cref->fields = list_make2( -// makeString(unpivot_alias), -// makeString(measure_colname)); -// measure_cref->location = -1; -// measure_res->name = measure_colname; /* Explicit name */ -// measure_res->indirection = NIL; -// measure_res->val = (Node *) measure_cref; -// measure_res->location = -1; - -// /* Add dimension column with explicit alias */ -// dim_cref->fields = list_make2( -// makeString(unpivot_alias), -// makeString(dim_colname)); -// dim_cref->location = -1; -// dim_res->name = dim_colname; /* Explicit name */ -// dim_res->indirection = NIL; -// dim_res->val = (Node *) dim_cref; -// dim_res->location = -1; - -// new_targetlist = lappend(new_targetlist, measure_res); -// new_targetlist = lappend(new_targetlist, dim_res); -// } - -// list_free(used_names); -// return new_targetlist; -// } - static void transform_unpivot_clause(ParseState *pstate, SelectStmt *stmt) { Node *where_clause = stmt->whereClause; - // Node *srcSql = (Node *) copyObject(stmt->srcSql); ListCell *lc; - // Query *temp_query; - // List *temp_targetlist; - // ListCell *tl; + List *dim_cols = NIL; + char *outer_alias = NULL; foreach(lc, stmt->fromClause) { - transform_unpivot_clause_recursive((Node**)&(lc->ptr_value), &where_clause); + transform_unpivot_clause_recursive((Node**)&(lc->ptr_value), &where_clause, &dim_cols, &outer_alias); } - // temp_query = parse_sub_analyze(srcSql, - // pstate, - // NULL, - // false, - // false - // ); - - // temp_targetlist = temp_query->targetList; - - // /* Print each target entry */ - // elog(NOTICE, "Target List Entries:"); - // foreach(tl, temp_targetlist) - // { - // TargetEntry *te = (TargetEntry *) lfirst(tl); - // elog(NOTICE, "Column: %s, ResNo: %d", - // te->resname ? te->resname : "unnamed", - // te->resno); - - // /* Print more details about the expression */ - // if (te->expr) - // { - // elog(NOTICE, "Expression type: %d", nodeTag(te->expr)); - // elog(NOTICE, "Expression dump: %s", nodeToString(te->expr)); - // } - // } + /* Create IS NOT NULL where conditions for all collected columns */ + if (outer_alias != NULL && dim_cols != NIL) + { + foreach(lc, dim_cols) + { + char *measure_col = strVal(lfirst(lc)); + ColumnRef *measure_ref; + NullTest *null_test; + + /* Create IS NOT NULL condition */ + measure_ref = makeNode(ColumnRef); + measure_ref->fields = list_make2(makeString(outer_alias), + makeString(measure_col)); + measure_ref->location = -1; + + null_test = makeNode(NullTest); + null_test->arg = (Expr *)measure_ref; + null_test->nulltesttype = IS_NOT_NULL; + null_test->argisrow = false; + null_test->location = -1; + + /* Add to WHERE clause */ + if (where_clause) + { + BoolExpr *bool_expr = makeNode(BoolExpr); + bool_expr->boolop = AND_EXPR; + bool_expr->args = list_make2(where_clause, null_test); + bool_expr->location = -1; + where_clause = (Node *)bool_expr; + } + else + { + where_clause = (Node *)null_test; + } + } + } stmt->whereClause = where_clause; } -static void transform_unpivot_clause_recursive(Node **node_ptr, Node **where_clause) +static void transform_unpivot_clause_recursive(Node **node_ptr, Node **where_clause, List **dim_cols, char **outer_alias) { JoinExpr *join; List *unpivot_info; char *unpivot_alias; char *measure_col; Node *transformed_node; - ColumnRef *measure_ref; - NullTest *null_test; - BoolExpr *bool_expr; if (node_ptr == NULL || *node_ptr == NULL) return; @@ -5507,8 +5392,8 @@ static void transform_unpivot_clause_recursive(Node **node_ptr, Node **where_cla if (IsA(*node_ptr, JoinExpr)) { join = (JoinExpr *)*node_ptr; - transform_unpivot_clause_recursive(&join->larg, where_clause); - transform_unpivot_clause_recursive(&join->rarg, where_clause); + transform_unpivot_clause_recursive(&join->larg, where_clause, dim_cols, outer_alias); + transform_unpivot_clause_recursive(&join->rarg, where_clause, dim_cols, outer_alias); } else if (IsA(*node_ptr, List)) { @@ -5521,34 +5406,19 @@ static void transform_unpivot_clause_recursive(Node **node_ptr, Node **where_cla measure_col = strVal(list_nth(unpivot_info,3)); transformed_node = list_nth(unpivot_info, 5); - /* Create IS NOT NULL condition */ - measure_ref = makeNode(ColumnRef); - measure_ref->fields = list_make2(makeString(unpivot_alias), makeString(measure_col)); - measure_ref->location = -1; + /* Update outer_alias with most recent alias */ - null_test = makeNode(NullTest); - null_test->arg = (Expr *)measure_ref; - null_test->nulltesttype = IS_NOT_NULL; - null_test->argisrow = false; - null_test->location = -1; - - /* Add to WHERE clause */ - if (*where_clause) + if (*outer_alias == NULL) { - bool_expr = makeNode(BoolExpr); - bool_expr->boolop = AND_EXPR; - bool_expr->args = list_make2(*where_clause, null_test); - bool_expr->location = -1; - *where_clause = (Node *)bool_expr; - } - else - { - *where_clause = (Node *)null_test; + *outer_alias = pstrdup(unpivot_alias); // Allocate memory for the string } + /* Add this measure column to the list */ + *dim_cols = lappend(*dim_cols, makeString(measure_col)); + /* Replace UNPIVOT info with transformed node and recurse on it */ *node_ptr = transformed_node; - transform_unpivot_clause_recursive(node_ptr, where_clause); + transform_unpivot_clause_recursive(node_ptr, where_clause, dim_cols, outer_alias); } } } diff --git a/test/JDBC/input/unpivot-vu-cleanup.sql b/test/JDBC/input/unpivot-vu-cleanup.sql new file mode 100644 index 0000000000..e69de29bb2 diff --git a/test/JDBC/input/unpivot-vu-prepare.sql b/test/JDBC/input/unpivot-vu-prepare.sql new file mode 100644 index 0000000000..b8a1cfeb28 --- /dev/null +++ b/test/JDBC/input/unpivot-vu-prepare.sql @@ -0,0 +1,124 @@ +CREATE TABLE customer_turnover ( + customer_id INT, + customer_desc VARCHAR(50), + customer_type CHAR(1), + q1 INT, q2 INT, q3 INT, q4 INT +); +GO + +INSERT INTO customer_turnover VALUES + (1, 'Cust A', 'R', 100, 200, 300, 400), + (2, 'Cust B', 'P', 150, 250, 350, 450), + (3, 'Cust C', 'R', NULL, 0, 400, 500); +GO + +CREATE TABLE sales_data ( + product_id INT, + q1_sales INT, + q2_sales INT, + q1_region VARCHAR(50), + q2_region VARCHAR(50) +); +GO + +INSERT INTO sales_data VALUES + (1, 100, 150, 'North', 'South'), + (2, 200, 250, 'East', 'West'), + (3, NULL, 350, 'Central', 'East'); +GO + +CREATE TABLE product_sales ( + product_id INT, + quantity_q1 INT, revenue_q1 DECIMAL(10,2), + quantity_q2 INT, revenue_q2 DECIMAL(10,2) +); +GO + +INSERT INTO product_sales VALUES + (1, 100, 1000.00, 150, 1500.00), + (2, 80, 1600.00, 90, 1800.00), + (3, 0, 0, NULL, NULL); +GO + +CREATE TABLE customer_info ( + customer_id INT PRIMARY KEY, + customer_name VARCHAR(100), + customer_segment VARCHAR(50) +); +GO + +CREATE TABLE product_info ( + product_id INT, + product_name VARCHAR(50) +); +GO + +INSERT INTO customer_info (customer_id, customer_name, customer_segment) +VALUES +(1, 'John Doe', 'Premium'), +(2, 'Jane Smith', 'Standard'), +(3, 'Bob Johnson', 'Premium'); +GO + +INSERT INTO product_info VALUES + (1, 'Widget'), + (2, 'Gadget'); +GO + +CREATE TABLE product_performance ( + product_id INT, + product_name VARCHAR(50), + sales_q1 INT, + sales_q2 INT, + profit_q1 DECIMAL(10,2), + profit_q2 DECIMAL(10,2), + region VARCHAR(20) +); +GO + +INSERT INTO product_performance VALUES + (1, 'Laptop', 100, 150, 1000.00, 1500.00, 'North'), + (2, 'Desktop', 80, 120, 800.00, 1200.00, 'South'), + (3, 'Tablet', 200, 250, 2000.00, 2500.00, 'East'), + (4, 'Phone', NULL, 0, NULL, 0, 'West'); +GO + + + +CREATE TABLE sales_data1 ( + product_id INT, + q1_sales INT, + q2_sales INT, + q3_sales INT +); +GO +CREATE TABLE inventory_data ( + product_id INT, + q1_stock INT, + q2_stock INT, + q3_stock INT +); +GO + +-- Insert sample data +INSERT INTO sales_data1 VALUES + (1, 100, 200, 300), + (2, 150, 250, 350), + (3, 120, 220, NULL); +GO + +INSERT INTO inventory_data VALUES + (1, 500, 400, 300), + (2, 600, 500, 400), + (3, 550, 450, 350); +GO + +-- for insert unpivot +CREATE TABLE quarterly_sales +( + customer_id INT, + customer_desc VARCHAR(50), + quarter VARCHAR(2), + sales_value INT +); +GO \ No newline at end of file diff --git a/test/JDBC/input/unpivot-vu-verify.sql b/test/JDBC/input/unpivot-vu-verify.sql new file mode 100644 index 0000000000..a436e9f227 --- /dev/null +++ b/test/JDBC/input/unpivot-vu-verify.sql @@ -0,0 +1,247 @@ +-- Basic unpivot without targetlist aliases +SELECT customer_id, turnover, quarter +FROM customer_turnover +UNPIVOT ( + turnover FOR quarter IN (q1, q2, q3, q4) +) AS unpvt; + + +SELECT unpvt.customer_id, unpvt.turnover, unpvt.quarter +FROM customer_turnover +UNPIVOT ( + turnover FOR quarter IN (q1, q2, q3, q4) +) AS unpvt; +GO + +SELECT * +FROM customer_turnover k +UNPIVOT ( + turnover FOR quarter IN (q1, q2, q3, q4) +) AS unpvt; +GO + +-- Subquery as source +SELECT customer_id, turnover, quarter +FROM ( + SELECT customer_id, q1, q2, q3, q4 + FROM customer_turnover + WHERE q2 > 120 +) AS source_data +UNPIVOT ( + turnover FOR quarter IN (q1, q2, q3, q4) +) AS unpvt; +GO + +-- Join as source +SELECT p.product_name, u.customer_desc, u.turnover, u.quarter +FROM product_info p +JOIN customer_turnover c +UNPIVOT ( + turnover FOR quarter IN (q1, q2, q3, q4) +) AS u ON p.product_id = u.customer_id; + +-- with TOP +SELECT TOP 5 + customer_id, + quarter, + turnover +FROM customer_turnover +UNPIVOT +( + turnover + FOR quarter IN (q1, q2, q3, q4) +) AS unpivoted_data +ORDER BY turnover DESC; +GO + + + +-- Consecutive unpivots +SELECT product_id, sales, quarter, region, region_quarter +FROM sales_data +UNPIVOT ( sales FOR quarter IN (q1_sales, q2_sales)) AS sales_unpvt +UNPIVOT ( region FOR region_quarter IN (q1_region, q2_region)) AS region_unpvt; +GO + +SELECT + product_id AS PID, + RIGHT(col_name, 2) as quarter, + quantity, + revenue +FROM product_sales p +UNPIVOT ( quantity for col_name in (quantity_q1, quantity_q2) ) AS q +UNPIVOT ( revenue for col_name1 in (revenue_q1, revenue_q2) ) AS r +WHERE RIGHT(col_name, 2) = RIGHT(col_name1, 2) ; +GO + + +SELECT + r.product_id AS PID, + RIGHT(r.col_name, 2) as quarter, + r.quantity, + r.revenue +FROM product_sales p +UNPIVOT (quantity for col_name in (quantity_q1, quantity_q2)) AS q +UNPIVOT (revenue for col_name1 in (revenue_q1, revenue_q2)) AS r +WHERE RIGHT(r.col_name, 2) = RIGHT(r.col_name1, 2); +GO + +SELECT + r.product_id AS PID, + RIGHT(r.col_name, 2) as quarter, + r.quantity, + r.revenue +FROM +( + ( product_sales p + + CROSS JOIN LATERAL ( VALUES + (P.quantity_q1, 'quantity_q1'), + (P.quantity_q2, 'quantity_q2') + ) q1(quantity, col_name) + ) AS q + +CROSS JOIN LATERAL ( VALUES + (q.revenue_q1, 'revenue_q1'), (q.revenue_q2, 'revenue_q2') + ) r1(revenue, col_name1) +) AS r + +WHERE RIGHT(r.col_name, 2) + = RIGHT(r.col_name1, 2) + AND r.quantity is NOT NULL + AND r.revenue is NOT NULL; + + + + + -- Create view with UNPIVOT +CREATE VIEW vw_quarterly_sales AS +SELECT + product_id, + product_name, + RIGHT(sales_quarter, 2) as quarter, + sales_value, + profit_value, + region +FROM product_performance +UNPIVOT ( + sales_value FOR sales_quarter IN (sales_q1, sales_q2) +) AS sales_unpvt +UNPIVOT ( + profit_value FOR profit_quarter IN (profit_q1, profit_q2) +) AS profit_unpvt +WHERE RIGHT(sales_quarter, 2) = RIGHT(profit_quarter, 2); +GO + +SELECT * from vw_quarterly_sales; +GO + +CREATE VIEW sales_vw AS +SELECT + product_id, + product_name, + sales_value, + RIGHT(quarter_col, 2) as quarter, + region +FROM product_performance +UNPIVOT ( + sales_value FOR quarter_col IN (sales_q1, sales_q2) +) AS unpvt; +GO + +SELECT * from sales_vw; +GO + +-- Query using CTE with UNPIVOT +WITH sales_unpivoted AS ( + SELECT + product_id, + product_name, + sales_value, + RIGHT(quarter_col, 2) as quarter, + region + FROM product_performance + UNPIVOT ( + sales_value FOR quarter_col IN (sales_q1, sales_q2) + ) AS unpvt +) +SELECT + s.product_id, + s.product_name, + s.quarter, + s.sales_value, + s.region, + AVG(s.sales_value) OVER (PARTITION BY s.region) as avg_regional_sales +FROM sales_unpivoted s; +GO + +-- Simple UNPIVOT-JOIN-UNPIVOT query +SELECT + s.product_id, + s.quarter as sales_quarter, + s.sales, + i.stock, + i.quarter as inventory_quarter +FROM + (SELECT product_id, sales, quarter + FROM sales_data1 + UNPIVOT (sales FOR quarter IN (q1_sales, q2_sales, q3_sales)) AS sales_unpvt) s +JOIN + (SELECT product_id, stock, quarter + FROM inventory_data + UNPIVOT (stock FOR quarter IN (q1_stock, q2_stock, q3_stock)) AS inv_unpvt) i +ON s.product_id = i.product_id +AND LEFT(s.quarter, 2) = LEFT(i.quarter, 2) +ORDER BY s.product_id, s.quarter; + + +-- Testing insert: +INSERT INTO quarterly_sales (customer_id, customer_desc, quarter, sales_value) +SELECT customer_id, + customer_desc, + quarter, + sales_value +FROM customer_turnover +UNPIVOT +( + sales_value + FOR quarter IN (q1, q2, q3, q4) +) AS unpvt; +GO + +SELECT * from quarterly_sales; +GO + + +-- Errors: + + -- alias mismatch, columns should not be found +SELECT + p.product_id AS PID, + RIGHT(q.col_name, 2) as quarter, + q.quantity, + r.revenue +FROM product_sales p +UNPIVOT (quantity for col_name in (quantity_q1, quantity_q2)) AS q +UNPIVOT (revenue for col_name1 in (revenue_q1, revenue_q2)) AS r +WHERE RIGHT(q.col_name, 2) = RIGHT(r.col_name1, 2); + +error: +SELECT c.customer_id, unpvt.turnover, unpvt.quarter +FROM customer_turnover c +UNPIVOT ( + turnover FOR quarter IN (q1, q2, q3, q4) +) AS unpvt; +GO + +error: +SELECT + p.product_id AS PID, + RIGHT(q.col_name, 2) as quarter, + q.quantity, + r.revenue +FROM product_sales p +UNPIVOT ( quantity for col_name in (quantity_q1, quantity_q2) ) AS q +UNPIVOT ( revenue for col_name1 in (revenue_q1, revenue_q2) ) AS r +WHERE RIGHT(q.col_name, 2) = RIGHT(r.col_name1, 2) ; +GO