65 lines
2.6 KiB
PL/PgSQL
65 lines
2.6 KiB
PL/PgSQL
CREATE OR REPLACE VIEW virtual_flow_pool_settings_view 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
|
|
|
|
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 := 'SELECT virtual_flow_pool_months.pool_id,
|
|
virtual_flow_pool_months.package_id,
|
|
COUNT(*) as members,
|
|
SUM(virtual_flow_pool_settings_view.flows::NUMERIC) AS minimum_flows,
|
|
SUM(virtual_flow_pool_settings_view.price::NUMERIC) AS minimum_price,
|
|
CASE WHEN SUM(virtual_flow_pool_months.mebibyte) - SUM(virtual_flow_pool_settings_view.flows::NUMERIC) < 0 THEN 0
|
|
ELSE SUM(virtual_flow_pool_months.mebibyte) - SUM(virtual_flow_pool_settings_view.flows::NUMERIC) END AS excess_flows,
|
|
AVG(virtual_flow_pool_settings_view.gradient::int) AS gradient,
|
|
AVG(virtual_flow_pool_settings_view.gradient_price::NUMERIC) AS gradient_price
|
|
FROM virtual_flow_pool_months
|
|
JOIN virtual_flow_pool_settings_view ON
|
|
virtual_flow_pool_settings_view.package_id::int = virtual_flow_pool_months.package_id AND
|
|
virtual_flow_pool_settings_view.pool_id::int = virtual_flow_pool_months.pool_id AND
|
|
virtual_flow_pool_settings_view.start_at <=
|
|
(overlay($1::text placing ''-'' from 5 for 0) || ''-01 00:00:00'')::TIMESTAMP AND
|
|
(virtual_flow_pool_settings_view.end_at >=
|
|
(overlay($1::text placing ''-'' from 5 for 0) || ''-01 23:59:59'')::TIMESTAMP OR
|
|
virtual_flow_pool_settings_view.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
|
|
';
|
|
|
|
query := 'SELECT pool_id,
|
|
SUM(members) as members,
|
|
SUM(minimum_flows) as minimum_flows,
|
|
SUM(minimum_price) as minimum_price,
|
|
SUM(excess_flows) as excess_flows,
|
|
CEIL(SUM(excess_flows) / AVG(gradient)) * AVG(gradient) * AVG(gradient_price) as excess_price
|
|
FROM (' || query || ') AS t GROUP BY pool_id';
|
|
|
|
RAISE NOTICE '%s', query;
|
|
|
|
RETURN QUERY EXECUTE query USING $1;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
|
|
|