From 7c7ad562e984f5ecb5cd83593d3667de0bbf35de Mon Sep 17 00:00:00 2001 From: Prashant Date: Fri, 28 Mar 2025 15:31:29 -0700 Subject: [PATCH 1/3] ADD SQL script for Polaris setup --- scripts/postgres/schema-v1-postgresql.sql | 111 ++++++++++++++++++++++ 1 file changed, 111 insertions(+) create mode 100644 scripts/postgres/schema-v1-postgresql.sql diff --git a/scripts/postgres/schema-v1-postgresql.sql b/scripts/postgres/schema-v1-postgresql.sql new file mode 100644 index 0000000000..7e4d922581 --- /dev/null +++ b/scripts/postgres/schema-v1-postgresql.sql @@ -0,0 +1,111 @@ +/* + * 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. + */ + +-- +-- +-- 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. +-- + +-- Note: Database and schema creation is not included in this script. Please create the database and +-- schema before running this script. for example in psql: +-- CREATE DATABASE polaris_db; +-- \c polaris_db +-- CREATE SCHEMA polaris_schema; +-- set search_path to polaris_schema; + +CREATE TABLE IF NOT EXISTS entities ( + catalog_id BIGINT NOT NULL, + id BIGINT NOT NULL, + parent_id BIGINT NOT NULL, + name VARCHAR(126) 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, + PRIMARY KEY (catalog_id, id), + CONSTRAINT constraint_name UNIQUE (catalog_id, parent_id, type_code, name) +); + +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 'grant record version of the entity'; + +CREATE TABLE IF NOT EXISTS grant_records ( + 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 (securable_catalog_id, securable_id, grantee_catalog_id, grantee_id, privilege_code) +); + +CREATE INDEX IF NOT EXISTS idx_grant_records ON grant_records (securable_catalog_id, securable_id, grantee_catalog_id, grantee_id); + +COMMENT ON TABLE grant_records IS 'grant records'; + +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 id'; + + +CREATE TABLE IF NOT EXISTS principal_secrets ( + principal_id BIGINT NOT NULL, + principal_client_id VARCHAR(500) NOT NULL, + main_secret_hash VARCHAR(500) NOT NULL, + secondary_secret_hash VARCHAR(500) NOT NULL, + secret_salt VARCHAR(500) NOT NULL, + PRIMARY KEY (principal_client_id) +); + +COMMENT ON TABLE principal_secrets IS 'principal secrets'; + +COMMENT ON COLUMN principal_secrets.principal_id IS 'principal id'; +COMMENT ON COLUMN principal_secrets.principal_client_id IS 'client id'; +COMMENT ON COLUMN principal_secrets.main_secret_hash IS 'secret hash'; +COMMENT ON COLUMN principal_secrets.secondary_secret_hash IS 'secondary secret hash'; +COMMENT ON COLUMN principal_secrets.secret_salt IS 'secret salt'; \ No newline at end of file From d78e49d7cfad84bea07bc6834840b7f5a663a8fd Mon Sep 17 00:00:00 2001 From: Prashant Date: Mon, 31 Mar 2025 09:39:30 -0700 Subject: [PATCH 2/3] address review feedbacks --- scripts/postgres/schema-v1-postgresql.sql | 50 +++++++---------------- 1 file changed, 15 insertions(+), 35 deletions(-) diff --git a/scripts/postgres/schema-v1-postgresql.sql b/scripts/postgres/schema-v1-postgresql.sql index 7e4d922581..469744729a 100644 --- a/scripts/postgres/schema-v1-postgresql.sql +++ b/scripts/postgres/schema-v1-postgresql.sql @@ -1,23 +1,11 @@ -/* - * 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. - */ - -- +-- 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 -- @@ -40,7 +28,7 @@ CREATE TABLE IF NOT EXISTS entities ( catalog_id BIGINT NOT NULL, id BIGINT NOT NULL, parent_id BIGINT NOT NULL, - name VARCHAR(126) NOT NULL, + name TEXT NOT NULL, entity_version INT NOT NULL, type_code INT NOT NULL, sub_type_code INT NOT NULL, @@ -82,9 +70,7 @@ CREATE TABLE IF NOT EXISTS grant_records ( PRIMARY KEY (securable_catalog_id, securable_id, grantee_catalog_id, grantee_id, privilege_code) ); -CREATE INDEX IF NOT EXISTS idx_grant_records ON grant_records (securable_catalog_id, securable_id, grantee_catalog_id, grantee_id); - -COMMENT ON TABLE grant_records IS 'grant records'; +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'; @@ -93,19 +79,13 @@ COMMENT ON COLUMN grant_records.grantee_id IS 'id of the grantee'; COMMENT ON COLUMN grant_records.privilege_code IS 'privilege id'; -CREATE TABLE IF NOT EXISTS principal_secrets ( +CREATE TABLE IF NOT EXISTS principal_authentication_data ( principal_id BIGINT NOT NULL, - principal_client_id VARCHAR(500) NOT NULL, - main_secret_hash VARCHAR(500) NOT NULL, - secondary_secret_hash VARCHAR(500) NOT NULL, - secret_salt VARCHAR(500) 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 (principal_client_id) ); -COMMENT ON TABLE principal_secrets IS 'principal secrets'; - -COMMENT ON COLUMN principal_secrets.principal_id IS 'principal id'; -COMMENT ON COLUMN principal_secrets.principal_client_id IS 'client id'; -COMMENT ON COLUMN principal_secrets.main_secret_hash IS 'secret hash'; -COMMENT ON COLUMN principal_secrets.secondary_secret_hash IS 'secondary secret hash'; -COMMENT ON COLUMN principal_secrets.secret_salt IS 'secret salt'; \ No newline at end of file +COMMENT ON TABLE principal_authentication_data IS 'authentication data for client'; \ No newline at end of file From 297ff2e94d7c2c662054d260b8a29436000c4c10 Mon Sep 17 00:00:00 2001 From: Prashant Date: Mon, 31 Mar 2025 14:45:27 -0700 Subject: [PATCH 3/3] Add yufei feedback --- scripts/postgres/schema-v1-postgresql.sql | 11 +++++++---- 1 file changed, 7 insertions(+), 4 deletions(-) diff --git a/scripts/postgres/schema-v1-postgresql.sql b/scripts/postgres/schema-v1-postgresql.sql index 469744729a..3de1a7cd7e 100644 --- a/scripts/postgres/schema-v1-postgresql.sql +++ b/scripts/postgres/schema-v1-postgresql.sql @@ -40,10 +40,13 @@ CREATE TABLE IF NOT EXISTS entities ( properties JSONB not null default '{}'::JSONB, internal_properties JSONB not null default '{}'::JSONB, grant_records_version INT NOT NULL, - PRIMARY KEY (catalog_id, id), + PRIMARY KEY (id), CONSTRAINT constraint_name UNIQUE (catalog_id, parent_id, type_code, name) ); +-- TODO: create indexes based on all query pattern. +CREATE INDEX IF NOT EXISTS idx_entities ON entities (catalog_id, id); + COMMENT ON TABLE entities IS 'all the entities'; COMMENT ON COLUMN entities.catalog_id IS 'catalog id'; @@ -59,7 +62,7 @@ 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 'grant record version of the entity'; +COMMENT ON COLUMN entities.grant_records_version IS 'the version of grant records change on the entity'; CREATE TABLE IF NOT EXISTS grant_records ( securable_catalog_id BIGINT NOT NULL, @@ -76,7 +79,7 @@ COMMENT ON COLUMN grant_records.securable_catalog_id IS 'catalog id of the secur 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 id'; +COMMENT ON COLUMN grant_records.privilege_code IS 'privilege code'; CREATE TABLE IF NOT EXISTS principal_authentication_data ( @@ -88,4 +91,4 @@ CREATE TABLE IF NOT EXISTS principal_authentication_data ( PRIMARY KEY (principal_client_id) ); -COMMENT ON TABLE principal_authentication_data IS 'authentication data for client'; \ No newline at end of file +COMMENT ON TABLE principal_authentication_data IS 'authentication data for client';