Skip to content

Commit

Permalink
Fixed Bucketing Range Wierdness
Browse files Browse the repository at this point in the history
the ranges came out uneven so i updated the query and made it work with
the series data rather than min/max of the data in the bucket. it's a
little heavier in run time, but it makes the output much cleaner and
easier to comprehend.

also added tests for limiting to time range and bbox.

updates #264
  • Loading branch information
Vince Forgione committed Apr 5, 2018
1 parent 3ff06e9 commit 4594190
Show file tree
Hide file tree
Showing 3 changed files with 121 additions and 45 deletions.
6 changes: 3 additions & 3 deletions lib/plenario/actions/chart_meta_actions.ex
Expand Up @@ -55,7 +55,7 @@ defmodule Plenario.Actions.ChartMetaActions do

@template_dir "chart-meta-queries"

def query_time_bucket!(chart, ts_trunc_interval, ts_trunc_span, ts_range \\ nil, bbox \\ nil) do
def query_time_bucket!(chart, interval, span, ts_range \\ nil, bbox \\ nil) do
meta = MetaActions.get(chart.meta_id)

data_fields =
Expand All @@ -69,8 +69,8 @@ defmodule Plenario.Actions.ChartMetaActions do
ts_range: ts_range,
bbox: bbox,
data_fields: data_fields,
ts_trunc_interval: ts_trunc_interval,
ts_trunc_span: ts_trunc_span,
interval: interval,
span: span,
], trim: true)

case Ecto.Adapters.SQL.query(Repo, sql) do
Expand Down
72 changes: 47 additions & 25 deletions priv/chart-meta-queries/width_bucket.sql.eex
@@ -1,7 +1,7 @@
WITH stats AS (
SELECT
MIN(DATE_TRUNC('<%= ts_trunc_span %>', "<%= chart.timestamp_field %>")) AS min,
MAX(DATE_TRUNC('<%= ts_trunc_span %>', "<%= chart.timestamp_field %>")) AS max
MIN("<%= chart.timestamp_field %>") AS min,
MAX("<%= chart.timestamp_field %>") AS max
FROM
"<%= table_name %>"
<%= if ts_range != nil or bbox != nil do %>
Expand All @@ -10,50 +10,72 @@ WITH stats AS (
'<%= ts_range %>'::tstzrange @> "<%= chart.timestamp_field %>"
<%= if bbox != nil do %>
AND
<% end %>
<% end %>
<% end %> <%# end AND joiner for bbox %>
<% end %> <%# end ts range %>
<%= if bbox != nil do %>
ST_CONTAINS('<%= bbox %>'::geometry, "<%= chart.location_field %>")
<% end %>
<% end %>
<% end %> <%# end bbox %>
<% end %> <%# end where %>
),
series AS (
SELECT
ARRAY(
SELECT * FROM GENERATE_SERIES(min, max, '<%= interval %> <%= span %>')
) AS tsarray
FROM
stats
),
buckets AS (
SELECT
WIDTH_BUCKET("<%= chart.timestamp_field %>", tsarray) AS bucket
FROM
"<%= table_name %>",
series
<%= if ts_range != nil or bbox != nil do %>
WHERE
<%= if ts_range != nil do %>
'<%= ts_range %>'::tstzrange @> "<%= chart.timestamp_field %>"
<%= if bbox != nil do %>
AND
<% end %> <%# end AND joiner for bbox %>
<% end %> <%# end ts range %>
<%= if bbox != nil do %>
ST_CONTAINS('<%= bbox %>'::geometry, "<%= chart.location_field %>")
<% end %> <%# end bbox %>
<% end %> <%# end where %>
),
histogram AS (
SELECT
WIDTH_BUCKET(
"<%= chart.timestamp_field %>",
ARRAY(
SELECT * FROM GENERATE_SERIES(min, max, '<%= ts_trunc_interval %> <%= ts_trunc_span %>')
)
) AS bucket,
TSTZRANGE(
MIN(DATE_TRUNC('<%= ts_trunc_span %>', "<%= chart.timestamp_field %>")),
MAX(DATE_TRUNC('<%= ts_trunc_span %>', "<%= chart.timestamp_field %>")),
'[]'
) AS range
bucket,
MIN(tsarray[bucket - 1]) AS lower,
MAX(tsarray[bucket]) AS upper
<%= for {path, field} <- data_fields do %>
, <%= chart.data_agg_func %>((<%= field %>)::numeric) AS "<%= path %>"
<% end %>
FROM
"<%= table_name %>",
stats
buckets,
series
<%= if ts_range != nil or bbox != nil do %>
WHERE
<%= if ts_range != nil do %>
'<%= ts_range %>'::tstzrange @> "<%= chart.timestamp_field %>"
<%= if bbox != nil do %>
AND
<% end %>
<% end %>
<% end %> <%# end AND joiner for bbox %>
<% end %> <%# end ts range %>
<%= if bbox != nil do %>
ST_CONTAINS('<%= bbox %>'::geometry, "<%= chart.location_field %>")
<% end %>
<% end %>
GROUP BY bucket
ORDER BY bucket
<% end %> <%# end bbox %>
<% end %> <%# end where %>
GROUP BY
bucket
ORDER BY
bucket
)
SELECT
bucket,
range
TSTZRANGE(lower, upper) AS range
<%= for {path, _} <- data_fields do %>
, "<%= path %>"::float
<% end %>
Expand Down
88 changes: 71 additions & 17 deletions test/plenario/chart_meta_actions_test.exs
Expand Up @@ -101,7 +101,6 @@ defmodule Plenario.Testing.ChartMetaActionsTest do
"""
{:ok, _} = Ecto.Adapters.SQL.query(Repo, insert)


{:ok, cm} = ChartMetaActions.create(
meta, "name", "description", "timestamp", vp.name,
["observations.BMP180.temperature"], "avg")
Expand All @@ -115,41 +114,98 @@ defmodule Plenario.Testing.ChartMetaActionsTest do

assert rows == [
[
1, %Postgrex.Range{
lower: {{2018, 1, 1}, {0, 0, 0, 0}},
lower_inclusive: true,
upper: {{2018, 1, 1}, {0, 4, 0, 0}},
upper_inclusive: true
1,
%Postgrex.Range{
lower_inclusive: false,
lower: nil,
upper: {{2018, 1, 1}, {0, 0, 0, 0}},
upper_inclusive: false
},
-1.65
],
[
4,
%Postgrex.Range{
lower: {{2018, 1, 1}, {0, 16, 0, 0}},
lower_inclusive: true,
upper: {{2018, 1, 1}, {0, 16, 0, 0}},
upper_inclusive: true
lower: {{2018, 1, 1}, {0, 10, 0, 0}},
upper: {{2018, 1, 1}, {0, 15, 0, 0}},
upper_inclusive: false
},
nil
-1.65
],
[
6,
%Postgrex.Range{
lower: {{2018, 1, 1}, {0, 25, 0, 0}},
lower_inclusive: true,
upper: {{2018, 1, 1}, {0, 25, 0, 0}},
upper_inclusive: true
lower: {{2018, 1, 1}, {0, 20, 0, 0}},
upper_inclusive: false
},
-1.65
],
[
7,
%Postgrex.Range{
lower: {{2018, 1, 1}, {0, 33, 0, 0}},
lower_inclusive: true,
upper: {{2018, 1, 1}, {0, 33, 0, 0}},
upper_inclusive: true
lower: {{2018, 1, 1}, {0, 25, 0, 0}},
upper: {{2018, 1, 1}, {0, 30, 0, 0}},
upper_inclusive: false
},
-1.65
]
]
end

test "query time bucket with time range and bbox", %{meta: meta, vp: vp} do
insert = """
INSERT INTO "#{meta.table_name}"
(node_id, timestamp, longitude, latitude, observations)
VALUES
('001', '2018-01-05 00:00:00+00:00', 10, 10, '{"BMP180": {"temperature": -1.65}}'),
('001', '2017-01-05 00:00:00+00:00', 10, 10, '{"BMP180": {"temperature": -1.64}}'),
('002', '2018-01-05 00:05:00+00:00', -10, -10, '{"BMP180": {"temperature": 1.65}}'),
('002', '2017-01-05 00:05:00+00:00', -10, -10, '{"BMP180": {"temperature": 1.64}}'),
('003', '2018-01-05 00:10:00+00:00', 9, 9, '{"BMP180": {"temperature": -1.65}}'),
('003', '2017-01-05 00:10:00+00:00', 9, 9, '{"BMP180": {"temperature": -1.64}}'),
('004', '2018-01-05 00:15:00+00:00', -9, -9, '{"BMP180": {"temperature": 1.65}}'),
('004', '2017-01-05 00:15:00+00:00', -9, -9, '{"BMP180": {"temperature": 1.64}}')
"""
{:ok, _} = Ecto.Adapters.SQL.query(Repo, insert)

{:ok, cm} = ChartMetaActions.create(
meta, "name", "description", "timestamp", vp.name,
["observations.BMP180.temperature"], "avg")

%Postgrex.Result{columns: cols, rows: rows, num_rows: 2} =
ChartMetaActions.query_time_bucket!(
cm, 30, "seconds", "[2018-01-01, 2018-01-31]",
%Geo.Polygon{srid: 4326, coordinates: [
[{11, 8}, {11, 11}, {8, 11}, {8, 8}, {11, 8}]
]}
)

assert cols == [
"bucket", "range", "observations.BMP180.temperature"
]

assert rows == [
[
1,
%Postgrex.Range{
lower_inclusive: false,
lower: nil,
upper: {{2018, 1, 5}, {0, 0, 0, 0}},
upper_inclusive: false
},
-1.65
],
[
21,
%Postgrex.Range{
lower_inclusive: true,
lower: {{2018, 1, 5}, {0, 9, 30, 0}},
upper: {{2018, 1, 5}, {0, 10, 0, 0}},
upper_inclusive: false
},
-1.65
]
Expand All @@ -172,7 +228,6 @@ defmodule Plenario.Testing.ChartMetaActionsTest do
"""
{:ok, _} = Ecto.Adapters.SQL.query(Repo, insert)


{:ok, cm} = ChartMetaActions.create(
meta, "name", "description", "timestamp", vp.name,
["observations.BMP180.temperature"], "avg")
Expand Down Expand Up @@ -212,7 +267,6 @@ defmodule Plenario.Testing.ChartMetaActionsTest do
"""
{:ok, _} = Ecto.Adapters.SQL.query(Repo, insert)


{:ok, cm} = ChartMetaActions.create(
meta, "name", "description", "timestamp", vp.name,
["observations.BMP180.temperature"], "avg")
Expand Down

0 comments on commit 4594190

Please sign in to comment.