Variables can also be used to emulate analytic functions. A few examples follow. For simplicity, let’s assume all data fields NOT NULL, and sorting and partitioning (PARTITION BY) use one column only. Including NULLs and multi-column sorting/partitioning would make the examples more cumbersome and difficult to read without changing their basic idea.
Let’s create a table named TestTable for our examples:
CREATETABLE TestTable(
group_id INT NOTNULL,
order_id INT UNIQUENOTNULL,
value INT NOTNULL
);
Here, group_id is the group identifier (the equivalent of an analytic function window), order_id contains unique values used for sorting, and value is just a numeric value.
Let’s fill our table with test data:
INSERT TestTable(order_id, group_id, value)
SELECT *
FROM(
SELECT1 order_id, 1 group_id, 1 value
UNIONALLSELECT2, 1, 2
UNIONALLSELECT3, 1, 2
UNIONALLSELECT4, 2, 1
UNIONALLSELECT5, 2, 2
UNIONALLSELECT6, 2, 3
UNIONALLSELECT7, 3, 1
UNIONALLSELECT8, 3, 2
UNIONALLSELECT9, 4, 1
UNIONALLSELECT11, 3, 2
)T;
Some examples of analytic function substitutes.
1) ROW_NUMBER() OVER(ORDER BY order_id)
SELECT T.*, @I:=@I+1 RowNum
FROM TestTable T,(SELECT @I:=0)I
ORDERBY order_id;
group_id
order_id
value
RowNum
1
1
1
1
1
2
2
2
1
3
2
3
2
4
1
4
2
5
2
5
2
6
3
6
3
7
1
7
3
8
2
8
4
9
1
9
3
11
2
10
2) ROW_NUMBER() OVER(PARTITION BY group_id ORDER BY order_id)