-
Notifications
You must be signed in to change notification settings - Fork 600
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
test: add some real-world use cases to e2e testing (#3158)
- Loading branch information
1 parent
dc2a9ef
commit c4b56bd
Showing
4 changed files
with
328 additions
and
1 deletion.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
|
@@ -9,4 +9,7 @@ create table ddl_t (v1 int not null); | |
query T | ||
show tables; | ||
---- | ||
ddl_t | ||
ddl_t | ||
|
||
statement ok | ||
drop table ddl_t; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,120 @@ | ||
statement ok | ||
SET RW_IMPLICIT_FLUSH TO true; | ||
|
||
# Refer to the blog: | ||
# https://www.risingwave.dev/docs/latest/perform-real-time-ad-performance-analysis/ | ||
|
||
statement ok | ||
CREATE TABLE ad_impression ( | ||
bid_id BIGINT, | ||
ad_id BIGINT, | ||
impression_timestamp TIMESTAMP | ||
); | ||
|
||
statement ok | ||
CREATE TABLE ad_click ( | ||
bid_id BIGINT, | ||
click_timestamp TIMESTAMP | ||
); | ||
|
||
statement ok | ||
INSERT INTO ad_impression VALUES | ||
('8821808526777993777', '7', '2022-06-10 12:20:04.858173'), | ||
('7151244365040293409', '7', '2022-06-10 12:20:06.409411'), | ||
('6925263822026025842', '7', '2022-06-10 12:20:06.420565'), | ||
('3665010658430074808', '8', '2022-06-10 12:20:06.911027'); | ||
|
||
statement ok | ||
INSERT INTO ad_click VALUES | ||
('8821808526777993777', '2022-06-10 12:20:04.923066'), | ||
('3665010658430074808', '2022-06-10 12:20:07.651162'); | ||
|
||
statement ok | ||
CREATE MATERIALIZED VIEW ad_ctr AS | ||
SELECT | ||
ad_clicks.ad_id AS ad_id, | ||
ad_clicks.clicks_count :: NUMERIC / ad_impressions.impressions_count AS ctr | ||
FROM | ||
( | ||
SELECT | ||
ad_impression.ad_id AS ad_id, | ||
COUNT(*) AS impressions_count | ||
FROM | ||
ad_impression | ||
GROUP BY | ||
ad_id | ||
) AS ad_impressions | ||
JOIN ( | ||
SELECT | ||
ai.ad_id, | ||
COUNT(*) AS clicks_count | ||
FROM | ||
ad_click AS ac | ||
LEFT JOIN ad_impression AS ai ON ac.bid_id = ai.bid_id | ||
GROUP BY | ||
ai.ad_id | ||
) AS ad_clicks ON ad_impressions.ad_id = ad_clicks.ad_id; | ||
|
||
query T | ||
SELECT ROUND(ctr, 2) FROM ad_ctr WHERE ad_id = 7; | ||
---- | ||
0.33 | ||
|
||
statement ok | ||
CREATE MATERIALIZED VIEW ad_ctr_5min AS | ||
SELECT | ||
ac.ad_id AS ad_id, | ||
ac.clicks_count :: NUMERIC / ai.impressions_count AS ctr, | ||
ai.window_end AS window_end | ||
FROM | ||
( | ||
SELECT | ||
ad_id, | ||
COUNT(*) AS impressions_count, | ||
window_end | ||
FROM | ||
TUMBLE( | ||
ad_impression, | ||
impression_timestamp, | ||
INTERVAL '1' MINUTE | ||
) | ||
GROUP BY | ||
ad_id, | ||
window_end | ||
) AS ai | ||
JOIN ( | ||
SELECT | ||
ai.ad_id, | ||
COUNT(*) AS clicks_count, | ||
ai.window_end AS window_end | ||
FROM | ||
TUMBLE(ad_click, click_timestamp, INTERVAL '1' MINUTE) AS ac | ||
INNER JOIN TUMBLE( | ||
ad_impression, | ||
impression_timestamp, | ||
INTERVAL '1' MINUTE | ||
) AS ai ON ai.bid_id = ac.bid_id | ||
AND ai.window_end = ac.window_end | ||
GROUP BY | ||
ai.ad_id, | ||
ai.window_end | ||
) AS ac ON ai.ad_id = ac.ad_id | ||
AND ai.window_end = ac.window_end; | ||
|
||
query TTT | ||
SELECT ad_id, ROUND(ctr, 2), window_end FROM ad_ctr_5min; | ||
---- | ||
7 0.33 2022-06-10 12:21:00 | ||
8 1 2022-06-10 12:21:00 | ||
|
||
statement ok | ||
DROP MATERIALIZED VIEW ad_ctr; | ||
|
||
statement ok | ||
DROP MATERIALIZED VIEW ad_ctr_5min; | ||
|
||
statement ok | ||
DROP TABLE ad_impression; | ||
|
||
statement ok | ||
DROP TABLE ad_click; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,157 @@ | ||
statement ok | ||
CREATE TABLE nics_metrics ( | ||
device_id VARCHAR, | ||
device_type VARCHAR, | ||
metric_name VARCHAR, | ||
aggregation VARCHAR, | ||
nic_name VARCHAR, | ||
report_time TIMESTAMP, | ||
link_bandwidth FLOAT, | ||
value FLOAT, | ||
); | ||
|
||
statement ok | ||
CREATE TABLE tcp_metrics ( | ||
device_id VARCHAR, | ||
device_type VARCHAR, | ||
report_time TIMESTAMP, | ||
metric_name VARCHAR, | ||
domain VARCHAR, | ||
value FLOAT, | ||
); | ||
|
||
statement ok | ||
INSERT INTO nics_metrics VALUES | ||
('812b4ba287f5ee0bc9d43bbf5bbe87fb', '3', 'tx_bytes', 'avg', 'eth0', '2022-06-08 09:37:02', '9100000', '71456460'), | ||
('812b4ba287f5ee0bc9d43bbf5bbe87fb', '3', 'tx_bytes', 'avg', 'eth0', '2022-06-08 09:38:03', '9100000', '666606187'), | ||
('812b4ba287f5ee0bc9d43bbf5bbe87fb', '3', 'tx_bytes', 'avg', 'eth0', '2022-06-08 09:39:03', '9100000', '804539010'); | ||
|
||
statement ok | ||
INSERT INTO tcp_metrics VALUES | ||
('812b4ba287f5ee0bc9d43bbf5bbe87fb', '3', '2022-06-08 09:37:54', 'retrans_rate', 'all', '0.245309986782795776'), | ||
('812b4ba287f5ee0bc9d43bbf5bbe87fb', '3', '2022-06-08 09:37:54', 'srtt', 'all', '554.4752006561499'), | ||
('812b4ba287f5ee0bc9d43bbf5bbe87fb', '3', '2022-06-08 09:37:54', 'download_speed', 'all', '131.5221997377209'), | ||
('812b4ba287f5ee0bc9d43bbf5bbe87fb', '3', '2022-06-08 09:38:54', 'retrans_rate', 'all', '0.24800597740570458'), | ||
('812b4ba287f5ee0bc9d43bbf5bbe87fb', '3', '2022-06-08 09:38:54', 'srtt', 'all', '636.00260113591'), | ||
('812b4ba287f5ee0bc9d43bbf5bbe87fb', '3', '2022-06-08 09:38:54', 'download_speed', 'all', '116.841272498187'), | ||
('812b4ba287f5ee0bc9d43bbf5bbe87fb', '3', '2022-06-08 09:39:54', 'retrans_rate', 'all', '0.24821624079901723'), | ||
('812b4ba287f5ee0bc9d43bbf5bbe87fb', '3', '2022-06-08 09:39:54', 'srtt', 'all', '599.9202978109153'), | ||
('812b4ba287f5ee0bc9d43bbf5bbe87fb', '3', '2022-06-08 09:39:54', 'download_speed', 'all', '149.7339243859982'); | ||
|
||
statement ok | ||
CREATE MATERIALIZED VIEW high_util_tcp_metrics AS | ||
SELECT | ||
tcp.device_id AS device_id, | ||
tcp.window_end AS window_end, | ||
tcp.metric_name AS metric_name, | ||
tcp.metric_value AS metric_value | ||
FROM | ||
( | ||
SELECT | ||
device_id, | ||
window_end, | ||
metric_name, | ||
AVG(value) AS metric_value | ||
FROM | ||
TUMBLE( | ||
tcp_metrics, | ||
report_time, | ||
INTERVAL '3' MINUTE | ||
) | ||
WHERE | ||
domain = 'all' | ||
GROUP BY | ||
device_id, | ||
window_end, | ||
metric_name | ||
) AS tcp | ||
JOIN ( | ||
SELECT | ||
device_id, | ||
window_end, | ||
AVG((value * 8 / 10) / link_bandwidth) AS avg_util | ||
FROM | ||
TUMBLE( | ||
nics_metrics, | ||
report_time, | ||
INTERVAL '3' MINUTE | ||
) | ||
WHERE | ||
metric_name = 'tx_bytes' | ||
AND aggregation = 'avg' | ||
GROUP BY | ||
device_id, | ||
window_end | ||
) AS nic ON tcp.device_id = nic.device_id | ||
AND tcp.window_end = nic.window_end | ||
WHERE | ||
avg_util >= 50; | ||
|
||
statement ok | ||
CREATE MATERIALIZED VIEW retrans_incidents AS | ||
SELECT | ||
device_id, | ||
window_end AS trigger_time, | ||
metric_value AS trigger_value | ||
FROM | ||
high_util_tcp_metrics | ||
WHERE | ||
metric_name = 'retrans_rate' | ||
AND metric_value > 0.15; | ||
|
||
statement ok | ||
CREATE MATERIALIZED VIEW rtt_incidents AS | ||
SELECT | ||
device_id, | ||
window_end AS trigger_time, | ||
metric_value AS trigger_value | ||
FROM | ||
high_util_tcp_metrics | ||
WHERE | ||
metric_name = 'srtt' | ||
AND metric_value > 500.0; | ||
|
||
statement ok | ||
CREATE MATERIALIZED VIEW download_incidents AS | ||
SELECT | ||
device_id, | ||
window_end AS trigger_time, | ||
metric_value AS trigger_value | ||
FROM | ||
high_util_tcp_metrics | ||
WHERE | ||
metric_name = 'download_speed' | ||
AND metric_value < 200.0; | ||
|
||
query TTT | ||
select * from retrans_incidents; | ||
---- | ||
812b4ba287f5ee0bc9d43bbf5bbe87fb 2022-06-08 09:42:00 0.24821624079901722 | ||
|
||
query TTT | ||
select * from rtt_incidents; | ||
---- | ||
812b4ba287f5ee0bc9d43bbf5bbe87fb 2022-06-08 09:42:00 599.9202978109153 | ||
|
||
query TTT | ||
select * from download_incidents; | ||
---- | ||
812b4ba287f5ee0bc9d43bbf5bbe87fb 2022-06-08 09:42:00 149.7339243859982 | ||
|
||
statement ok | ||
DROP MATERIALIZED VIEW download_incidents; | ||
|
||
statement ok | ||
DROP MATERIALIZED VIEW retrans_incidents; | ||
|
||
statement ok | ||
DROP MATERIALIZED VIEW rtt_incidents; | ||
|
||
statement ok | ||
DROP MATERIALIZED VIEW high_util_tcp_metrics; | ||
|
||
statement ok | ||
DROP TABLE tcp_metrics; | ||
|
||
statement ok | ||
DROP TABLE nics_metrics; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters