0073_magical_manta.sql 6.0 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127
  1. CREATE TABLE IF NOT EXISTS "usage_ledger" (
  2. "id" serial PRIMARY KEY NOT NULL,
  3. "request_id" integer NOT NULL,
  4. "user_id" integer NOT NULL,
  5. "key" varchar NOT NULL,
  6. "provider_id" integer NOT NULL,
  7. "final_provider_id" integer NOT NULL,
  8. "model" varchar(128),
  9. "original_model" varchar(128),
  10. "endpoint" varchar(256),
  11. "api_type" varchar(20),
  12. "session_id" varchar(64),
  13. "status_code" integer,
  14. "is_success" boolean DEFAULT false NOT NULL,
  15. "blocked_by" varchar(50),
  16. "cost_usd" numeric(21, 15) DEFAULT '0',
  17. "cost_multiplier" numeric(10, 4),
  18. "input_tokens" bigint,
  19. "output_tokens" bigint,
  20. "cache_creation_input_tokens" bigint,
  21. "cache_read_input_tokens" bigint,
  22. "cache_creation_5m_input_tokens" bigint,
  23. "cache_creation_1h_input_tokens" bigint,
  24. "cache_ttl_applied" varchar(10),
  25. "context_1m_applied" boolean DEFAULT false,
  26. "swap_cache_ttl_applied" boolean DEFAULT false,
  27. "duration_ms" integer,
  28. "ttfb_ms" integer,
  29. "created_at" timestamp with time zone NOT NULL
  30. );
  31. --> statement-breakpoint
  32. CREATE UNIQUE INDEX IF NOT EXISTS "idx_usage_ledger_request_id" ON "usage_ledger" USING btree ("request_id");--> statement-breakpoint
  33. CREATE INDEX IF NOT EXISTS "idx_usage_ledger_user_created_at" ON "usage_ledger" USING btree ("user_id","created_at") WHERE "usage_ledger"."blocked_by" IS NULL;--> statement-breakpoint
  34. CREATE INDEX IF NOT EXISTS "idx_usage_ledger_key_created_at" ON "usage_ledger" USING btree ("key","created_at") WHERE "usage_ledger"."blocked_by" IS NULL;--> statement-breakpoint
  35. CREATE INDEX IF NOT EXISTS "idx_usage_ledger_provider_created_at" ON "usage_ledger" USING btree ("final_provider_id","created_at") WHERE "usage_ledger"."blocked_by" IS NULL;--> statement-breakpoint
  36. CREATE INDEX IF NOT EXISTS "idx_usage_ledger_created_at_minute" ON "usage_ledger" USING btree (date_trunc('minute', "created_at" AT TIME ZONE 'UTC'));--> statement-breakpoint
  37. CREATE INDEX IF NOT EXISTS "idx_usage_ledger_created_at_desc_id" ON "usage_ledger" USING btree ("created_at" DESC NULLS LAST,"id" DESC NULLS LAST);--> statement-breakpoint
  38. CREATE INDEX IF NOT EXISTS "idx_usage_ledger_session_id" ON "usage_ledger" USING btree ("session_id") WHERE "usage_ledger"."session_id" IS NOT NULL;--> statement-breakpoint
  39. CREATE INDEX IF NOT EXISTS "idx_usage_ledger_model" ON "usage_ledger" USING btree ("model") WHERE "usage_ledger"."model" IS NOT NULL;--> statement-breakpoint
  40. CREATE INDEX IF NOT EXISTS "idx_usage_ledger_key_cost" ON "usage_ledger" USING btree ("key","cost_usd") WHERE "usage_ledger"."blocked_by" IS NULL;--> statement-breakpoint
  41. -- Trigger: auto-upsert usage_ledger on message_request INSERT/UPDATE
  42. CREATE OR REPLACE FUNCTION fn_upsert_usage_ledger()
  43. RETURNS TRIGGER AS $$
  44. DECLARE
  45. v_final_provider_id integer;
  46. v_is_success boolean;
  47. BEGIN
  48. IF NEW.blocked_by = 'warmup' THEN
  49. -- If a ledger row already exists (row was originally non-warmup), mark it as warmup
  50. UPDATE usage_ledger SET blocked_by = 'warmup' WHERE request_id = NEW.id;
  51. RETURN NEW;
  52. END IF;
  53. IF NEW.provider_chain IS NOT NULL
  54. AND jsonb_typeof(NEW.provider_chain) = 'array'
  55. AND jsonb_array_length(NEW.provider_chain) > 0
  56. AND jsonb_typeof(NEW.provider_chain -> -1) = 'object'
  57. AND (NEW.provider_chain -> -1 ? 'id')
  58. AND (NEW.provider_chain -> -1 ->> 'id') ~ '^[0-9]+$' THEN
  59. v_final_provider_id := (NEW.provider_chain -> -1 ->> 'id')::integer;
  60. ELSE
  61. v_final_provider_id := NEW.provider_id;
  62. END IF;
  63. v_is_success := (NEW.error_message IS NULL OR NEW.error_message = '');
  64. INSERT INTO usage_ledger (
  65. request_id, user_id, key, provider_id, final_provider_id,
  66. model, original_model, endpoint, api_type, session_id,
  67. status_code, is_success, blocked_by,
  68. cost_usd, cost_multiplier,
  69. input_tokens, output_tokens,
  70. cache_creation_input_tokens, cache_read_input_tokens,
  71. cache_creation_5m_input_tokens, cache_creation_1h_input_tokens,
  72. cache_ttl_applied, context_1m_applied, swap_cache_ttl_applied,
  73. duration_ms, ttfb_ms, created_at
  74. ) VALUES (
  75. NEW.id, NEW.user_id, NEW.key, NEW.provider_id, v_final_provider_id,
  76. NEW.model, NEW.original_model, NEW.endpoint, NEW.api_type, NEW.session_id,
  77. NEW.status_code, v_is_success, NEW.blocked_by,
  78. NEW.cost_usd, NEW.cost_multiplier,
  79. NEW.input_tokens, NEW.output_tokens,
  80. NEW.cache_creation_input_tokens, NEW.cache_read_input_tokens,
  81. NEW.cache_creation_5m_input_tokens, NEW.cache_creation_1h_input_tokens,
  82. NEW.cache_ttl_applied, NEW.context_1m_applied, NEW.swap_cache_ttl_applied,
  83. NEW.duration_ms, NEW.ttfb_ms, NEW.created_at
  84. )
  85. ON CONFLICT (request_id) DO UPDATE SET
  86. user_id = EXCLUDED.user_id,
  87. key = EXCLUDED.key,
  88. provider_id = EXCLUDED.provider_id,
  89. final_provider_id = EXCLUDED.final_provider_id,
  90. model = EXCLUDED.model,
  91. original_model = EXCLUDED.original_model,
  92. endpoint = EXCLUDED.endpoint,
  93. api_type = EXCLUDED.api_type,
  94. session_id = EXCLUDED.session_id,
  95. status_code = EXCLUDED.status_code,
  96. is_success = EXCLUDED.is_success,
  97. blocked_by = EXCLUDED.blocked_by,
  98. cost_usd = EXCLUDED.cost_usd,
  99. cost_multiplier = EXCLUDED.cost_multiplier,
  100. input_tokens = EXCLUDED.input_tokens,
  101. output_tokens = EXCLUDED.output_tokens,
  102. cache_creation_input_tokens = EXCLUDED.cache_creation_input_tokens,
  103. cache_read_input_tokens = EXCLUDED.cache_read_input_tokens,
  104. cache_creation_5m_input_tokens = EXCLUDED.cache_creation_5m_input_tokens,
  105. cache_creation_1h_input_tokens = EXCLUDED.cache_creation_1h_input_tokens,
  106. cache_ttl_applied = EXCLUDED.cache_ttl_applied,
  107. context_1m_applied = EXCLUDED.context_1m_applied,
  108. swap_cache_ttl_applied = EXCLUDED.swap_cache_ttl_applied,
  109. duration_ms = EXCLUDED.duration_ms,
  110. ttfb_ms = EXCLUDED.ttfb_ms,
  111. created_at = EXCLUDED.created_at;
  112. RETURN NEW;
  113. EXCEPTION WHEN OTHERS THEN
  114. RAISE WARNING 'fn_upsert_usage_ledger failed for request_id=%: %', NEW.id, SQLERRM;
  115. RETURN NEW;
  116. END;
  117. $$ LANGUAGE plpgsql;--> statement-breakpoint
  118. CREATE TRIGGER trg_upsert_usage_ledger
  119. AFTER INSERT OR UPDATE ON message_request
  120. FOR EACH ROW
  121. EXECUTE FUNCTION fn_upsert_usage_ledger();