obelix74 commented on code in PR #3523:
URL: https://github.com/apache/polaris/pull/3523#discussion_r2771637291


##########
persistence/relational-jdbc/src/main/resources/postgres/schema-metrics-v1.sql:
##########
@@ -0,0 +1,207 @@
+--
+-- Licensed to the Apache Software Foundation (ASF) under one
+-- or more contributor license agreements.  See the NOTICE file--
+--  distributed with this work for additional information
+-- regarding copyright ownership.  The ASF licenses this file
+-- to you under the Apache License, Version 2.0 (the
+-- "License"). You may not use this file except in compliance
+-- with the License.  You may obtain a copy of the License at
+--
+--  http://www.apache.org/licenses/LICENSE-2.0
+--
+-- Unless required by applicable law or agreed to in writing,
+-- software distributed under the License is distributed on an
+-- "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
+-- KIND, either express or implied.  See the License for the
+-- specific language governing permissions and limitations
+-- under the License.
+
+-- ============================================================================
+-- POLARIS METRICS SCHEMA VERSION 1 (PostgreSQL)
+-- ============================================================================
+-- This schema is SEPARATE from the entity schema and can evolve independently.
+-- It contains tables for storing Iceberg metrics reports.
+--
+-- Tables:
+--   * `metrics_version` - Version tracking for the metrics schema
+--   * `scan_metrics_report` - Scan metrics reports
+--   * `scan_metrics_report_roles` - Junction table for principal roles
+--   * `commit_metrics_report` - Commit metrics reports
+--   * `commit_metrics_report_roles` - Junction table for principal roles
+-- ============================================================================
+
+CREATE SCHEMA IF NOT EXISTS POLARIS_SCHEMA;
+SET search_path TO POLARIS_SCHEMA;
+
+-- Metrics schema version tracking (separate from entity schema version)
+CREATE TABLE IF NOT EXISTS metrics_version (
+    version_key TEXT PRIMARY KEY,
+    version_value INTEGER NOT NULL
+);
+
+INSERT INTO metrics_version (version_key, version_value)
+VALUES ('metrics_version', 1)
+ON CONFLICT (version_key) DO UPDATE
+SET version_value = EXCLUDED.version_value;
+
+COMMENT ON TABLE metrics_version IS 'the version of the metrics schema in use';
+
+-- ============================================================================
+-- SCAN METRICS REPORT TABLE
+-- ============================================================================
+
+CREATE TABLE IF NOT EXISTS scan_metrics_report (
+    report_id TEXT NOT NULL,
+    realm_id TEXT NOT NULL,
+    catalog_id BIGINT NOT NULL,
+    namespace TEXT NOT NULL,
+    table_id BIGINT NOT NULL,
+
+    -- Report metadata
+    timestamp_ms BIGINT NOT NULL,
+    principal_name TEXT,
+    request_id TEXT,
+
+    -- Trace correlation
+    otel_trace_id TEXT,
+    otel_span_id TEXT,
+    report_trace_id TEXT,
+
+    -- Scan context
+    snapshot_id BIGINT,
+    schema_id INTEGER,
+    filter_expression TEXT,
+    projected_field_ids TEXT,
+    projected_field_names TEXT,
+
+    -- Scan metrics
+    result_data_files BIGINT DEFAULT 0,
+    result_delete_files BIGINT DEFAULT 0,
+    total_file_size_bytes BIGINT DEFAULT 0,
+    total_data_manifests BIGINT DEFAULT 0,
+    total_delete_manifests BIGINT DEFAULT 0,
+    scanned_data_manifests BIGINT DEFAULT 0,
+    scanned_delete_manifests BIGINT DEFAULT 0,
+    skipped_data_manifests BIGINT DEFAULT 0,
+    skipped_delete_manifests BIGINT DEFAULT 0,
+    skipped_data_files BIGINT DEFAULT 0,
+    skipped_delete_files BIGINT DEFAULT 0,
+    total_planning_duration_ms BIGINT DEFAULT 0,
+
+    -- Equality/positional delete metrics
+    equality_delete_files BIGINT DEFAULT 0,
+    positional_delete_files BIGINT DEFAULT 0,
+    indexed_delete_files BIGINT DEFAULT 0,
+    total_delete_file_size_bytes BIGINT DEFAULT 0,
+
+    -- Additional metadata (for extensibility)
+    metadata JSONB DEFAULT '{}'::JSONB,
+
+    PRIMARY KEY (realm_id, report_id)
+);
+
+COMMENT ON TABLE scan_metrics_report IS 'Scan metrics reports as first-class 
entities';
+COMMENT ON COLUMN scan_metrics_report.report_id IS 'Unique identifier for the 
report';
+COMMENT ON COLUMN scan_metrics_report.realm_id IS 'Realm ID for multi-tenancy';
+COMMENT ON COLUMN scan_metrics_report.catalog_id IS 'Catalog ID';
+COMMENT ON COLUMN scan_metrics_report.otel_trace_id IS 'OpenTelemetry trace ID 
from HTTP headers';
+COMMENT ON COLUMN scan_metrics_report.report_trace_id IS 'Trace ID from report 
metadata';
+
+-- Index for retention cleanup by timestamp
+CREATE INDEX IF NOT EXISTS idx_scan_report_timestamp
+    ON scan_metrics_report(realm_id, timestamp_ms DESC);
+
+-- Junction table for scan metrics report roles
+CREATE TABLE IF NOT EXISTS scan_metrics_report_roles (
+    realm_id TEXT NOT NULL,
+    report_id TEXT NOT NULL,
+    role_name TEXT NOT NULL,
+    PRIMARY KEY (realm_id, report_id, role_name),
+    FOREIGN KEY (realm_id, report_id) REFERENCES scan_metrics_report(realm_id, 
report_id) ON DELETE CASCADE
+);
+
+COMMENT ON TABLE scan_metrics_report_roles IS 'Activated principal roles for 
scan metrics reports';
+
+-- ============================================================================
+-- COMMIT METRICS REPORT TABLE
+-- ============================================================================
+
+CREATE TABLE IF NOT EXISTS commit_metrics_report (
+    report_id TEXT NOT NULL,
+    realm_id TEXT NOT NULL,
+    catalog_id BIGINT NOT NULL,
+    namespace TEXT NOT NULL,
+    table_id BIGINT NOT NULL,
+
+    -- Report metadata
+    timestamp_ms BIGINT NOT NULL,
+    principal_name TEXT,
+    request_id TEXT,
+
+    -- Trace correlation
+    otel_trace_id TEXT,
+    otel_span_id TEXT,
+    report_trace_id TEXT,
+
+    -- Commit context
+    snapshot_id BIGINT NOT NULL,
+    sequence_number BIGINT,
+    operation TEXT NOT NULL,
+
+    -- File metrics
+    added_data_files BIGINT DEFAULT 0,
+    removed_data_files BIGINT DEFAULT 0,
+    total_data_files BIGINT DEFAULT 0,
+    added_delete_files BIGINT DEFAULT 0,
+    removed_delete_files BIGINT DEFAULT 0,
+    total_delete_files BIGINT DEFAULT 0,
+
+    -- Equality delete files
+    added_equality_delete_files BIGINT DEFAULT 0,
+    removed_equality_delete_files BIGINT DEFAULT 0,
+
+    -- Positional delete files
+    added_positional_delete_files BIGINT DEFAULT 0,
+    removed_positional_delete_files BIGINT DEFAULT 0,
+
+    -- Record metrics
+    added_records BIGINT DEFAULT 0,
+    removed_records BIGINT DEFAULT 0,
+    total_records BIGINT DEFAULT 0,
+
+    -- Size metrics
+    added_file_size_bytes BIGINT DEFAULT 0,
+    removed_file_size_bytes BIGINT DEFAULT 0,
+    total_file_size_bytes BIGINT DEFAULT 0,
+
+    -- Duration and attempts
+    total_duration_ms BIGINT DEFAULT 0,
+    attempts INTEGER DEFAULT 1,
+
+    -- Additional metadata (for extensibility)
+    metadata JSONB DEFAULT '{}'::JSONB,
+
+    PRIMARY KEY (realm_id, report_id)
+);
+
+COMMENT ON TABLE commit_metrics_report IS 'Commit metrics reports as 
first-class entities';
+COMMENT ON COLUMN commit_metrics_report.report_id IS 'Unique identifier for 
the report';
+COMMENT ON COLUMN commit_metrics_report.realm_id IS 'Realm ID for 
multi-tenancy';
+COMMENT ON COLUMN commit_metrics_report.operation IS 'Commit operation type: 
append, overwrite, delete, replace';
+COMMENT ON COLUMN commit_metrics_report.otel_trace_id IS 'OpenTelemetry trace 
ID from HTTP headers';
+
+-- Index for retention cleanup by timestamp
+CREATE INDEX IF NOT EXISTS idx_commit_report_timestamp
+    ON commit_metrics_report(realm_id, timestamp_ms DESC);
+
+-- Junction table for commit metrics report roles
+CREATE TABLE IF NOT EXISTS commit_metrics_report_roles (

Review Comment:
   @dimas-b there was an open question from @singhpk234 about this. He was 
asking us if we need a dedicated table for this or if we can store role ids as 
a JSON [] in commit_metrics_report.



-- 
This is an automated message from the Apache Git Service.
To respond to the message, please log on to GitHub and use the
URL above to go to the specific comment.

To unsubscribe, e-mail: [email protected]

For queries about this service, please contact Infrastructure at:
[email protected]

Reply via email to