121 lines
5.0 KiB
PL/PgSQL
121 lines
5.0 KiB
PL/PgSQL
CREATE OR REPLACE FUNCTION GET_TIMELINES(INT8[])
|
|
RETURNS TABLE
|
|
(
|
|
id INT,
|
|
sim INT8,
|
|
"type" INT2,
|
|
package_id INT,
|
|
service_start_at TIMESTAMP,
|
|
service_end_at TIMESTAMP
|
|
)
|
|
AS $$
|
|
DECLARE
|
|
activate_cards JSONB := '[]';
|
|
query TEXT;
|
|
order_row RECORD;
|
|
temp_service_start_at TIMESTAMP;
|
|
temp_service_end_at TIMESTAMP;
|
|
activated_at TIMESTAMP;
|
|
BEGIN
|
|
SELECT array_to_json(array_agg(row_to_json(t))) INTO activate_cards
|
|
FROM (SELECT cards.sim, cards.virtual_activated_at FROM vd.cards WHERE cards.sim = ANY ($1)) t;
|
|
|
|
query := 'SELECT virtual_order_cards_partition.id, virtual_order_cards_partition.type, virtual_order_cards_partition.sim, 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 = ANY($1)
|
|
ORDER BY sim ASC, created_at ASC';
|
|
|
|
FOR order_row IN EXECUTE query USING $1
|
|
LOOP
|
|
SELECT value->>'virtual_activated_at' INTO activated_at
|
|
FROM json_array_elements(activate_cards::JSON)
|
|
WHERE value->>'sim' = order_row.sim::TEXT;
|
|
|
|
IF NOT FOUND THEN
|
|
temp_service_start_at := NULL;
|
|
temp_service_end_at := NULL;
|
|
ELSEIF activated_at IS NULL THEN
|
|
temp_service_start_at := NULL;
|
|
temp_service_end_at := NULL;
|
|
ELSE
|
|
-- 服务时间
|
|
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 (temp_service_end_at > order_row.created_at) THEN
|
|
temp_service_start_at := TO_CHAR(temp_service_end_at + '1 month'::INTERVAL, 'YYYY-MM-01 00:00:00');
|
|
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.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;
|
|
END IF;
|
|
|
|
id := order_row.id::INT;
|
|
sim := order_row.sim::INT8;
|
|
"type" := order_row."type"::INT2;
|
|
package_id := order_row."package_id"::INT;
|
|
service_start_at := temp_service_start_at::TIMESTAMP;
|
|
service_end_at := temp_service_end_at::TIMESTAMP;
|
|
RETURN NEXT;
|
|
END LOOP;
|
|
RETURN;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE OR REPLACE FUNCTION FIX_TIMELINES(INT8[])
|
|
RETURNS void
|
|
AS $$
|
|
BEGIN
|
|
UPDATE vd.virtual_order_cards_partition
|
|
SET service_start_at=tmp.service_start_at,
|
|
service_end_at=tmp.service_end_at
|
|
FROM (SELECT * FROM GET_TIMELINES($1)) as tmp
|
|
WHERE tmp.id = virtual_order_cards_partition.id;
|
|
|
|
END;
|
|
$$ LANGUAGE plpgsql SET synchronous_commit TO OFF;
|
|
|
|
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;
|