-
Notifications
You must be signed in to change notification settings - Fork 1.3k
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Browse files
Browse the repository at this point in the history
* 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
- Loading branch information
Showing
24 changed files
with
543 additions
and
4 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -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 | ||
$$ |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -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$; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -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$ |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -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'; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,5 @@ | ||
DROP SCHEMA bitwarden cascade; | ||
|
||
CREATE SCHEMA bitwarden AUTHORIZATION bitwarden; | ||
|
||
ALTER ROLE bitwarden SET search_path TO bitwarden; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -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); | ||
|
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -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); | ||
|
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -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); | ||
|
||
|
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -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); | ||
|
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -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 | ||
); | ||
|
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -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) | ||
); | ||
|
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -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); | ||
|
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -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); | ||
|
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -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); | ||
|
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -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); | ||
|
Oops, something went wrong.