1
0
mirror of https://github.com/bitwarden/server.git synced 2024-11-22 12:15:36 +01:00

#453 Added PostgreSQL initial db scripts (User) (#556)

* PostgreSQL initial commit of translation from SQL Server to PostgreSQL

* snake_case added.
set search path for schema.  schema qualified name no longer needed for creation and access of functions.

* Table DDL for PostgreSQL
This commit is contained in:
Papina 2019-09-12 03:38:46 +10:00 committed by Kyle Spearrin
parent 12c8e4b124
commit 5000de6fa8
24 changed files with 543 additions and 4 deletions

View File

@ -0,0 +1,103 @@
CREATE OR REPLACE FUNCTION user_create
(
_id uuid,
_name varchar(50),
_email varchar(50),
_email_verified bit,
_master_password varchar(300),
_master_password_hint varchar(50),
_culture varchar(10),
_security_stamp varchar(50),
_two_factor_providers text,
_two_factor_recovery_code varchar(32),
_equivalent_domains text,
_excluded_global_equivalent_domains text,
_account_revision_date timestamptz,
_key text,
_public_key text,
_private_key text,
_premium bit,
_premium_expiration_date timestamptz,
_renewal_reminder_date timestamptz,
_storage bigint,
_max_storage_gb smallint,
_gateway smallint,
_gateway_customer_id varchar(50),
_gateway_subscription_id varchar(50),
_license_key varchar(100),
_kdf smallint,
_kdf_iterations int,
_creation_date timestamptz,
_revision_date timestamptz
)
RETURNS VOID
LANGUAGE 'plpgsql'
AS
$$
BEGIN
INSERT INTO "user"
(
id,
name,
email,
email_verified,
master_password,
master_password_hint,
culture,
security_stamp,
two_factor_providers,
two_factor_recoverycode,
equivalent_domains,
excluded_global_equivalent_domains,
account_revision_date,
key,
public_key,
private_key,
premium,
premium_expiration_date,
renewal_reminder_date,
storage,
max_storage_gb,
gateway,
gateway_customer_id,
gateway_subscription_id,
license_key,
kdf,
kdf_iterations,
creation_date,
revision_date
)
VALUES
(
_id,
_name,
_email,
_email_verified,
_master_password,
_master_password_hint,
_culture,
_security_stamp,
_two_factor_providers,
_two_factor_recovery_code,
_equivalent_domains,
_excluded_global_equivalent_domains,
_account_revision_date,
_key,
_public_key,
_private_key,
_premium,
_premium_expiration_date,
_renewal_reminder_date,
_storage,
_max_storage_gb,
_gateway,
_gateway_customer_id,
_gateway_subscription_id,
_license_key,
_kdf,
_kdf_iterations,
_creation_date,
_revision_date
);
END
$$

View File

@ -1,14 +1,20 @@
DROP FUNCTION IF EXISTS user_read_by_id;
CREATE OR REPLACE FUNCTION user_read_by_id
(
id uuid
_id uuid
)
RETURNS SETOF "user"
LANGUAGE 'sql'
AS $BODY$
LANGUAGE 'plpgsql'
AS
$BODY$
BEGIN
RETURN QUERY
SELECT
*
FROM
"user"
WHERE
"id" = id;
"id" = _id;
END
$BODY$;

View File

@ -0,0 +1,30 @@
DROP FUNCTION IF EXISTS user_search;
CREATE OR REPLACE FUNCTION user_search
(
_email VARCHAR(50),
_skip INT DEFAULT 0,
_take INT DEFAULT 25
)
RETURNS SETOF user_view
LANGUAGE 'plpgsql'
AS
$BODY$
DECLARE
email_like_search VARCHAR(55) = _email || '%';
BEGIN
RETURN QUERY
SELECT
*
FROM
user_view
WHERE
email IS NULL
OR
email LIKE email_like_search
ORDER BY email ASC
OFFSET _skip ROWS
FETCH NEXT _take ROWS only;
end
$BODY$

View File

@ -0,0 +1,2 @@
-- Example command to create the standard bitwarden user role in an existing postgreSQL instance
-- CREATE ROLE bitwarden NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT LOGIN PASSWORD 'bitwarden';

View File

@ -0,0 +1,5 @@
DROP SCHEMA bitwarden cascade;
CREATE SCHEMA bitwarden AUTHORIZATION bitwarden;
ALTER ROLE bitwarden SET search_path TO bitwarden;

View File

@ -0,0 +1,43 @@
DROP TABLE IF EXISTS "user" CASCADE;
CREATE TABLE "user" (
id UUID NOT NULL,
name VARCHAR (50) NULL,
email VARCHAR (50) NOT NULL,
email_verified BIT NOT NULL,
master_password VARCHAR (300) NOT NULL,
master_password_hint VARCHAR (50) NULL,
culture VARCHAR (10) NOT NULL,
security_stamp VARCHAR (50) NOT NULL,
two_factor_providers TEXT NULL,
two_factor_recovery_code VARCHAR (32) NULL,
equivalent_domains TEXT NULL,
excluded_global_equivalent_domains TEXT NULL,
account_revision_date TIMESTAMPTZ NOT NULL,
key TEXT NULL,
public_key TEXT NULL,
private_key TEXT NULL,
premium BIT NOT NULL,
premium_expiration_date TIMESTAMPTZ NULL,
renewal_reminder_date TIMESTAMPTZ NULL,
storage BIGINT NULL,
max_storage_gb SMALLINT NULL,
gateway SMALLINT NULL,
gateway_customer_id VARCHAR (50) NULL,
gateway_subscription_id VARCHAR (50) NULL,
license_key VARCHAR (100) NULL,
kdf SMALLINT NOT NULL,
kdf_iterations INT NOT NULL,
creation_date TIMESTAMPTZ NOT NULL,
revision_date TIMESTAMPTZ NOT NULL,
CONSTRAINT pk_user PRIMARY KEY (id)
);
CREATE UNIQUE INDEX ix_user_email
ON "user"(email ASC);
CREATE INDEX ix_user_premium_premium_expiration_date_renewal_reminder_date
ON "user"(premium ASC, premium_expiration_date ASC, renewal_reminder_date ASC);

View File

@ -0,0 +1,29 @@
DROP TABLE IF EXISTS cipher;
CREATE TABLE IF NOT EXISTS cipher (
id UUID NOT NULL,
user_id UUID NULL,
organization_id UUID NULL,
type SMALLINT NOT NULL,
data TEXT NOT NULL,
favorites TEXT NULL,
folders TEXT NULL,
attachments TEXT NULL,
creation_date TIMESTAMPTZ NOT NULL,
revision_date TIMESTAMPTZ NOT NULL,
CONSTRAINT pk_cipher PRIMARY KEY (Id),
CONSTRAINT fk_cipher_organization FOREIGN KEY (organization_id) REFERENCES Organization (id),
CONSTRAINT fk_cipher_user FOREIGN KEY (user_id) REFERENCES "user" (id)
);
CREATE INDEX ix_cipher_user_id_organization_id_include_all
ON cipher(user_id ASC, organization_id ASC)
INCLUDE (type, data, favorites, folders, attachments, creation_date, revision_date);
CREATE INDEX ix_cipher_organization_id
ON cipher(organization_id ASC);

View File

@ -0,0 +1,19 @@
DROP TABLE IF EXISTS collection;
CREATE TABLE IF NOT EXISTS collection (
id UUID NOT NULL,
organization_id UUID NOT NULL,
name TEXT NOT NULL,
external_id VARCHAR (300) NULL,
creation_date TIMESTAMPTZ NOT NULL,
revision_date TIMESTAMPTZ NOT NULL,
CONSTRAINT pk_collection PRIMARY KEY (id),
CONSTRAINT fk_collection_organization FOREIGN KEY (organization_id) REFERENCES organization (id) ON DELETE CASCADE
);
CREATE INDEX ix_collection_organization_id_include_all
ON collection(organization_id ASC)
INCLUDE(creation_date, name, revision_date);

View File

@ -0,0 +1,15 @@
DROP TABLE IF EXISTS collection_cipher;
CREATE TABLE IF NOT EXISTS collection_cipher (
collection_id UUID NOT NULL,
cipher_id UUID NOT NULL,
CONSTRAINT pk_collection_cipher PRIMARY KEY (collection_id, cipher_id),
CONSTRAINT fk_collection_cipher_cipher FOREIGN KEY (cipher_id) REFERENCES cipher (id) ON DELETE CASCADE,
CONSTRAINT fk_collection_cipher_collection FOREIGN KEY (collection_id) REFERENCES collection (id) ON DELETE CASCADE
);
CREATE INDEX ix_collection_cipher_cipher_id
ON collection_cipher(cipher_id ASC);

View File

@ -0,0 +1,11 @@
DROP TABLE IF EXISTS collection_group;
CREATE TABLE IF NOT EXISTS collection_group (
collection_id UUID NOT NULL,
group_id UUID NOT NULL,
read_only BIT NOT NULL,
CONSTRAINT pk_collection_group PRIMARY KEY (collection_id, group_id),
CONSTRAINT fk_collection_group_collection FOREIGN KEY (collection_id) REFERENCES collection (id),
CONSTRAINT fk_collection_group_group FOREIGN KEY (group_id) REFERENCES "group" (id) ON DELETE CASCADE
);

View File

@ -0,0 +1,11 @@
DROP TABLE IF EXISTS collection_user;
CREATE TABLE IF NOT EXISTS collection_user (
collection_id UUID NOT NULL,
organization_user_id UUID NOT NULL,
read_only BIT NOT NULL,
CONSTRAINT pk_collection_user PRIMARY KEY (collection_id, organization_user_id),
CONSTRAINT fk_collection_user_collection FOREIGN KEY (collection_id) REFERENCES collection (id) ON DELETE CASCADE,
CONSTRAINT fk_collection_user_organization_user FOREIGN KEY (organization_user_id) REFERENCES organization_user (id)
);

View File

@ -0,0 +1,25 @@
DROP TABLE IF EXISTS device;
CREATE TABLE IF NOT EXISTS device (
id UUID NOT NULL,
user_id UUID NOT NULL,
name VARCHAR (50) NOT NULL,
type SMALLINT NOT NULL,
identifier VARCHAR (50) NOT NULL,
push_token VARCHAR (255) NULL,
creation_date TIMESTAMPTZ NOT NULL,
revision_date TIMESTAMPTZ NOT NULL,
CONSTRAINT pk_device PRIMARY KEY (id),
CONSTRAINT fk_device_user FOREIGN KEY (user_id) REFERENCES "user" (id)
);
CREATE UNIQUE INDEX ux_device_user_id_identifier
ON device(user_id ASC, identifier ASC);
CREATE INDEX ix_device_identifier
ON device(identifier ASC);

View File

@ -0,0 +1,22 @@
DROP TABLE IF EXISTS event;
CREATE TABLE IF NOT EXISTS event (
id UUID NOT NULL,
type INT NOT NULL,
user_id UUID NULL,
organization_id UUID NULL,
cipher_id UUID NULL,
collection_id UUID NULL,
group_id UUID NULL,
organization_user_id UUID NULL,
acting_user_id UUID NULL,
device_type SMALLINT NULL,
ip_address VARCHAR(50) NULL,
date TIMESTAMPTZ NOT NULL,
CONSTRAINT pk_event PRIMARY KEY (id)
);
CREATE INDEX ix_event_date_organization_id_user_id
ON event(date DESC, organization_id ASC, acting_user_id ASC, cipher_id ASC);

View File

@ -0,0 +1,18 @@
DROP TABLE IF EXISTS folder;
CREATE TABLE IF NOT EXISTS folder (
id UUID NOT NULL,
user_id UUID NOT NULL,
name TEXT NULL,
creation_date TIMESTAMPTZ NOT NULL,
revision_date TIMESTAMPTZ NOT NULL,
CONSTRAINT pk_folder PRIMARY KEY (id),
CONSTRAINT fk_folder_user FOREIGN KEY (user_id) REFERENCES "user" (id)
);
CREATE INDEX ix_folder_user_id_include_all
ON folder(user_id ASC)
INCLUDE (name, creation_date, revision_date);

View File

@ -0,0 +1,22 @@
DROP TABLE IF EXISTS "grant";
CREATE TABLE IF NOT EXISTS "grant" (
key VARCHAR (200) NOT NULL,
type VARCHAR (50) NULL,
subject_id VARCHAR (50) NULL,
client_id VARCHAR (50) NOT NULL,
creation_date TIMESTAMPTZ NOT NULL,
expiration_date TIMESTAMPTZ NULL,
data TEXT NOT NULL,
CONSTRAINT pk_grant PRIMARY KEY (key)
);
CREATE INDEX ix_grant_subject_id_client_id_type
ON "grant"(subject_id ASC, client_id ASC, type ASC);
CREATE INDEX ix_grant_expiration_date
ON "grant"(expiration_date ASC);

View File

@ -0,0 +1,14 @@
DROP TABLE IF EXISTS "group";
CREATE TABLE IF NOT EXISTS "group" (
id UUID NOT NULL,
organization_id UUID NOT NULL,
name VARCHAR (100) NOT NULL,
access_all BIT NOT NULL,
external_id VARCHAR (300) NULL,
creation_date TIMESTAMPTZ NOT NULL,
revision_date TIMESTAMPTZ NOT NULL,
CONSTRAINT pk_group PRIMARY KEY (id),
CONSTRAINT fk_group_organization FOREIGN KEY (organization_id) REFERENCES organization (id) ON DELETE CASCADE
);

View File

@ -0,0 +1,17 @@
DROP TABLE IF EXISTS group_user;
CREATE TABLE IF NOT EXISTS group_user (
group_id UUID NOT NULL,
organization_user_id UUID NOT NULL,
CONSTRAINT Pk_group_user PRIMARY KEY (group_id, organization_user_id),
CONSTRAINT Fk_group_user_group FOREIGN KEY (group_id) REFERENCES "group" (id) ON DELETE CASCADE,
CONSTRAINT Fk_group_user_organization_user FOREIGN KEY (organization_user_id) REFERENCES organization_user (id)
);
CREATE INDEX ix_group_user_organization_user_id
ON group_user(organization_user_id ASC);

View File

@ -0,0 +1,12 @@
DROP TABLE IF EXISTS installation;
CREATE TABLE IF NOT EXISTS installation (
id UUID NOT NULL,
email VARCHAR (50) NOT NULL,
key VARCHAR (150) NOT NULL,
enabled BIT NOT NULL,
creation_date TIMESTAMPTZ NOT NULL,
CONSTRAINT pk_installation PRIMARY KEY (id)
);

View File

@ -0,0 +1,44 @@
DROP TABLE IF EXISTS organization;
CREATE TABLE IF NOT EXISTS organization (
id UUID NOT NULL,
name VARCHAR (50) NOT NULL,
business_name VARCHAR (50) NULL,
business_address_1 VARCHAR (50) NULL,
business_address_2 VARCHAR (50) NULL,
business_address_3 VARCHAR (50) NULL,
business_country VARCHAR (2) NULL,
business_tax_number VARCHAR (30) NULL,
billing_email VARCHAR (50) NOT NULL,
plan VARCHAR (50) NOT NULL,
plan_type SMALLINT NOT NULL,
seats SMALLINT NULL,
max_collections SMALLINT NULL,
use_groups BIT NOT NULL,
use_directory BIT NOT NULL,
use_events BIT NOT NULL,
use_totp BIT NOT NULL,
use_2fa BIT NOT NULL,
use_api BIT NOT NULL,
self_host BIT NOT NULL,
users_get_premium BIT NOT NULL,
storage BIGINT NULL,
max_storage_gb SMALLINT NULL,
gateway SMALLINT NULL,
gateway_customer_id VARCHAR (50) NULL,
gateway_subscription_id VARCHAR (50) NULL,
enabled BIT NOT NULL,
license_key VARCHAR (100) NULL,
api_key VARCHAR (30) NOT NULL,
two_factor_providers TEXT NULL,
expiration_date TIMESTAMPTZ NULL,
creation_date TIMESTAMPTZ NOT NULL,
revision_date TIMESTAMPTZ NOT NULL,
CONSTRAINT pk_organization PRIMARY KEY (id)
);
CREATE INDEX ix_organization_enabled
ON organization(id ASC, enabled ASC)
INCLUDE (use_totp);

View File

@ -0,0 +1,28 @@
DROP TABLE IF EXISTS organization_user;
CREATE TABLE IF NOT EXISTS organization_user (
id UUID NOT NULL,
organization_id UUID NOT NULL,
user_id UUID NULL,
email VARCHAR (50) NULL,
key TEXT NULL,
status SMALLINT NOT NULL,
type SMALLINT NOT NULL,
access_all BIT NOT NULL,
external_id VARCHAR (300) NULL,
creation_date TIMESTAMPTZ NOT NULL,
revision_date TIMESTAMPTZ NOT NULL,
CONSTRAINT pk_organization_user PRIMARY KEY (id),
CONSTRAINT fk_organization_user_organization FOREIGN KEY (organization_id) REFERENCES organization (id) ON DELETE CASCADE,
CONSTRAINT fk_organization_user_user FOREIGN KEY (user_id) REFERENCES "user" (id)
);
CREATE INDEX ix_organization_user_user_id_organization_id_status
ON organization_user(user_id ASC, organization_id ASC, Status ASC)
INCLUDE (access_all);
CREATE INDEX ix_organization_user_organization_id
ON organization_user(organization_id aSC);

View File

@ -0,0 +1,29 @@
DROP TABLE IF EXISTS "transaction";
CREATE TABLE IF NOT EXISTS "transaction" (
id UUID NOT NULL,
user_id UUID NULL,
organization_id UUID NULL,
type SMALLINT NOT NULL,
amount NUMERIC (19,4) NOT NULL,
refunded BIT NULL,
refunded_amount NUMERIC (19,4) NULL,
details VARCHAR(100) NULL,
payment_method_type SMALLINT NULL,
gateway SMALLINT NULL,
gateway_id VARCHAR(50) NULL,
creation_date TIMESTAMPTZ NOT NULL,
CONSTRAINT pk_transaction PRIMARY KEY (id),
CONSTRAINT fk_transaction_user FOREIGN KEY (user_id) REFERENCES "user" (id) ON DELETE CASCADE,
CONSTRAINT fk_transaction_organization FOREIGN KEY (organization_id) REFERENCES organization (id) ON DELETE CASCADE
);
CREATE UNIQUE INDEX ix_transaction_gateway_gatewayid
ON "transaction"(gateway ASC, gateway_id ASC)
WHERE gateway IS NOT NULL AND gateway_id IS NOT NULL;
CREATE INDEX ix_transaction_user_id_organization_id_creation_date
ON "transaction"(user_id ASC, Organization_id ASC, Creation_date ASC);

View File

@ -0,0 +1,22 @@
DROP TABLE IF EXISTS u2f CASCADE;
CREATE TABLE IF NOT EXISTS u2f (
id SERIAL NOT NULL,
user_id UUID NOT NULL,
key_handle VARCHAR (200) NULL,
challenge VARCHAR (200) NOT NULL,
app_id VARCHAR (50) NOT NULL,
version VARCHAR (20) NOT NULL,
creation_date TIMESTAMPTZ NOT NULL,
CONSTRAINT pk_u2f PRIMARY KEY (id),
CONSTRAINT fk_u2f_user FOREIGN KEY (user_id) REFERENCES "user" (id)
);
CREATE INDEX ix_u2f_creation_date
ON u2f(creation_date ASC);
CREATE INDEX ix_u2f_user_id
ON u2f(user_id ASC);

View File

@ -0,0 +1,6 @@
CREATE VIEW u2f_view
AS
SELECT
*
FROM
u2f;

View File

@ -0,0 +1,6 @@
CREATE VIEW user_view
AS
SELECT
*
FROM
"user";