Skip to content

Commit

Permalink
MDEV-15073: Generic UDAF parser code in server for windows functions
Browse files Browse the repository at this point in the history
Added support for usual agreggate UDF (UDAF)
Added remove() call support for more efficient window function processing
Added example of aggregate UDF with efficient windows function support
  • Loading branch information
sanja-byelkin committed Nov 27, 2018
1 parent a956260 commit 555921a
Show file tree
Hide file tree
Showing 10 changed files with 386 additions and 0 deletions.
105 changes: 105 additions & 0 deletions mysql-test/main/udf.result
Expand Up @@ -465,3 +465,108 @@ a b
Hello HL
DROP FUNCTION METAPHON;
DROP TABLE t1;

MDEV-15073: Generic UDAF parser code in server for windows functions

CREATE AGGREGATE FUNCTION avgcost
RETURNS REAL SONAME "UDF_EXAMPLE_LIB";
CREATE AGGREGATE FUNCTION avg2
RETURNS REAL SONAME "UDF_EXAMPLE_LIB";
CREATE FUNCTION myfunc_double RETURNS REAL SONAME "UDF_EXAMPLE_LIB";
create table t1(pk int primary key,
a int,
sum int,
price float(24));
insert into t1 values
(1, 1, 100, 50.00),
(2, 1, 100, 100.00),
(3, 1, 100, 50.00),
(4, 1, 100, 50.00),
(5, 1, 100, 50.00),
(6, 1, 100, NULL),
(7, 1, NULL, NULL),
(8, 2, 2, 2),
(9, 2, 4, 4);
select pk, a, sum, price, avgcost(sum, price) over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 1 FOLLOWING)
from t1;
pk a sum price avgcost(sum, price) over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 1 FOLLOWING)
1 1 100 50 75.0000
2 1 100 100 66.6667
3 1 100 50 66.6667
4 1 100 50 50.0000
5 1 100 50 50.0000
6 1 100 NULL 50.0000
7 1 NULL NULL 0.0000
8 2 2 2 3.3333
9 2 4 4 3.3333
select pk, a, sum, price, avgcost(sum, price) over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 0 FOLLOWING)
from t1;
pk a sum price avgcost(sum, price) over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 0 FOLLOWING)
1 1 100 50 50.0000
2 1 100 100 75.0000
3 1 100 50 75.0000
4 1 100 50 50.0000
5 1 100 50 50.0000
6 1 100 NULL 50.0000
7 1 NULL NULL 0.0000
8 2 2 2 2.0000
9 2 4 4 3.3333
select pk, a, sum, price, avg2(sum, price) over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 1 FOLLOWING)
from t1;
pk a sum price avg2(sum, price) over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 1 FOLLOWING)
1 1 100 50 0.7500
2 1 100 100 0.6667
3 1 100 50 0.6667
4 1 100 50 0.5000
5 1 100 50 0.5000
6 1 100 NULL 0.5000
7 1 NULL NULL 0.0000
8 2 2 2 1.0000
9 2 4 4 1.0000
select pk, a, sum, price, avg2(sum, price) over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 0 FOLLOWING)
from t1;
pk a sum price avg2(sum, price) over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 0 FOLLOWING)
1 1 100 50 0.5000
2 1 100 100 0.7500
3 1 100 50 0.7500
4 1 100 50 0.5000
5 1 100 50 0.5000
6 1 100 NULL 0.5000
7 1 NULL NULL 0.0000
8 2 2 2 1.0000
9 2 4 4 1.0000
select pk, a, sum, price, tttttttt(sprice,sum) over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 0 FOLLOWING)
from t1;
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 0 FOLLOWING)
from ' at line 1
select pk, a, sum, price, myfunc_double(sum) over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 0 FOLLOWING)
from t1;
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 0 FOLLOWING)
from ' at line 1
select pk, a, sum, price, round(sprice,sum) over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 0 FOLLOWING)
from t1;
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 0 FOLLOWING)
from ' at line 1
select pk, a, sum, price, myfunc_double(sum) over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 0 FOLLOWING)
from t1;
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 0 FOLLOWING)
from ' at line 1
set @save_sql_mode = @@sql_mode;
set sql_mode="oracle";
select pk, a, sum, price, avg2(sum, price) over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 0 FOLLOWING)
from t1;
pk a sum price avg2(sum, price) over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 0 FOLLOWING)
1 1 100 50 0.5000
2 1 100 100 0.7500
3 1 100 50 0.7500
4 1 100 50 0.5000
5 1 100 50 0.5000
6 1 100 NULL 0.5000
7 1 NULL NULL 0.0000
8 2 2 2 1.0000
9 2 4 4 1.0000
set sql_mode= @save_sql_mode;
drop table t1;
DROP FUNCTION avgcost;
DROP FUNCTION avg2;
DROP FUNCTION myfunc_double;
66 changes: 66 additions & 0 deletions mysql-test/main/udf.test
Expand Up @@ -528,3 +528,69 @@ DROP FUNCTION METAPHON;
#INSERT INTO t1 (a) VALUES ('Hello');
#SELECT * FROM t1;
DROP TABLE t1;

--echo
--echo MDEV-15073: Generic UDAF parser code in server for windows functions
--echo

--replace_result $UDF_EXAMPLE_SO UDF_EXAMPLE_LIB
eval CREATE AGGREGATE FUNCTION avgcost
RETURNS REAL SONAME "$UDF_EXAMPLE_SO";
--replace_result $UDF_EXAMPLE_SO UDF_EXAMPLE_LIB
eval CREATE AGGREGATE FUNCTION avg2
RETURNS REAL SONAME "$UDF_EXAMPLE_SO";
--replace_result $UDF_EXAMPLE_SO UDF_EXAMPLE_LIB
eval CREATE FUNCTION myfunc_double RETURNS REAL SONAME "$UDF_EXAMPLE_SO";

create table t1(pk int primary key,
a int,
sum int,
price float(24));
insert into t1 values
(1, 1, 100, 50.00),
(2, 1, 100, 100.00),
(3, 1, 100, 50.00),
(4, 1, 100, 50.00),
(5, 1, 100, 50.00),
(6, 1, 100, NULL),
(7, 1, NULL, NULL),
(8, 2, 2, 2),
(9, 2, 4, 4);

--sorted_result
select pk, a, sum, price, avgcost(sum, price) over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 1 FOLLOWING)
from t1;
--sorted_result
select pk, a, sum, price, avgcost(sum, price) over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 0 FOLLOWING)
from t1;

--sorted_result
select pk, a, sum, price, avg2(sum, price) over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 1 FOLLOWING)
from t1;
--sorted_result
select pk, a, sum, price, avg2(sum, price) over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 0 FOLLOWING)
from t1;
--error ER_PARSE_ERROR
select pk, a, sum, price, tttttttt(sprice,sum) over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 0 FOLLOWING)
from t1;
--error ER_PARSE_ERROR
select pk, a, sum, price, myfunc_double(sum) over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 0 FOLLOWING)
from t1;
--error ER_PARSE_ERROR
select pk, a, sum, price, round(sprice,sum) over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 0 FOLLOWING)
from t1;
--error ER_PARSE_ERROR
select pk, a, sum, price, myfunc_double(sum) over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 0 FOLLOWING)
from t1;

set @save_sql_mode = @@sql_mode;
set sql_mode="oracle";
--sorted_result
select pk, a, sum, price, avg2(sum, price) over (partition by a order by pk ROWS BETWEEN 1 PRECEDING AND 0 FOLLOWING)
from t1;
set sql_mode= @save_sql_mode;

drop table t1;
DROP FUNCTION avgcost;
DROP FUNCTION avg2;
DROP FUNCTION myfunc_double;
19 changes: 19 additions & 0 deletions sql/item_sum.cc
Expand Up @@ -3235,6 +3235,25 @@ bool Item_udf_sum::add()
DBUG_RETURN(0);
}


bool Item_udf_sum::supports_removal() const
{
DBUG_ENTER("Item_udf_sum::supports_remove");
DBUG_PRINT("info", ("support: %d", udf.supports_removal()));
DBUG_RETURN(udf.supports_removal());
}


void Item_udf_sum::remove()
{
my_bool tmp_null_value;
DBUG_ENTER("Item_udf_sum::remove");
udf.remove(&tmp_null_value);
null_value= tmp_null_value;
DBUG_VOID_RETURN;
}


void Item_udf_sum::cleanup()
{
/*
Expand Down
2 changes: 2 additions & 0 deletions sql/item_sum.h
Expand Up @@ -1563,6 +1563,8 @@ class Item_udf_sum : public Item_sum

void clear();
bool add();
bool supports_removal() const;
void remove();
void reset_field() {};
void update_field() {};
void cleanup();
Expand Down
3 changes: 3 additions & 0 deletions sql/sql_udf.cc
Expand Up @@ -76,6 +76,8 @@ static const char *init_syms(udf_func *tmp, char *nm)
(void)strmov(end, "_add");
if (!((tmp->func_add= (Udf_func_add) dlsym(tmp->dlhandle, nm))))
return nm;
(void)strmov(end, "_remove");
tmp->func_remove= (Udf_func_add) dlsym(tmp->dlhandle, nm);
}

(void) strmov(end,"_deinit");
Expand Down Expand Up @@ -565,6 +567,7 @@ int mysql_create_function(THD *thd,udf_func *udf)
u_d->func_deinit= udf->func_deinit;
u_d->func_clear= udf->func_clear;
u_d->func_add= udf->func_add;
u_d->func_remove= udf->func_remove;

/* create entry in mysql.func table */

Expand Down
15 changes: 15 additions & 0 deletions sql/sql_udf.h
Expand Up @@ -47,6 +47,7 @@ typedef struct st_udf_func
Udf_func_deinit func_deinit;
Udf_func_clear func_clear;
Udf_func_add func_add;
Udf_func_add func_remove;
ulong usage_count;
} udf_func;

Expand Down Expand Up @@ -131,6 +132,20 @@ class udf_handler :public Sql_alloc
func(&initid, &f_args, &is_null, &error);
*null_value= (my_bool) (is_null || error);
}
bool supports_removal() const
{ return MY_TEST(u_d->func_remove); }
void remove(my_bool *null_value)
{
DBUG_ASSERT(u_d->func_remove);
if (get_arguments())
{
*null_value=1;
return;
}
Udf_func_add func= u_d->func_remove;
func(&initid, &f_args, &is_null, &error);
*null_value= (my_bool) (is_null || error);
}
String *val_str(String *str,String *save_str);
};

Expand Down
15 changes: 15 additions & 0 deletions sql/sql_yacc.yy
Expand Up @@ -11348,6 +11348,21 @@ window_func:
|
sum_expr
{
((Item_sum *) $1)->mark_as_window_func_sum_expr();
}
|
function_call_generic
{
Item* item = (Item*)$1;
/* Only UDF aggregate here possible */
if ((item == NULL) ||
(item->type() != Item::SUM_FUNC_ITEM)
|| (((Item_sum *)item)->sum_func() != Item_sum::UDF_SUM_FUNC))
{
thd->parse_error();
MYSQL_YYABORT;
}

((Item_sum *) $1)->mark_as_window_func_sum_expr();
}
;
Expand Down
15 changes: 15 additions & 0 deletions sql/sql_yacc_ora.yy
Expand Up @@ -11382,6 +11382,21 @@ window_func:
|
sum_expr
{
((Item_sum *) $1)->mark_as_window_func_sum_expr();
}
|
function_call_generic
{
Item* item = (Item*)$1;
/* Only UDF aggregate here possible */
if ((item == NULL) ||
(item->type() != Item::SUM_FUNC_ITEM)
|| (((Item_sum *)item)->sum_func() != Item_sum::UDF_SUM_FUNC))
{
thd->parse_error();
MYSQL_YYABORT;
}

((Item_sum *) $1)->mark_as_window_func_sum_expr();
}
;
Expand Down

0 comments on commit 555921a

Please sign in to comment.