-- 创建序列 CREATE SEQUENCE IF NOT EXISTS "virtual_order_cards_partition_id_seq" INCREMENT 1 MINVALUE 1 MAXVALUE 2147483647 START 1 CACHE 1; -- 创建主表 CREATE TABLE "virtual_order_cards_partition" ( "id" int4 NOT NULL DEFAULT nextval('virtual_order_cards_partition_id_seq'::regclass), "type" int2 NOT NULL DEFAULT 0, "sim" int8 NOT NULL DEFAULT 0, "order_id" int4 NOT NULL DEFAULT 0, "company_id" int4 NOT NULL DEFAULT 0, "package_id" int4 NOT NULL DEFAULT 0, "counts" int4 NOT NULL DEFAULT 1, "created_at" timestamp(0), "updated_at" timestamp(0), "deleted_at" timestamp(0)) PARTITION BY LIST ( "type" ); -- 序列 ALTER SEQUENCE "virtual_order_cards_partition_id_seq" OWNED BY "virtual_order_cards_partition"."id"; -- 备注 COMMENT ON COLUMN "virtual_order_cards_partition"."id" IS '关联表ID'; COMMENT ON COLUMN "virtual_order_cards_partition"."type" IS '订单类型(0:基础套餐 1:套餐续费 2:续费包 3:加油包 4:可选包 5:附加包)'; COMMENT ON COLUMN "virtual_order_cards_partition"."sim" IS 'SIM卡号'; COMMENT ON COLUMN "virtual_order_cards_partition"."order_id" IS '订单ID'; COMMENT ON COLUMN "virtual_order_cards_partition"."company_id" IS '企业ID'; COMMENT ON COLUMN "virtual_order_cards_partition"."package_id" IS '套餐ID'; COMMENT ON COLUMN "virtual_order_cards_partition"."counts" IS '数量'; COMMENT ON TABLE "virtual_order_cards_partition" IS 'VD卡关联套餐订单'; -- 分区表 CREATE TABLE virtual_order_cards PARTITION OF virtual_order_cards_partition FOR VALUES IN (0); CREATE TABLE virtual_order_renewal_cards PARTITION OF virtual_order_cards_partition FOR VALUES IN (1); CREATE TABLE virtual_order_renewal_package_cards PARTITION OF virtual_order_cards_partition FOR VALUES IN (2); CREATE TABLE virtual_order_flows_package_cards PARTITION OF virtual_order_cards_partition FOR VALUES IN (3); -- 唯一索引 CREATE UNIQUE INDEX "virtual_order_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_renewal_cards_order_id_sim_deleted_at_unique" ON "virtual_order_renewal_cards" (order_id, sim, COALESCE(deleted_at, '1970-01-01 08:00:00'::timestamp)); CREATE UNIQUE INDEX "virtual_order_renewal_package_cards_order_id_sim_deleted_at_unique" ON "virtual_order_renewal_package_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_flows_package_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_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 (); -- 优化多核心建立索引 ALTER TABLE virtual_order_cards SET (parallel_workers = 4); ALTER TABLE virtual_order_renewal_cards SET (parallel_workers = 4); ALTER TABLE virtual_order_renewal_package_cards SET (parallel_workers = 4); ALTER TABLE virtual_order_flows_package_cards SET (parallel_workers = 4); SET max_parallel_maintenance_workers TO 4; SET maintenance_work_mem TO '2GB';