diff --git a/lib/cartodb/models/dataview/histogram.js b/lib/cartodb/models/dataview/histogram.js index 9ec42906..42dd15d3 100644 --- a/lib/cartodb/models/dataview/histogram.js +++ b/lib/cartodb/models/dataview/histogram.js @@ -230,58 +230,61 @@ const dateOverrideBasicsQueryTpl = ctx => ` ) `; -var dateBinsQueryTpl = dot.template([ - '__cdb_bins AS (', - ' SELECT', - ' __cdb_bins_array,', - ' ARRAY_LENGTH(__cdb_bins_array, 1) AS __cdb_bins_number', - ' FROM (', - ' SELECT', - ' ARRAY(', - ' SELECT GENERATE_SERIES(', - ' __cdb_start_date::timestamptz,', - ' __cdb_end_date::timestamptz,', - ' {{?it._aggregation==="quarter"}}\'3 month\'{{??}}\'1 {{=it._aggregation}}\'{{?}}::interval', - ' )', - ' ) AS __cdb_bins_array', - ' FROM __cdb_basics', - ' ) __cdb_bins_array_query', - ')' -].join('\n')); +const dateBinsQueryTpl = ctx => ` + __cdb_bins AS ( + SELECT + __cdb_bins_array, + ARRAY_LENGTH(__cdb_bins_array, 1) AS __cdb_bins_number + FROM ( + SELECT + ARRAY( + SELECT GENERATE_SERIES( + __cdb_start_date::timestamptz, + __cdb_end_date::timestamptz, + ${ctx._aggregation === 'quarter' ? `'3 month'::interval` : `'1 ${ctx._aggregation}'::interval`} + ) + ) AS __cdb_bins_array + FROM __cdb_basics + ) __cdb_bins_array_query + ) +`; -var dateHistogramQueryTpl = dot.template([ - 'SELECT', - ' (__cdb_max_val - __cdb_min_val) / cast(__cdb_bins_number as float) AS bin_width,', - ' __cdb_bins_number AS bins_number,', - ' __cdb_nulls_count AS nulls_count,', - ' CASE WHEN __cdb_min_val = __cdb_max_val', - ' THEN 0', - ' ELSE GREATEST(1, LEAST(', - ' WIDTH_BUCKET(', - ' {{=it._column}}::timestamp AT TIME ZONE \'{{=it._offset}}\',', - ' __cdb_bins_array', - ' ),', - ' __cdb_bins_number', - ' )) - 1', - ' END AS bin,', - ' min(', - ' date_part(', - ' \'epoch\', ', - ' date_trunc(', - ' \'{{=it._aggregation}}\', {{=it._column}}::timestamp AT TIME ZONE \'{{=it._offset}}\'', - ' ) AT TIME ZONE \'{{=it._offset}}\'', - ' )', - ' )::numeric AS timestamp,', - ' date_part(\'epoch\', __cdb_start_date)::numeric AS timestamp_start,', - ' min(date_part(\'epoch\', {{=it._column}}))::numeric AS min,', - ' max(date_part(\'epoch\', {{=it._column}}))::numeric AS max,', - ' avg(date_part(\'epoch\', {{=it._column}}))::numeric AS avg,', - ' count(*) AS freq', - 'FROM ({{=it._query}}) __cdb_histogram, __cdb_basics, __cdb_bins, __cdb_nulls', - 'WHERE date_part(\'epoch\', {{=it._column}}) IS NOT NULL', - 'GROUP BY bin, bins_number, bin_width, nulls_count, timestamp_start', - 'ORDER BY bin' -].join('\n')); +const dateHistogramQueryTpl = ctx => ` + SELECT + (__cdb_max_val - __cdb_min_val) / cast(__cdb_bins_number as float) AS bin_width, + __cdb_bins_number AS bins_number, + __cdb_nulls_count AS nulls_count, + CASE WHEN __cdb_min_val = __cdb_max_val + THEN 0 + ELSE GREATEST( + 1, + LEAST( + WIDTH_BUCKET( + ${ctx._column}::timestamp AT TIME ZONE '${ctx._offset}', + __cdb_bins_array + ), + __cdb_bins_number + ) + ) - 1 + END AS bin, + min( + date_part( + 'epoch', + date_trunc( + '${ctx._aggregation}', ${ctx._column}::timestamp AT TIME ZONE '${ctx._offset}' + ) AT TIME ZONE '${ctx._offset}' + ) + )::numeric AS timestamp, + date_part('epoch', __cdb_start_date)::numeric AS timestamp_start, + min(date_part('epoch', ${ctx._column}))::numeric AS min, + max(date_part('epoch', ${ctx._column}))::numeric AS max, + avg(date_part('epoch', ${ctx._column}))::numeric AS avg, + count(*) AS freq + FROM (${ctx._query}) __cdb_histogram, __cdb_basics, __cdb_bins, __cdb_nulls + WHERE date_part('epoch', ${ctx._column}) IS NOT NULL + GROUP BY bin, bins_number, bin_width, nulls_count, timestamp_start + ORDER BY bin +`; var TYPE = 'histogram';