Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

feat(unique-count): Prorated unique count queries #1704

Merged
merged 1 commit into from
Feb 16, 2024
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
28 changes: 22 additions & 6 deletions app/services/events/stores/clickhouse/unique_count_query.rb
Original file line number Diff line number Diff line change
Expand Up @@ -30,7 +30,7 @@ def query
GROUP BY property
)

SELECT SUM(sum_adjusted_value) AS aggregation FROM event_values
SELECT coalesce(SUM(sum_adjusted_value), 0) AS aggregation FROM event_values
SQL
end

Expand All @@ -55,7 +55,7 @@ def prorated_query
GROUP BY property, operation_type, timestamp
)

SELECT SUM(period_ratio) as aggregation
SELECT coalesce(SUM(period_ratio), 0) as aggregation
FROM (
SELECT (#{period_ratio_sql}) AS period_ratio
FROM event_values
Expand Down Expand Up @@ -87,7 +87,7 @@ def grouped_query

SELECT
#{group_names},
SUM(sum_adjusted_value) as aggregation
coalesce(SUM(sum_adjusted_value), 0) as aggregation
FROM event_values
GROUP BY #{group_names}
SQL
Expand Down Expand Up @@ -119,7 +119,7 @@ def grouped_prorated_query

SELECT
#{group_names},
SUM(period_ratio) as aggregation
coalesce(SUM(period_ratio), 0) as aggregation
FROM (
SELECT
(#{grouped_period_ratio_sql}) AS period_ratio,
Expand Down Expand Up @@ -246,7 +246,15 @@ def period_ratio_sql
operation_type = 'add',
-- NOTE: duration in seconds between current add and next remove - using end of period as final boundaries if no remove
toDecimal128(
(date_diff('seconds', timestamp, leadInFrame(timestamp, 1, toDateTime64(:to_datetime, 5, 'UTC')) OVER (PARTITION BY property ORDER BY timestamp ASC ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING))),
(date_diff(
'seconds',
if(timestamp < toDateTime64(:from_datetime, 5, 'UTC'), toDateTime64(:from_datetime, 5, 'UTC'), timestamp),
if(
(leadInFrame(timestamp, 1, toDateTime64(:to_datetime, 5, 'UTC')) OVER (PARTITION BY property ORDER BY timestamp ASC ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)) < toDateTime64(:from_datetime, 5, 'UTC'),
toDateTime64(:to_datetime, 5, 'UTC'),
leadInFrame(timestamp, 1, toDateTime64(:to_datetime, 5, 'UTC')) OVER (PARTITION BY property ORDER BY timestamp ASC ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
)
)),
:decimal_scale
)
/
Expand All @@ -265,7 +273,15 @@ def grouped_period_ratio_sql
operation_type = 'add',
-- NOTE: duration in seconds between current add and next remove - using end of period as final boundaries if no remove
toDecimal128(
(date_diff('seconds', timestamp, leadInFrame(timestamp, 1, toDateTime64(:to_datetime, 5, 'UTC')) OVER (PARTITION BY #{group_names}, property ORDER BY timestamp ASC ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING))),
(date_diff(
'seconds',
if(timestamp < toDateTime64(:from_datetime, 5, 'UTC'), toDateTime64(:from_datetime, 5, 'UTC'), timestamp),
if(
(leadInFrame(timestamp, 1, toDateTime64(:to_datetime, 5, 'UTC')) OVER (PARTITION BY #{group_names}, property ORDER BY timestamp ASC ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)) < toDateTime64(:from_datetime, 5, 'UTC'),
toDateTime64(:to_datetime, 5, 'UTC'),
leadInFrame(timestamp, 1, toDateTime64(:to_datetime, 5, 'UTC')) OVER (PARTITION BY #{group_names}, property ORDER BY timestamp ASC ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING)
)
)),
:decimal_scale
)
/
Expand Down
2 changes: 2 additions & 0 deletions app/services/events/stores/clickhouse_store.rb
Original file line number Diff line number Diff line change
Expand Up @@ -136,6 +136,7 @@ def prorated_unique_count
[
query.prorated_query,
{
from_datetime:,
to_datetime: to_datetime.ceil,
decimal_scale: DECIMAL_SCALE,
},
Expand Down Expand Up @@ -167,6 +168,7 @@ def grouped_prorated_unique_count
[
query.grouped_prorated_query,
{
from_datetime:,
to_datetime: to_datetime.ceil,
decimal_scale: DECIMAL_SCALE,
},
Expand Down
40 changes: 34 additions & 6 deletions app/services/events/stores/postgres/unique_count_query.rb
Original file line number Diff line number Diff line change
Expand Up @@ -30,7 +30,7 @@ def query
GROUP BY property
)

SELECT SUM(sum_adjusted_value) AS aggregation FROM event_values
SELECT COALESCE(SUM(sum_adjusted_value), 0) AS aggregation FROM event_values
SQL
end

Expand All @@ -55,7 +55,7 @@ def prorated_query
GROUP BY property, operation_type, timestamp
)

SELECT SUM(period_ratio) as aggregation
SELECT COALESCE(SUM(period_ratio), 0) as aggregation
FROM (
SELECT (#{period_ratio_sql}) AS period_ratio
FROM event_values
Expand Down Expand Up @@ -87,7 +87,7 @@ def grouped_query

SELECT
#{group_names},
SUM(sum_adjusted_value) as aggregation
COALESCE(SUM(sum_adjusted_value), 0) as aggregation
FROM event_values
GROUP BY #{group_names}
SQL
Expand Down Expand Up @@ -119,7 +119,7 @@ def grouped_prorated_query

SELECT
#{group_names},
SUM(period_ratio) as aggregation
COALESCE(SUM(period_ratio), 0) as aggregation
FROM (
SELECT
(#{grouped_period_ratio_sql}) AS period_ratio,
Expand Down Expand Up @@ -237,7 +237,21 @@ def period_ratio_sql
CASE WHEN operation_type = 'add'
THEN
-- NOTE: duration in seconds between current event and next one - using end of period as final boundaries
EXTRACT(EPOCH FROM LEAD(timestamp, 1, :to_datetime) OVER (PARTITION BY property ORDER BY timestamp) - timestamp)
EXTRACT(
EPOCH FROM (
(
-- NOTE: if following event is older than the start of the period, we use the start of the period as the reference
CASE WHEN (LEAD(timestamp, 1, :to_datetime) OVER (PARTITION BY property ORDER BY timestamp)) < :from_datetime
THEN :from_datetime
ELSE LEAD(timestamp, 1, :to_datetime) OVER (PARTITION BY property ORDER BY timestamp)
END
)
- (
-- NOTE: if events is older than the start of the period, we use the start of the period as the reference
CASE WHEN timestamp < :from_datetime THEN :from_datetime ELSE timestamp END
)
)
)
/
-- NOTE: full duration of the period
#{charges_duration.days.to_i}
Expand All @@ -252,7 +266,21 @@ def grouped_period_ratio_sql
CASE WHEN operation_type = 'add'
THEN
-- NOTE: duration in seconds between current event and next one - using end of period as final boundaries
EXTRACT(EPOCH FROM LEAD(timestamp, 1, :to_datetime) OVER (PARTITION BY #{group_names}, property ORDER BY timestamp) - timestamp)
EXTRACT(
EPOCH FROM (
(
-- NOTE: if following event is older than the start of the period, we use the start of the period as the reference
CASE WHEN (LEAD(timestamp, 1, :to_datetime) OVER (PARTITION BY #{group_names}, property ORDER BY timestamp)) < :from_datetime
THEN :from_datetime
ELSE LEAD(timestamp, 1, :to_datetime) OVER (PARTITION BY #{group_names}, property ORDER BY timestamp)
END
)
- (
-- NOTE: if events is older than the start of the period, we use the start of the period as the reference
CASE WHEN timestamp < :from_datetime THEN :from_datetime ELSE timestamp END
)
)
)
/
-- NOTE: full duration of the period
#{charges_duration.days.to_i}
Expand Down
2 changes: 2 additions & 0 deletions app/services/events/stores/postgres_store.rb
Original file line number Diff line number Diff line change
Expand Up @@ -93,6 +93,7 @@ def prorated_unique_count
[
query.prorated_query,
{
from_datetime:,
to_datetime: to_datetime.ceil,
},
],
Expand All @@ -118,6 +119,7 @@ def grouped_prorated_unique_count
[
query.grouped_prorated_query,
{
from_datetime:,
to_datetime: to_datetime.ceil,
},
],
Expand Down
Loading