175 lines
6.1 KiB
PL/PgSQL
175 lines
6.1 KiB
PL/PgSQL
CREATE OR REPLACE FUNCTION FIX_TIMELINES (sim INT8, activated_at TIMESTAMP without TIME zone)
|
|
RETURNS BOOLEAN
|
|
AS $$
|
|
DECLARE
|
|
query TEXT;
|
|
order_row RECORD;
|
|
temp_service_start_at TIMESTAMP;
|
|
temp_service_end_at TIMESTAMP;
|
|
next_timestamp TIMESTAMP;
|
|
BEGIN
|
|
RAISE NOTICE '% - %', sim, activated_at;
|
|
IF activated_at IS NULL THEN
|
|
UPDATE
|
|
vd.virtual_order_cards_partition
|
|
SET
|
|
service_start_at = NULL,
|
|
service_end_at = NULL
|
|
WHERE
|
|
virtual_order_cards_partition.sim = FIX_TIMELINES.sim;
|
|
ELSE
|
|
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(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;
|
|
next_timestamp := temp_service_end_at + '1 second'::INTERVAL;
|
|
-- 更新数据库
|
|
UPDATE
|
|
vd.virtual_order_cards_partition
|
|
SET
|
|
service_start_at = temp_service_start_at,
|
|
service_end_at = temp_service_end_at
|
|
WHERE
|
|
virtual_order_cards_partition. "id" = order_row. "id";
|
|
END LOOP;
|
|
END IF;
|
|
RETURN TRUE;
|
|
END;
|
|
$$
|
|
LANGUAGE plpgsql;
|
|
|
|
CREATE OR REPLACE FUNCTION CARD_TIMELINES ()
|
|
RETURNS TRIGGER
|
|
AS $$
|
|
BEGIN
|
|
IF (TG_OP = 'INSERT') THEN
|
|
-- 插入数据
|
|
IF (NEW.virtual_activated_at IS NOT NULL) THEN
|
|
PERFORM
|
|
vd.FIX_TIMELINES (NEW.sim,
|
|
NEW.virtual_activated_at);
|
|
END IF;
|
|
ELSIF (TG_OP = 'UPDATE') THEN
|
|
-- 更新数据
|
|
IF (OLD.virtual_activated_at IS NOT NULL) OR (NEW.virtual_activated_at IS NOT NULL) THEN
|
|
PERFORM
|
|
vd.FIX_TIMELINES (NEW.sim,
|
|
NEW.virtual_activated_at);
|
|
END IF;
|
|
ELSIF (TG_OP = 'DELETE') THEN
|
|
-- 删除数据
|
|
PERFORM
|
|
vd.FIX_TIMELINES (NEW.sim,
|
|
NULL);
|
|
END IF;
|
|
RETURN NULL;
|
|
END;
|
|
$$
|
|
LANGUAGE plpgsql;
|
|
|
|
DROP TRIGGER IF EXISTS CARD_TIMELINES ON cards;
|
|
|
|
CREATE TRIGGER CARD_TIMELINES AFTER INSERT
|
|
OR
|
|
UPDATE
|
|
OR DELETE ON cards FOR EACH ROW EXECUTE PROCEDURE CARD_TIMELINES ();
|
|
|
|
CREATE OR REPLACE FUNCTION ORDER_TIMELINES ()
|
|
RETURNS TRIGGER
|
|
AS $$
|
|
DECLARE
|
|
order_row RECORD;
|
|
BEGIN
|
|
IF (TG_OP = 'INSERT') THEN
|
|
-- 插入数据
|
|
SELECT
|
|
NEW.sim,
|
|
virtual_activated_at
|
|
FROM
|
|
vd.cards INTO order_row
|
|
WHERE
|
|
cards.sim = NEW.sim;
|
|
PERFORM
|
|
vd.FIX_TIMELINES (order_row.sim,
|
|
order_row.virtual_activated_at);
|
|
ELSIF (TG_OP = 'DELETE') THEN
|
|
SELECT
|
|
NEW.sim,
|
|
virtual_activated_at
|
|
FROM
|
|
vd.cards INTO order_row
|
|
WHERE
|
|
cards.sim = NEW.sim;
|
|
PERFORM
|
|
vd.FIX_TIMELINES (order_row.sim,
|
|
order_row.virtual_activated_at);
|
|
END IF;
|
|
RETURN NULL;
|
|
END;
|
|
$$
|
|
LANGUAGE plpgsql;
|
|
|
|
DROP TRIGGER IF EXISTS ORDER_TIMELINES ON virtual_order_cards;
|
|
|
|
CREATE TRIGGER ORDER_TIMELINES AFTER INSERT
|
|
OR DELETE ON virtual_order_cards FOR EACH ROW EXECUTE PROCEDURE ORDER_TIMELINES ();
|
|
|
|
|
|
DROP TRIGGER IF EXISTS ORDER_TIMELINES ON virtual_order_renewal_cards;
|
|
|
|
CREATE TRIGGER ORDER_TIMELINES AFTER INSERT
|
|
OR DELETE ON virtual_order_renewal_cards FOR EACH ROW EXECUTE PROCEDURE ORDER_TIMELINES ();
|
|
|
|
DROP TRIGGER IF EXISTS ORDER_TIMELINES ON virtual_order_renewal_package_cards;
|
|
|
|
CREATE TRIGGER ORDER_TIMELINES AFTER INSERT
|
|
OR DELETE ON virtual_order_renewal_package_cards FOR EACH ROW EXECUTE PROCEDURE ORDER_TIMELINES ();
|
|
|
|
DROP TRIGGER IF EXISTS ORDER_TIMELINES ON virtual_order_flows_package_cards;
|
|
|
|
CREATE TRIGGER ORDER_TIMELINES AFTER INSERT
|
|
OR DELETE ON virtual_order_flows_package_cards FOR EACH ROW EXECUTE PROCEDURE ORDER_TIMELINES ();
|
|
|