「SaaSでありがちな JSONB + 集計」を、具体的なテーブル定義 → データ例 → 集計クエリでまとめます。
(PostgreSQL前提。JSONB + GINインデックスを使うパターン)
CREATE TABLE event_logs (id bigserial PRIMARY KEY,tenant_id uuid NOT NULL,user_id uuid NOT NULL,event_type text NOT NULL, -- 'click', 'purchase', 'login' などoccurred_at timestamptz NOT NULL,props jsonb NOT NULL -- 追加属性はJSONBに逃がす);-- JSONB検索を速くする(contains系に効く)CREATE INDEX event_logs_props_gin ON event_logs USING gin (props);-- 時系列検索も多いのでCREATE INDEX event_logs_tenant_time ON event_logs (tenant_id, occurred_at);INSERT INTO event_logs (tenant_id, user_id, event_type, occurred_at, props)VALUES('11111111-1111-1111-1111-111111111111','aaaaaaaa-aaaa-aaaa-aaaa-aaaaaaaaaaaa','click', now() - interval '1 day','{"feature":"dashboard","button":"export","plan":"pro"}'),('11111111-1111-1111-1111-111111111111','bbbbbbbb-bbbb-bbbb-bbbb-bbbbbbbbbbbb','purchase',now() - interval '1 day','{"feature":"billing","amount":1200,"currency":"JPY","plan":"pro"}'),('11111111-1111-1111-1111-111111111111','aaaaaaaa-aaaa-aaaa-aaaa-aaaaaaaaaaaa','click', now(),'{"feature":"billing","button":"change_card","plan":"pro"}');SELECTdate_trunc('day', occurred_at) AS day,props->>'feature' AS feature,count(*) AS eventsFROM event_logsWHERE tenant_id = '11111111-1111-1111-1111-111111111111'AND occurred_at >= now() - interval '7 days'GROUP BY 1, 2ORDER BY 1, 2;SELECTdate_trunc('day', occurred_at) AS day,sum( (props->>'amount')::numeric ) AS revenueFROM event_logsWHERE tenant_id = '11111111-1111-1111-1111-111111111111'AND event_type = 'purchase'AND occurred_at >= now() - interval '30 days'GROUP BY 1ORDER BY 1;SaaSは顧客ごとに「カスタムフィールド」が増える:
例)CRMの顧客(customer)の attrs に自由項目
CREATE TABLE customers (id bigserial PRIMARY KEY,tenant_id uuid NOT NULL,name text NOT NULL,attrs jsonb NOT NULL, -- {"industry":"IT","employees":50,"region":"Kanto"}created_at timestamptz NOT NULL DEFAULT now());CREATE INDEX customers_attrs_gin ON customers USING gin (attrs);CREATE INDEX customers_tenant ON customers (tenant_id);SELECTattrs->>'industry' AS industry,count(*) AS customersFROM customersWHERE tenant_id = '11111111-1111-1111-1111-111111111111'GROUP BY 1ORDER BY customers DESC;SELECTCASEWHEN (attrs->>'employees')::int < 10 THEN '1-9'WHEN (attrs->>'employees')::int < 50 THEN '10-49'WHEN (attrs->>'employees')::int < 200 THEN '50-199'ELSE '200+'END AS size_bucket,count(*) AS customersFROM customersWHERE tenant_id = '11111111-1111-1111-1111-111111111111'AND attrs ? 'employees' -- キー存在チェックGROUP BY 1ORDER BY 1;CREATE TABLE orders (id bigserial PRIMARY KEY,tenant_id uuid NOT NULL,ordered_at timestamptz NOT NULL,payload jsonb NOT NULL-- payload例:-- {"order_id":"x","items":[{"sku":"A","qty":2,"price":300},{"sku":"B","qty":1,"price":500}]});CREATE INDEX orders_tenant_time ON orders (tenant_id, ordered_at);SELECTitem->>'sku' AS sku,sum( (item->>'qty')::int ) AS total_qty,sum( ((item->>'qty')::int) * ((item->>'price')::numeric) ) AS revenueFROM ordersCROSS JOIN LATERAL jsonb_array_elements(payload->'items') AS itemWHERE tenant_id = '11111111-1111-1111-1111-111111111111'AND ordered_at >= now() - interval '30 days'GROUP BY 1ORDER BY revenue DESC;