diff --git a/lib/db/sql.go b/lib/db/sql.go index b25970405ef9dcc2061f66c5353ff7afc47eccb1..0de27bd21753711f076b8723854cda4e9034d69b 100644 --- a/lib/db/sql.go +++ b/lib/db/sql.go @@ -7,7 +7,7 @@ SELECT email, is_admin, is_blocked, - bucket_capacity + v1.positive_or_null(ratelimit_bucket_capacity) FROM user_ u, legacy_token t @@ -84,10 +84,10 @@ SELECT o.type::integer, o.location, o.content_type, - v1.content_length(o.content_length), + v1.positive_or_null(o.content_length), o.created_at, o.tombstoned_at, - o.tombstone_reason, + o.tombstone_description, o.md5_digest, o.sha256_digest, o.owned_by @@ -112,10 +112,10 @@ SELECT o.type::integer, o.location, o.content_type, - v1.content_length(o.content_length), + v1.positive_or_null(o.content_length), o.created_at, o.tombstoned_at, - o.tombstone_reason, + o.tombstone_description, o.md5_digest, o.sha256_digest, o.owned_by @@ -148,7 +148,7 @@ SET location = NULL, content_type = NULL, content_length = -1, - tombstone_reason = $1, + tombstone_description = $1, md5_digest = NULL, sha256_digest = NULL, owned_by = NULL @@ -166,7 +166,7 @@ SET location = NULL, content_type = NULL, content_length = -1, - tombstone_reason = $1, + tombstone_description = $1, md5_digest = NULL, sha256_digest = NULL WHERE @@ -183,7 +183,7 @@ SET location = NULL, content_type = NULL, content_length = -1, - tombstone_reason = $1 + tombstone_description = $1 WHERE bucket = $2 AND path = path_normalize('/' || $3) @@ -198,7 +198,7 @@ SET location = NULL, content_type = NULL, content_length = -1, - tombstone_reason = $1, + tombstone_description = $1, md5_digest = NULL, sha256_digest = NULL, owned_by = NULL @@ -215,7 +215,7 @@ SET location = NULL, content_type = NULL, content_length = -1, - tombstone_reason = $1, + tombstone_description = $1, md5_digest = NULL, sha256_digest = NULL WHERE @@ -231,7 +231,7 @@ SET location = NULL, content_type = NULL, content_length = -1, - tombstone_reason = $1 + tombstone_description = $1 WHERE sha256_digest = $2 ` @@ -250,7 +250,7 @@ INSERT INTO file_ban (sha256_digest, did_quarantine, reason, description, malware_name) VALUES -- FIXME(auri): why is the cast to integer necessary??? - ($1, $2, $3::integer, $4, $5) + ($1, $2, $3::integer, COALESCE($4, ''), $5) ` var listBannedFiles = ` diff --git a/sql/v1tov2.sql b/sql/v1tov2.sql index e4701e6d68cdd2ce272e05c53f3ae5e076f615dc..d5d5097f55cd77bf50a45b158fe2cd017ca1bf44 100644 --- a/sql/v1tov2.sql +++ b/sql/v1tov2.sql @@ -3,6 +3,13 @@ SET LOCAL search_path = public; -- API v1 compatibility helpers. To be dropped when API server v1 is retired. CREATE SCHEMA v1; +-- Case-insensitive, language-agnostic. +CREATE COLLATION "und-u-ks-level2-x-icu" ( + locale = 'und@colStrength=secondary', + provider = 'icu', + deterministic = false +); + CREATE TYPE object_type AS ENUM ('file', 'redirect', 'tombstone'); CREATE TYPE file_ban_reason AS ENUM ('other', 'malware', 'takedown'); @@ -21,9 +28,14 @@ CREATE DOMAIN sha256 AS bytea CHECK (octet_length(VALUE) = 32); CREATE DOMAIN md5 AS bytea CHECK (octet_length(VALUE) = 16); --- ...a reasonable limit? +-- RFC 9110 recommends a limit of, at a minimum, 8000 octets; however, this only +-- applies to parsers and similar implementations. WHATWG-URL, of course, says +-- nothing about this. I believe 4096 (locale) characters is enough for any +-- reasonable use case. CREATE DOMAIN url AS character varying(4096); +CREATE DOMAIN bucket_name AS character varying(32); + CREATE DOMAIN object_path AS character varying(4096); -- Given '//foo/bar//baz', return '/foo/bar/baz'. @@ -66,7 +78,7 @@ CREATE FUNCTION path_directory(object_path) RETURNS object_path END $$; -CREATE FUNCTION v1.content_length(bigint) RETURNS bigint +CREATE FUNCTION v1.positive_or_null(bigint) RETURNS bigint IMMUTABLE STRICT LANGUAGE SQL AS $$SELECT (CASE WHEN $1 < 0 THEN NULL ELSE $1 END);$$; @@ -122,16 +134,14 @@ CREATE CAST (integer AS file_ban_reason) CREATE CAST (file_ban_reason AS integer) WITH FUNCTION v1.as_api_integer(file_ban_reason); -CREATE COLLATION "und-u-ks-level2-x-icu" ( - locale = 'und@colStrength=secondary', - provider = 'icu', - deterministic = false -); - ALTER TABLE users RENAME TO user_; -ALTER TABLE user_ RENAME CONSTRAINT users_pk TO user__pk; +ALTER TABLE user_ RENAME COLUMN bucket_capacity TO ratelimit_bucket_capacity; +ALTER TABLE user_ RENAME CONSTRAINT users_pk TO user__pkey; ALTER TABLE user_ RENAME CONSTRAINT users_email_key TO user__email_key; +-- Prepare for ALTER TABLE user_ ALTER COLUMN ratelimit_bucket_capacity SET NOT NULL +UPDATE user_ SET ratelimit_bucket_capacity = -1 WHERE ratelimit_bucket_capacity IS NULL; + ALTER TABLE user_ -- Replaced by the ICU collation on username and user__username_key. DROP COLUMN username_lower, @@ -142,6 +152,8 @@ ALTER TABLE user_ ALTER COLUMN username SET DATA TYPE character varying(256) COLLATE "und-u-ks-level2-x-icu", ALTER COLUMN email SET DATA TYPE emailaddr, + ALTER COLUMN ratelimit_bucket_capacity SET NOT NULL, + ALTER COLUMN ratelimit_bucket_capacity SET DEFAULT -1, ADD COLUMN created_on timestamp with time zone NOT NULL DEFAULT now(), ADD UNIQUE (username); @@ -160,14 +172,16 @@ ALTER TABLE legacy_token DROP COLUMN id, DROP CONSTRAINT tokens_token_key, ALTER COLUMN owned_by SET DATA TYPE uuid USING owned_by::uuid, + ALTER COLUMN token SET DATA TYPE uuid USING token::uuid, ADD PRIMARY KEY (token), ADD FOREIGN KEY (owned_by) REFERENCES user_ (id); CREATE TABLE bucket ( - name character varying(32) PRIMARY KEY COLLATE "und-u-ks-level2-x-icu", + name bucket_name PRIMARY KEY COLLATE "und-u-ks-level2-x-icu", owned_by uuid NOT NULL REFERENCES user_ (id), - created_at timestamp with time zone NOT NULL DEFAULT now(), enforce_unique_names boolean NOT NULL, + created_at timestamp with time zone NOT NULL DEFAULT now(), + -- Needed to make the FK constraint on object work. UNIQUE (name, enforce_unique_names) ); @@ -184,14 +198,12 @@ ALTER TABLE object RENAME COLUMN sha256_hash TO sha256_digest; ALTER TABLE object RENAME COLUMN md5_hash TO md5_digest; ALTER TABLE object RENAME COLUMN associated_user TO owned_by; ALTER TABLE object RENAME COLUMN deleted_at TO tombstoned_at; -ALTER TABLE object RENAME COLUMN delete_reason TO tombstone_reason; +ALTER TABLE object RENAME COLUMN delete_reason TO tombstone_description; ALTER INDEX objects_associated_user RENAME TO object_owned_by_idx; ALTER INDEX objects_sha256_hash_idx RENAME TO object_sha256_digest_idx; -- Prepare for ALTER COLUMN content_length SET NOT NULL. -UPDATE object - SET content_length = -1 - WHERE content_length IS NULL; +UPDATE object SET content_length = -1 WHERE content_length IS NULL; ALTER TABLE object -- Unused. @@ -215,12 +227,11 @@ ALTER TABLE object ALTER COLUMN created_at SET DATA TYPE timestamp with time zone, ALTER COLUMN tombstoned_at SET DATA TYPE timestamp with time zone, -- DEFAULT NULL is implied on nullable columns. - ALTER COLUMN tombstone_reason DROP DEFAULT, - ADD COLUMN id uuid DEFAULT gen_random_uuid() PRIMARY KEY, + ALTER COLUMN tombstone_description DROP DEFAULT, ADD FOREIGN KEY (owned_by) REFERENCES user_ (id), ADD CHECK (content_length >= -1), ADD CONSTRAINT object_is_valid_file_check - CHECK (type != 'file' OR content_type IS NOT NULL + CHECK (type != 'file' OR content_type IS NOT NULL AND content_length >= 0 AND sha256_digest IS NOT NULL AND md5_digest IS NOT NULL), @@ -231,10 +242,11 @@ ALTER TABLE object -- Unify bucket_key, bucket, key, dir and random_key. ALTER TABLE object - ALTER COLUMN bucket SET DATA TYPE character varying(32), + ALTER COLUMN bucket SET DATA TYPE bucket_name, ADD COLUMN path object_path NOT NULL GENERATED ALWAYS AS (path_normalize(dir || '/' || key)) STORED, - ADD COLUMN enforce_unique_name boolean, + ADD COLUMN enforce_unique_name boolean NOT NULL, + ADD PRIMARY KEY (bucket, path), ADD FOREIGN KEY (bucket, enforce_unique_name) REFERENCES bucket (name, enforce_unique_names); @@ -247,8 +259,6 @@ ALTER TABLE object DROP COLUMN dir, DROP COLUMN random_key; -CREATE UNIQUE INDEX object_bucket_path_key - ON object (bucket, path); CREATE UNIQUE INDEX object_path_full_stem_path_key ON object (path_full_stem(path)) WHERE enforce_unique_name; @@ -262,15 +272,17 @@ CREATE TRIGGER object_before_insert_normalize_path_tg ALTER TABLE file_bans RENAME TO file_ban; ALTER TABLE file_ban RENAME COLUMN sha256_hash TO sha256_digest; -ALTER TABLE file_ban RENAME CONSTRAINT file_bans_sha256_hash_key TO file_ban_sha256_digest_key; ALTER TABLE file_ban + DROP CONSTRAINT file_bans_sha256_hash_key, ALTER COLUMN did_quarantine DROP DEFAULT, ALTER COLUMN reason DROP DEFAULT, ALTER COLUMN reason SET DATA TYPE file_ban_reason, ALTER COLUMN sha256_digest SET DATA TYPE sha256, - -- DEFAULT NULL is implied on nullable columns. + ALTER COLUMN description SET NOT NULL, ALTER COLUMN description DROP DEFAULT, + -- DEFAULT NULL is implied on nullable columns. ALTER COLUMN malware_name DROP DEFAULT, + ADD PRIMARY KEY (sha256_digest), ADD CONSTRAINT file_ban_is_valid_malware CHECK (reason != 'malware' OR malware_name IS NOT NULL);