vd/database/migrations/create_virtaul_order_cards_func.pgsql
2019-01-21 17:08:35 +08:00

145 lines
6.3 KiB
PL/PgSQL

CREATE OR REPLACE FUNCTION TIMELINES_JSON (sim INT8)
RETURNS JSONB
AS $$
DECLARE
timelines JSONB := '[]';
query TEXT;
order_row RECORD;
temp_text TEXT;
temp_activated_at TIMESTAMP;
temp_service_start_at TIMESTAMP;
temp_service_end_at TIMESTAMP;
next_timestamp TIMESTAMP;
BEGIN
SELECT virtual_activated_at INTO temp_activated_at FROM cards WHERE cards.sim = TIMELINES_JSON.sim;
IF temp_activated_at IS NULL THEN
RETURN timelines;
END IF;
query := 'SELECT
virtual_order_cards_partition.*,
virtual_packages.service_months,
virtual_packages.effect_months,
virtual_packages.delay_months
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(temp_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('{"sim": %s, "type": %s, "package_id": %s, "service_start_at": "%s", "service_end_at": "%s"}', 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_RANGE (sim INT8)
RETURNS TSRANGE[]
AS $$
DECLARE
timelines TSRANGE[] := '{}';
query TEXT;
order_row RECORD;
temp_text TEXT;
temp_activated_at TIMESTAMP;
temp_service_start_at TIMESTAMP;
temp_service_end_at TIMESTAMP;
next_timestamp TIMESTAMP;
BEGIN
SELECT virtual_activated_at INTO temp_activated_at FROM cards WHERE cards.sim = TIMELINES_RANGE.sim;
IF temp_activated_at IS NULL THEN
RETURN timelines;
END IF;
query := 'SELECT
virtual_order_cards_partition.*,
virtual_packages.service_months,
virtual_packages.effect_months,
virtual_packages.delay_months
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(temp_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;
timelines := timelines || TSRANGE(temp_service_start_at, temp_service_end_at);
END LOOP;
RETURN timelines;
END;
$$
LANGUAGE plpgsql IMMUTABLE;