CREATE OR REPLACE FUNCTION GET_FLOW_POOL_MONTH_STAT(INT) RETURNS TABLE ( pool_id INT, members NUMERIC, minimum_flows NUMERIC, minimum_price NUMERIC, excess_flows NUMERIC, excess_price NUMERIC ) AS $$ DECLARE query TEXT; BEGIN query := 'WITH settings AS ( SELECT pool_id, json_array_elements(minimum_settings::json) ->> ''package_id'' AS package_id, json_array_elements(minimum_settings::json) ->> ''flows'' AS flows, json_array_elements(minimum_settings::json) ->> ''price'' AS price, gradient * pow(1024, gradient_unit) as gradient, gradient_price / pow(1024, gradient_unit) as gradient_price, start_at, end_at FROM virtual_flow_pool_settings ), pool_package AS ( SELECT virtual_flow_pool_months.pool_id, virtual_flow_pool_months.package_id, COUNT(*) as members, SUM(settings.flows::NUMERIC) AS minimum_flows, SUM(settings.price::NUMERIC) AS minimum_price, SUM(virtual_flow_pool_months.mebibyte) AS total_flows, AVG(settings.gradient::int) AS gradient, AVG(settings.gradient_price::NUMERIC) AS gradient_price FROM virtual_flow_pool_months JOIN settings ON settings.package_id::int = virtual_flow_pool_months.package_id AND settings.pool_id::int = virtual_flow_pool_months.pool_id AND settings.start_at <= (overlay($1::text placing ''-'' from 5 for 0) || ''-01 00:00:00'')::TIMESTAMP AND (settings.end_at >= (overlay($1::text placing ''-'' from 5 for 0) || ''-01 23:59:59'')::TIMESTAMP OR settings.end_at IS NULL) WHERE virtual_flow_pool_months.month = $1 GROUP BY virtual_flow_pool_months.pool_id, virtual_flow_pool_months.package_id ) SELECT pool_id, SUM(members) as members, SUM(minimum_flows) as minimum_flows, SUM(minimum_price) as minimum_price, CASE WHEN SUM(total_flows) - SUM(minimum_flows) < 0 THEN 0 ELSE SUM(total_flows) - SUM(minimum_flows) END as excess_flows, CEIL((CASE WHEN SUM(total_flows) - SUM(minimum_flows) < 0 THEN 0 ELSE SUM(total_flows) - SUM(minimum_flows) END)/AVG(gradient))*AVG(gradient)*AVG(gradient_price) as excess_price FROM pool_package AS t GROUP BY pool_id '; RETURN QUERY EXECUTE query USING $1; END; $$ LANGUAGE plpgsql;