优化同步
This commit is contained in:
parent
fe98879597
commit
f8f3fbe74d
@ -36,106 +36,105 @@ DECLARE
|
||||
temp_service_end_at TIMESTAMP;
|
||||
activated_at TIMESTAMP;
|
||||
BEGIN
|
||||
FOR row IN (SELECT cards.sim, virtual_activated_at FROM vd.cards WHERE cards.sim = ANY ($1))
|
||||
LOOP
|
||||
activate_cards := activate_cards || jsonb_build_object(row.sim, row_to_json(row));
|
||||
END LOOP;
|
||||
SELECT jsonb_object_agg(cards.sim, virtual_activated_at) INTO activate_cards FROM vd.cards WHERE cards.sim = ANY ($1);
|
||||
|
||||
FOR row IN (SELECT virtual_packages.id,
|
||||
virtual_packages.service_months,
|
||||
virtual_packages.effect_months,
|
||||
virtual_packages.delay_months
|
||||
FROM vd.virtual_packages)
|
||||
LOOP
|
||||
packages := packages || jsonb_build_object(row.id, row_to_json(row));
|
||||
END LOOP;
|
||||
IF activate_cards IS NOT NULL THEN
|
||||
SELECT jsonb_object_agg(t.id, row_to_json(t)) INTO packages FROM (
|
||||
SELECT virtual_packages.id,
|
||||
virtual_packages.service_months,
|
||||
virtual_packages.effect_months,
|
||||
virtual_packages.delay_months
|
||||
FROM vd.virtual_packages
|
||||
) t;
|
||||
|
||||
query := 'SELECT id, type, sim, package_id, created_at, counts, service_start_at, service_end_at
|
||||
query := 'SELECT id, type, sim, package_id, created_at, counts, service_start_at, service_end_at
|
||||
FROM vd.virtual_order_cards_partition
|
||||
WHERE sim = ANY($1)
|
||||
ORDER BY sim ASC, created_at ASC';
|
||||
|
||||
SELECT array_agg(row_to_json(t)) INTO orders
|
||||
FROM (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_order_cards_partition.counts,
|
||||
virtual_order_cards_partition.service_start_at,
|
||||
virtual_order_cards_partition.service_end_at
|
||||
FROM vd.virtual_order_cards_partition
|
||||
WHERE sim = ANY($1)
|
||||
ORDER BY sim ASC, created_at ASC';
|
||||
WHERE virtual_order_cards_partition.sim = ANY ($1)
|
||||
ORDER BY virtual_order_cards_partition.sim ASC, virtual_order_cards_partition.created_at ASC) t;
|
||||
|
||||
SELECT array_agg(row_to_json(t)) INTO orders
|
||||
FROM (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_order_cards_partition.counts,
|
||||
virtual_order_cards_partition.service_start_at,
|
||||
virtual_order_cards_partition.service_end_at
|
||||
FROM vd.virtual_order_cards_partition
|
||||
WHERE virtual_order_cards_partition.sim = ANY ($1)
|
||||
ORDER BY virtual_order_cards_partition.sim ASC, virtual_order_cards_partition.created_at ASC) t;
|
||||
|
||||
FOR i IN 1..array_length(orders, 1)
|
||||
LOOP
|
||||
order_row := orders [ i];
|
||||
activated_at := activate_cards -> (order_row->>'sim')->>'virtual_activated_at';
|
||||
package_row := packages -> (order_row->>'package_id');
|
||||
-- 服务时间
|
||||
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 + (package_row->>'service_months' || ' month')::INTERVAL +
|
||||
(package_row->>'delay_months' || ' month')::INTERVAL - '1 second'::INTERVAL;
|
||||
WHEN '1', '2' THEN
|
||||
IF (temp_service_end_at > (order_row->>'created_at')::TIMESTAMP) 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')::TIMESTAMP + (package_row->>'effect_months' || ' month')::INTERVAL,
|
||||
'YYYY-MM-01 00:00:00');
|
||||
END IF;
|
||||
temp_service_end_at :=
|
||||
temp_service_start_at + (order_row->>'counts')::INT * (package_row->>'service_months' || ' month')::INTERVAL +
|
||||
(package_row->>'delay_months' || ' month')::INTERVAL - '1 second'::INTERVAL;
|
||||
ELSE
|
||||
-- 先购买了加油包后再激活的
|
||||
IF ((order_row->>'created_at')::TIMESTAMP < activated_at) THEN
|
||||
IF ((order_row->>'created_at')::TIMESTAMP <=
|
||||
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');
|
||||
FOR i IN 1..array_length(orders, 1)
|
||||
LOOP
|
||||
order_row := orders [ i];
|
||||
activated_at := activate_cards -> (order_row->>'sim')->>'virtual_activated_at';
|
||||
package_row := packages -> (order_row->>'package_id');
|
||||
-- 服务时间
|
||||
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 + (package_row->>'service_months' || ' month')::INTERVAL +
|
||||
(package_row->>'delay_months' || ' month')::INTERVAL - '1 second'::INTERVAL;
|
||||
WHEN '1', '2' THEN
|
||||
IF (temp_service_end_at > (order_row->>'created_at')::TIMESTAMP) 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(activated_at + (package_row->>'effect_months' || ' month')::INTERVAL,
|
||||
'YYYY-MM-01 00:00:00');
|
||||
temp_service_start_at :=
|
||||
TO_CHAR(
|
||||
(order_row->>'created_at')::TIMESTAMP + (package_row->>'effect_months' || ' month')::INTERVAL,
|
||||
'YYYY-MM-01 00:00:00');
|
||||
END IF;
|
||||
ELSE
|
||||
-- 延时生效
|
||||
temp_service_start_at :=
|
||||
TO_CHAR(
|
||||
(order_row->>'created_at')::TIMESTAMP + (package_row->>'effect_months' || ' month')::INTERVAL,
|
||||
'YYYY-MM-01 00:00:00');
|
||||
END IF;
|
||||
temp_service_end_at := temp_service_start_at + (package_row->>'service_months' || ' month')::INTERVAL +
|
||||
(package_row->>'delay_months' || ' month')::INTERVAL - '1 second'::INTERVAL;
|
||||
END CASE;
|
||||
temp_service_end_at :=
|
||||
temp_service_start_at + (order_row->>'counts')::INT * (package_row->>'service_months' || ' month')::INTERVAL +
|
||||
(package_row->>'delay_months' || ' month')::INTERVAL - '1 second'::INTERVAL;
|
||||
ELSE
|
||||
-- 先购买了加油包后再激活的
|
||||
IF ((order_row->>'created_at')::TIMESTAMP < activated_at) THEN
|
||||
IF ((order_row->>'created_at')::TIMESTAMP <=
|
||||
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 + (package_row->>'effect_months' || ' month')::INTERVAL,
|
||||
'YYYY-MM-01 00:00:00');
|
||||
END IF;
|
||||
ELSE
|
||||
-- 延时生效
|
||||
temp_service_start_at :=
|
||||
TO_CHAR(
|
||||
(order_row->>'created_at')::TIMESTAMP + (package_row->>'effect_months' || ' month')::INTERVAL,
|
||||
'YYYY-MM-01 00:00:00');
|
||||
END IF;
|
||||
temp_service_end_at := temp_service_start_at + (package_row->>'service_months' || ' month')::INTERVAL +
|
||||
(package_row->>'delay_months' || ' month')::INTERVAL - '1 second'::INTERVAL;
|
||||
END CASE;
|
||||
|
||||
temp_service_start_at :=
|
||||
COALESCE((order_row->>'service_start_at')::TIMESTAMP, temp_service_start_at::TIMESTAMP);
|
||||
temp_service_end_at := COALESCE((order_row->>'service_end_at')::TIMESTAMP, temp_service_end_at::TIMESTAMP);
|
||||
temp_service_start_at :=
|
||||
COALESCE((order_row->>'service_start_at')::TIMESTAMP, temp_service_start_at::TIMESTAMP);
|
||||
temp_service_end_at := COALESCE((order_row->>'service_end_at')::TIMESTAMP, temp_service_end_at::TIMESTAMP);
|
||||
|
||||
order_row = order_row || jsonb_build_object('service_start_at', temp_service_start_at) ||
|
||||
jsonb_build_object('service_end_at', temp_service_end_at);
|
||||
order_row = order_row || jsonb_build_object('service_start_at', temp_service_start_at) ||
|
||||
jsonb_build_object('service_end_at', temp_service_end_at);
|
||||
|
||||
orders [ i] = order_row;
|
||||
orders [ i] = order_row;
|
||||
END LOOP;
|
||||
|
||||
FOR i IN 1..array_length(orders, 1)
|
||||
LOOP
|
||||
order_row := orders[i];
|
||||
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 := (order_row->>'service_start_at')::TIMESTAMP;
|
||||
service_end_at := (order_row->>'service_end_at')::TIMESTAMP;
|
||||
RETURN NEXT;
|
||||
END LOOP;
|
||||
END IF;
|
||||
|
||||
FOR i IN 1..array_length(orders, 1)
|
||||
LOOP
|
||||
order_row := orders[i];
|
||||
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 := (order_row->>'service_start_at')::TIMESTAMP;
|
||||
service_end_at := (order_row->>'service_end_at')::TIMESTAMP;
|
||||
RETURN NEXT;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
Loading…
x
Reference in New Issue
Block a user