diff --git a/database/migrations/create_virtaul_order_cards_func.pgsql b/database/migrations/create_virtaul_order_cards_func.pgsql index dd7f90d7..bf5aec88 100644 --- a/database/migrations/create_virtaul_order_cards_func.pgsql +++ b/database/migrations/create_virtaul_order_cards_func.pgsql @@ -11,14 +11,16 @@ DECLARE 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; + SELECT virtual_activated_at INTO temp_activated_at FROM vd.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_order_cards_partition.type, + virtual_order_cards_partition.package_id, + virtual_order_cards_partition.created_at, virtual_packages.service_months, virtual_packages.effect_months, virtual_packages.delay_months @@ -75,70 +77,44 @@ CREATE OR REPLACE FUNCTION TIMELINES_RANGE (sim INT8) 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; + timelines_json JSONB; + item JSONB; BEGIN - SELECT virtual_activated_at INTO temp_activated_at FROM cards WHERE cards.sim = TIMELINES_RANGE.sim; + timelines_json := vd.TIMELINES_JSON(sim); - IF temp_activated_at IS NULL THEN - RETURN timelines; - END IF; + FOR item IN SELECT * FROM json_array_elements(timelines_json::JSON) LOOP + timelines := timelines || TSRANGE((item->>'service_start_at')::TIMESTAMP, (item->>'service_end_at')::TIMESTAMP); + END LOOP; + RETURN timelines; +END; +$$ +LANGUAGE plpgsql; - 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'; +CREATE OR REPLACE FUNCTION TIMELINES_ARRAY (sim INT8) + RETURNS INT[] +AS $$ +DECLARE + timelines INT[] := '{}'; + timelines_json JSONB; + item JSONB; + temp_months INT; + i INT; +BEGIN + timelines_json := vd.TIMELINES_JSON(sim); - 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; + FOR item IN SELECT * FROM json_array_elements(timelines_json::JSON) LOOP + temp_months = (TO_CHAR((item->>'service_end_at')::TIMESTAMP, 'YYYY')::INT - TO_CHAR((item->>'service_start_at')::TIMESTAMP, 'YYYY')::INT) * 12 + + (TO_CHAR((item->>'service_end_at')::TIMESTAMP, 'MM')::INT - TO_CHAR((item->>'service_start_at')::TIMESTAMP, 'MM')::INT); + i := 0; - timelines := timelines || TSRANGE(temp_service_start_at, temp_service_end_at); + RAISE NOTICE 'TIMELINES_ARRAY: % - % - %', item->>'sim', item->>'package_id', temp_months; + + WHILE i <= temp_months LOOP + timelines := timelines || TO_CHAR((item->>'service_start_at')::TIMESTAMP + (i || ' month')::INTERVAL, 'YYYYMM')::INT; + i := i + 1; + END LOOP; END LOOP; RETURN timelines; END; $$ LANGUAGE plpgsql IMMUTABLE; - - diff --git a/database/migrations/create_virtual_order_cards_table.pgsql b/database/migrations/create_virtual_order_cards_table.pgsql index d05775c5..ed6037e2 100644 --- a/database/migrations/create_virtual_order_cards_table.pgsql +++ b/database/migrations/create_virtual_order_cards_table.pgsql @@ -41,7 +41,33 @@ CREATE UNIQUE INDEX "virtual_order_renewal_cards_order_id_sim_deleted_at_unique" CREATE UNIQUE INDEX "virtual_order_renewal_package_cards_order_id_sim_deleted_at_unique" ON "virtual_order_cards" (order_id, sim, COALESCE(deleted_at, '1970-01-01 08:00:00'::timestamp)); CREATE UNIQUE INDEX "virtual_order_flows_package_cards_order_id_sim_deleted_at_unique" ON "virtual_order_cards" (order_id, sim, COALESCE(deleted_at, '1970-01-01 08:00:00'::timestamp)); -CREATE INDEX "virtual_order_cards_timelines_index" ON "virtual_order_cards" USING GIN (timelines_range(sim)); -CREATE INDEX "virtual_order_renewal_cards_timelines_index" ON "virtual_order_cards" USING GIN (timelines_range(sim)); -CREATE INDEX "virtual_order_renewal_package_cards_timelines_index" ON "virtual_order_cards" USING GIN (timelines_range(sim)); -CREATE INDEX "virtual_order_flows_package_cards_index" ON "virtual_order_cards" USING GIN (timelines_range(sim)); +CREATE INDEX "virtual_order_cards_timelines_index" ON "vd.virtual_order_cards" USING GIN (timelines_array(sim)); +CREATE INDEX "virtual_order_renewal_cards_timelines_index" ON "virtual_order_renewal_cards" USING GIN (timelines_array(sim)); +CREATE INDEX "virtual_order_renewal_package_cards_timelines_index" ON "virtual_order_renewal_package_cards" USING GIN (timelines_array(sim)); +CREATE INDEX "virtual_order_flows_package_cards_index" ON "virtual_order_flows_package_cards" USING GIN (timelines_array(sim)); + +CREATE OR REPLACE FUNCTION REINDEX_TIMELINES () + RETURNS TRIGGER +AS $$ +BEGIN + IF (TG_OP = 'INSERT') THEN + UPDATE vd.virtual_order_cards_partition SET updated_at = CURRENT_TIMESTAMP WHERE virtual_order_cards_partition.sim = NEW.sim; + ELSIF (TG_OP = 'UPDATE') THEN + UPDATE vd.virtual_order_cards_partition SET updated_at = CURRENT_TIMESTAMP WHERE virtual_order_cards_partition.sim = NEW.sim; + ELSIF (TG_OP = 'DELETE') THEN + UPDATE vd.virtual_order_cards_partition SET updated_at = CURRENT_TIMESTAMP WHERE virtual_order_cards_partition.sim = OLD.sim; + END IF; + + RETURN NULL; +END; +$$ +LANGUAGE plpgsql; + +DROP TRIGGER IF EXISTS REINDEX_TIMELINES ON cards; + +CREATE TRIGGER "reindex_timelines" AFTER INSERT +OR UPDATE OF "virtual_activated_at" +OR DELETE +ON cards +FOR EACH ROW +EXECUTE PROCEDURE REINDEX_TIMELINES ();