180 lines
6.6 KiB
PL/PgSQL
180 lines
6.6 KiB
PL/PgSQL
CREATE OR REPLACE FUNCTION TIMELINES_JSON (sim INT8, activated_at TIMESTAMP)
|
|
RETURNS JSONB
|
|
AS $$
|
|
DECLARE
|
|
timelines JSONB := '[]';
|
|
query TEXT;
|
|
order_row RECORD;
|
|
temp_text TEXT;
|
|
temp_service_start_at TIMESTAMP;
|
|
temp_service_end_at TIMESTAMP;
|
|
next_timestamp TIMESTAMP;
|
|
BEGIN
|
|
IF activated_at IS NULL THEN
|
|
RETURN timelines;
|
|
END IF;
|
|
|
|
query := 'SELECT
|
|
virtual_order_cards_partition.id,
|
|
virtual_order_cards_partition.type,
|
|
virtual_order_cards_partition.package_id,
|
|
virtual_order_cards_partition.created_at,
|
|
virtual_packages.service_months,
|
|
virtual_packages.effect_months,
|
|
virtual_packages.delay_months,
|
|
virtual_order_cards_partition.counts
|
|
FROM
|
|
vd.virtual_order_cards_partition
|
|
JOIN vd.virtual_packages ON virtual_order_cards_partition.package_id = virtual_packages."id"
|
|
WHERE
|
|
virtual_order_cards_partition.sim = $1
|
|
ORDER BY
|
|
"type" ASC,
|
|
created_at ASC';
|
|
|
|
FOR order_row IN EXECUTE query USING sim LOOP
|
|
-- 服务时间
|
|
CASE (order_row. "type")
|
|
WHEN 0 THEN
|
|
temp_service_start_at := TO_CHAR(activated_at, 'YYYY-MM-01 00:00:00');
|
|
temp_service_end_at := temp_service_start_at + (order_row.service_months || ' month')::INTERVAL + (order_row.delay_months || ' month')::INTERVAL - '1 second'::INTERVAL;
|
|
WHEN 1, 2 THEN
|
|
IF (next_timestamp > order_row.created_at) THEN
|
|
temp_service_start_at := TO_CHAR(next_timestamp, 'YYYY-MM-01 00:00:00');
|
|
ELSE
|
|
temp_service_start_at := TO_CHAR(order_row.created_at, 'YYYY-MM-01 00:00:00');
|
|
END IF;
|
|
temp_service_end_at := temp_service_start_at + order_row.counts * (order_row.service_months || ' month')::INTERVAL + (order_row.delay_months || ' month')::INTERVAL - '1 second'::INTERVAL;
|
|
ELSE
|
|
-- 先购买了加油包后再激活的
|
|
IF (order_row.created_at < activated_at) THEN
|
|
IF (order_row.created_at < TO_CHAR(activated_at - '1 month'::INTERVAL, 'YYYY-MM-01 00:00:00')::TIMESTAMP) THEN
|
|
-- 购买时间小于一个月的,直接生效
|
|
temp_service_start_at := TO_CHAR(activated_at, 'YYYY-MM-01 00:00:00');
|
|
ELSE
|
|
-- 延时生效
|
|
temp_service_start_at := TO_CHAR(activated_at + (order_row.effect_months || ' month')::INTERVAL,
|
|
'YYYY-MM-01 00:00:00');
|
|
END IF;
|
|
ELSE
|
|
-- 延时生效
|
|
temp_service_start_at := TO_CHAR(order_row.created_at + (order_row.effect_months || ' month')::INTERVAL, 'YYYY-MM-01 00:00:00');
|
|
END IF;
|
|
temp_service_end_at := temp_service_start_at + (order_row.service_months || ' month')::INTERVAL + (order_row.delay_months || ' month')::INTERVAL - '1 second'::INTERVAL;
|
|
END CASE;
|
|
|
|
temp_text := format('{"id": %s, "sim": %s, "type": %s, "package_id": %s, "service_start_at": "%s", "service_end_at": "%s"}', order_row.id, sim, order_row.type, order_row.package_id, temp_service_start_at, temp_service_end_at);
|
|
timelines := timelines::JSONB || temp_text::JSONB;
|
|
END LOOP;
|
|
RETURN timelines;
|
|
END;
|
|
$$
|
|
LANGUAGE plpgsql;
|
|
|
|
CREATE OR REPLACE FUNCTION TIMELINES_JSON (sim INT8)
|
|
RETURNS JSONB
|
|
AS $$
|
|
DECLARE
|
|
activated_at TIMESTAMP;
|
|
BEGIN
|
|
SELECT virtual_activated_at INTO activated_at FROM vd.cards WHERE cards.sim = TIMELINES_JSON.sim;
|
|
RETURN vd.TIMELINES_JSON(sim, activated_at);
|
|
END;
|
|
$$
|
|
LANGUAGE plpgsql;
|
|
|
|
CREATE OR REPLACE FUNCTION TIMELINES_RANGE (sim INT8)
|
|
RETURNS TSRANGE[]
|
|
AS $$
|
|
DECLARE
|
|
timelines TSRANGE[] := '{}';
|
|
timelines_json JSONB;
|
|
item JSONB;
|
|
BEGIN
|
|
timelines_json := vd.TIMELINES_JSON(sim);
|
|
|
|
FOR item IN SELECT * FROM json_array_elements(timelines_json::JSON) LOOP
|
|
timelines := timelines || TSRANGE((item->>'service_start_at')::TIMESTAMP, (item->>'service_end_at')::TIMESTAMP);
|
|
END LOOP;
|
|
RETURN timelines;
|
|
END;
|
|
$$
|
|
LANGUAGE plpgsql;
|
|
|
|
CREATE OR REPLACE FUNCTION TIMELINES_INDEX (id INT, sim INT8)
|
|
RETURNS INT[]
|
|
AS $$
|
|
DECLARE
|
|
timelines INT[] := '{}';
|
|
timelines_json JSONB;
|
|
item JSONB;
|
|
temp_months INT;
|
|
i INT;
|
|
BEGIN
|
|
timelines_json := vd.TIMELINES_JSON(sim);
|
|
FOR item IN SELECT * FROM json_array_elements(timelines_json::JSON) LOOP
|
|
IF (item->>'id')::INT = id THEN
|
|
temp_months = (TO_CHAR((item->>'service_end_at')::TIMESTAMP, 'YYYY')::INT - TO_CHAR((item->>'service_start_at')::TIMESTAMP, 'YYYY')::INT) * 12
|
|
+ (TO_CHAR((item->>'service_end_at')::TIMESTAMP, 'MM')::INT - TO_CHAR((item->>'service_start_at')::TIMESTAMP, 'MM')::INT);
|
|
i := 0;
|
|
|
|
RAISE NOTICE 'TIMELINES_INDEX: % - % - % - %', item->>'id', item->>'sim', item->>'package_id', temp_months;
|
|
|
|
WHILE i <= temp_months LOOP
|
|
timelines := timelines || TO_CHAR((item->>'service_start_at')::TIMESTAMP + (i || ' month')::INTERVAL, 'YYYYMM')::INT;
|
|
i := i + 1;
|
|
END LOOP;
|
|
END IF;
|
|
END LOOP;
|
|
RETURN timelines;
|
|
END;
|
|
$$
|
|
LANGUAGE plpgsql IMMUTABLE;
|
|
|
|
CREATE OR REPLACE FUNCTION TIMELINES_ARRAY (sim INT8)
|
|
RETURNS INT[]
|
|
AS $$
|
|
DECLARE
|
|
timelines INT[] := '{}';
|
|
timelines_json JSONB;
|
|
item JSONB;
|
|
temp_months INT;
|
|
i INT;
|
|
BEGIN
|
|
timelines_json := vd.TIMELINES_JSON(sim);
|
|
|
|
FOR item IN SELECT * FROM json_array_elements(timelines_json::JSON) LOOP
|
|
temp_months = (TO_CHAR((item->>'service_end_at')::TIMESTAMP, 'YYYY')::INT - TO_CHAR((item->>'service_start_at')::TIMESTAMP, 'YYYY')::INT) * 12
|
|
+ (TO_CHAR((item->>'service_end_at')::TIMESTAMP, 'MM')::INT - TO_CHAR((item->>'service_start_at')::TIMESTAMP, 'MM')::INT);
|
|
i := 0;
|
|
|
|
RAISE NOTICE 'TIMELINES_ARRAY: % - % - %', item->>'sim', item->>'package_id', temp_months;
|
|
|
|
WHILE i <= temp_months LOOP
|
|
timelines := timelines || TO_CHAR((item->>'service_start_at')::TIMESTAMP + (i || ' month')::INTERVAL, 'YYYYMM')::INT;
|
|
i := i + 1;
|
|
END LOOP;
|
|
END LOOP;
|
|
RETURN timelines;
|
|
END;
|
|
$$
|
|
LANGUAGE plpgsql IMMUTABLE;
|
|
|
|
CREATE OR REPLACE FUNCTION FIX_ORDER_COUNTS ()
|
|
RETURNS BOOLEAN
|
|
AS $$
|
|
BEGIN
|
|
UPDATE virtual_orders SET counts = COALESCE (
|
|
(
|
|
SELECT COUNT( * )
|
|
FROM virtual_order_cards_partition
|
|
WHERE virtual_order_cards_partition."type" = virtual_orders."type"
|
|
AND virtual_order_cards_partition.order_id = virtual_orders."id"
|
|
GROUP BY "type",order_id
|
|
), 0);
|
|
|
|
RETURN TRUE;
|
|
END;
|
|
$$
|
|
LANGUAGE plpgsql;
|