From b19a5fc3dcccce2abd3163fe9e109594c18fa770 Mon Sep 17 00:00:00 2001 From: Paul Norman Date: Wed, 20 Apr 2016 16:07:00 -0700 Subject: [PATCH] Convert CDB_EqualIntervalBins to a single SQL statement and add float version --- scripts-available/CDB_EqualIntervalBins.sql | 44 +++++++++------------ 1 file changed, 19 insertions(+), 25 deletions(-) diff --git a/scripts-available/CDB_EqualIntervalBins.sql b/scripts-available/CDB_EqualIntervalBins.sql index 5f98084..eef914e 100644 --- a/scripts-available/CDB_EqualIntervalBins.sql +++ b/scripts-available/CDB_EqualIntervalBins.sql @@ -1,7 +1,7 @@ -- -- Calculate the equal interval bins for a given column -- --- @param in_array A numeric array of numbers to determine the best +-- @param in_array A numeric or double precision array of numbers to determine the best -- to determine the bin boundary -- -- @param breaks The number of bins you want to find. @@ -10,28 +10,22 @@ -- Returns: upper edges of bins -- -- - CREATE OR REPLACE FUNCTION CDB_EqualIntervalBins ( in_array NUMERIC[], breaks INT ) RETURNS NUMERIC[] as $$ -DECLARE - diff numeric; - min_val numeric; - max_val numeric; - tmp_val numeric; - i INT := 1; - reply numeric[]; -BEGIN - SELECT min(e), max(e) INTO min_val, max_val FROM ( SELECT unnest(in_array) e ) x WHERE e IS NOT NULL; - diff = (max_val - min_val) / breaks::numeric; - LOOP - IF i < breaks THEN - tmp_val = min_val + i::numeric * diff; - reply = array_append(reply, tmp_val); - i := i+1; - ELSE - reply = array_append(reply, max_val); - EXIT; - END IF; - END LOOP; - RETURN reply; -END; -$$ language plpgsql IMMUTABLE; +WITH stats AS ( + SELECT min(e), (max(e)-min(e))/breaks AS del + FROM (SELECT unnest(in_array) e) AS p) +SELECT array_agg(bins) + FROM ( + SELECT min + generate_series(1,breaks)*del AS bins + FROM stats) q; +$$ LANGUAGE SQL IMMUTABLE; + +CREATE OR REPLACE FUNCTION CDB_EqualIntervalBins ( in_array double precision[], breaks INT ) RETURNS double precision[] as $$ +WITH stats AS ( + SELECT min(e), (max(e)-min(e))/breaks AS del + FROM (SELECT unnest(in_array) e) AS p) +SELECT array_agg(bins) + FROM ( + SELECT min + generate_series(1,breaks)*del AS bins + FROM stats) q; +$$ LANGUAGE SQL IMMUTABLE;