CREATE OR REPLACE VIEW real_virtual_relations AS SELECT r.type as type, r.company_id as real_company_id, r.package_id as real_package_id, v.company_id as virtual_company_id, v.package_id as virtual_package_id, COUNT(*) as times, MAX(v.created_at) as updated_at FROM real_order_cards_partition as r JOIN virtual_orders as v ON v.id = r.virtual_order_id WHERE r.virtual_order_id <> 0 GROUP BY r.type,r.company_id,r.package_id,v.company_id,v.package_id; 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 := '[]'; packages JSONB := '[]'; query TEXT; package_row JSONB := '[]'; orders JSON[] := '{}'; 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; SELECT array_to_json(array_agg(row_to_json(t))) INTO packages FROM (SELECT virtual_packages.id, virtual_packages.service_months, virtual_packages.effect_months, virtual_packages.effect_months FROM vd.virtual_packages) t; 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 EXECUTE query; RAISE NOTICE '%s', orders; 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 SELECT value INTO package_row FROM json_array_elements(packages::JSON) WHERE value->>'id' = order_row.package_id::TEXT; -- 服务时间 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) 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 + (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 * (package_row->>'service_months' || ' month')::INTERVAL + (package_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 + (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 + (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; 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 := COALESCE(order_row.service_start_at::TIMESTAMP, temp_service_start_at::TIMESTAMP); service_end_at := COALESCE(order_row.service_end_at::TIMESTAMP, temp_service_end_at::TIMESTAMP); RETURN NEXT; END LOOP; RETURN; END; $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION FIX_TIMELINES(INT8[]) RETURNS void AS $$ DECLARE chunk INT8[] := '{}'; sim INT8; BEGIN FOREACH sim IN ARRAY $1 LOOP chunk := chunk || sim; IF array_length(chunk, 1) = 1000 THEN 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(chunk)) as tmp WHERE tmp.id = virtual_order_cards_partition.id; chunk := '{}'; END IF; END LOOP; IF array_length(chunk, 1) > 0 THEN 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(chunk)) as tmp WHERE tmp.id = virtual_order_cards_partition.id; END IF; END; $$ LANGUAGE plpgsql; 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; CREATE OR REPLACE FUNCTION CHANGE_CARDS(INT8[]) RETURNS void AS $$ DECLARE maxCursor INT2; params TEXT := ''; simRow INT8; query TEXT; BEGIN FOREACH simRow IN ARRAY $1 LOOP IF SUBSTR(simRow::text, 4, 1)::INT > 4 THEN RAISE EXCEPTION 'Error Card Sim --> %', simRow USING ERRCODE = '10000'; END IF; params := params || OVERLAY(simRow::text PLACING '_' FROM 4 FOR 1); END LOOP; params := trim('|' from params); RAISE NOTICE 'params : %', params; SELECT MAX(SUBSTR(sim::text, 4, 1)) INTO maxCursor FROM cards WHERE sim::TEXT SIMILAR TO params; RAISE NOTICE 'maxCursor : %', maxCursor; IF maxCursor > 8 THEN RAISE EXCEPTION 'Max Cursor --> %', maxCursor USING ERRCODE = '10001'; END IF; query := 'WITH new_cards AS ( SELECT cards.sim as original_sim, OVERLAY(cards.sim::TEXT PLACING (4 + t.counts)::TEXT FROM 4 FOR 1)::INT8 as sim, OVERLAY(imsi::TEXT PLACING (1 + t.counts)::TEXT FROM 3 FOR 1) as imsi, OVERLAY(iccid::TEXT PLACING (1 + t.counts)::TEXT FROM 5 FOR 1) as iccid, carrier_operator, activated_at, virtual_activated_at, 1 as type, cancelled_at, created_at, updated_at FROM cards JOIN ( SELECT OVERLAY(sim::TEXT PLACING $1 FROM 4 FOR 1), COUNT ( * ) AS counts, MIN ( sim ) AS sim FROM cards WHERE sim::TEXT SIMILAR TO $2 GROUP BY 1 ) AS t ON t.sim = cards.sim ), new_inserts AS ( INSERT INTO cards (sim,imsi,iccid, carrier_operator, activated_at, virtual_activated_at, type, cancelled_at, created_at, updated_at) SELECT sim,imsi,iccid, carrier_operator, activated_at, virtual_activated_at, type, cancelled_at, created_at, updated_at FROM new_cards ) UPDATE virtual_order_cards_partition SET original_sim=t.original_sim,sim=t.sim FROM (SELECT sim,original_sim FROM new_cards) as t WHERE virtual_order_cards_partition.sim=t.original_sim'; EXECUTE query USING '_', params; END; $$ LANGUAGE plpgsql SET synchronous_commit TO OFF; CREATE OR REPLACE FUNCTION GEN_PRODUCTS() RETURNS void AS $$ DECLARE order_row RECORD; product_row RECORD; package_row RECORD; _ids INT4[]; BEGIN TRUNCATE virtual_products RESTART IDENTITY; FOR order_row IN SELECT * FROM virtual_orders ORDER BY created_at LOOP SELECT * INTO package_row FROM virtual_packages WHERE id = order_row.package_id LIMIT 1; SELECT * INTO product_row FROM virtual_products WHERE company_id = order_row.company_id AND package_id = order_row.package_id AND deleted_at IS NULL LIMIT 1; IF NOT FOUND THEN INSERT INTO virtual_products (type, sn, "name", company_id, package_id, price, renew_price, remark, status, created_at, updated_at) VALUES (CASE order_row.type WHEN 1 THEN 0 ELSE order_row.type END, package_row.sn || '_' || order_row.company_id, package_row.name, order_row.company_id, order_row.package_id, order_row.unit_price, order_row.unit_price, package_row.description, 0, order_row.created_at, order_row.created_at); ELSE IF order_row.type = 1 THEN IF order_row.unit_price <> product_row.renew_price THEN UPDATE virtual_products SET updated_at = order_row.created_at, deleted_at = order_row.created_at + (product_row.id || ' second')::INTERVAL WHERE id = product_row.id; INSERT INTO virtual_products (type, sn, "name", company_id, package_id, price, renew_price, remark, status, created_at, updated_at) VALUES (product_row.type, product_row.sn, product_row.name, product_row.company_id, product_row.package_id, product_row.price, order_row.unit_price, product_row.remark, 0, order_row.created_at, order_row.created_at); END IF; ELSE IF order_row.unit_price <> product_row.price THEN UPDATE virtual_products SET updated_at = order_row.created_at, deleted_at = order_row.created_at + (product_row.id || ' second')::INTERVAL WHERE id = product_row.id; INSERT INTO virtual_products (type, sn, "name", company_id, package_id, price, renew_price, remark, status, created_at, updated_at) VALUES (product_row.type, product_row.sn, product_row.name, product_row.company_id, product_row.package_id, order_row.unit_price, product_row.renew_price, product_row.remark, 0, order_row.created_at, order_row.created_at); END IF; END IF; END IF; END LOOP; END; $$ LANGUAGE plpgsql;