up
This commit is contained in:
@@ -44,28 +44,57 @@ This document specifies the PostgreSQL database design for StellaOps control-pla
|
||||
| `policy` | Policy | Policy packs, rules, risk profiles, evaluations |
|
||||
| `packs` | PacksRegistry | Package attestations, mirrors, lifecycle |
|
||||
| `issuer` | IssuerDirectory | Trust anchors, issuer keys, certificates |
|
||||
| `unknowns` | Unknowns | Bitemporal ambiguity tracking for scan gaps |
|
||||
| `audit` | Shared | Cross-cutting audit log (optional) |
|
||||
|
||||
### 2.3 Multi-Tenancy Model
|
||||
|
||||
**Strategy:** Single database, single schema set, `tenant_id` column on all tenant-scoped tables.
|
||||
**Strategy:** Single database, single schema set, `tenant_id` column on all tenant-scoped tables with **mandatory Row-Level Security (RLS)**.
|
||||
|
||||
```sql
|
||||
-- Every tenant-scoped table includes:
|
||||
tenant_id UUID NOT NULL,
|
||||
|
||||
-- Session-level tenant context (set on connection open):
|
||||
-- Session-level tenant context (MUST be set on connection open):
|
||||
SET app.tenant_id = '<tenant-uuid>';
|
||||
|
||||
-- Row-level security policy (optional, for defense in depth):
|
||||
CREATE POLICY tenant_isolation ON <table>
|
||||
USING (tenant_id = current_setting('app.tenant_id')::uuid);
|
||||
-- Row-level security policy (MANDATORY for all tenant-scoped tables):
|
||||
ALTER TABLE <schema>.<table> ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE <schema>.<table> FORCE ROW LEVEL SECURITY;
|
||||
|
||||
CREATE POLICY <table>_tenant_isolation ON <schema>.<table>
|
||||
FOR ALL
|
||||
USING (tenant_id = <schema>_app.require_current_tenant())
|
||||
WITH CHECK (tenant_id = <schema>_app.require_current_tenant());
|
||||
```
|
||||
|
||||
**RLS Helper Function Pattern:**
|
||||
Each schema with tenant-scoped tables has a companion `<schema>_app` schema containing a `require_current_tenant()` function that validates `app.tenant_id` is set.
|
||||
|
||||
```sql
|
||||
CREATE SCHEMA IF NOT EXISTS <schema>_app;
|
||||
|
||||
CREATE OR REPLACE FUNCTION <schema>_app.require_current_tenant()
|
||||
RETURNS TEXT
|
||||
LANGUAGE plpgsql STABLE SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
v_tenant TEXT;
|
||||
BEGIN
|
||||
v_tenant := current_setting('app.tenant_id', true);
|
||||
IF v_tenant IS NULL OR v_tenant = '' THEN
|
||||
RAISE EXCEPTION 'app.tenant_id session variable not set';
|
||||
END IF;
|
||||
RETURN v_tenant;
|
||||
END;
|
||||
$$;
|
||||
```
|
||||
|
||||
**Rationale:**
|
||||
- Simplest operational model
|
||||
- Shared connection pooling
|
||||
- Easy cross-tenant queries for admin operations
|
||||
- Defense-in-depth tenant isolation at the database level
|
||||
- Prevents data leakage even if application bugs bypass tenant checks
|
||||
- Shared connection pooling compatible
|
||||
- Admin bypass via `BYPASSRLS` roles for cross-tenant operations
|
||||
- Composite indexes on `(tenant_id, ...)` for query performance
|
||||
|
||||
---
|
||||
@@ -214,6 +243,51 @@ CREATE INDEX idx_<table>_<column>_gin ON <table> USING GIN (<column>);
|
||||
CREATE INDEX idx_<table>_<column>_<path> ON <table> ((<column>->>'path'));
|
||||
```
|
||||
|
||||
### 4.5 Generated Columns for JSONB Hot Fields
|
||||
|
||||
When JSONB fields are frequently queried with equality or range filters, use **generated columns** to extract them as first-class columns. This enables:
|
||||
- B-tree indexes with accurate statistics
|
||||
- Index-only scans via covering indexes
|
||||
- Proper cardinality estimates for query planning
|
||||
|
||||
**Pattern:**
|
||||
```sql
|
||||
-- Extract hot field as generated column
|
||||
ALTER TABLE <schema>.<table>
|
||||
ADD COLUMN IF NOT EXISTS <field_name> <type>
|
||||
GENERATED ALWAYS AS ((<jsonb_column>->>'<json_key>')::<type>) STORED;
|
||||
|
||||
-- Create B-tree index on generated column
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_<table>_<field_name>
|
||||
ON <schema>.<table> (<field_name>)
|
||||
WHERE <field_name> IS NOT NULL;
|
||||
|
||||
-- Covering index for dashboard queries
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_<table>_listing
|
||||
ON <schema>.<table> (tenant_id, created_at DESC)
|
||||
INCLUDE (<generated_col1>, <generated_col2>, <generated_col3>);
|
||||
|
||||
-- Update statistics
|
||||
ANALYZE <schema>.<table>;
|
||||
```
|
||||
|
||||
**Example (scheduler.runs stats extraction):**
|
||||
```sql
|
||||
ALTER TABLE scheduler.runs
|
||||
ADD COLUMN IF NOT EXISTS finding_count INT
|
||||
GENERATED ALWAYS AS (NULLIF((stats->>'findingCount'), '')::int) STORED;
|
||||
|
||||
CREATE INDEX ix_runs_with_findings
|
||||
ON scheduler.runs (tenant_id, created_at DESC)
|
||||
WHERE finding_count > 0;
|
||||
```
|
||||
|
||||
**Guidelines:**
|
||||
- Use `NULLIF(<expr>, '')` before casting to handle empty strings
|
||||
- Add `WHERE <column> IS NOT NULL` to partial indexes for sparse data
|
||||
- Use `INCLUDE` clause for covering indexes that return multiple generated columns
|
||||
- Run `ANALYZE` after adding generated columns to populate statistics
|
||||
|
||||
---
|
||||
|
||||
## 5. Schema Definitions
|
||||
|
||||
Reference in New Issue
Block a user