Merge pull request #233 from CartoDB/232-overviews-avg

Fix AVG computation in overview tables
This commit is contained in:
Carla 2016-04-15 11:10:26 +02:00
commit 20989e2f28
2 changed files with 17 additions and 3 deletions

View File

@ -529,6 +529,9 @@ AS $$
DECLARE
column_type TEXT;
qualified_column TEXT;
has_counter_column BOOLEAN;
feature_count TEXT;
total_feature_count TEXT;
BEGIN
IF table_alias <> '' THEN
qualified_column := Format('%I.%I', table_alias, column_name);
@ -538,12 +541,23 @@ BEGIN
column_type := CDB_ColumnType(reloid, column_name);
SELECT EXISTS (
SELECT * FROM CDB_ColumnNames(reloid) as colname WHERE colname = '_feature_count'
) INTO has_counter_column;
IF has_counter_column THEN
feature_count := '_feature_count';
total_feature_count := 'SUM(_feature_count)';
ELSE
feature_count := '1';
total_feature_count := 'count(*)';
END IF;
CASE column_type
WHEN 'double precision', 'real', 'integer', 'bigint', 'numeric' THEN
IF column_name = '_feature_count' THEN
RETURN 'SUM(_feature_count)';
ELSE
RETURN Format('AVG(%s)::' || column_type, qualified_column);
RETURN Format('SUM(%s*%s)/%s::' || column_type, qualified_column, feature_count, total_feature_count);
END IF;
WHEN 'text' THEN
-- TODO: we could define a new aggregate function that returns distinct

View File

@ -12,8 +12,8 @@ SELECT 1114
{_vovw_2_base_bare_t,_vovw_1_base_bare_t,_vovw_0_base_bare_t}
126
number,int_number,name,start
AVG(number)::double precision AS number,AVG(int_number)::integer AS int_number,CASE count(*) WHEN 1 THEN MIN(name) ELSE NULL END::text AS name,CASE count(*) WHEN 1 THEN MIN(start) ELSE NULL END::date AS start
AVG(tab.number)::double precision AS number,AVG(tab.int_number)::integer AS int_number,CASE count(*) WHEN 1 THEN MIN(tab.name) ELSE NULL END::text AS name,CASE count(*) WHEN 1 THEN MIN(tab.start) ELSE NULL END::date AS start
SUM(number*1)/count(*)::double precision AS number,SUM(int_number*1)/count(*)::integer AS int_number,CASE count(*) WHEN 1 THEN MIN(name) ELSE NULL END::text AS name,CASE count(*) WHEN 1 THEN MIN(start) ELSE NULL END::date AS start
SUM(tab.number*1)/count(*)::double precision AS number,SUM(tab.int_number*1)/count(*)::integer AS int_number,CASE count(*) WHEN 1 THEN MIN(tab.name) ELSE NULL END::text AS name,CASE count(*) WHEN 1 THEN MIN(tab.start) ELSE NULL END::date AS start
{_vovw_2_base_t,_vovw_1_base_t,_vovw_0_base_t}
126