From 057a7505633024d150cd28a92f6e8e39dd6d4d47 Mon Sep 17 00:00:00 2001 From: Timothy Heys Date: Tue, 10 Jul 2018 14:28:22 +0200 Subject: [PATCH] Added special case for using rolling operation with date dimension and date filter in order to adjust the filter then truncate the resulting data frame --- fireant/slicer/operations.py | 47 +- fireant/slicer/queries/builder.py | 23 +- fireant/slicer/queries/special_cases.py | 77 + .../queries/test_build_dimension_filters.py | 295 ++ .../slicer/queries/test_build_dimensions.py | 452 ++++ .../tests/slicer/queries/test_build_joins.py | 138 + .../queries/test_build_metric_filters.py | 141 + .../slicer/queries/test_build_metrics.py | 61 + .../slicer/queries/test_build_operations.py | 61 + .../slicer/queries/test_build_orderbys.py | 173 ++ .../slicer/queries/test_build_pagination.py | 67 + .../slicer/queries/test_build_references.py | 958 +++++++ .../tests/slicer/queries/test_build_render.py | 147 + fireant/tests/slicer/queries/test_builder.py | 2377 ----------------- 14 files changed, 2626 insertions(+), 2391 deletions(-) create mode 100644 fireant/slicer/queries/special_cases.py create mode 100644 fireant/tests/slicer/queries/test_build_dimension_filters.py create mode 100644 fireant/tests/slicer/queries/test_build_dimensions.py create mode 100644 fireant/tests/slicer/queries/test_build_joins.py create mode 100644 fireant/tests/slicer/queries/test_build_metric_filters.py create mode 100644 fireant/tests/slicer/queries/test_build_metrics.py create mode 100644 fireant/tests/slicer/queries/test_build_operations.py create mode 100644 fireant/tests/slicer/queries/test_build_orderbys.py create mode 100644 fireant/tests/slicer/queries/test_build_pagination.py create mode 100644 fireant/tests/slicer/queries/test_build_references.py create mode 100644 fireant/tests/slicer/queries/test_build_render.py diff --git a/fireant/slicer/operations.py b/fireant/slicer/operations.py index 54c26f0f..1af7a41a 100644 --- a/fireant/slicer/operations.py +++ b/fireant/slicer/operations.py @@ -19,6 +19,10 @@ class Operation(object): def apply(self, data_frame): raise NotImplementedError() + @property + def metrics(self): + raise NotImplementedError() + @property def operations(self): return [] @@ -32,6 +36,17 @@ def __init__(self, key, label, prefix=None, suffix=None, precision=None): self.suffix = suffix self.precision = precision + def apply(self, data_frame): + raise NotImplementedError() + + @property + def metrics(self): + raise NotImplementedError() + + @property + def operations(self): + raise NotImplementedError() + def _group_levels(self, index): """ Get the index levels that need to be grouped. This is to avoid apply the cumulative function across separate @@ -57,6 +72,9 @@ def __init__(self, arg): self.arg = arg + def apply(self, data_frame): + raise NotImplementedError() + @property def metrics(self): return [metric @@ -70,9 +88,6 @@ def operations(self): if isinstance(operation, Operation) for op_and_children in [operation] + operation.operations] - def apply(self, data_frame): - raise NotImplementedError() - def __repr__(self): return self.key @@ -123,9 +138,9 @@ def apply(self, data_frame): return self.cummean(data_frame[df_key]) -class _Rolling(_BaseOperation): +class RollingOperation(_BaseOperation): def __init__(self, arg, window, min_periods=None): - super(_Rolling, self).__init__( + super(RollingOperation, self).__init__( key='{}({})'.format(self.__class__.__name__.lower(), getattr(arg, 'key', arg)), label='{}({})'.format(self.__class__.__name__, @@ -139,11 +154,31 @@ def __init__(self, arg, window, min_periods=None): self.window = window self.min_periods = min_periods + def _should_adjust(self, other_operations): + # Need to figure out if this rolling operation is has the largest window, and if it's the first of multiple + # rolling operations if there are more than one operation sharing the largest window. + first_max_rolling = list(sorted(other_operations, key=lambda operation: operation.window))[0] + + return first_max_rolling is self + def apply(self, data_frame): raise NotImplementedError() + @property + def metrics(self): + return [metric + for metric in [self.arg] + if isinstance(metric, Metric)] + + @property + def operations(self): + return [op_and_children + for operation in [self.arg] + if isinstance(operation, Operation) + for op_and_children in [operation] + operation.operations] + -class RollingMean(_Rolling): +class RollingMean(RollingOperation): def rolling_mean(self, x): return x.rolling(self.window, self.min_periods).mean() diff --git a/fireant/slicer/queries/builder.py b/fireant/slicer/queries/builder.py index 5633d689..2457cfd3 100644 --- a/fireant/slicer/queries/builder.py +++ b/fireant/slicer/queries/builder.py @@ -13,6 +13,7 @@ format_metric_key, immutable, ) +from . import special_cases from .database import fetch_data from .finders import ( find_and_group_references_for_dimensions, @@ -154,14 +155,18 @@ def query(self): reference_groups = find_and_group_references_for_dimensions(self._references) totals_dimensions = find_dimensions_with_totals(self._dimensions) - query = make_slicer_query_with_references_and_totals(self.slicer.database, - self.table, - self.slicer.joins, - self._dimensions, - find_metrics_for_widgets(self._widgets), - self._filters, - reference_groups, - totals_dimensions) + operations = find_operations_for_widgets(self._widgets) + args = special_cases.apply_to_query_args(self.slicer.database, + self.table, + self.slicer.joins, + self._dimensions, + find_metrics_for_widgets(self._widgets), + self._filters, + reference_groups, + totals_dimensions, + operations) + + query = make_slicer_query_with_references_and_totals(*args) # Add ordering orders = (self._orders or make_orders_for_dimensions(self._dimensions)) @@ -193,6 +198,8 @@ def fetch(self, hint=None) -> Iterable[Dict]: df_key = format_metric_key(operation.key) data_frame[df_key] = operation.apply(data_frame) + data_frame = special_cases.apply_operations_to_data_frame(operations, data_frame) + # Apply transformations return [widget.transform(data_frame, self.slicer, self._dimensions, self._references) for widget in self._widgets] diff --git a/fireant/slicer/queries/special_cases.py b/fireant/slicer/queries/special_cases.py new file mode 100644 index 00000000..26986429 --- /dev/null +++ b/fireant/slicer/queries/special_cases.py @@ -0,0 +1,77 @@ +from datetime import timedelta + +import pandas as pd + +from fireant.slicer.dimensions import DatetimeDimension +from fireant.slicer.filters import RangeFilter +from fireant.slicer.operations import RollingOperation + + +def adjust_daterange_filter_for_rolling_window(dimensions, operations, filters): + has_datetime_dimension_in_first_dimension_pos = not len(dimensions) \ + or not isinstance(dimensions[0], DatetimeDimension) + if has_datetime_dimension_in_first_dimension_pos: + return filters + + has_rolling = any([isinstance(operation, RollingOperation) + for operation in operations]) + if not has_rolling: + return filters + + dim0 = dimensions[0] + filters_on_dim0 = [filter_ + for filter_ in filters + if isinstance(filter_, RangeFilter) + and str(filter_.definition.term) == str(dim0.definition)] + if not 0 < len(filters_on_dim0): + return filters + + max_rolling_period = max(operation.window + for operation in operations + if isinstance(operation, RollingOperation)) + + for filter_ in filters_on_dim0: + # Monkey patch the update start date on the date filter + args = {dim0.interval + 's': max_rolling_period} \ + if 'quarter' != dim0.interval \ + else {'months': max_rolling_period * 3} + filter_.definition.start.value -= timedelta(**args) + + return filters + + +def adjust_dataframe_for_rolling_window(operations, data_frame): + has_rolling = any([isinstance(operation, RollingOperation) + for operation in operations]) + if not has_rolling: + return data_frame + + max_rolling_period = max(operation.window + for operation in operations + if isinstance(operation, RollingOperation)) + + if isinstance(data_frame.index, pd.DatetimeIndex): + return data_frame.iloc[max_rolling_period - 1:] + + if isinstance(data_frame.index, pd.MultiIndex) \ + and isinstance(data_frame.index.levels[0], pd.DatetimeIndex): + num_levels = len(data_frame.index.levels) + + return data_frame.groupby(level=list(range(1, num_levels))) \ + .apply(lambda df: df.iloc[max_rolling_period - 1:]) \ + .reset_index(level=list(range(num_levels - 1)), drop=True) + + return data_frame + + +def apply_to_query_args(database, table, joins, dimensions, metrics, filters, reference_groups, totals_dimensions, + operations): + filters = adjust_daterange_filter_for_rolling_window(dimensions, operations, filters) + + return database, table, joins, dimensions, metrics, filters, reference_groups, totals_dimensions + + +def apply_operations_to_data_frame(operations, data_frame): + data_frame = adjust_dataframe_for_rolling_window(operations, data_frame) + + return data_frame diff --git a/fireant/tests/slicer/queries/test_build_dimension_filters.py b/fireant/tests/slicer/queries/test_build_dimension_filters.py new file mode 100644 index 00000000..4e1741e6 --- /dev/null +++ b/fireant/tests/slicer/queries/test_build_dimension_filters.py @@ -0,0 +1,295 @@ +from datetime import date +from unittest import TestCase + +import fireant as f +from ..mocks import slicer + + +# noinspection SqlDialectInspection,SqlNoDataSourceInspection +class QueryBuilderDimensionFilterTests(TestCase): + maxDiff = None + + def test_build_query_with_filter_isin_categorical_dim(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.political_party.isin(['d'])) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "political_party" IN (\'d\')', str(query)) + + def test_build_query_with_filter_notin_categorical_dim(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.political_party.notin(['d'])) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "political_party" NOT IN (\'d\')', str(query)) + + def test_build_query_with_filter_like_categorical_dim(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.political_party.like('Rep%')) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "political_party" LIKE \'Rep%\'', str(query)) + + def test_build_query_with_filter_not_like_categorical_dim(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.political_party.not_like('Rep%')) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "political_party" NOT LIKE \'Rep%\'', str(query)) + + def test_build_query_with_filter_isin_unique_dim(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.candidate.isin([1])) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "candidate_id" IN (1)', str(query)) + + def test_build_query_with_filter_notin_unique_dim(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.candidate.notin([1])) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "candidate_id" NOT IN (1)', str(query)) + + def test_build_query_with_filter_isin_unique_dim_display(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.candidate.isin(['Donald Trump'], use_display=True)) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "candidate_name" IN (\'Donald Trump\')', str(query)) + + def test_build_query_with_filter_notin_unique_dim_display(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.candidate.notin(['Donald Trump'], use_display=True)) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "candidate_name" NOT IN (\'Donald Trump\')', str(query)) + + def test_build_query_with_filter_like_unique_dim(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.candidate.like('%Trump')) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "candidate_name" LIKE \'%Trump\'', str(query)) + + def test_build_query_with_filter_like_display_dim(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.candidate_display.like('%Trump')) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "candidate_name" LIKE \'%Trump\'', str(query)) + + def test_build_query_with_filter_not_like_unique_dim(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.candidate.not_like('%Trump')) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "candidate_name" NOT LIKE \'%Trump\'', str(query)) + + def test_build_query_with_filter_not_like_display_dim(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.candidate_display.not_like('%Trump')) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "candidate_name" NOT LIKE \'%Trump\'', str(query)) + + def test_build_query_with_filter_like_categorical_dim_multiple_patterns(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.political_party.like('Rep%', 'Dem%')) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "political_party" LIKE \'Rep%\' ' + 'OR "political_party" LIKE \'Dem%\'', str(query)) + + def test_build_query_with_filter_not_like_categorical_dim_multiple_patterns(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.political_party.not_like('Rep%', 'Dem%')) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "political_party" NOT LIKE \'Rep%\' ' + 'OR "political_party" NOT LIKE \'Dem%\'', str(query)) + + def test_build_query_with_filter_like_pattern_dim_multiple_patterns(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.pattern.like('a%', 'b%')) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "pattern" LIKE \'a%\' ' + 'OR "pattern" LIKE \'b%\'', str(query)) + + def test_build_query_with_filter_not_like_pattern_dim_multiple_patterns(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.pattern.not_like('a%', 'b%')) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "pattern" NOT LIKE \'a%\' ' + 'OR "pattern" NOT LIKE \'b%\'', str(query)) + + def test_build_query_with_filter_like_unique_dim_multiple_patterns(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.candidate.like('%Trump', '%Clinton')) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "candidate_name" LIKE \'%Trump\' ' + 'OR "candidate_name" LIKE \'%Clinton\'', str(query)) + + def test_build_query_with_filter_like_display_dim_multiple_patterns(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.candidate_display.like('%Trump', '%Clinton')) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "candidate_name" LIKE \'%Trump\' ' + 'OR "candidate_name" LIKE \'%Clinton\'', str(query)) + + def test_build_query_with_filter_not_like_unique_dim_multiple_patterns(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.candidate.not_like('%Trump', '%Clinton')) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "candidate_name" NOT LIKE \'%Trump\' ' + 'OR "candidate_name" NOT LIKE \'%Clinton\'', str(query)) + + def test_build_query_with_filter_not_like_display_dim_multiple_patterns(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.candidate_display.not_like('%Trump', '%Clinton')) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "candidate_name" NOT LIKE \'%Trump\' ' + 'OR "candidate_name" NOT LIKE \'%Clinton\'', str(query)) + + def test_build_query_with_filter_isin_raise_exception_when_display_definition_undefined(self): + with self.assertRaises(f.QueryException): + slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.deepjoin.isin([1], use_display=True)) + + def test_build_query_with_filter_notin_raise_exception_when_display_definition_undefined(self): + with self.assertRaises(f.QueryException): + slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.deepjoin.notin([1], use_display=True)) + + def test_build_query_with_filter_like_raise_exception_when_display_definition_undefined(self): + with self.assertRaises(f.QueryException): + slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.deepjoin.like('test')) + + def test_build_query_with_filter_not_like_raise_exception_when_display_definition_undefined(self): + with self.assertRaises(f.QueryException): + slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.deepjoin.not_like('test')) + + def test_build_query_with_filter_range_datetime_dimension(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.timestamp.between(date(2009, 1, 20), date(2017, 1, 20))) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "timestamp" BETWEEN \'2009-01-20\' AND \'2017-01-20\'', str(query)) + + def test_build_query_with_filter_boolean_true(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.winner.is_(True)) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "is_winner"', str(query)) + + def test_build_query_with_filter_boolean_false(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.winner.is_(False)) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE NOT "is_winner"', str(query)) diff --git a/fireant/tests/slicer/queries/test_build_dimensions.py b/fireant/tests/slicer/queries/test_build_dimensions.py new file mode 100644 index 00000000..ee3adb3a --- /dev/null +++ b/fireant/tests/slicer/queries/test_build_dimensions.py @@ -0,0 +1,452 @@ +from datetime import date +from unittest import TestCase + +import fireant as f +from ..mocks import slicer + + +# noinspection SqlDialectInspection,SqlNoDataSourceInspection +class QueryBuilderDimensionTests(TestCase): + maxDiff = None + + def test_build_query_with_datetime_dimension(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.timestamp) \ + .query + + self.assertEqual('SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp" ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_build_query_with_datetime_dimension_hourly(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.timestamp(f.hourly)) \ + .query + + self.assertEqual('SELECT ' + 'TRUNC("timestamp",\'HH\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp" ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_build_query_with_datetime_dimension_daily(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.timestamp(f.daily)) \ + .query + + self.assertEqual('SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp" ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_build_query_with_datetime_dimension_weekly(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.timestamp(f.weekly)) \ + .query + + self.assertEqual('SELECT ' + 'TRUNC("timestamp",\'IW\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp" ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_build_query_with_datetime_dimension_monthly(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.timestamp(f.monthly)) \ + .query + + self.assertEqual('SELECT ' + 'TRUNC("timestamp",\'MM\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp" ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_build_query_with_datetime_dimension_quarterly(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.timestamp(f.quarterly)) \ + .query + + self.assertEqual('SELECT ' + 'TRUNC("timestamp",\'Q\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp" ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_build_query_with_datetime_dimension_annually(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.timestamp(f.annually)) \ + .query + + self.assertEqual('SELECT ' + 'TRUNC("timestamp",\'Y\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp" ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_build_query_with_boolean_dimension(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.winner) \ + .query + + self.assertEqual('SELECT ' + '"is_winner" "$d$winner",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$winner" ' + 'ORDER BY "$d$winner"', str(query)) + + def test_build_query_with_categorical_dimension(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.political_party) \ + .query + + self.assertEqual('SELECT ' + '"political_party" "$d$political_party",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$political_party" ' + 'ORDER BY "$d$political_party"', str(query)) + + def test_build_query_with_unique_dimension(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.election) \ + .query + + self.assertEqual('SELECT ' + '"election_id" "$d$election",' + '"election_year" "$d$election_display",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$election","$d$election_display" ' + 'ORDER BY "$d$election_display"', str(query)) + + def test_build_query_with_pattern_dimension(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.pattern(['groupA%', 'groupB%'])) \ + .query + + self.assertEqual('SELECT ' + 'CASE ' + 'WHEN "pattern" LIKE \'groupA%\' THEN \'groupA%\' ' + 'WHEN "pattern" LIKE \'groupB%\' THEN \'groupB%\' ' + 'ELSE \'No Group\' ' + 'END "$d$pattern",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$pattern" ' + 'ORDER BY "$d$pattern"', str(query)) + + def test_build_query_with_pattern_no_values(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.pattern) \ + .query + + self.assertEqual('SELECT ' + '\'No Group\' "$d$pattern",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$pattern" ' + 'ORDER BY "$d$pattern"', str(query)) + + def test_build_query_with_multiple_dimensions(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.timestamp) \ + .dimension(slicer.dimensions.candidate) \ + .query + + self.assertEqual('SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + '"candidate_id" "$d$candidate",' + '"candidate_name" "$d$candidate_display",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp","$d$candidate","$d$candidate_display" ' + 'ORDER BY "$d$timestamp","$d$candidate_display"', str(query)) + + def test_build_query_with_multiple_dimensions_and_visualizations(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes, slicer.metrics.wins)) \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes)) + .axis(f.HighCharts.LineChart(slicer.metrics.wins))) \ + .dimension(slicer.dimensions.timestamp) \ + .dimension(slicer.dimensions.political_party) \ + .query + + self.assertEqual('SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + '"political_party" "$d$political_party",' + 'SUM("votes") "$m$votes",' + 'SUM("is_winner") "$m$wins" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp","$d$political_party" ' + 'ORDER BY "$d$timestamp","$d$political_party"', str(query)) + + +# noinspection SqlDialectInspection,SqlNoDataSourceInspection +class QueryBuilderDimensionTotalsTests(TestCase): + maxDiff = None + + def test_build_query_with_totals_cat_dimension(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.political_party.rollup()) \ + .query + + self.assertEqual('(SELECT ' + '"political_party" "$d$political_party",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$political_party") ' + + 'UNION ALL ' + + '(SELECT ' + 'NULL "$d$political_party",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician") ' + + 'ORDER BY "$d$political_party"', str(query)) + + def test_build_query_with_totals_uni_dimension(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.candidate.rollup()) \ + .query + + self.assertEqual('(SELECT ' + '"candidate_id" "$d$candidate",' + '"candidate_name" "$d$candidate_display",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$candidate","$d$candidate_display") ' + + 'UNION ALL ' + + '(SELECT ' + 'NULL "$d$candidate",' + 'NULL "$d$candidate_display",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician") ' + + 'ORDER BY "$d$candidate_display"', str(query)) + + def test_build_query_with_totals_on_dimension_and_subsequent_dimensions(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.timestamp, + slicer.dimensions.candidate.rollup(), + slicer.dimensions.political_party) \ + .query + + self.assertEqual('(SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + '"candidate_id" "$d$candidate",' + '"candidate_name" "$d$candidate_display",' + '"political_party" "$d$political_party",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp","$d$candidate","$d$candidate_display","$d$political_party") ' + + 'UNION ALL ' + + '(SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'NULL "$d$candidate",' + 'NULL "$d$candidate_display",' + 'NULL "$d$political_party",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp") ' + 'ORDER BY "$d$timestamp","$d$candidate_display","$d$political_party"', str(query)) + + def test_build_query_with_totals_on_multiple_dimensions_dimension(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.timestamp, + slicer.dimensions.candidate.rollup(), + slicer.dimensions.political_party.rollup()) \ + .query + + self.assertEqual('(SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + '"candidate_id" "$d$candidate",' + '"candidate_name" "$d$candidate_display",' + '"political_party" "$d$political_party",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp","$d$candidate","$d$candidate_display","$d$political_party") ' + + 'UNION ALL ' + + '(SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'NULL "$d$candidate",' + 'NULL "$d$candidate_display",' + 'NULL "$d$political_party",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp") ' + + 'UNION ALL ' + + '(SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + '"candidate_id" "$d$candidate",' + '"candidate_name" "$d$candidate_display",' + 'NULL "$d$political_party",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp","$d$candidate","$d$candidate_display") ' + + 'ORDER BY "$d$timestamp","$d$candidate_display","$d$political_party"', str(query)) + + def test_build_query_with_totals_cat_dimension_with_references(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.timestamp, + slicer.dimensions.political_party.rollup()) \ + .reference(f.DayOverDay(slicer.dimensions.timestamp)) \ + .query + + # Important that in reference queries when using totals that the null dimensions are omitted from the nested + # queries and selected in the container query + self.assertEqual('(SELECT ' + 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) ' + '"$d$timestamp",' + 'COALESCE("$base"."$d$political_party","$dod"."$d$political_party") "$d$political_party",' + '"$base"."$m$votes" "$m$votes",' + '"$dod"."$m$votes" "$m$votes_dod" ' + 'FROM (' + + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + '"political_party" "$d$political_party",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp","$d$political_party"' + ') "$base" ' + + 'FULL OUTER JOIN (' + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + '"political_party" "$d$political_party",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp","$d$political_party"' + ') "$dod" ' + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' + 'AND "$base"."$d$political_party"="$dod"."$d$political_party") ' + + 'UNION ALL ' + + '(SELECT ' + 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) ' + '"$d$timestamp",' + 'NULL "$d$political_party",' + '"$base"."$m$votes" "$m$votes",' + '"$dod"."$m$votes" "$m$votes_dod" ' + 'FROM (' + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$base" ' + + 'FULL OUTER JOIN (' + 'SELECT TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$dod" ' + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) ' + 'ORDER BY "$d$timestamp","$d$political_party"', str(query)) + + def test_build_query_with_totals_cat_dimension_with_references_and_date_filters(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.timestamp) \ + .dimension(slicer.dimensions.political_party.rollup()) \ + .reference(f.DayOverDay(slicer.dimensions.timestamp)) \ + .filter(slicer.dimensions.timestamp.between(date(2018, 1, 1), date(2019, 1, 1))) \ + .query + + self.assertEqual('(SELECT ' + 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) ' + '"$d$timestamp",' + 'COALESCE("$base"."$d$political_party","$dod"."$d$political_party") "$d$political_party",' + '"$base"."$m$votes" "$m$votes",' + '"$dod"."$m$votes" "$m$votes_dod" ' + 'FROM (' + + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + '"political_party" "$d$political_party",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "timestamp" BETWEEN \'2018-01-01\' AND \'2019-01-01\' ' + 'GROUP BY "$d$timestamp","$d$political_party"' + ') "$base" ' + + 'FULL OUTER JOIN (' + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + '"political_party" "$d$political_party",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE TIMESTAMPADD(\'day\',1,"timestamp") BETWEEN \'2018-01-01\' AND \'2019-01-01\' ' + 'GROUP BY "$d$timestamp","$d$political_party"' + ') "$dod" ' + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' + 'AND "$base"."$d$political_party"="$dod"."$d$political_party") ' + + 'UNION ALL ' + + '(SELECT ' + 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) ' + '"$d$timestamp",' + 'NULL "$d$political_party",' + '"$base"."$m$votes" "$m$votes",' + '"$dod"."$m$votes" "$m$votes_dod" ' + 'FROM (' + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "timestamp" BETWEEN \'2018-01-01\' AND \'2019-01-01\' ' + 'GROUP BY "$d$timestamp"' + ') "$base" ' + + 'FULL OUTER JOIN (' + 'SELECT TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE TIMESTAMPADD(\'day\',1,"timestamp") BETWEEN \'2018-01-01\' AND \'2019-01-01\' ' + 'GROUP BY "$d$timestamp"' + ') "$dod" ' + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) ' + 'ORDER BY "$d$timestamp","$d$political_party"', str(query)) diff --git a/fireant/tests/slicer/queries/test_build_joins.py b/fireant/tests/slicer/queries/test_build_joins.py new file mode 100644 index 00000000..d4d89326 --- /dev/null +++ b/fireant/tests/slicer/queries/test_build_joins.py @@ -0,0 +1,138 @@ +from unittest import TestCase + +import fireant as f +from ..mocks import slicer + + +# noinspection SqlDialectInspection,SqlNoDataSourceInspection +class QueryBuilderJoinTests(TestCase): + maxDiff = None + + def test_dimension_with_join_includes_join_in_query(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.timestamp) \ + .dimension(slicer.dimensions.district) \ + .query + + self.assertEqual('SELECT ' + 'TRUNC("politician"."timestamp",\'DD\') "$d$timestamp",' + '"politician"."district_id" "$d$district",' + '"district"."district_name" "$d$district_display",' + 'SUM("politician"."votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'OUTER JOIN "locations"."district" ' + 'ON "politician"."district_id"="district"."id" ' + 'GROUP BY "$d$timestamp","$d$district","$d$district_display" ' + 'ORDER BY "$d$timestamp","$d$district_display"', str(query)) + + def test_dimension_with_multiple_joins_includes_joins_ordered__in_query(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes, + slicer.metrics.voters)) \ + .dimension(slicer.dimensions.timestamp) \ + .dimension(slicer.dimensions.district) \ + .query + + self.assertEqual('SELECT ' + 'TRUNC("politician"."timestamp",\'DD\') "$d$timestamp",' + '"politician"."district_id" "$d$district",' + '"district"."district_name" "$d$district_display",' + 'SUM("politician"."votes") "$m$votes",' + 'COUNT("voter"."id") "$m$voters" ' + 'FROM "politics"."politician" ' + 'JOIN "politics"."voter" ' + 'ON "politician"."id"="voter"."politician_id" ' + 'OUTER JOIN "locations"."district" ' + 'ON "politician"."district_id"="district"."id" ' + 'GROUP BY "$d$timestamp","$d$district","$d$district_display" ' + 'ORDER BY "$d$timestamp","$d$district_display"', str(query)) + + def test_dimension_with_recursive_join_joins_all_join_tables(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.timestamp) \ + .dimension(slicer.dimensions.state) \ + .query + + self.assertEqual('SELECT ' + 'TRUNC("politician"."timestamp",\'DD\') "$d$timestamp",' + '"district"."state_id" "$d$state",' + '"state"."state_name" "$d$state_display",' + 'SUM("politician"."votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'OUTER JOIN "locations"."district" ' + 'ON "politician"."district_id"="district"."id" ' + 'JOIN "locations"."state" ' + 'ON "district"."state_id"="state"."id" ' + 'GROUP BY "$d$timestamp","$d$state","$d$state_display" ' + 'ORDER BY "$d$timestamp","$d$state_display"', str(query)) + + def test_metric_with_join_includes_join_in_query(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.voters)) \ + .dimension(slicer.dimensions.political_party) \ + .query + + self.assertEqual('SELECT ' + '"politician"."political_party" "$d$political_party",' + 'COUNT("voter"."id") "$m$voters" ' + 'FROM "politics"."politician" ' + 'JOIN "politics"."voter" ' + 'ON "politician"."id"="voter"."politician_id" ' + 'GROUP BY "$d$political_party" ' + 'ORDER BY "$d$political_party"', str(query)) + + def test_dimension_filter_with_join_on_display_definition_does_not_include_join_in_query(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.district.isin([1])) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "district_id" IN (1)', str(query)) + + def test_dimension_filter_display_field_with_join_includes_join_in_query(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.district.isin(['District 4'], use_display=True)) \ + .query + + self.assertEqual('SELECT ' + 'SUM("politician"."votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'OUTER JOIN "locations"."district" ' + 'ON "politician"."district_id"="district"."id" ' + 'WHERE "district"."district_name" IN (\'District 4\')', str(query)) + + def test_dimension_filter_with_recursive_join_includes_join_in_query(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.state.isin([1])) \ + .query + + self.assertEqual('SELECT ' + 'SUM("politician"."votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'OUTER JOIN "locations"."district" ' + 'ON "politician"."district_id"="district"."id" ' + 'WHERE "district"."state_id" IN (1)', str(query)) + + def test_dimension_filter_with_deep_recursive_join_includes_joins_in_query(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.dimensions.deepjoin.isin([1])) \ + .query + + self.assertEqual('SELECT ' + 'SUM("politician"."votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'OUTER JOIN "locations"."district" ' + 'ON "politician"."district_id"="district"."id" ' + 'JOIN "locations"."state" ' + 'ON "district"."state_id"="state"."id" ' + 'JOIN "test"."deep" ' + 'ON "deep"."id"="state"."ref_id" ' + 'WHERE "deep"."id" IN (1)', str(query)) diff --git a/fireant/tests/slicer/queries/test_build_metric_filters.py b/fireant/tests/slicer/queries/test_build_metric_filters.py new file mode 100644 index 00000000..25c4ed6b --- /dev/null +++ b/fireant/tests/slicer/queries/test_build_metric_filters.py @@ -0,0 +1,141 @@ +from unittest import TestCase + +import fireant as f +from ..mocks import slicer + + +# noinspection SqlDialectInspection,SqlNoDataSourceInspection +class QueryBuilderMetricFilterTests(TestCase): + maxDiff = None + + def test_build_query_with_metric_filter_eq(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.metrics.votes == 5) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'HAVING SUM("votes")=5', str(query)) + + def test_build_query_with_metric_filter_eq_left(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(5 == slicer.metrics.votes) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'HAVING SUM("votes")=5', str(query)) + + def test_build_query_with_metric_filter_ne(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.metrics.votes != 5) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'HAVING SUM("votes")<>5', str(query)) + + def test_build_query_with_metric_filter_ne_left(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(5 != slicer.metrics.votes) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'HAVING SUM("votes")<>5', str(query)) + + def test_build_query_with_metric_filter_gt(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.metrics.votes > 5) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'HAVING SUM("votes")>5', str(query)) + + def test_build_query_with_metric_filter_gt_left(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(5 < slicer.metrics.votes) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'HAVING SUM("votes")>5', str(query)) + + def test_build_query_with_metric_filter_gte(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.metrics.votes >= 5) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'HAVING SUM("votes")>=5', str(query)) + + def test_build_query_with_metric_filter_gte_left(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(5 <= slicer.metrics.votes) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'HAVING SUM("votes")>=5', str(query)) + + def test_build_query_with_metric_filter_lt(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.metrics.votes < 5) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'HAVING SUM("votes")<5', str(query)) + + def test_build_query_with_metric_filter_lt_left(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(5 > slicer.metrics.votes) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'HAVING SUM("votes")<5', str(query)) + + def test_build_query_with_metric_filter_lte(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(slicer.metrics.votes <= 5) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'HAVING SUM("votes")<=5', str(query)) + + def test_build_query_with_metric_filter_lte_left(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .filter(5 >= slicer.metrics.votes) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'HAVING SUM("votes")<=5', str(query)) diff --git a/fireant/tests/slicer/queries/test_build_metrics.py b/fireant/tests/slicer/queries/test_build_metrics.py new file mode 100644 index 00000000..71c94089 --- /dev/null +++ b/fireant/tests/slicer/queries/test_build_metrics.py @@ -0,0 +1,61 @@ +from unittest import TestCase + +import fireant as f +from ..mocks import slicer + + +# noinspection SqlDialectInspection,SqlNoDataSourceInspection +class QueryBuilderMetricTests(TestCase): + maxDiff = None + + def test_build_query_with_single_metric(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician"', str(query)) + + def test_build_query_with_multiple_metrics(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes, slicer.metrics.wins)) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes",' + 'SUM("is_winner") "$m$wins" ' + 'FROM "politics"."politician"', str(query)) + + def test_build_query_with_multiple_visualizations(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .widget(f.DataTablesJS(slicer.metrics.wins)) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes",' + 'SUM("is_winner") "$m$wins" ' + 'FROM "politics"."politician"', str(query)) + + def test_build_query_for_chart_visualization_with_single_axis(self): + query = slicer.data \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician"', str(query)) + + def test_build_query_for_chart_visualization_with_multiple_axes(self): + query = slicer.data \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes)) + .axis(f.HighCharts.LineChart(slicer.metrics.wins))) \ + .query + + self.assertEqual('SELECT ' + 'SUM("votes") "$m$votes",' + 'SUM("is_winner") "$m$wins" ' + 'FROM "politics"."politician"', str(query)) diff --git a/fireant/tests/slicer/queries/test_build_operations.py b/fireant/tests/slicer/queries/test_build_operations.py new file mode 100644 index 00000000..16d15d48 --- /dev/null +++ b/fireant/tests/slicer/queries/test_build_operations.py @@ -0,0 +1,61 @@ +from unittest import TestCase + +import fireant as f +from ..mocks import slicer + + +# noinspection SqlDialectInspection,SqlNoDataSourceInspection +class QueryBuilderOperationTests(TestCase): + maxDiff = None + + def test_build_query_with_cumsum_operation(self): + query = slicer.data \ + .widget(f.DataTablesJS(f.CumSum(slicer.metrics.votes))) \ + .dimension(slicer.dimensions.timestamp) \ + .query + + self.assertEqual('SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp" ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_build_query_with_cummean_operation(self): + query = slicer.data \ + .widget(f.DataTablesJS(f.CumMean(slicer.metrics.votes))) \ + .dimension(slicer.dimensions.timestamp) \ + .query + + self.assertEqual('SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp" ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_build_query_with_cumprod_operation(self): + query = slicer.data \ + .widget(f.DataTablesJS(f.CumProd(slicer.metrics.votes))) \ + .dimension(slicer.dimensions.timestamp) \ + .query + + self.assertEqual('SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp" ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_build_query_with_rollingmean_operation(self): + query = slicer.data \ + .widget(f.DataTablesJS(f.RollingMean(slicer.metrics.votes, 3, 3))) \ + .dimension(slicer.dimensions.timestamp) \ + .query + + self.assertEqual('SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp" ' + 'ORDER BY "$d$timestamp"', str(query)) diff --git a/fireant/tests/slicer/queries/test_build_orderbys.py b/fireant/tests/slicer/queries/test_build_orderbys.py new file mode 100644 index 00000000..47ce1657 --- /dev/null +++ b/fireant/tests/slicer/queries/test_build_orderbys.py @@ -0,0 +1,173 @@ +from unittest import TestCase + +from pypika import Order + +import fireant as f +from ..mocks import slicer + + +class QueryBuilderOrderTests(TestCase): + maxDiff = None + + def test_build_query_order_by_dimension(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.timestamp) \ + .orderby(slicer.dimensions.timestamp) \ + .query + + self.assertEqual('SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp" ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_build_query_order_by_dimension_display(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.candidate) \ + .orderby(slicer.dimensions.candidate_display) \ + .query + + self.assertEqual('SELECT ' + '"candidate_id" "$d$candidate",' + '"candidate_name" "$d$candidate_display",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$candidate","$d$candidate_display" ' + 'ORDER BY "$d$candidate_display"', str(query)) + + def test_build_query_order_by_dimension_asc(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.timestamp) \ + .orderby(slicer.dimensions.timestamp, orientation=Order.asc) \ + .query + + self.assertEqual('SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp" ' + 'ORDER BY "$d$timestamp" ASC', str(query)) + + def test_build_query_order_by_dimension_desc(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.timestamp) \ + .orderby(slicer.dimensions.timestamp, orientation=Order.desc) \ + .query + + self.assertEqual('SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp" ' + 'ORDER BY "$d$timestamp" DESC', str(query)) + + def test_build_query_order_by_metric(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.timestamp) \ + .orderby(slicer.metrics.votes) \ + .query + + self.assertEqual('SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp" ' + 'ORDER BY "$m$votes"', str(query)) + + def test_build_query_order_by_metric_asc(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.timestamp) \ + .orderby(slicer.metrics.votes, orientation=Order.asc) \ + .query + + self.assertEqual('SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp" ' + 'ORDER BY "$m$votes" ASC', str(query)) + + def test_build_query_order_by_metric_desc(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.timestamp) \ + .orderby(slicer.metrics.votes, orientation=Order.desc) \ + .query + + self.assertEqual('SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp" ' + 'ORDER BY "$m$votes" DESC', str(query)) + + def test_build_query_order_by_multiple_dimensions(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.timestamp, slicer.dimensions.candidate) \ + .orderby(slicer.dimensions.timestamp) \ + .orderby(slicer.dimensions.candidate) \ + .query + + self.assertEqual('SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + '"candidate_id" "$d$candidate",' + '"candidate_name" "$d$candidate_display",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp","$d$candidate","$d$candidate_display" ' + 'ORDER BY "$d$timestamp","$d$candidate"', str(query)) + + def test_build_query_order_by_multiple_dimensions_with_different_orientations(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.timestamp, slicer.dimensions.candidate) \ + .orderby(slicer.dimensions.timestamp, orientation=Order.desc) \ + .orderby(slicer.dimensions.candidate, orientation=Order.asc) \ + .query + + self.assertEqual('SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + '"candidate_id" "$d$candidate",' + '"candidate_name" "$d$candidate_display",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp","$d$candidate","$d$candidate_display" ' + 'ORDER BY "$d$timestamp" DESC,"$d$candidate" ASC', str(query)) + + def test_build_query_order_by_metrics_and_dimensions(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.timestamp) \ + .orderby(slicer.dimensions.timestamp) \ + .orderby(slicer.metrics.votes) \ + .query + + self.assertEqual('SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp" ' + 'ORDER BY "$d$timestamp","$m$votes"', str(query)) + + def test_build_query_order_by_metrics_and_dimensions_with_different_orientations(self): + query = slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.timestamp) \ + .orderby(slicer.dimensions.timestamp, orientation=Order.asc) \ + .orderby(slicer.metrics.votes, orientation=Order.desc) \ + .query + + self.assertEqual('SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp" ' + 'ORDER BY "$d$timestamp" ASC,"$m$votes" DESC', str(query)) diff --git a/fireant/tests/slicer/queries/test_build_pagination.py b/fireant/tests/slicer/queries/test_build_pagination.py new file mode 100644 index 00000000..7ea916ec --- /dev/null +++ b/fireant/tests/slicer/queries/test_build_pagination.py @@ -0,0 +1,67 @@ +from unittest import TestCase +from unittest.mock import ( + ANY, + Mock, + patch, +) + +import fireant as f +from ..matchers import ( + DimensionMatcher, +) +from ..mocks import slicer + + +@patch('fireant.slicer.queries.builder.fetch_data') +class QueryBuildPaginationTests(TestCase): + def test_set_limit(self, mock_fetch_data: Mock): + slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.timestamp) \ + .limit(20) \ + .fetch() + + mock_fetch_data.assert_called_once_with(ANY, + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp" ' + 'ORDER BY "$d$timestamp" LIMIT 20', + dimensions=DimensionMatcher(slicer.dimensions.timestamp)) + + def test_set_offset(self, mock_fetch_data: Mock): + slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.timestamp) \ + .offset(20) \ + .fetch() + + mock_fetch_data.assert_called_once_with(ANY, + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp" ' + 'ORDER BY "$d$timestamp" ' + 'OFFSET 20', + dimensions=DimensionMatcher(slicer.dimensions.timestamp)) + + def test_set_limit_and_offset(self, mock_fetch_data: Mock): + slicer.data \ + .widget(f.DataTablesJS(slicer.metrics.votes)) \ + .dimension(slicer.dimensions.timestamp) \ + .limit(20) \ + .offset(30) \ + .fetch() + + mock_fetch_data.assert_called_once_with(ANY, + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp" ' + 'ORDER BY "$d$timestamp" ' + 'LIMIT 20 ' + 'OFFSET 30', + dimensions=DimensionMatcher(slicer.dimensions.timestamp)) diff --git a/fireant/tests/slicer/queries/test_build_references.py b/fireant/tests/slicer/queries/test_build_references.py new file mode 100644 index 00000000..d6ef2dd9 --- /dev/null +++ b/fireant/tests/slicer/queries/test_build_references.py @@ -0,0 +1,958 @@ +from datetime import date +from unittest import TestCase + +import fireant as f +from ..mocks import slicer + + +# noinspection SqlDialectInspection,SqlNoDataSourceInspection +class QueryBuilderDatetimeReferenceTests(TestCase): + maxDiff = None + + def test_single_reference_dod_with_no_dimension_uses_multiple_from_clauses_instead_of_joins(self): + query = slicer.data \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ + .reference(f.DayOverDay(slicer.dimensions.timestamp)) \ + .query + + self.assertEqual('SELECT ' + '"$base"."$m$votes" "$m$votes",' + '"$dod"."$m$votes" "$m$votes_dod" ' + + 'FROM (' + 'SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician"' + ') "$base",(' + 'SELECT ' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician"' + ') "$dod"', str(query)) + + def test_single_reference_dod_with_dimension_but_not_reference_dimension_in_query_using_filter(self): + query = slicer.data \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ + .dimension(slicer.dimensions.political_party) \ + .reference(f.DayOverDay(slicer.dimensions.timestamp)) \ + .filter(slicer.dimensions.timestamp.between(date(2000, 1, 1), date(2000, 3, 1))) \ + .query + + self.assertEqual('SELECT ' + 'COALESCE("$base"."$d$political_party","$dod"."$d$political_party") "$d$political_party",' + '"$base"."$m$votes" "$m$votes",' + '"$dod"."$m$votes" "$m$votes_dod" ' + 'FROM ' + + '(' # nested + 'SELECT ' + '"political_party" "$d$political_party",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "timestamp" BETWEEN \'2000-01-01\' AND \'2000-03-01\' ' + 'GROUP BY "$d$political_party"' + ') "$base" ' # end-nested + + 'FULL OUTER JOIN (' # nested + 'SELECT ' + '"political_party" "$d$political_party",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE TIMESTAMPADD(\'day\',1,"timestamp") BETWEEN \'2000-01-01\' AND \'2000-03-01\' ' + 'GROUP BY "$d$political_party"' + ') "$dod" ' # end-nested + + 'ON "$base"."$d$political_party"="$dod"."$d$political_party" ' + 'ORDER BY "$d$political_party"', str(query)) + + def test_dimension_with_single_reference_dod(self): + query = slicer.data \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ + .dimension(slicer.dimensions.timestamp) \ + .reference(f.DayOverDay(slicer.dimensions.timestamp)) \ + .query + + self.assertEqual('SELECT ' + 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) ' + '"$d$timestamp",' + '"$base"."$m$votes" "$m$votes",' + '"$dod"."$m$votes" "$m$votes_dod" ' + 'FROM ' + + '(' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$base" ' # end-nested + + 'FULL OUTER JOIN (' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$dod" ' # end-nested + + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_dimension_with_single_reference_wow(self): + query = slicer.data \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ + .dimension(slicer.dimensions.timestamp) \ + .reference(f.WeekOverWeek(slicer.dimensions.timestamp)) \ + .query + + self.assertEqual('SELECT ' + 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'week\',1,"$wow"."$d$timestamp")) ' + '"$d$timestamp",' + '"$base"."$m$votes" "$m$votes",' + '"$wow"."$m$votes" "$m$votes_wow" ' + 'FROM ' + + '(' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$base" ' # end-nested + + 'FULL OUTER JOIN (' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$wow" ' # end-nested + + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'week\',1,"$wow"."$d$timestamp") ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_dimension_with_single_reference_mom(self): + query = slicer.data \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ + .dimension(slicer.dimensions.timestamp) \ + .reference(f.MonthOverMonth(slicer.dimensions.timestamp)) \ + .query + + self.assertEqual('SELECT ' + 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'month\',1,"$mom"."$d$timestamp")) ' + '"$d$timestamp",' + '"$base"."$m$votes" "$m$votes",' + '"$mom"."$m$votes" "$m$votes_mom" ' + 'FROM ' + + '(' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$base" ' # end-nested + + 'FULL OUTER JOIN (' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$mom" ' # end-nested + + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'month\',1,"$mom"."$d$timestamp") ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_dimension_with_single_reference_qoq(self): + query = slicer.data \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ + .dimension(slicer.dimensions.timestamp) \ + .reference(f.QuarterOverQuarter(slicer.dimensions.timestamp)) \ + .query + + self.assertEqual('SELECT ' + 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'quarter\',1,"$qoq"."$d$timestamp")) ' + '"$d$timestamp",' + '"$base"."$m$votes" "$m$votes",' + '"$qoq"."$m$votes" "$m$votes_qoq" ' + 'FROM ' + + '(' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$base" ' # end-nested + + 'FULL OUTER JOIN (' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$qoq" ' # end-nested + + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'quarter\',1,"$qoq"."$d$timestamp") ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_dimension_with_single_reference_yoy(self): + query = slicer.data \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ + .dimension(slicer.dimensions.timestamp) \ + .reference(f.YearOverYear(slicer.dimensions.timestamp)) \ + .query + + self.assertEqual('SELECT ' + 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp")) ' + '"$d$timestamp",' + '"$base"."$m$votes" "$m$votes",' + '"$yoy"."$m$votes" "$m$votes_yoy" ' + 'FROM ' + + '(' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$base" ' # end-nested + + 'FULL OUTER JOIN (' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$yoy" ' # end-nested + + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp") ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_dimension_with_single_reference_as_a_delta(self): + query = slicer.data \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ + .dimension(slicer.dimensions.timestamp) \ + .reference(f.DayOverDay(slicer.dimensions.timestamp, delta=True)) \ + .query + + self.assertEqual('SELECT ' + 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) ' + '"$d$timestamp",' + '"$base"."$m$votes" "$m$votes",' + '"$base"."$m$votes"-"$dod"."$m$votes" "$m$votes_dod_delta" ' + 'FROM ' + + '(' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$base" ' # end-nested + + 'FULL OUTER JOIN (' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$dod" ' # end-nested + + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_dimension_with_single_reference_as_a_delta_percentage(self): + query = slicer.data \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ + .dimension(slicer.dimensions.timestamp) \ + .reference(f.DayOverDay(slicer.dimensions.timestamp, delta_percent=True)) \ + .query + + self.assertEqual('SELECT ' + 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) ' + '"$d$timestamp",' + '"$base"."$m$votes" "$m$votes",' + '("$base"."$m$votes"-"$dod"."$m$votes")*100/NULLIF("$dod"."$m$votes",' + '0) "$m$votes_dod_delta_percent" ' + 'FROM ' + + '(' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$base" ' # end-nested + + 'FULL OUTER JOIN (' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$dod" ' # end-nested + + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_reference_on_dimension_with_weekly_interval(self): + weekly_timestamp = slicer.dimensions.timestamp(f.weekly) + query = slicer.data \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ + .dimension(weekly_timestamp) \ + .reference(f.DayOverDay(weekly_timestamp)) \ + .query + + self.assertEqual('SELECT ' + 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) ' + '"$d$timestamp",' + '"$base"."$m$votes" "$m$votes",' + '"$dod"."$m$votes" "$m$votes_dod" ' + 'FROM ' + + '(' # nested + 'SELECT ' + 'TRUNC("timestamp",\'IW\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$base" ' # end-nested + + 'FULL OUTER JOIN (' # nested + 'SELECT ' + 'TRUNC("timestamp",\'IW\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$dod" ' # end-nested + + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_reference_on_dimension_with_weekly_interval_no_interval_on_reference(self): + query = slicer.data \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ + .dimension(slicer.dimensions.timestamp(f.weekly)) \ + .reference(f.DayOverDay(slicer.dimensions.timestamp)) \ + .query + + self.assertEqual('SELECT ' + 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) ' + '"$d$timestamp",' + '"$base"."$m$votes" "$m$votes",' + '"$dod"."$m$votes" "$m$votes_dod" ' + 'FROM ' + + '(' # nested + 'SELECT ' + 'TRUNC("timestamp",\'IW\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$base" ' # end-nested + + 'FULL OUTER JOIN (' # nested + 'SELECT ' + 'TRUNC("timestamp",\'IW\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$dod" ' # end-nested + + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_reference_on_dimension_with_monthly_interval(self): + query = slicer.data \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ + .dimension(slicer.dimensions.timestamp(f.monthly)) \ + .reference(f.DayOverDay(slicer.dimensions.timestamp)) \ + .query + + self.assertEqual('SELECT ' + 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) ' + '"$d$timestamp",' + '"$base"."$m$votes" "$m$votes",' + '"$dod"."$m$votes" "$m$votes_dod" ' + 'FROM ' + + '(' # nested + 'SELECT ' + 'TRUNC("timestamp",\'MM\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$base" ' # end-nested + + 'FULL OUTER JOIN (' # nested + 'SELECT ' + 'TRUNC("timestamp",\'MM\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$dod" ' # end-nested + + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_reference_on_dimension_with_quarterly_interval(self): + query = slicer.data \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ + .dimension(slicer.dimensions.timestamp(f.quarterly)) \ + .reference(f.DayOverDay(slicer.dimensions.timestamp)) \ + .query + + self.assertEqual('SELECT ' + 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) ' + '"$d$timestamp",' + '"$base"."$m$votes" "$m$votes",' + '"$dod"."$m$votes" "$m$votes_dod" ' + 'FROM ' + + '(' # nested + 'SELECT ' + 'TRUNC("timestamp",\'Q\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$base" ' # end-nested + + 'FULL OUTER JOIN (' # nested + 'SELECT ' + 'TRUNC("timestamp",\'Q\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$dod" ' # end-nested + + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_reference_on_dimension_with_annual_interval(self): + query = slicer.data \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ + .dimension(slicer.dimensions.timestamp(f.annually)) \ + .reference(f.DayOverDay(slicer.dimensions.timestamp)) \ + .query + + self.assertEqual('SELECT ' + 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) ' + '"$d$timestamp",' + '"$base"."$m$votes" "$m$votes",' + '"$dod"."$m$votes" "$m$votes_dod" ' + 'FROM ' + + '(' # nested + 'SELECT ' + 'TRUNC("timestamp",\'Y\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$base" ' # end-nested + + 'FULL OUTER JOIN (' # nested + 'SELECT ' + 'TRUNC("timestamp",\'Y\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$dod" ' # end-nested + + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_dimension_with_multiple_references(self): + query = slicer.data \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ + .dimension(slicer.dimensions.timestamp) \ + .reference(f.DayOverDay(slicer.dimensions.timestamp)) \ + .reference(f.YearOverYear(slicer.dimensions.timestamp, delta_percent=True)) \ + .query + + self.assertEqual('SELECT ' + + 'COALESCE(' + '"$base"."$d$timestamp",' + 'TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp"),' + 'TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp")' + ') "$d$timestamp",' + + '"$base"."$m$votes" "$m$votes",' + '"$dod"."$m$votes" "$m$votes_dod",' + '("$base"."$m$votes"-"$yoy"."$m$votes")*100/NULLIF("$yoy"."$m$votes",' + '0) "$m$votes_yoy_delta_percent" ' + 'FROM ' + + '(' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$base" ' # end-nested + + 'FULL OUTER JOIN (' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$dod" ' # end-nested + + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' + + 'FULL OUTER JOIN (' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$yoy" ' # end-nested + + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp") ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_reference_joins_nested_query_on_dimensions(self): + query = slicer.data \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ + .dimension(slicer.dimensions.timestamp) \ + .dimension(slicer.dimensions.political_party) \ + .reference(f.YearOverYear(slicer.dimensions.timestamp)) \ + .query + + self.assertEqual('SELECT ' + 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp")) ' + '"$d$timestamp",' + 'COALESCE("$base"."$d$political_party","$yoy"."$d$political_party") "$d$political_party",' + '"$base"."$m$votes" "$m$votes",' + '"$yoy"."$m$votes" "$m$votes_yoy" ' + 'FROM ' + + '(' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + '"political_party" "$d$political_party",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp","$d$political_party"' + ') "$base" ' # end-nested + + 'FULL OUTER JOIN (' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + '"political_party" "$d$political_party",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp","$d$political_party"' + ') "$yoy" ' # end-nested + + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp") ' + 'AND "$base"."$d$political_party"="$yoy"."$d$political_party" ' + 'ORDER BY "$d$timestamp","$d$political_party"', str(query)) + + def test_reference_with_unique_dimension_includes_display_definition(self): + query = slicer.data \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ + .dimension(slicer.dimensions.timestamp) \ + .dimension(slicer.dimensions.candidate) \ + .reference(f.YearOverYear(slicer.dimensions.timestamp)) \ + .query + + self.assertEqual('SELECT ' + 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp")) ' + '"$d$timestamp",' + 'COALESCE("$base"."$d$candidate","$yoy"."$d$candidate") "$d$candidate",' + 'COALESCE("$base"."$d$candidate_display","$yoy"."$d$candidate_display") ' + '"$d$candidate_display",' + '"$base"."$m$votes" "$m$votes",' + '"$yoy"."$m$votes" "$m$votes_yoy" ' + 'FROM ' + + '(' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + '"candidate_id" "$d$candidate",' + '"candidate_name" "$d$candidate_display",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp","$d$candidate","$d$candidate_display"' + ') "$base" ' # end-nested + + 'FULL OUTER JOIN (' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + '"candidate_id" "$d$candidate",' + '"candidate_name" "$d$candidate_display",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp","$d$candidate","$d$candidate_display"' + ') "$yoy" ' # end-nested + + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp") ' + 'AND "$base"."$d$candidate"="$yoy"."$d$candidate" ' + 'ORDER BY "$d$timestamp","$d$candidate_display"', str(query)) + + def test_adjust_reference_dimension_filters_in_reference_query(self): + query = slicer.data \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ + .dimension(slicer.dimensions.timestamp) \ + .reference(f.DayOverDay(slicer.dimensions.timestamp)) \ + .filter(slicer.dimensions.timestamp + .between(date(2018, 1, 1), date(2018, 1, 31))) \ + .query + + self.assertEqual('SELECT ' + 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) ' + '"$d$timestamp",' + '"$base"."$m$votes" "$m$votes",' + '"$dod"."$m$votes" "$m$votes_dod" ' + 'FROM ' + + '(' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "timestamp" BETWEEN \'2018-01-01\' AND \'2018-01-31\' ' + 'GROUP BY "$d$timestamp"' + ') "$base" ' # end-nested + + 'FULL OUTER JOIN (' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE TIMESTAMPADD(\'day\',1,"timestamp") BETWEEN \'2018-01-01\' AND \'2018-01-31\' ' + 'GROUP BY "$d$timestamp"' + ') "$dod" ' # end-nested + + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_adjust_reference_dimension_filters_in_reference_query_with_multiple_filters(self): + query = slicer.data \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ + .dimension(slicer.dimensions.timestamp) \ + .reference(f.DayOverDay(slicer.dimensions.timestamp)) \ + .filter(slicer.dimensions.timestamp + .between(date(2018, 1, 1), date(2018, 1, 31))) \ + .filter(slicer.dimensions.political_party + .isin(['d'])) \ + .query + + self.assertEqual('SELECT ' + 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) ' + '"$d$timestamp",' + '"$base"."$m$votes" "$m$votes",' + '"$dod"."$m$votes" "$m$votes_dod" ' + 'FROM ' + + '(' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "timestamp" BETWEEN \'2018-01-01\' AND \'2018-01-31\' ' + 'AND "political_party" IN (\'d\') ' + 'GROUP BY "$d$timestamp"' + ') "$base" ' # end-nested + + 'FULL OUTER JOIN (' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE TIMESTAMPADD(\'day\',1,"timestamp") BETWEEN \'2018-01-01\' AND \'2018-01-31\' ' + 'AND "political_party" IN (\'d\') ' + 'GROUP BY "$d$timestamp"' + ') "$dod" ' # end-nested + + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_adapt_dow_for_leap_year_for_yoy_reference(self): + query = slicer.data \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ + .dimension(slicer.dimensions.timestamp(f.weekly)) \ + .reference(f.YearOverYear(slicer.dimensions.timestamp)) \ + .query + + self.assertEqual('SELECT ' + 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp")) ' + '"$d$timestamp",' + '"$base"."$m$votes" "$m$votes",' + '"$yoy"."$m$votes" "$m$votes_yoy" ' + 'FROM ' + + '(' # nested + 'SELECT ' + 'TRUNC("timestamp",\'IW\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$base" ' # end-nested + + 'FULL OUTER JOIN (' # nested + 'SELECT ' + 'TIMESTAMPADD(\'year\',-1,TRUNC(TIMESTAMPADD(\'year\',1,"timestamp"),\'IW\')) "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$yoy" ' # end-nested + + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp") ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_adapt_dow_for_leap_year_for_yoy_delta_reference(self): + query = slicer.data \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ + .dimension(slicer.dimensions.timestamp(f.weekly)) \ + .reference(f.YearOverYear(slicer.dimensions.timestamp, delta=True)) \ + .query + + self.assertEqual('SELECT ' + 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp")) ' + '"$d$timestamp",' + '"$base"."$m$votes" "$m$votes",' + '"$base"."$m$votes"-"$yoy"."$m$votes" "$m$votes_yoy_delta" ' + 'FROM ' + + '(' # nested + 'SELECT ' + 'TRUNC("timestamp",\'IW\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$base" ' # end-nested + + 'FULL OUTER JOIN (' # nested + 'SELECT ' + 'TIMESTAMPADD(\'year\',-1,TRUNC(TIMESTAMPADD(\'year\',1,"timestamp"),\'IW\')) "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$yoy" ' # end-nested + + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp") ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_adapt_dow_for_leap_year_for_yoy_delta_percent_reference(self): + query = slicer.data \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ + .dimension(slicer.dimensions.timestamp(f.weekly)) \ + .reference(f.YearOverYear(slicer.dimensions.timestamp, delta_percent=True)) \ + .query + + self.assertEqual('SELECT ' + 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp")) ' + '"$d$timestamp",' + '"$base"."$m$votes" "$m$votes",' + '("$base"."$m$votes"-"$yoy"."$m$votes")*100/NULLIF("$yoy"."$m$votes",' + '0) "$m$votes_yoy_delta_percent" ' + 'FROM ' + + '(' # nested + 'SELECT ' + 'TRUNC("timestamp",\'IW\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$base" ' # end-nested + + 'FULL OUTER JOIN (' # nested + 'SELECT ' + 'TIMESTAMPADD(\'year\',-1,TRUNC(TIMESTAMPADD(\'year\',1,"timestamp"),\'IW\')) "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$yoy" ' # end-nested + + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp") ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_adapt_dow_for_leap_year_for_yoy_reference_with_date_filter(self): + query = slicer.data \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ + .dimension(slicer.dimensions.timestamp(f.weekly)) \ + .reference(f.YearOverYear(slicer.dimensions.timestamp)) \ + .filter(slicer.dimensions.timestamp.between(date(2018, 1, 1), date(2018, 1, 31))) \ + .query + + self.assertEqual('SELECT ' + 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp")) ' + '"$d$timestamp",' + '"$base"."$m$votes" "$m$votes",' + '"$yoy"."$m$votes" "$m$votes_yoy" ' + 'FROM ' + + '(' # nested + 'SELECT ' + 'TRUNC("timestamp",\'IW\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE "timestamp" BETWEEN \'2018-01-01\' AND \'2018-01-31\' ' + 'GROUP BY "$d$timestamp"' + ') "$base" ' # end-nested + + 'FULL OUTER JOIN (' # nested + 'SELECT ' + 'TIMESTAMPADD(\'year\',-1,TRUNC(TIMESTAMPADD(\'year\',1,"timestamp"),\'IW\')) "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'WHERE TIMESTAMPADD(\'year\',1,"timestamp") BETWEEN \'2018-01-01\' AND \'2018-01-31\' ' + 'GROUP BY "$d$timestamp"' + ') "$yoy" ' # end-nested + + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp") ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_adding_duplicate_reference_does_not_join_more_queries(self): + query = slicer.data \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ + .dimension(slicer.dimensions.timestamp) \ + .reference(f.DayOverDay(slicer.dimensions.timestamp), + f.DayOverDay(slicer.dimensions.timestamp)) \ + .query + + self.assertEqual('SELECT ' + 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) ' + '"$d$timestamp",' + '"$base"."$m$votes" "$m$votes",' + '"$dod"."$m$votes" "$m$votes_dod" ' + 'FROM ' + + '(' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$base" ' # end-nested + + 'FULL OUTER JOIN (' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$dod" ' # end-nested + + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_use_same_nested_query_for_joining_references_with_same_period_and_dimension(self): + query = slicer.data \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ + .dimension(slicer.dimensions.timestamp) \ + .reference(f.DayOverDay(slicer.dimensions.timestamp), + f.DayOverDay(slicer.dimensions.timestamp, delta=True), + f.DayOverDay(slicer.dimensions.timestamp, delta_percent=True)) \ + .query + + self.assertEqual('SELECT ' + 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) ' + '"$d$timestamp",' + '"$base"."$m$votes" "$m$votes",' + '"$dod"."$m$votes" "$m$votes_dod",' + '"$base"."$m$votes"-"$dod"."$m$votes" "$m$votes_dod_delta",' + '("$base"."$m$votes"-"$dod"."$m$votes")*100/NULLIF("$dod"."$m$votes",' + '0) "$m$votes_dod_delta_percent" ' + 'FROM ' + + '(' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$base" ' # end-nested + + 'FULL OUTER JOIN (' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$dod" ' # end-nested + + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' + 'ORDER BY "$d$timestamp"', str(query)) + + def test_use_same_nested_query_for_joining_references_with_same_period_and_dimension_with_different_periods(self): + query = slicer.data \ + .widget(f.HighCharts() + .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ + .dimension(slicer.dimensions.timestamp) \ + .reference(f.DayOverDay(slicer.dimensions.timestamp), + f.DayOverDay(slicer.dimensions.timestamp, delta=True), + f.YearOverYear(slicer.dimensions.timestamp), + f.YearOverYear(slicer.dimensions.timestamp, delta=True)) \ + .query + + self.assertEqual('SELECT ' + 'COALESCE(' + '"$base"."$d$timestamp",' + 'TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp"),' + 'TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp")' + ') "$d$timestamp",' + '"$base"."$m$votes" "$m$votes",' + '"$dod"."$m$votes" "$m$votes_dod",' + '"$base"."$m$votes"-"$dod"."$m$votes" "$m$votes_dod_delta",' + '"$yoy"."$m$votes" "$m$votes_yoy",' + '"$base"."$m$votes"-"$yoy"."$m$votes" "$m$votes_yoy_delta" ' + 'FROM ' + + '(' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$base" ' # end-nested + + 'FULL OUTER JOIN (' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$dod" ' # end-nested + + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' + + 'FULL OUTER JOIN (' # nested + 'SELECT ' + 'TRUNC("timestamp",\'DD\') "$d$timestamp",' + 'SUM("votes") "$m$votes" ' + 'FROM "politics"."politician" ' + 'GROUP BY "$d$timestamp"' + ') "$yoy" ' # end-nested + + 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp") ' + 'ORDER BY "$d$timestamp"', str(query)) diff --git a/fireant/tests/slicer/queries/test_build_render.py b/fireant/tests/slicer/queries/test_build_render.py new file mode 100644 index 00000000..93e8028b --- /dev/null +++ b/fireant/tests/slicer/queries/test_build_render.py @@ -0,0 +1,147 @@ +from unittest import TestCase +from unittest.mock import ( + ANY, + Mock, + patch, +) + +import fireant as f +from fireant.utils import ( + format_metric_key, +) +from ..matchers import ( + DimensionMatcher, +) +from ..mocks import slicer + + +# noinspection SqlDialectInspection,SqlNoDataSourceInspection +@patch('fireant.slicer.queries.builder.fetch_data') +class QueryBuilderRenderTests(TestCase): + def test_pass_slicer_database_as_arg(self, mock_fetch_data: Mock): + mock_widget = f.Widget(slicer.metrics.votes) + mock_widget.transform = Mock() + + slicer.data \ + .widget(mock_widget) \ + .fetch() + + mock_fetch_data.assert_called_once_with(slicer.database, + ANY, + dimensions=ANY) + + def test_pass_query_from_builder_as_arg(self, mock_fetch_data: Mock): + mock_widget = f.Widget(slicer.metrics.votes) + mock_widget.transform = Mock() + + slicer.data \ + .widget(mock_widget) \ + .fetch() + + mock_fetch_data.assert_called_once_with(ANY, + 'SELECT SUM("votes") "$m$votes" ' + 'FROM "politics"."politician"', + dimensions=ANY) + + def test_builder_dimensions_as_arg_with_zero_dimensions(self, mock_fetch_data: Mock): + mock_widget = f.Widget(slicer.metrics.votes) + mock_widget.transform = Mock() + + slicer.data \ + .widget(mock_widget) \ + .fetch() + + mock_fetch_data.assert_called_once_with(ANY, ANY, dimensions=[]) + + def test_builder_dimensions_as_arg_with_one_dimension(self, mock_fetch_data: Mock): + mock_widget = f.Widget(slicer.metrics.votes) + mock_widget.transform = Mock() + + dimensions = [slicer.dimensions.state] + + slicer.data \ + .widget(mock_widget) \ + .dimension(*dimensions) \ + .fetch() + + mock_fetch_data.assert_called_once_with(ANY, ANY, dimensions=DimensionMatcher(*dimensions)) + + def test_builder_dimensions_as_arg_with_multiple_dimensions(self, mock_fetch_data: Mock): + mock_widget = f.Widget(slicer.metrics.votes) + mock_widget.transform = Mock() + + dimensions = slicer.dimensions.timestamp, slicer.dimensions.state, slicer.dimensions.political_party + + slicer.data \ + .widget(mock_widget) \ + .dimension(*dimensions) \ + .fetch() + + mock_fetch_data.assert_called_once_with(ANY, ANY, dimensions=DimensionMatcher(*dimensions)) + + def test_call_transform_on_widget(self, mock_fetch_data: Mock): + mock_widget = f.Widget(slicer.metrics.votes) + mock_widget.transform = Mock() + + # Need to keep widget the last call in the chain otherwise the object gets cloned and the assertion won't work + slicer.data \ + .dimension(slicer.dimensions.timestamp) \ + .widget(mock_widget) \ + .fetch() + + mock_widget.transform.assert_called_once_with(mock_fetch_data.return_value, + slicer, + DimensionMatcher(slicer.dimensions.timestamp), + []) + + def test_returns_results_from_widget_transform(self, mock_fetch_data: Mock): + mock_widget = f.Widget(slicer.metrics.votes) + mock_widget.transform = Mock() + + # Need to keep widget the last call in the chain otherwise the object gets cloned and the assertion won't work + result = slicer.data \ + .dimension(slicer.dimensions.timestamp) \ + .widget(mock_widget) \ + .fetch() + + self.assertListEqual(result, [mock_widget.transform.return_value]) + + def test_operations_evaluated(self, mock_fetch_data: Mock): + mock_operation = Mock(name='mock_operation ', spec=f.Operation) + mock_operation.key, mock_operation.definition = 'mock_operation', slicer.table.abc + mock_operation.metrics = [] + + mock_widget = f.Widget(mock_operation) + mock_widget.transform = Mock() + + mock_df = {} + mock_fetch_data.return_value = mock_df + + # Need to keep widget the last call in the chain otherwise the object gets cloned and the assertion won't work + slicer.data \ + .dimension(slicer.dimensions.timestamp) \ + .widget(mock_widget) \ + .fetch() + + mock_operation.apply.assert_called_once_with(mock_df) + + def test_operations_results_stored_in_data_frame(self, mock_fetch_data: Mock): + mock_operation = Mock(name='mock_operation ', spec=f.Operation) + mock_operation.key, mock_operation.definition = 'mock_operation', slicer.table.abc + mock_operation.metrics = [] + + mock_widget = f.Widget(mock_operation) + mock_widget.transform = Mock() + + mock_df = {} + mock_fetch_data.return_value = mock_df + + # Need to keep widget the last call in the chain otherwise the object gets cloned and the assertion won't work + slicer.data \ + .dimension(slicer.dimensions.timestamp) \ + .widget(mock_widget) \ + .fetch() + + f_op_key = format_metric_key(mock_operation.key) + self.assertIn(f_op_key, mock_df) + self.assertEqual(mock_df[f_op_key], mock_operation.apply.return_value) diff --git a/fireant/tests/slicer/queries/test_builder.py b/fireant/tests/slicer/queries/test_builder.py index 769aa72d..e9ea9993 100644 --- a/fireant/tests/slicer/queries/test_builder.py +++ b/fireant/tests/slicer/queries/test_builder.py @@ -1,17 +1,7 @@ -from datetime import date from unittest import TestCase -from unittest.mock import ( - ANY, - Mock, - patch, -) - -from pypika import Order import fireant as f from fireant.slicer.exceptions import MetricRequiredException -from fireant.utils import format_metric_key -from ..matchers import DimensionMatcher from ..mocks import slicer @@ -41,2244 +31,6 @@ def test_orderby_is_immutable(self): self.assertIsNot(query1, query2) -# noinspection SqlDialectInspection,SqlNoDataSourceInspection -class QueryBuilderMetricTests(TestCase): - maxDiff = None - - def test_build_query_with_single_metric(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician"', str(query)) - - def test_build_query_with_multiple_metrics(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes, slicer.metrics.wins)) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes",' - 'SUM("is_winner") "$m$wins" ' - 'FROM "politics"."politician"', str(query)) - - def test_build_query_with_multiple_visualizations(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .widget(f.DataTablesJS(slicer.metrics.wins)) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes",' - 'SUM("is_winner") "$m$wins" ' - 'FROM "politics"."politician"', str(query)) - - def test_build_query_for_chart_visualization_with_single_axis(self): - query = slicer.data \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician"', str(query)) - - def test_build_query_for_chart_visualization_with_multiple_axes(self): - query = slicer.data \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes)) - .axis(f.HighCharts.LineChart(slicer.metrics.wins))) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes",' - 'SUM("is_winner") "$m$wins" ' - 'FROM "politics"."politician"', str(query)) - - -# noinspection SqlDialectInspection,SqlNoDataSourceInspection -class QueryBuilderDimensionTests(TestCase): - maxDiff = None - - def test_build_query_with_datetime_dimension(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.timestamp) \ - .query - - self.assertEqual('SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp" ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_build_query_with_datetime_dimension_hourly(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.timestamp(f.hourly)) \ - .query - - self.assertEqual('SELECT ' - 'TRUNC("timestamp",\'HH\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp" ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_build_query_with_datetime_dimension_daily(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.timestamp(f.daily)) \ - .query - - self.assertEqual('SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp" ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_build_query_with_datetime_dimension_weekly(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.timestamp(f.weekly)) \ - .query - - self.assertEqual('SELECT ' - 'TRUNC("timestamp",\'IW\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp" ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_build_query_with_datetime_dimension_monthly(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.timestamp(f.monthly)) \ - .query - - self.assertEqual('SELECT ' - 'TRUNC("timestamp",\'MM\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp" ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_build_query_with_datetime_dimension_quarterly(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.timestamp(f.quarterly)) \ - .query - - self.assertEqual('SELECT ' - 'TRUNC("timestamp",\'Q\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp" ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_build_query_with_datetime_dimension_annually(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.timestamp(f.annually)) \ - .query - - self.assertEqual('SELECT ' - 'TRUNC("timestamp",\'Y\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp" ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_build_query_with_boolean_dimension(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.winner) \ - .query - - self.assertEqual('SELECT ' - '"is_winner" "$d$winner",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$winner" ' - 'ORDER BY "$d$winner"', str(query)) - - def test_build_query_with_categorical_dimension(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.political_party) \ - .query - - self.assertEqual('SELECT ' - '"political_party" "$d$political_party",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$political_party" ' - 'ORDER BY "$d$political_party"', str(query)) - - def test_build_query_with_unique_dimension(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.election) \ - .query - - self.assertEqual('SELECT ' - '"election_id" "$d$election",' - '"election_year" "$d$election_display",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$election","$d$election_display" ' - 'ORDER BY "$d$election_display"', str(query)) - - def test_build_query_with_pattern_dimension(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.pattern(['groupA%', 'groupB%'])) \ - .query - - self.assertEqual('SELECT ' - 'CASE ' - 'WHEN "pattern" LIKE \'groupA%\' THEN \'groupA%\' ' - 'WHEN "pattern" LIKE \'groupB%\' THEN \'groupB%\' ' - 'ELSE \'No Group\' ' - 'END "$d$pattern",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$pattern" ' - 'ORDER BY "$d$pattern"', str(query)) - - def test_build_query_with_pattern_no_values(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.pattern) \ - .query - - self.assertEqual('SELECT ' - '\'No Group\' "$d$pattern",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$pattern" ' - 'ORDER BY "$d$pattern"', str(query)) - - def test_build_query_with_multiple_dimensions(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.timestamp) \ - .dimension(slicer.dimensions.candidate) \ - .query - - self.assertEqual('SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - '"candidate_id" "$d$candidate",' - '"candidate_name" "$d$candidate_display",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp","$d$candidate","$d$candidate_display" ' - 'ORDER BY "$d$timestamp","$d$candidate_display"', str(query)) - - def test_build_query_with_multiple_dimensions_and_visualizations(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes, slicer.metrics.wins)) \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes)) - .axis(f.HighCharts.LineChart(slicer.metrics.wins))) \ - .dimension(slicer.dimensions.timestamp) \ - .dimension(slicer.dimensions.political_party) \ - .query - - self.assertEqual('SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - '"political_party" "$d$political_party",' - 'SUM("votes") "$m$votes",' - 'SUM("is_winner") "$m$wins" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp","$d$political_party" ' - 'ORDER BY "$d$timestamp","$d$political_party"', str(query)) - - -# noinspection SqlDialectInspection,SqlNoDataSourceInspection -class QueryBuilderDimensionTotalsTests(TestCase): - maxDiff = None - - def test_build_query_with_totals_cat_dimension(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.political_party.rollup()) \ - .query - - self.assertEqual('(SELECT ' - '"political_party" "$d$political_party",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$political_party") ' - - 'UNION ALL ' - - '(SELECT ' - 'NULL "$d$political_party",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician") ' - - 'ORDER BY "$d$political_party"', str(query)) - - def test_build_query_with_totals_uni_dimension(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.candidate.rollup()) \ - .query - - self.assertEqual('(SELECT ' - '"candidate_id" "$d$candidate",' - '"candidate_name" "$d$candidate_display",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$candidate","$d$candidate_display") ' - - 'UNION ALL ' - - '(SELECT ' - 'NULL "$d$candidate",' - 'NULL "$d$candidate_display",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician") ' - - 'ORDER BY "$d$candidate_display"', str(query)) - - def test_build_query_with_totals_on_dimension_and_subsequent_dimensions(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.timestamp, - slicer.dimensions.candidate.rollup(), - slicer.dimensions.political_party) \ - .query - - self.assertEqual('(SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - '"candidate_id" "$d$candidate",' - '"candidate_name" "$d$candidate_display",' - '"political_party" "$d$political_party",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp","$d$candidate","$d$candidate_display","$d$political_party") ' - - 'UNION ALL ' - - '(SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'NULL "$d$candidate",' - 'NULL "$d$candidate_display",' - 'NULL "$d$political_party",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp") ' - 'ORDER BY "$d$timestamp","$d$candidate_display","$d$political_party"', str(query)) - - def test_build_query_with_totals_on_multiple_dimensions_dimension(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.timestamp, - slicer.dimensions.candidate.rollup(), - slicer.dimensions.political_party.rollup()) \ - .query - - self.assertEqual('(SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - '"candidate_id" "$d$candidate",' - '"candidate_name" "$d$candidate_display",' - '"political_party" "$d$political_party",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp","$d$candidate","$d$candidate_display","$d$political_party") ' - - 'UNION ALL ' - - '(SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'NULL "$d$candidate",' - 'NULL "$d$candidate_display",' - 'NULL "$d$political_party",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp") ' - - 'UNION ALL ' - - '(SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - '"candidate_id" "$d$candidate",' - '"candidate_name" "$d$candidate_display",' - 'NULL "$d$political_party",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp","$d$candidate","$d$candidate_display") ' - - 'ORDER BY "$d$timestamp","$d$candidate_display","$d$political_party"', str(query)) - - def test_build_query_with_totals_cat_dimension_with_references(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.timestamp, - slicer.dimensions.political_party.rollup()) \ - .reference(f.DayOverDay(slicer.dimensions.timestamp)) \ - .query - - # Important that in reference queries when using totals that the null dimensions are omitted from the nested - # queries and selected in the container query - self.assertEqual('(SELECT ' - 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) "$d$timestamp",' - 'COALESCE("$base"."$d$political_party","$dod"."$d$political_party") "$d$political_party",' - '"$base"."$m$votes" "$m$votes",' - '"$dod"."$m$votes" "$m$votes_dod" ' - 'FROM (' - - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - '"political_party" "$d$political_party",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp","$d$political_party"' - ') "$base" ' - - 'FULL OUTER JOIN (' - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - '"political_party" "$d$political_party",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp","$d$political_party"' - ') "$dod" ' - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' - 'AND "$base"."$d$political_party"="$dod"."$d$political_party") ' - - 'UNION ALL ' - - '(SELECT ' - 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) "$d$timestamp",' - 'NULL "$d$political_party",' - '"$base"."$m$votes" "$m$votes",' - '"$dod"."$m$votes" "$m$votes_dod" ' - 'FROM (' - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$base" ' - - 'FULL OUTER JOIN (' - 'SELECT TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$dod" ' - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) ' - 'ORDER BY "$d$timestamp","$d$political_party"', str(query)) - - def test_build_query_with_totals_cat_dimension_with_references_and_date_filters(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.timestamp) \ - .dimension(slicer.dimensions.political_party.rollup()) \ - .reference(f.DayOverDay(slicer.dimensions.timestamp)) \ - .filter(slicer.dimensions.timestamp.between(date(2018, 1, 1), date(2019, 1, 1))) \ - .query - - self.assertEqual('(SELECT ' - 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) "$d$timestamp",' - 'COALESCE("$base"."$d$political_party","$dod"."$d$political_party") "$d$political_party",' - '"$base"."$m$votes" "$m$votes",' - '"$dod"."$m$votes" "$m$votes_dod" ' - 'FROM (' - - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - '"political_party" "$d$political_party",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "timestamp" BETWEEN \'2018-01-01\' AND \'2019-01-01\' ' - 'GROUP BY "$d$timestamp","$d$political_party"' - ') "$base" ' - - 'FULL OUTER JOIN (' - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - '"political_party" "$d$political_party",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE TIMESTAMPADD(\'day\',1,"timestamp") BETWEEN \'2018-01-01\' AND \'2019-01-01\' ' - 'GROUP BY "$d$timestamp","$d$political_party"' - ') "$dod" ' - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' - 'AND "$base"."$d$political_party"="$dod"."$d$political_party") ' - - 'UNION ALL ' - - '(SELECT ' - 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) "$d$timestamp",' - 'NULL "$d$political_party",' - '"$base"."$m$votes" "$m$votes",' - '"$dod"."$m$votes" "$m$votes_dod" ' - 'FROM (' - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "timestamp" BETWEEN \'2018-01-01\' AND \'2019-01-01\' ' - 'GROUP BY "$d$timestamp"' - ') "$base" ' - - 'FULL OUTER JOIN (' - 'SELECT TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE TIMESTAMPADD(\'day\',1,"timestamp") BETWEEN \'2018-01-01\' AND \'2019-01-01\' ' - 'GROUP BY "$d$timestamp"' - ') "$dod" ' - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) ' - 'ORDER BY "$d$timestamp","$d$political_party"', str(query)) - - -# noinspection SqlDialectInspection,SqlNoDataSourceInspection -class QueryBuilderDimensionFilterTests(TestCase): - maxDiff = None - - def test_build_query_with_filter_isin_categorical_dim(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.political_party.isin(['d'])) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "political_party" IN (\'d\')', str(query)) - - def test_build_query_with_filter_notin_categorical_dim(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.political_party.notin(['d'])) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "political_party" NOT IN (\'d\')', str(query)) - - def test_build_query_with_filter_like_categorical_dim(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.political_party.like('Rep%')) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "political_party" LIKE \'Rep%\'', str(query)) - - def test_build_query_with_filter_not_like_categorical_dim(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.political_party.not_like('Rep%')) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "political_party" NOT LIKE \'Rep%\'', str(query)) - - def test_build_query_with_filter_isin_unique_dim(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.candidate.isin([1])) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "candidate_id" IN (1)', str(query)) - - def test_build_query_with_filter_notin_unique_dim(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.candidate.notin([1])) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "candidate_id" NOT IN (1)', str(query)) - - def test_build_query_with_filter_isin_unique_dim_display(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.candidate.isin(['Donald Trump'], use_display=True)) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "candidate_name" IN (\'Donald Trump\')', str(query)) - - def test_build_query_with_filter_notin_unique_dim_display(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.candidate.notin(['Donald Trump'], use_display=True)) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "candidate_name" NOT IN (\'Donald Trump\')', str(query)) - - def test_build_query_with_filter_like_unique_dim(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.candidate.like('%Trump')) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "candidate_name" LIKE \'%Trump\'', str(query)) - - def test_build_query_with_filter_like_display_dim(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.candidate_display.like('%Trump')) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "candidate_name" LIKE \'%Trump\'', str(query)) - - def test_build_query_with_filter_not_like_unique_dim(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.candidate.not_like('%Trump')) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "candidate_name" NOT LIKE \'%Trump\'', str(query)) - - def test_build_query_with_filter_not_like_display_dim(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.candidate_display.not_like('%Trump')) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "candidate_name" NOT LIKE \'%Trump\'', str(query)) - - def test_build_query_with_filter_like_categorical_dim_multiple_patterns(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.political_party.like('Rep%', 'Dem%')) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "political_party" LIKE \'Rep%\' ' - 'OR "political_party" LIKE \'Dem%\'', str(query)) - - def test_build_query_with_filter_not_like_categorical_dim_multiple_patterns(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.political_party.not_like('Rep%', 'Dem%')) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "political_party" NOT LIKE \'Rep%\' ' - 'OR "political_party" NOT LIKE \'Dem%\'', str(query)) - - def test_build_query_with_filter_like_pattern_dim_multiple_patterns(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.pattern.like('a%', 'b%')) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "pattern" LIKE \'a%\' ' - 'OR "pattern" LIKE \'b%\'', str(query)) - - def test_build_query_with_filter_not_like_pattern_dim_multiple_patterns(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.pattern.not_like('a%', 'b%')) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "pattern" NOT LIKE \'a%\' ' - 'OR "pattern" NOT LIKE \'b%\'', str(query)) - - def test_build_query_with_filter_like_unique_dim_multiple_patterns(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.candidate.like('%Trump', '%Clinton')) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "candidate_name" LIKE \'%Trump\' ' - 'OR "candidate_name" LIKE \'%Clinton\'', str(query)) - - def test_build_query_with_filter_like_display_dim_multiple_patterns(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.candidate_display.like('%Trump', '%Clinton')) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "candidate_name" LIKE \'%Trump\' ' - 'OR "candidate_name" LIKE \'%Clinton\'', str(query)) - - def test_build_query_with_filter_not_like_unique_dim_multiple_patterns(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.candidate.not_like('%Trump', '%Clinton')) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "candidate_name" NOT LIKE \'%Trump\' ' - 'OR "candidate_name" NOT LIKE \'%Clinton\'', str(query)) - - def test_build_query_with_filter_not_like_display_dim_multiple_patterns(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.candidate_display.not_like('%Trump', '%Clinton')) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "candidate_name" NOT LIKE \'%Trump\' ' - 'OR "candidate_name" NOT LIKE \'%Clinton\'', str(query)) - - def test_build_query_with_filter_isin_raise_exception_when_display_definition_undefined(self): - with self.assertRaises(f.QueryException): - slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.deepjoin.isin([1], use_display=True)) - - def test_build_query_with_filter_notin_raise_exception_when_display_definition_undefined(self): - with self.assertRaises(f.QueryException): - slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.deepjoin.notin([1], use_display=True)) - - def test_build_query_with_filter_like_raise_exception_when_display_definition_undefined(self): - with self.assertRaises(f.QueryException): - slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.deepjoin.like('test')) - - def test_build_query_with_filter_not_like_raise_exception_when_display_definition_undefined(self): - with self.assertRaises(f.QueryException): - slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.deepjoin.not_like('test')) - - def test_build_query_with_filter_range_datetime_dimension(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.timestamp.between(date(2009, 1, 20), date(2017, 1, 20))) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "timestamp" BETWEEN \'2009-01-20\' AND \'2017-01-20\'', str(query)) - - def test_build_query_with_filter_boolean_true(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.winner.is_(True)) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "is_winner"', str(query)) - - def test_build_query_with_filter_boolean_false(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.winner.is_(False)) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE NOT "is_winner"', str(query)) - - -# noinspection SqlDialectInspection,SqlNoDataSourceInspection -class QueryBuilderMetricFilterTests(TestCase): - maxDiff = None - - def test_build_query_with_metric_filter_eq(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.metrics.votes == 5) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'HAVING SUM("votes")=5', str(query)) - - def test_build_query_with_metric_filter_eq_left(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(5 == slicer.metrics.votes) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'HAVING SUM("votes")=5', str(query)) - - def test_build_query_with_metric_filter_ne(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.metrics.votes != 5) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'HAVING SUM("votes")<>5', str(query)) - - def test_build_query_with_metric_filter_ne_left(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(5 != slicer.metrics.votes) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'HAVING SUM("votes")<>5', str(query)) - - def test_build_query_with_metric_filter_gt(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.metrics.votes > 5) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'HAVING SUM("votes")>5', str(query)) - - def test_build_query_with_metric_filter_gt_left(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(5 < slicer.metrics.votes) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'HAVING SUM("votes")>5', str(query)) - - def test_build_query_with_metric_filter_gte(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.metrics.votes >= 5) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'HAVING SUM("votes")>=5', str(query)) - - def test_build_query_with_metric_filter_gte_left(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(5 <= slicer.metrics.votes) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'HAVING SUM("votes")>=5', str(query)) - - def test_build_query_with_metric_filter_lt(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.metrics.votes < 5) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'HAVING SUM("votes")<5', str(query)) - - def test_build_query_with_metric_filter_lt_left(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(5 > slicer.metrics.votes) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'HAVING SUM("votes")<5', str(query)) - - def test_build_query_with_metric_filter_lte(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.metrics.votes <= 5) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'HAVING SUM("votes")<=5', str(query)) - - def test_build_query_with_metric_filter_lte_left(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(5 >= slicer.metrics.votes) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'HAVING SUM("votes")<=5', str(query)) - - -# noinspection SqlDialectInspection,SqlNoDataSourceInspection -class QueryBuilderOperationTests(TestCase): - maxDiff = None - - def test_build_query_with_cumsum_operation(self): - query = slicer.data \ - .widget(f.DataTablesJS(f.CumSum(slicer.metrics.votes))) \ - .dimension(slicer.dimensions.timestamp) \ - .query - - self.assertEqual('SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp" ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_build_query_with_cummean_operation(self): - query = slicer.data \ - .widget(f.DataTablesJS(f.CumMean(slicer.metrics.votes))) \ - .dimension(slicer.dimensions.timestamp) \ - .query - - self.assertEqual('SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp" ' - 'ORDER BY "$d$timestamp"', str(query)) - - -# noinspection SqlDialectInspection,SqlNoDataSourceInspection -class QueryBuilderDatetimeReferenceTests(TestCase): - maxDiff = None - - def test_single_reference_dod_with_no_dimension_uses_multiple_from_clauses_instead_of_joins(self): - query = slicer.data \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ - .reference(f.DayOverDay(slicer.dimensions.timestamp)) \ - .query - - self.assertEqual('SELECT ' - '"$base"."$m$votes" "$m$votes",' - '"$dod"."$m$votes" "$m$votes_dod" ' - - 'FROM (' - 'SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician"' - ') "$base",(' - 'SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician"' - ') "$dod"', str(query)) - - def test_single_reference_dod_with_dimension_but_not_reference_dimension_in_query_using_filter(self): - query = slicer.data \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ - .dimension(slicer.dimensions.political_party) \ - .reference(f.DayOverDay(slicer.dimensions.timestamp)) \ - .filter(slicer.dimensions.timestamp.between(date(2000, 1, 1), date(2000, 3, 1))) \ - .query - - self.assertEqual('SELECT ' - 'COALESCE("$base"."$d$political_party","$dod"."$d$political_party") "$d$political_party",' - '"$base"."$m$votes" "$m$votes",' - '"$dod"."$m$votes" "$m$votes_dod" ' - 'FROM ' - - '(' # nested - 'SELECT ' - '"political_party" "$d$political_party",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "timestamp" BETWEEN \'2000-01-01\' AND \'2000-03-01\' ' - 'GROUP BY "$d$political_party"' - ') "$base" ' # end-nested - - 'FULL OUTER JOIN (' # nested - 'SELECT ' - '"political_party" "$d$political_party",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE TIMESTAMPADD(\'day\',1,"timestamp") BETWEEN \'2000-01-01\' AND \'2000-03-01\' ' - 'GROUP BY "$d$political_party"' - ') "$dod" ' # end-nested - - 'ON "$base"."$d$political_party"="$dod"."$d$political_party" ' - 'ORDER BY "$d$political_party"', str(query)) - - def test_dimension_with_single_reference_dod(self): - query = slicer.data \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ - .dimension(slicer.dimensions.timestamp) \ - .reference(f.DayOverDay(slicer.dimensions.timestamp)) \ - .query - - self.assertEqual('SELECT ' - 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) "$d$timestamp",' - '"$base"."$m$votes" "$m$votes",' - '"$dod"."$m$votes" "$m$votes_dod" ' - 'FROM ' - - '(' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$base" ' # end-nested - - 'FULL OUTER JOIN (' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$dod" ' # end-nested - - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_dimension_with_single_reference_wow(self): - query = slicer.data \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ - .dimension(slicer.dimensions.timestamp) \ - .reference(f.WeekOverWeek(slicer.dimensions.timestamp)) \ - .query - - self.assertEqual('SELECT ' - 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'week\',1,"$wow"."$d$timestamp")) "$d$timestamp",' - '"$base"."$m$votes" "$m$votes",' - '"$wow"."$m$votes" "$m$votes_wow" ' - 'FROM ' - - '(' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$base" ' # end-nested - - 'FULL OUTER JOIN (' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$wow" ' # end-nested - - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'week\',1,"$wow"."$d$timestamp") ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_dimension_with_single_reference_mom(self): - query = slicer.data \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ - .dimension(slicer.dimensions.timestamp) \ - .reference(f.MonthOverMonth(slicer.dimensions.timestamp)) \ - .query - - self.assertEqual('SELECT ' - 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'month\',1,"$mom"."$d$timestamp")) "$d$timestamp",' - '"$base"."$m$votes" "$m$votes",' - '"$mom"."$m$votes" "$m$votes_mom" ' - 'FROM ' - - '(' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$base" ' # end-nested - - 'FULL OUTER JOIN (' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$mom" ' # end-nested - - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'month\',1,"$mom"."$d$timestamp") ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_dimension_with_single_reference_qoq(self): - query = slicer.data \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ - .dimension(slicer.dimensions.timestamp) \ - .reference(f.QuarterOverQuarter(slicer.dimensions.timestamp)) \ - .query - - self.assertEqual('SELECT ' - 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'quarter\',1,"$qoq"."$d$timestamp")) "$d$timestamp",' - '"$base"."$m$votes" "$m$votes",' - '"$qoq"."$m$votes" "$m$votes_qoq" ' - 'FROM ' - - '(' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$base" ' # end-nested - - 'FULL OUTER JOIN (' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$qoq" ' # end-nested - - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'quarter\',1,"$qoq"."$d$timestamp") ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_dimension_with_single_reference_yoy(self): - query = slicer.data \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ - .dimension(slicer.dimensions.timestamp) \ - .reference(f.YearOverYear(slicer.dimensions.timestamp)) \ - .query - - self.assertEqual('SELECT ' - 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp")) "$d$timestamp",' - '"$base"."$m$votes" "$m$votes",' - '"$yoy"."$m$votes" "$m$votes_yoy" ' - 'FROM ' - - '(' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$base" ' # end-nested - - 'FULL OUTER JOIN (' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$yoy" ' # end-nested - - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp") ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_dimension_with_single_reference_as_a_delta(self): - query = slicer.data \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ - .dimension(slicer.dimensions.timestamp) \ - .reference(f.DayOverDay(slicer.dimensions.timestamp, delta=True)) \ - .query - - self.assertEqual('SELECT ' - 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) "$d$timestamp",' - '"$base"."$m$votes" "$m$votes",' - '"$base"."$m$votes"-"$dod"."$m$votes" "$m$votes_dod_delta" ' - 'FROM ' - - '(' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$base" ' # end-nested - - 'FULL OUTER JOIN (' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$dod" ' # end-nested - - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_dimension_with_single_reference_as_a_delta_percentage(self): - query = slicer.data \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ - .dimension(slicer.dimensions.timestamp) \ - .reference(f.DayOverDay(slicer.dimensions.timestamp, delta_percent=True)) \ - .query - - self.assertEqual('SELECT ' - 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) "$d$timestamp",' - '"$base"."$m$votes" "$m$votes",' - '("$base"."$m$votes"-"$dod"."$m$votes")*100/NULLIF("$dod"."$m$votes",0) "$m$votes_dod_delta_percent" ' - 'FROM ' - - '(' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$base" ' # end-nested - - 'FULL OUTER JOIN (' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$dod" ' # end-nested - - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_reference_on_dimension_with_weekly_interval(self): - weekly_timestamp = slicer.dimensions.timestamp(f.weekly) - query = slicer.data \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ - .dimension(weekly_timestamp) \ - .reference(f.DayOverDay(weekly_timestamp)) \ - .query - - self.assertEqual('SELECT ' - 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) "$d$timestamp",' - '"$base"."$m$votes" "$m$votes",' - '"$dod"."$m$votes" "$m$votes_dod" ' - 'FROM ' - - '(' # nested - 'SELECT ' - 'TRUNC("timestamp",\'IW\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$base" ' # end-nested - - 'FULL OUTER JOIN (' # nested - 'SELECT ' - 'TRUNC("timestamp",\'IW\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$dod" ' # end-nested - - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_reference_on_dimension_with_weekly_interval_no_interval_on_reference(self): - query = slicer.data \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ - .dimension(slicer.dimensions.timestamp(f.weekly)) \ - .reference(f.DayOverDay(slicer.dimensions.timestamp)) \ - .query - - self.assertEqual('SELECT ' - 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) "$d$timestamp",' - '"$base"."$m$votes" "$m$votes",' - '"$dod"."$m$votes" "$m$votes_dod" ' - 'FROM ' - - '(' # nested - 'SELECT ' - 'TRUNC("timestamp",\'IW\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$base" ' # end-nested - - 'FULL OUTER JOIN (' # nested - 'SELECT ' - 'TRUNC("timestamp",\'IW\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$dod" ' # end-nested - - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_reference_on_dimension_with_monthly_interval(self): - query = slicer.data \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ - .dimension(slicer.dimensions.timestamp(f.monthly)) \ - .reference(f.DayOverDay(slicer.dimensions.timestamp)) \ - .query - - self.assertEqual('SELECT ' - 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) "$d$timestamp",' - '"$base"."$m$votes" "$m$votes",' - '"$dod"."$m$votes" "$m$votes_dod" ' - 'FROM ' - - '(' # nested - 'SELECT ' - 'TRUNC("timestamp",\'MM\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$base" ' # end-nested - - 'FULL OUTER JOIN (' # nested - 'SELECT ' - 'TRUNC("timestamp",\'MM\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$dod" ' # end-nested - - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_reference_on_dimension_with_quarterly_interval(self): - query = slicer.data \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ - .dimension(slicer.dimensions.timestamp(f.quarterly)) \ - .reference(f.DayOverDay(slicer.dimensions.timestamp)) \ - .query - - self.assertEqual('SELECT ' - 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) "$d$timestamp",' - '"$base"."$m$votes" "$m$votes",' - '"$dod"."$m$votes" "$m$votes_dod" ' - 'FROM ' - - '(' # nested - 'SELECT ' - 'TRUNC("timestamp",\'Q\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$base" ' # end-nested - - 'FULL OUTER JOIN (' # nested - 'SELECT ' - 'TRUNC("timestamp",\'Q\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$dod" ' # end-nested - - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_reference_on_dimension_with_annual_interval(self): - query = slicer.data \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ - .dimension(slicer.dimensions.timestamp(f.annually)) \ - .reference(f.DayOverDay(slicer.dimensions.timestamp)) \ - .query - - self.assertEqual('SELECT ' - 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) "$d$timestamp",' - '"$base"."$m$votes" "$m$votes",' - '"$dod"."$m$votes" "$m$votes_dod" ' - 'FROM ' - - '(' # nested - 'SELECT ' - 'TRUNC("timestamp",\'Y\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$base" ' # end-nested - - 'FULL OUTER JOIN (' # nested - 'SELECT ' - 'TRUNC("timestamp",\'Y\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$dod" ' # end-nested - - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_dimension_with_multiple_references(self): - query = slicer.data \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ - .dimension(slicer.dimensions.timestamp) \ - .reference(f.DayOverDay(slicer.dimensions.timestamp)) \ - .reference(f.YearOverYear(slicer.dimensions.timestamp, delta_percent=True)) \ - .query - - self.assertEqual('SELECT ' - - 'COALESCE(' - '"$base"."$d$timestamp",' - 'TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp"),' - 'TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp")' - ') "$d$timestamp",' - - '"$base"."$m$votes" "$m$votes",' - '"$dod"."$m$votes" "$m$votes_dod",' - '("$base"."$m$votes"-"$yoy"."$m$votes")*100/NULLIF("$yoy"."$m$votes",0) "$m$votes_yoy_delta_percent" ' - 'FROM ' - - '(' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$base" ' # end-nested - - 'FULL OUTER JOIN (' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$dod" ' # end-nested - - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' - - 'FULL OUTER JOIN (' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$yoy" ' # end-nested - - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp") ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_reference_joins_nested_query_on_dimensions(self): - query = slicer.data \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ - .dimension(slicer.dimensions.timestamp) \ - .dimension(slicer.dimensions.political_party) \ - .reference(f.YearOverYear(slicer.dimensions.timestamp)) \ - .query - - self.assertEqual('SELECT ' - 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp")) "$d$timestamp",' - 'COALESCE("$base"."$d$political_party","$yoy"."$d$political_party") "$d$political_party",' - '"$base"."$m$votes" "$m$votes",' - '"$yoy"."$m$votes" "$m$votes_yoy" ' - 'FROM ' - - '(' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - '"political_party" "$d$political_party",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp","$d$political_party"' - ') "$base" ' # end-nested - - 'FULL OUTER JOIN (' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - '"political_party" "$d$political_party",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp","$d$political_party"' - ') "$yoy" ' # end-nested - - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp") ' - 'AND "$base"."$d$political_party"="$yoy"."$d$political_party" ' - 'ORDER BY "$d$timestamp","$d$political_party"', str(query)) - - def test_reference_with_unique_dimension_includes_display_definition(self): - query = slicer.data \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ - .dimension(slicer.dimensions.timestamp) \ - .dimension(slicer.dimensions.candidate) \ - .reference(f.YearOverYear(slicer.dimensions.timestamp)) \ - .query - - self.assertEqual('SELECT ' - 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp")) "$d$timestamp",' - 'COALESCE("$base"."$d$candidate","$yoy"."$d$candidate") "$d$candidate",' - 'COALESCE("$base"."$d$candidate_display","$yoy"."$d$candidate_display") "$d$candidate_display",' - '"$base"."$m$votes" "$m$votes",' - '"$yoy"."$m$votes" "$m$votes_yoy" ' - 'FROM ' - - '(' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - '"candidate_id" "$d$candidate",' - '"candidate_name" "$d$candidate_display",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp","$d$candidate","$d$candidate_display"' - ') "$base" ' # end-nested - - 'FULL OUTER JOIN (' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - '"candidate_id" "$d$candidate",' - '"candidate_name" "$d$candidate_display",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp","$d$candidate","$d$candidate_display"' - ') "$yoy" ' # end-nested - - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp") ' - 'AND "$base"."$d$candidate"="$yoy"."$d$candidate" ' - 'ORDER BY "$d$timestamp","$d$candidate_display"', str(query)) - - def test_adjust_reference_dimension_filters_in_reference_query(self): - query = slicer.data \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ - .dimension(slicer.dimensions.timestamp) \ - .reference(f.DayOverDay(slicer.dimensions.timestamp)) \ - .filter(slicer.dimensions.timestamp - .between(date(2018, 1, 1), date(2018, 1, 31))) \ - .query - - self.assertEqual('SELECT ' - 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) "$d$timestamp",' - '"$base"."$m$votes" "$m$votes",' - '"$dod"."$m$votes" "$m$votes_dod" ' - 'FROM ' - - '(' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "timestamp" BETWEEN \'2018-01-01\' AND \'2018-01-31\' ' - 'GROUP BY "$d$timestamp"' - ') "$base" ' # end-nested - - 'FULL OUTER JOIN (' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE TIMESTAMPADD(\'day\',1,"timestamp") BETWEEN \'2018-01-01\' AND \'2018-01-31\' ' - 'GROUP BY "$d$timestamp"' - ') "$dod" ' # end-nested - - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_adjust_reference_dimension_filters_in_reference_query_with_multiple_filters(self): - query = slicer.data \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ - .dimension(slicer.dimensions.timestamp) \ - .reference(f.DayOverDay(slicer.dimensions.timestamp)) \ - .filter(slicer.dimensions.timestamp - .between(date(2018, 1, 1), date(2018, 1, 31))) \ - .filter(slicer.dimensions.political_party - .isin(['d'])) \ - .query - - self.assertEqual('SELECT ' - 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) "$d$timestamp",' - '"$base"."$m$votes" "$m$votes",' - '"$dod"."$m$votes" "$m$votes_dod" ' - 'FROM ' - - '(' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "timestamp" BETWEEN \'2018-01-01\' AND \'2018-01-31\' ' - 'AND "political_party" IN (\'d\') ' - 'GROUP BY "$d$timestamp"' - ') "$base" ' # end-nested - - 'FULL OUTER JOIN (' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE TIMESTAMPADD(\'day\',1,"timestamp") BETWEEN \'2018-01-01\' AND \'2018-01-31\' ' - 'AND "political_party" IN (\'d\') ' - 'GROUP BY "$d$timestamp"' - ') "$dod" ' # end-nested - - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_adapt_dow_for_leap_year_for_yoy_reference(self): - query = slicer.data \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ - .dimension(slicer.dimensions.timestamp(f.weekly)) \ - .reference(f.YearOverYear(slicer.dimensions.timestamp)) \ - .query - - self.assertEqual('SELECT ' - 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp")) "$d$timestamp",' - '"$base"."$m$votes" "$m$votes",' - '"$yoy"."$m$votes" "$m$votes_yoy" ' - 'FROM ' - - '(' # nested - 'SELECT ' - 'TRUNC("timestamp",\'IW\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$base" ' # end-nested - - 'FULL OUTER JOIN (' # nested - 'SELECT ' - 'TIMESTAMPADD(\'year\',-1,TRUNC(TIMESTAMPADD(\'year\',1,"timestamp"),\'IW\')) "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$yoy" ' # end-nested - - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp") ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_adapt_dow_for_leap_year_for_yoy_delta_reference(self): - query = slicer.data \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ - .dimension(slicer.dimensions.timestamp(f.weekly)) \ - .reference(f.YearOverYear(slicer.dimensions.timestamp, delta=True)) \ - .query - - self.assertEqual('SELECT ' - 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp")) "$d$timestamp",' - '"$base"."$m$votes" "$m$votes",' - '"$base"."$m$votes"-"$yoy"."$m$votes" "$m$votes_yoy_delta" ' - 'FROM ' - - '(' # nested - 'SELECT ' - 'TRUNC("timestamp",\'IW\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$base" ' # end-nested - - 'FULL OUTER JOIN (' # nested - 'SELECT ' - 'TIMESTAMPADD(\'year\',-1,TRUNC(TIMESTAMPADD(\'year\',1,"timestamp"),\'IW\')) "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$yoy" ' # end-nested - - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp") ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_adapt_dow_for_leap_year_for_yoy_delta_percent_reference(self): - query = slicer.data \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ - .dimension(slicer.dimensions.timestamp(f.weekly)) \ - .reference(f.YearOverYear(slicer.dimensions.timestamp, delta_percent=True)) \ - .query - - self.assertEqual('SELECT ' - 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp")) "$d$timestamp",' - '"$base"."$m$votes" "$m$votes",' - '("$base"."$m$votes"-"$yoy"."$m$votes")*100/NULLIF("$yoy"."$m$votes",0) "$m$votes_yoy_delta_percent" ' - 'FROM ' - - '(' # nested - 'SELECT ' - 'TRUNC("timestamp",\'IW\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$base" ' # end-nested - - 'FULL OUTER JOIN (' # nested - 'SELECT ' - 'TIMESTAMPADD(\'year\',-1,TRUNC(TIMESTAMPADD(\'year\',1,"timestamp"),\'IW\')) "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$yoy" ' # end-nested - - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp") ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_adapt_dow_for_leap_year_for_yoy_reference_with_date_filter(self): - query = slicer.data \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ - .dimension(slicer.dimensions.timestamp(f.weekly)) \ - .reference(f.YearOverYear(slicer.dimensions.timestamp)) \ - .filter(slicer.dimensions.timestamp.between(date(2018, 1, 1), date(2018, 1, 31))) \ - .query - - self.assertEqual('SELECT ' - 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp")) "$d$timestamp",' - '"$base"."$m$votes" "$m$votes",' - '"$yoy"."$m$votes" "$m$votes_yoy" ' - 'FROM ' - - '(' # nested - 'SELECT ' - 'TRUNC("timestamp",\'IW\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "timestamp" BETWEEN \'2018-01-01\' AND \'2018-01-31\' ' - 'GROUP BY "$d$timestamp"' - ') "$base" ' # end-nested - - 'FULL OUTER JOIN (' # nested - 'SELECT ' - 'TIMESTAMPADD(\'year\',-1,TRUNC(TIMESTAMPADD(\'year\',1,"timestamp"),\'IW\')) "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE TIMESTAMPADD(\'year\',1,"timestamp") BETWEEN \'2018-01-01\' AND \'2018-01-31\' ' - 'GROUP BY "$d$timestamp"' - ') "$yoy" ' # end-nested - - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp") ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_adding_duplicate_reference_does_not_join_more_queries(self): - query = slicer.data \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ - .dimension(slicer.dimensions.timestamp) \ - .reference(f.DayOverDay(slicer.dimensions.timestamp), - f.DayOverDay(slicer.dimensions.timestamp)) \ - .query - - self.assertEqual('SELECT ' - 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) "$d$timestamp",' - '"$base"."$m$votes" "$m$votes",' - '"$dod"."$m$votes" "$m$votes_dod" ' - 'FROM ' - - '(' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$base" ' # end-nested - - 'FULL OUTER JOIN (' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$dod" ' # end-nested - - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_use_same_nested_query_for_joining_references_with_same_period_and_dimension(self): - query = slicer.data \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ - .dimension(slicer.dimensions.timestamp) \ - .reference(f.DayOverDay(slicer.dimensions.timestamp), - f.DayOverDay(slicer.dimensions.timestamp, delta=True), - f.DayOverDay(slicer.dimensions.timestamp, delta_percent=True)) \ - .query - - self.assertEqual('SELECT ' - 'COALESCE("$base"."$d$timestamp",TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp")) "$d$timestamp",' - '"$base"."$m$votes" "$m$votes",' - '"$dod"."$m$votes" "$m$votes_dod",' - '"$base"."$m$votes"-"$dod"."$m$votes" "$m$votes_dod_delta",' - '("$base"."$m$votes"-"$dod"."$m$votes")*100/NULLIF("$dod"."$m$votes",0) "$m$votes_dod_delta_percent" ' - 'FROM ' - - '(' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$base" ' # end-nested - - 'FULL OUTER JOIN (' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$dod" ' # end-nested - - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_use_same_nested_query_for_joining_references_with_same_period_and_dimension_with_different_periods(self): - query = slicer.data \ - .widget(f.HighCharts() - .axis(f.HighCharts.LineChart(slicer.metrics.votes))) \ - .dimension(slicer.dimensions.timestamp) \ - .reference(f.DayOverDay(slicer.dimensions.timestamp), - f.DayOverDay(slicer.dimensions.timestamp, delta=True), - f.YearOverYear(slicer.dimensions.timestamp), - f.YearOverYear(slicer.dimensions.timestamp, delta=True)) \ - .query - - self.assertEqual('SELECT ' - 'COALESCE(' - '"$base"."$d$timestamp",' - 'TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp"),' - 'TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp")' - ') "$d$timestamp",' - '"$base"."$m$votes" "$m$votes",' - '"$dod"."$m$votes" "$m$votes_dod",' - '"$base"."$m$votes"-"$dod"."$m$votes" "$m$votes_dod_delta",' - '"$yoy"."$m$votes" "$m$votes_yoy",' - '"$base"."$m$votes"-"$yoy"."$m$votes" "$m$votes_yoy_delta" ' - 'FROM ' - - '(' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$base" ' # end-nested - - 'FULL OUTER JOIN (' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$dod" ' # end-nested - - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'day\',1,"$dod"."$d$timestamp") ' - - 'FULL OUTER JOIN (' # nested - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp"' - ') "$yoy" ' # end-nested - - 'ON "$base"."$d$timestamp"=TIMESTAMPADD(\'year\',1,"$yoy"."$d$timestamp") ' - 'ORDER BY "$d$timestamp"', str(query)) - - -# noinspection SqlDialectInspection,SqlNoDataSourceInspection -class QueryBuilderJoinTests(TestCase): - maxDiff = None - - def test_dimension_with_join_includes_join_in_query(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.timestamp) \ - .dimension(slicer.dimensions.district) \ - .query - - self.assertEqual('SELECT ' - 'TRUNC("politician"."timestamp",\'DD\') "$d$timestamp",' - '"politician"."district_id" "$d$district",' - '"district"."district_name" "$d$district_display",' - 'SUM("politician"."votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'OUTER JOIN "locations"."district" ' - 'ON "politician"."district_id"="district"."id" ' - 'GROUP BY "$d$timestamp","$d$district","$d$district_display" ' - 'ORDER BY "$d$timestamp","$d$district_display"', str(query)) - - def test_dimension_with_multiple_joins_includes_joins_ordered__in_query(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes, - slicer.metrics.voters)) \ - .dimension(slicer.dimensions.timestamp) \ - .dimension(slicer.dimensions.district) \ - .query - - self.assertEqual('SELECT ' - 'TRUNC("politician"."timestamp",\'DD\') "$d$timestamp",' - '"politician"."district_id" "$d$district",' - '"district"."district_name" "$d$district_display",' - 'SUM("politician"."votes") "$m$votes",' - 'COUNT("voter"."id") "$m$voters" ' - 'FROM "politics"."politician" ' - 'JOIN "politics"."voter" ' - 'ON "politician"."id"="voter"."politician_id" ' - 'OUTER JOIN "locations"."district" ' - 'ON "politician"."district_id"="district"."id" ' - 'GROUP BY "$d$timestamp","$d$district","$d$district_display" ' - 'ORDER BY "$d$timestamp","$d$district_display"', str(query)) - - def test_dimension_with_recursive_join_joins_all_join_tables(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.timestamp) \ - .dimension(slicer.dimensions.state) \ - .query - - self.assertEqual('SELECT ' - 'TRUNC("politician"."timestamp",\'DD\') "$d$timestamp",' - '"district"."state_id" "$d$state",' - '"state"."state_name" "$d$state_display",' - 'SUM("politician"."votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'OUTER JOIN "locations"."district" ' - 'ON "politician"."district_id"="district"."id" ' - 'JOIN "locations"."state" ' - 'ON "district"."state_id"="state"."id" ' - 'GROUP BY "$d$timestamp","$d$state","$d$state_display" ' - 'ORDER BY "$d$timestamp","$d$state_display"', str(query)) - - def test_metric_with_join_includes_join_in_query(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.voters)) \ - .dimension(slicer.dimensions.political_party) \ - .query - - self.assertEqual('SELECT ' - '"politician"."political_party" "$d$political_party",' - 'COUNT("voter"."id") "$m$voters" ' - 'FROM "politics"."politician" ' - 'JOIN "politics"."voter" ' - 'ON "politician"."id"="voter"."politician_id" ' - 'GROUP BY "$d$political_party" ' - 'ORDER BY "$d$political_party"', str(query)) - - def test_dimension_filter_with_join_on_display_definition_does_not_include_join_in_query(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.district.isin([1])) \ - .query - - self.assertEqual('SELECT ' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'WHERE "district_id" IN (1)', str(query)) - - def test_dimension_filter_display_field_with_join_includes_join_in_query(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.district.isin(['District 4'], use_display=True)) \ - .query - - self.assertEqual('SELECT ' - 'SUM("politician"."votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'OUTER JOIN "locations"."district" ' - 'ON "politician"."district_id"="district"."id" ' - 'WHERE "district"."district_name" IN (\'District 4\')', str(query)) - - def test_dimension_filter_with_recursive_join_includes_join_in_query(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.state.isin([1])) \ - .query - - self.assertEqual('SELECT ' - 'SUM("politician"."votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'OUTER JOIN "locations"."district" ' - 'ON "politician"."district_id"="district"."id" ' - 'WHERE "district"."state_id" IN (1)', str(query)) - - def test_dimension_filter_with_deep_recursive_join_includes_joins_in_query(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .filter(slicer.dimensions.deepjoin.isin([1])) \ - .query - - self.assertEqual('SELECT ' - 'SUM("politician"."votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'OUTER JOIN "locations"."district" ' - 'ON "politician"."district_id"="district"."id" ' - 'JOIN "locations"."state" ' - 'ON "district"."state_id"="state"."id" ' - 'JOIN "test"."deep" ' - 'ON "deep"."id"="state"."ref_id" ' - 'WHERE "deep"."id" IN (1)', str(query)) - - -class QueryBuilderOrderTests(TestCase): - maxDiff = None - - def test_build_query_order_by_dimension(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.timestamp) \ - .orderby(slicer.dimensions.timestamp) \ - .query - - self.assertEqual('SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp" ' - 'ORDER BY "$d$timestamp"', str(query)) - - def test_build_query_order_by_dimension_display(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.candidate) \ - .orderby(slicer.dimensions.candidate_display) \ - .query - - self.assertEqual('SELECT ' - '"candidate_id" "$d$candidate",' - '"candidate_name" "$d$candidate_display",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$candidate","$d$candidate_display" ' - 'ORDER BY "$d$candidate_display"', str(query)) - - def test_build_query_order_by_dimension_asc(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.timestamp) \ - .orderby(slicer.dimensions.timestamp, orientation=Order.asc) \ - .query - - self.assertEqual('SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp" ' - 'ORDER BY "$d$timestamp" ASC', str(query)) - - def test_build_query_order_by_dimension_desc(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.timestamp) \ - .orderby(slicer.dimensions.timestamp, orientation=Order.desc) \ - .query - - self.assertEqual('SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp" ' - 'ORDER BY "$d$timestamp" DESC', str(query)) - - def test_build_query_order_by_metric(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.timestamp) \ - .orderby(slicer.metrics.votes) \ - .query - - self.assertEqual('SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp" ' - 'ORDER BY "$m$votes"', str(query)) - - def test_build_query_order_by_metric_asc(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.timestamp) \ - .orderby(slicer.metrics.votes, orientation=Order.asc) \ - .query - - self.assertEqual('SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp" ' - 'ORDER BY "$m$votes" ASC', str(query)) - - def test_build_query_order_by_metric_desc(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.timestamp) \ - .orderby(slicer.metrics.votes, orientation=Order.desc) \ - .query - - self.assertEqual('SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp" ' - 'ORDER BY "$m$votes" DESC', str(query)) - - def test_build_query_order_by_multiple_dimensions(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.timestamp, slicer.dimensions.candidate) \ - .orderby(slicer.dimensions.timestamp) \ - .orderby(slicer.dimensions.candidate) \ - .query - - self.assertEqual('SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - '"candidate_id" "$d$candidate",' - '"candidate_name" "$d$candidate_display",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp","$d$candidate","$d$candidate_display" ' - 'ORDER BY "$d$timestamp","$d$candidate"', str(query)) - - def test_build_query_order_by_multiple_dimensions_with_different_orientations(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.timestamp, slicer.dimensions.candidate) \ - .orderby(slicer.dimensions.timestamp, orientation=Order.desc) \ - .orderby(slicer.dimensions.candidate, orientation=Order.asc) \ - .query - - self.assertEqual('SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - '"candidate_id" "$d$candidate",' - '"candidate_name" "$d$candidate_display",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp","$d$candidate","$d$candidate_display" ' - 'ORDER BY "$d$timestamp" DESC,"$d$candidate" ASC', str(query)) - - def test_build_query_order_by_metrics_and_dimensions(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.timestamp) \ - .orderby(slicer.dimensions.timestamp) \ - .orderby(slicer.metrics.votes) \ - .query - - self.assertEqual('SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp" ' - 'ORDER BY "$d$timestamp","$m$votes"', str(query)) - - def test_build_query_order_by_metrics_and_dimensions_with_different_orientations(self): - query = slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.timestamp) \ - .orderby(slicer.dimensions.timestamp, orientation=Order.asc) \ - .orderby(slicer.metrics.votes, orientation=Order.desc) \ - .query - - self.assertEqual('SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp" ' - 'ORDER BY "$d$timestamp" ASC,"$m$votes" DESC', str(query)) - - -@patch('fireant.slicer.queries.builder.fetch_data') -class QueryBuildPaginationTests(TestCase): - def test_set_limit(self, mock_fetch_data: Mock): - slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.timestamp) \ - .limit(20) \ - .fetch() - - mock_fetch_data.assert_called_once_with(ANY, - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp" ' - 'ORDER BY "$d$timestamp" LIMIT 20', - dimensions=DimensionMatcher(slicer.dimensions.timestamp)) - - def test_set_offset(self, mock_fetch_data: Mock): - slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.timestamp) \ - .offset(20) \ - .fetch() - - mock_fetch_data.assert_called_once_with(ANY, - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp" ' - 'ORDER BY "$d$timestamp" ' - 'OFFSET 20', - dimensions=DimensionMatcher(slicer.dimensions.timestamp)) - - def test_set_limit_and_offset(self, mock_fetch_data: Mock): - slicer.data \ - .widget(f.DataTablesJS(slicer.metrics.votes)) \ - .dimension(slicer.dimensions.timestamp) \ - .limit(20) \ - .offset(30) \ - .fetch() - - mock_fetch_data.assert_called_once_with(ANY, - 'SELECT ' - 'TRUNC("timestamp",\'DD\') "$d$timestamp",' - 'SUM("votes") "$m$votes" ' - 'FROM "politics"."politician" ' - 'GROUP BY "$d$timestamp" ' - 'ORDER BY "$d$timestamp" ' - 'LIMIT 20 ' - 'OFFSET 30', - dimensions=DimensionMatcher(slicer.dimensions.timestamp)) # noinspection SqlDialectInspection,SqlNoDataSourceInspection @@ -2297,132 +49,3 @@ def test_datatablesjs_requires_at_least_one_metric(self): slicer.data \ .widget(f.DataTablesJS()) - -# noinspection SqlDialectInspection,SqlNoDataSourceInspection -@patch('fireant.slicer.queries.builder.fetch_data') -class QueryBuilderRenderTests(TestCase): - def test_pass_slicer_database_as_arg(self, mock_fetch_data: Mock): - mock_widget = f.Widget(slicer.metrics.votes) - mock_widget.transform = Mock() - - slicer.data \ - .widget(mock_widget) \ - .fetch() - - mock_fetch_data.assert_called_once_with(slicer.database, - ANY, - dimensions=ANY) - - def test_pass_query_from_builder_as_arg(self, mock_fetch_data: Mock): - mock_widget = f.Widget(slicer.metrics.votes) - mock_widget.transform = Mock() - - slicer.data \ - .widget(mock_widget) \ - .fetch() - - mock_fetch_data.assert_called_once_with(ANY, - 'SELECT SUM("votes") "$m$votes" ' - 'FROM "politics"."politician"', - dimensions=ANY) - - def test_builder_dimensions_as_arg_with_zero_dimensions(self, mock_fetch_data: Mock): - mock_widget = f.Widget(slicer.metrics.votes) - mock_widget.transform = Mock() - - slicer.data \ - .widget(mock_widget) \ - .fetch() - - mock_fetch_data.assert_called_once_with(ANY, ANY, dimensions=[]) - - def test_builder_dimensions_as_arg_with_one_dimension(self, mock_fetch_data: Mock): - mock_widget = f.Widget(slicer.metrics.votes) - mock_widget.transform = Mock() - - dimensions = [slicer.dimensions.state] - - slicer.data \ - .widget(mock_widget) \ - .dimension(*dimensions) \ - .fetch() - - mock_fetch_data.assert_called_once_with(ANY, ANY, dimensions=DimensionMatcher(*dimensions)) - - def test_builder_dimensions_as_arg_with_multiple_dimensions(self, mock_fetch_data: Mock): - mock_widget = f.Widget(slicer.metrics.votes) - mock_widget.transform = Mock() - - dimensions = slicer.dimensions.timestamp, slicer.dimensions.state, slicer.dimensions.political_party - - slicer.data \ - .widget(mock_widget) \ - .dimension(*dimensions) \ - .fetch() - - mock_fetch_data.assert_called_once_with(ANY, ANY, dimensions=DimensionMatcher(*dimensions)) - - def test_call_transform_on_widget(self, mock_fetch_data: Mock): - mock_widget = f.Widget(slicer.metrics.votes) - mock_widget.transform = Mock() - - # Need to keep widget the last call in the chain otherwise the object gets cloned and the assertion won't work - slicer.data \ - .dimension(slicer.dimensions.timestamp) \ - .widget(mock_widget) \ - .fetch() - - mock_widget.transform.assert_called_once_with(mock_fetch_data.return_value, - slicer, - DimensionMatcher(slicer.dimensions.timestamp), - []) - - def test_returns_results_from_widget_transform(self, mock_fetch_data: Mock): - mock_widget = f.Widget(slicer.metrics.votes) - mock_widget.transform = Mock() - - # Need to keep widget the last call in the chain otherwise the object gets cloned and the assertion won't work - result = slicer.data \ - .dimension(slicer.dimensions.timestamp) \ - .widget(mock_widget) \ - .fetch() - - self.assertListEqual(result, [mock_widget.transform.return_value]) - - def test_operations_evaluated(self, mock_fetch_data: Mock): - mock_operation = Mock(name='mock_operation ', spec=f.Operation) - mock_operation.key, mock_operation.definition = 'mock_operation', slicer.table.abc - - mock_widget = f.Widget(mock_operation) - mock_widget.transform = Mock() - - mock_df = {} - mock_fetch_data.return_value = mock_df - - # Need to keep widget the last call in the chain otherwise the object gets cloned and the assertion won't work - slicer.data \ - .dimension(slicer.dimensions.timestamp) \ - .widget(mock_widget) \ - .fetch() - - mock_operation.apply.assert_called_once_with(mock_df) - - def test_operations_results_stored_in_data_frame(self, mock_fetch_data: Mock): - mock_operation = Mock(name='mock_operation ', spec=f.Operation) - mock_operation.key, mock_operation.definition = 'mock_operation', slicer.table.abc - - mock_widget = f.Widget(mock_operation) - mock_widget.transform = Mock() - - mock_df = {} - mock_fetch_data.return_value = mock_df - - # Need to keep widget the last call in the chain otherwise the object gets cloned and the assertion won't work - slicer.data \ - .dimension(slicer.dimensions.timestamp) \ - .widget(mock_widget) \ - .fetch() - - f_op_key = format_metric_key(mock_operation.key) - self.assertIn(f_op_key, mock_df) - self.assertEqual(mock_df[f_op_key], mock_operation.apply.return_value)