Skip to content
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
163 changes: 163 additions & 0 deletions persistence/relational-jdbc/src/main/resources/h2/schema-v4.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,163 @@
--
-- 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.
--

-- Changes from v2:
-- * Added `events` table
-- * Added `idempotency_records` table for REST idempotency

CREATE SCHEMA IF NOT EXISTS POLARIS_SCHEMA;
SET SCHEMA POLARIS_SCHEMA;

CREATE TABLE IF NOT EXISTS version (
version_key VARCHAR PRIMARY KEY,
version_value INTEGER NOT NULL
);

MERGE INTO version (version_key, version_value)
KEY (version_key)
VALUES ('version', 3);
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Should this version be set to 4? @singhpk234 @dimas-b

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

@obelix74 Thanks for catching this problem. I will fix this in next PR.


-- H2 supports COMMENT, but some modes may ignore it
COMMENT ON TABLE version IS 'the version of the JDBC schema in use';

CREATE TABLE IF NOT EXISTS entities (
realm_id TEXT NOT NULL,
catalog_id BIGINT NOT NULL,
id BIGINT NOT NULL,
parent_id BIGINT NOT NULL,
name TEXT NOT NULL,
entity_version INT NOT NULL,
type_code INT NOT NULL,
sub_type_code INT NOT NULL,
create_timestamp BIGINT NOT NULL,
drop_timestamp BIGINT NOT NULL,
purge_timestamp BIGINT NOT NULL,
to_purge_timestamp BIGINT NOT NULL,
last_update_timestamp BIGINT NOT NULL,
properties TEXT NOT NULL DEFAULT '{}',
internal_properties TEXT NOT NULL DEFAULT '{}',
grant_records_version INT NOT NULL,
location_without_scheme TEXT,
PRIMARY KEY (realm_id, id),
CONSTRAINT constraint_name UNIQUE (realm_id, catalog_id, parent_id, type_code, name)
);

CREATE INDEX IF NOT EXISTS idx_locations ON entities(realm_id, catalog_id, location_without_scheme);

-- TODO: create indexes based on all query pattern.
CREATE INDEX IF NOT EXISTS idx_entities ON entities (realm_id, catalog_id, id);

COMMENT ON TABLE entities IS 'all the entities';

COMMENT ON COLUMN entities.catalog_id IS 'catalog id';
COMMENT ON COLUMN entities.id IS 'entity id';
COMMENT ON COLUMN entities.parent_id IS 'entity id of parent';
COMMENT ON COLUMN entities.name IS 'entity name';
COMMENT ON COLUMN entities.entity_version IS 'version of the entity';
COMMENT ON COLUMN entities.type_code IS 'type code';
COMMENT ON COLUMN entities.sub_type_code IS 'sub type of entity';
COMMENT ON COLUMN entities.create_timestamp IS 'creation time of entity';
COMMENT ON COLUMN entities.drop_timestamp IS 'time of drop of entity';
COMMENT ON COLUMN entities.purge_timestamp IS 'time to start purging entity';
COMMENT ON COLUMN entities.last_update_timestamp IS 'last time the entity is touched';
COMMENT ON COLUMN entities.properties IS 'entities properties json';
COMMENT ON COLUMN entities.internal_properties IS 'entities internal properties json';
COMMENT ON COLUMN entities.grant_records_version IS 'the version of grant records change on the entity';

CREATE TABLE IF NOT EXISTS grant_records (
realm_id TEXT NOT NULL,
securable_catalog_id BIGINT NOT NULL,
securable_id BIGINT NOT NULL,
grantee_catalog_id BIGINT NOT NULL,
grantee_id BIGINT NOT NULL,
privilege_code INTEGER,
PRIMARY KEY (realm_id, securable_catalog_id, securable_id, grantee_catalog_id, grantee_id, privilege_code)
);

COMMENT ON TABLE grant_records IS 'grant records for entities';
COMMENT ON COLUMN grant_records.securable_catalog_id IS 'catalog id of the securable';
COMMENT ON COLUMN grant_records.securable_id IS 'entity id of the securable';
COMMENT ON COLUMN grant_records.grantee_catalog_id IS 'catalog id of the grantee';
COMMENT ON COLUMN grant_records.grantee_id IS 'id of the grantee';
COMMENT ON COLUMN grant_records.privilege_code IS 'privilege code';

CREATE TABLE IF NOT EXISTS principal_authentication_data (
realm_id TEXT NOT NULL,
principal_id BIGINT NOT NULL,
principal_client_id VARCHAR(255) NOT NULL,
main_secret_hash VARCHAR(255) NOT NULL,
secondary_secret_hash VARCHAR(255) NOT NULL,
secret_salt VARCHAR(255) NOT NULL,
PRIMARY KEY (realm_id, principal_client_id)
);

COMMENT ON TABLE principal_authentication_data IS 'authentication data for client';

CREATE TABLE IF NOT EXISTS policy_mapping_record (
realm_id TEXT NOT NULL,
target_catalog_id BIGINT NOT NULL,
target_id BIGINT NOT NULL,
policy_type_code INTEGER NOT NULL,
policy_catalog_id BIGINT NOT NULL,
policy_id BIGINT NOT NULL,
parameters TEXT NOT NULL DEFAULT '{}',
PRIMARY KEY (realm_id, target_catalog_id, target_id, policy_type_code, policy_catalog_id, policy_id)
);

CREATE INDEX IF NOT EXISTS idx_policy_mapping_record ON policy_mapping_record (realm_id, policy_type_code, policy_catalog_id, policy_id, target_catalog_id, target_id);

CREATE TABLE IF NOT EXISTS events (
realm_id TEXT NOT NULL,
catalog_id TEXT NOT NULL,
event_id TEXT NOT NULL,
request_id TEXT,
event_type TEXT NOT NULL,
timestamp_ms BIGINT NOT NULL,
principal_name TEXT,
resource_type TEXT NOT NULL,
resource_identifier TEXT NOT NULL,
additional_properties TEXT NOT NULL,
PRIMARY KEY (event_id)
);

CREATE TABLE IF NOT EXISTS idempotency_records (
realm_id TEXT NOT NULL,
idempotency_key TEXT NOT NULL,
operation_type TEXT NOT NULL,
resource_id TEXT NOT NULL, -- normalized request-derived resource identifier (not a generated entity id)

-- Finalization/replay
http_status INTEGER, -- NULL while IN_PROGRESS; set only on finalized 2xx/terminal 4xx
error_subtype TEXT, -- optional: e.g., already_exists, namespace_not_empty, idempotency_replay_failed
response_summary TEXT, -- minimal body to reproduce equivalent response (JSON string)
response_headers TEXT, -- small whitelisted headers to replay (JSON string)
finalized_at TIMESTAMP, -- when http_status was written

-- Liveness/ops
created_at TIMESTAMP NOT NULL,
updated_at TIMESTAMP NOT NULL,
heartbeat_at TIMESTAMP, -- updated by owner while IN_PROGRESS
executor_id TEXT, -- owner pod/worker id
expires_at TIMESTAMP,

PRIMARY KEY (realm_id, idempotency_key)
);

CREATE INDEX IF NOT EXISTS idx_idemp_realm_expires
ON idempotency_records (realm_id, expires_at);
Original file line number Diff line number Diff line change
Expand Up @@ -134,31 +134,3 @@ CREATE TABLE IF NOT EXISTS events (
additional_properties JSONB NOT NULL DEFAULT '{}'::JSONB,
PRIMARY KEY (event_id)
);

-- Idempotency records (key-only idempotency; durable replay)
CREATE TABLE IF NOT EXISTS idempotency_records (
realm_id TEXT NOT NULL,
idempotency_key TEXT NOT NULL,
operation_type TEXT NOT NULL,
resource_id TEXT NOT NULL,

-- Finalization/replay
http_status INTEGER, -- NULL while IN_PROGRESS; set only on finalized 2xx/terminal 4xx
error_subtype TEXT, -- optional: e.g., already_exists, namespace_not_empty, idempotency_replay_failed
response_summary TEXT, -- minimal body to reproduce equivalent response (JSON string)
response_headers TEXT, -- small whitelisted headers to replay (JSON string)
finalized_at TIMESTAMP, -- when http_status was written

-- Liveness/ops
created_at TIMESTAMP NOT NULL,
updated_at TIMESTAMP NOT NULL,
heartbeat_at TIMESTAMP, -- updated by owner while IN_PROGRESS
executor_id TEXT, -- owner pod/worker id
expires_at TIMESTAMP,

PRIMARY KEY (realm_id, idempotency_key)
);

-- Helpful indexes
CREATE INDEX IF NOT EXISTS idx_idemp_realm_expires
ON idempotency_records (realm_id, expires_at);
165 changes: 165 additions & 0 deletions persistence/relational-jdbc/src/main/resources/postgres/schema-v4.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,165 @@
--
-- 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.

-- Changes from v2:
-- * Added `events` table
-- * Added `idempotency_records` table for REST idempotency

CREATE SCHEMA IF NOT EXISTS POLARIS_SCHEMA;
SET search_path TO POLARIS_SCHEMA;

CREATE TABLE IF NOT EXISTS version (
version_key TEXT PRIMARY KEY,
version_value INTEGER NOT NULL
);
INSERT INTO version (version_key, version_value)
VALUES ('version', 3)
ON CONFLICT (version_key) DO UPDATE
SET version_value = EXCLUDED.version_value;
COMMENT ON TABLE version IS 'the version of the JDBC schema in use';

CREATE TABLE IF NOT EXISTS entities (
realm_id TEXT NOT NULL,
catalog_id BIGINT NOT NULL,
id BIGINT NOT NULL,
parent_id BIGINT NOT NULL,
name TEXT NOT NULL,
entity_version INT NOT NULL,
type_code INT NOT NULL,
sub_type_code INT NOT NULL,
create_timestamp BIGINT NOT NULL,
drop_timestamp BIGINT NOT NULL,
purge_timestamp BIGINT NOT NULL,
to_purge_timestamp BIGINT NOT NULL,
last_update_timestamp BIGINT NOT NULL,
properties JSONB not null default '{}'::JSONB,
internal_properties JSONB not null default '{}'::JSONB,
grant_records_version INT NOT NULL,
location_without_scheme TEXT,
PRIMARY KEY (realm_id, id),
CONSTRAINT constraint_name UNIQUE (realm_id, catalog_id, parent_id, type_code, name)
);

-- TODO: create indexes based on all query pattern.
CREATE INDEX IF NOT EXISTS idx_entities ON entities (realm_id, catalog_id, id);
CREATE INDEX IF NOT EXISTS idx_locations
ON entities USING btree (realm_id, parent_id, location_without_scheme)
WHERE location_without_scheme IS NOT NULL;

COMMENT ON TABLE entities IS 'all the entities';

COMMENT ON COLUMN entities.realm_id IS 'realm_id used for multi-tenancy';
COMMENT ON COLUMN entities.catalog_id IS 'catalog id';
COMMENT ON COLUMN entities.id IS 'entity id';
COMMENT ON COLUMN entities.parent_id IS 'entity id of parent';
COMMENT ON COLUMN entities.name IS 'entity name';
COMMENT ON COLUMN entities.entity_version IS 'version of the entity';
COMMENT ON COLUMN entities.type_code IS 'type code';
COMMENT ON COLUMN entities.sub_type_code IS 'sub type of entity';
COMMENT ON COLUMN entities.create_timestamp IS 'creation time of entity';
COMMENT ON COLUMN entities.drop_timestamp IS 'time of drop of entity';
COMMENT ON COLUMN entities.purge_timestamp IS 'time to start purging entity';
COMMENT ON COLUMN entities.last_update_timestamp IS 'last time the entity is touched';
COMMENT ON COLUMN entities.properties IS 'entities properties json';
COMMENT ON COLUMN entities.internal_properties IS 'entities internal properties json';
COMMENT ON COLUMN entities.grant_records_version IS 'the version of grant records change on the entity';

CREATE TABLE IF NOT EXISTS grant_records (
realm_id TEXT NOT NULL,
securable_catalog_id BIGINT NOT NULL,
securable_id BIGINT NOT NULL,
grantee_catalog_id BIGINT NOT NULL,
grantee_id BIGINT NOT NULL,
privilege_code INTEGER,
PRIMARY KEY (realm_id, securable_catalog_id, securable_id, grantee_catalog_id, grantee_id, privilege_code)
);

COMMENT ON TABLE grant_records IS 'grant records for entities';

COMMENT ON COLUMN grant_records.securable_catalog_id IS 'catalog id of the securable';
COMMENT ON COLUMN grant_records.securable_id IS 'entity id of the securable';
COMMENT ON COLUMN grant_records.grantee_catalog_id IS 'catalog id of the grantee';
COMMENT ON COLUMN grant_records.grantee_id IS 'id of the grantee';
COMMENT ON COLUMN grant_records.privilege_code IS 'privilege code';

CREATE TABLE IF NOT EXISTS principal_authentication_data (
realm_id TEXT NOT NULL,
principal_id BIGINT NOT NULL,
principal_client_id VARCHAR(255) NOT NULL,
main_secret_hash VARCHAR(255) NOT NULL,
secondary_secret_hash VARCHAR(255) NOT NULL,
secret_salt VARCHAR(255) NOT NULL,
PRIMARY KEY (realm_id, principal_client_id)
);

COMMENT ON TABLE principal_authentication_data IS 'authentication data for client';

CREATE TABLE IF NOT EXISTS policy_mapping_record (
realm_id TEXT NOT NULL,
target_catalog_id BIGINT NOT NULL,
target_id BIGINT NOT NULL,
policy_type_code INTEGER NOT NULL,
policy_catalog_id BIGINT NOT NULL,
policy_id BIGINT NOT NULL,
parameters JSONB NOT NULL DEFAULT '{}'::JSONB,
PRIMARY KEY (realm_id, target_catalog_id, target_id, policy_type_code, policy_catalog_id, policy_id)
);

CREATE INDEX IF NOT EXISTS idx_policy_mapping_record ON policy_mapping_record (realm_id, policy_type_code, policy_catalog_id, policy_id, target_catalog_id, target_id);

CREATE TABLE IF NOT EXISTS events (
realm_id TEXT NOT NULL,
catalog_id TEXT NOT NULL,
event_id TEXT NOT NULL,
request_id TEXT,
event_type TEXT NOT NULL,
timestamp_ms BIGINT NOT NULL,
principal_name TEXT,
resource_type TEXT NOT NULL,
resource_identifier TEXT NOT NULL,
additional_properties JSONB NOT NULL DEFAULT '{}'::JSONB,
PRIMARY KEY (event_id)
);

-- Idempotency records (key-only idempotency; durable replay)
CREATE TABLE IF NOT EXISTS idempotency_records (
realm_id TEXT NOT NULL,
idempotency_key TEXT NOT NULL,
operation_type TEXT NOT NULL,
resource_id TEXT NOT NULL, -- normalized request-derived resource identifier (not a generated entity id)

-- Finalization/replay
http_status INTEGER, -- NULL while IN_PROGRESS; set only on finalized 2xx/terminal 4xx
error_subtype TEXT, -- optional: e.g., already_exists, namespace_not_empty, idempotency_replay_failed
response_summary TEXT, -- minimal body to reproduce equivalent response (JSON string)
response_headers TEXT, -- small whitelisted headers to replay (JSON string)
finalized_at TIMESTAMP, -- when http_status was written

-- Liveness/ops
created_at TIMESTAMP NOT NULL,
updated_at TIMESTAMP NOT NULL,
heartbeat_at TIMESTAMP, -- updated by owner while IN_PROGRESS
executor_id TEXT, -- owner pod/worker id
expires_at TIMESTAMP,

PRIMARY KEY (realm_id, idempotency_key)
);

-- Helpful indexes
CREATE INDEX IF NOT EXISTS idx_idemp_realm_expires
ON idempotency_records (realm_id, expires_at);
Original file line number Diff line number Diff line change
@@ -0,0 +1,29 @@
/*
* 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.
*/

package org.apache.polaris.persistence.relational.jdbc;

public class AtomicMetastoreManagerWithJdbcBasePersistenceImplV4SchemaTest
extends AtomicMetastoreManagerWithJdbcBasePersistenceImplTest {

@Override
public int schemaVersion() {
return 4;
}
}
Loading