diff --git a/.devcontainer/devcontainer.json b/.devcontainer/devcontainer.json index 3e70e73..0923acd 100644 --- a/.devcontainer/devcontainer.json +++ b/.devcontainer/devcontainer.json @@ -26,5 +26,6 @@ }, "postCreateCommand": "initdb -D $PGDATA && pg_ctl -D $PGDATA -o '-k /run/postgresql' -l /tmp/pg.log start && createdb chocomax && pg_ctl -D $PGDATA stop", "postStartCommand": "pg_ctl -D $PGDATA -o '-k /run/postgresql' -l /tmp/pg.log start", + "postAttachCommand": "sqlfluff fix database/ -v", "remoteUser": "vscode" } diff --git a/.github/workflows/suggest-version-bump.yml b/.github/workflows/suggest-version-bump.yml index 4eb20a2..b98050a 100644 --- a/.github/workflows/suggest-version-bump.yml +++ b/.github/workflows/suggest-version-bump.yml @@ -42,7 +42,7 @@ jobs: BUMP="patch" echo "$LABELS" | grep -q 'type: feature' && BUMP="minor" echo "$LABELS" | grep -q 'type: security' && BUMP="minor" - echo "$LABELS" | grep -q 'type: breaking' && BUMP="major" + echo "$LABELS" | grep -q 'special: breaking change' && BUMP="major" echo "bump=$BUMP" >> "$GITHUB_OUTPUT" - name: Get latest tag diff --git a/.github/workflows/super-linter.yml b/.github/workflows/super-linter.yml index cc84ce5..9123b80 100644 --- a/.github/workflows/super-linter.yml +++ b/.github/workflows/super-linter.yml @@ -27,8 +27,7 @@ jobs: uses: super-linter/super-linter/slim@v7 env: GITHUB_TOKEN: ${{ secrets.GITHUB_TOKEN }} - VALIDATE_ALL_CODEBASE: false - FILTER_REGEX_EXCLUDE: '(.github/pull_request_template.md|.github/ISSUE_TEMPLATE/*.md)' + DISABLE_ERRORS: true fix-lint: name: Fix Lint @@ -46,6 +45,7 @@ jobs: VALIDATE_ALL_CODEBASE: false FILTER_REGEX_EXCLUDE: '(.github/pull_request_template.md|.github/ISSUE_TEMPLATE/*.md)' GITHUB_TOKEN: ${{ secrets.GITHUB_TOKEN }} + FIX_JSON: true FIX_JSON_PRETTIER: true FIX_MARKDOWN: true FIX_MARKDOWN_PRETTIER: true @@ -61,6 +61,6 @@ jobs: uses: stefanzweifel/git-auto-commit-action@v5 with: branch: ${{ github.event.pull_request.head.ref }} - commit_message: 'chore: fix linting issues' + commit_message: 'Super-Linter: Fix linting issues' commit_user_name: super-linter commit_user_email: super-linter@super-linter.dev diff --git a/.github/workflows/unit-tests.yml b/.github/workflows/unit-tests.yml index dce8b21..7673ea1 100644 --- a/.github/workflows/unit-tests.yml +++ b/.github/workflows/unit-tests.yml @@ -80,17 +80,14 @@ jobs: run: | sudo -u "$PG_USER" psql -p "$PGPORT" -d "$PG_DATABASE" -c "CREATE EXTENSION IF NOT EXISTS pgtap;" - - name: Flatten and load schema SQL files + - name: Flatten SQL files run: | - mkdir flattened-sql - find database -type f -name "*.sql" ! -name "*.session.sql" ! -name "*.test.sql" | while read -r file; do - clean_path="${file#./}" - new_name="${clean_path//\//_}" - cp "$file" "flattened-sql/$new_name" - echo "✅ Copied: $file → flattened-sql/$new_name" - done + chmod +x scripts/flatten-sql.sh + ./scripts/flatten-sql.sh database flattened-sql - find flattened-sql -maxdepth 1 -name "*.sql" | while read -r file; do + - name: Load schema and seed data + run: | + find flattened-sql -maxdepth 1 -name "*.sql" | sort | while read -r file; do echo "➡️ Running $file..." sudo -u postgres psql -p "$PGPORT" -d "$PG_DATABASE" -f "$file" done diff --git a/.vscode/tasks.json b/.vscode/tasks.json index 16000b6..6c35b54 100644 --- a/.vscode/tasks.json +++ b/.vscode/tasks.json @@ -108,9 +108,6 @@ }, "presentation": { "close": true - }, - "runOptions": { - "runOn": "default" } }, { @@ -125,7 +122,7 @@ "panel": "shared", "close": true }, - "problemMatcher": [], + "problemMatcher": [] }, { "label": "Run Docker Container", @@ -135,7 +132,7 @@ "panel": "shared", "close": true }, - "problemMatcher": [], + "problemMatcher": [] }, { "label": "Remove Docker Container", @@ -145,7 +142,7 @@ "panel": "shared", "close": true }, - "problemMatcher": [], + "problemMatcher": [] }, { "label": "Reset Docker Container", diff --git a/README.md b/README.md index 32de60a..6994ac7 100644 --- a/README.md +++ b/README.md @@ -44,18 +44,18 @@ The database schema consists of the following tables: 5. **category_translations**: Contains translated names and descriptions for product categories. 6. **contact_messages**: Stores messages sent through the contact form by users or visitors. 7. **discount_codes**: Defines promotional discount codes with rules and usage limits. -8. **email_verifications**: Manages email verification tokens and statuses for user accounts. -9. **feedback**: Allows users to rate and comment on products they've purchased. -10. **login_attempts**: Records login attempts with metadata like IP, user agent, and success flag. -11. **loyalty_program**: Defines promotions such as "buy X get Y" for specific products. -12. **metrics_events**: Stores anonymous event logs for analytics purposes. -13. **moderation_actions**: Logs actions taken to moderate users, products, or comments. -14. **order_delivery_info**: Stores delivery-related information such as address and delivery agent. -15. **order_items**: Contains product variant items included in each order. -16. **order_status_history**: Tracks the status changes of orders over time. -17. **order_timestamps**: Keeps timestamps for different stages in the order lifecycle. -18. **orders**: Main order records with price, status, and delivery type. -19. **password_resets**: Stores reset tokens for users to change their passwords securely. +8. **feedback**: Allows users to rate and comment on products they've purchased. +9. **login_attempts**: Records login attempts with metadata like IP, user agent, and success flag. +10. **loyalty_program**: Defines promotions such as "buy X get Y" for specific products. +11. **metrics_events**: Stores anonymous event logs for analytics purposes. +12. **moderation_actions**: Logs actions taken to moderate users, products, or comments. +13. **order_delivery_info**: Stores delivery-related information such as address and delivery agent. +14. **order_items**: Contains product variant items included in each order. +15. **order_status_history**: Tracks the status changes of orders over time. +16. **order_timestamps**: Keeps timestamps for different stages in the order lifecycle. +17. **orders**: Main order records with price, status, and delivery type. +18. **password_resets**: Stores reset tokens for users to change their passwords securely. +19. **pending_users**: Manages email verification tokens and for new user. 20. **product_categories**: Defines categories to group products (e.g., Chocolate, Gifts). 21. **product_comments**: Stores user comments on products, optionally moderated. 22. **product_images**: Manages images associated with products and their variants. diff --git a/database/functions/authenticate_user.sql b/database/functions/authenticate_user.sql deleted file mode 100644 index 8a458c2..0000000 --- a/database/functions/authenticate_user.sql +++ /dev/null @@ -1,27 +0,0 @@ --- Authenticate a user and log the result -CREATE OR REPLACE FUNCTION authenticate_user( - p_username TEXT, - p_password_hash TEXT, - p_ip_address INET, - p_user_agent TEXT -) RETURNS BOOLEAN AS $$ -DECLARE - v_user_id UUID; -BEGIN - -- Attempt to find the user by username and hashed password - SELECT user_id INTO v_user_id - FROM users - WHERE username = p_username AND password_hash = p_password_hash - LIMIT 1; - - IF v_user_id IS NOT NULL THEN - -- Successful login: handle and log - CALL handle_successful_login(v_user_id, p_ip_address, p_user_agent); - RETURN TRUE; - ELSE - -- Failed login: log with NULL user_id - CALL log_login_attempt(NULL, p_ip_address, p_user_agent, FALSE); - RETURN FALSE; - END IF; -END; -$$ LANGUAGE plpgsql; diff --git a/database/functions/disable_2fa.sql b/database/functions/disable_2fa.sql deleted file mode 100644 index d5d4337..0000000 --- a/database/functions/disable_2fa.sql +++ /dev/null @@ -1,8 +0,0 @@ --- Disable 2FA for a user -CREATE OR REPLACE FUNCTION disable_2fa(p_user_id UUID) RETURNS VOID AS $$ -BEGIN - UPDATE user_authentication_methods - SET is_enabled = FALSE, updated_at = NOW() - WHERE user_id = p_user_id; -END; -$$ LANGUAGE plpgsql; diff --git a/database/functions/get_password_hash_by_email_hash.sql b/database/functions/get_password_hash_by_email_hash.sql new file mode 100644 index 0000000..f3ab884 --- /dev/null +++ b/database/functions/get_password_hash_by_email_hash.sql @@ -0,0 +1,10 @@ +-- Returns the password hash for a given email hash (for API-side verification) +CREATE OR REPLACE FUNCTION get_password_hash_by_email_hash( + p_email_hash TEXT +) +RETURNS TEXT AS $$ + SELECT password_hash + FROM users + WHERE email_hash = p_email_hash + LIMIT 1; +$$ LANGUAGE sql; diff --git a/database/functions/get_used_discriminators.sql b/database/functions/get_used_discriminators.sql new file mode 100644 index 0000000..a4905c9 --- /dev/null +++ b/database/functions/get_used_discriminators.sql @@ -0,0 +1,11 @@ +CREATE OR REPLACE FUNCTION get_used_discriminators( + p_username TEXT +) +RETURNS SETOF SMALLINT AS $$ +BEGIN + RETURN QUERY + SELECT discriminator + FROM users + WHERE username = p_username; +END; +$$ LANGUAGE plpgsql; diff --git a/database/functions/get_user_2fa_methods_by_email_hash.sql b/database/functions/get_user_2fa_methods_by_email_hash.sql new file mode 100644 index 0000000..bf00e76 --- /dev/null +++ b/database/functions/get_user_2fa_methods_by_email_hash.sql @@ -0,0 +1,13 @@ +-- Returns the 2FA secret and authentication method for a given email hash and authentication method (e.g., TOTP) +CREATE OR REPLACE FUNCTION get_user_2fa_methods_by_email_hash( + p_email_hash TEXT +) +RETURNS TABLE ( + authentication_method AUTHENTICATION_METHOD, + is_preferred BOOLEAN +) AS $$ + SELECT authentication_method, is_preferred + FROM user_authentication_methods + WHERE user_id = (SELECT user_id FROM users WHERE email_hash = p_email_hash) + AND is_enabled = TRUE; +$$ LANGUAGE sql STABLE; diff --git a/database/functions/get_user_2fa_secret.sql b/database/functions/get_user_2fa_secret.sql index d13f1bc..a00c941 100644 --- a/database/functions/get_user_2fa_secret.sql +++ b/database/functions/get_user_2fa_secret.sql @@ -1,5 +1,11 @@ -- Get the user's authentication methods secret -CREATE OR REPLACE FUNCTION get_user_authentication_method_secret(p_user_id UUID) RETURNS TABLE (method TEXT, secret TEXT) AS $$ +CREATE OR REPLACE FUNCTION get_user_authentication_method_secret( + p_user_id UUID +) +RETURNS TABLE ( + method TEXT, + secret TEXT +) AS $$ BEGIN RETURN QUERY SELECT authentication_method, user_authentication_method_secret diff --git a/database/functions/get_user_2fa_secret_by_email_hash.sql b/database/functions/get_user_2fa_secret_by_email_hash.sql new file mode 100644 index 0000000..2d450e9 --- /dev/null +++ b/database/functions/get_user_2fa_secret_by_email_hash.sql @@ -0,0 +1,16 @@ +-- Returns the 2FA secret and authentication method for a given email hash and authentication method (e.g., TOTP) +CREATE OR REPLACE FUNCTION get_user_2fa_secret_by_email_hash( + p_email_hash TEXT, + p_authentication_method AUTHENTICATION_METHOD +) +RETURNS TABLE ( + authentication_secret TEXT, + authentication_method AUTHENTICATION_METHOD +) AS $$ + SELECT user_authentication_method_secret AS authentication_secret, authentication_method + FROM user_authentication_methods + WHERE user_id = (SELECT user_id FROM users WHERE email_hash = p_email_hash) + AND authentication_method = p_authentication_method + AND is_enabled = TRUE + LIMIT 1; +$$ LANGUAGE sql STABLE; diff --git a/database/functions/get_user_info_by_email_hash.sql b/database/functions/get_user_info_by_email_hash.sql new file mode 100644 index 0000000..ecc779c --- /dev/null +++ b/database/functions/get_user_info_by_email_hash.sql @@ -0,0 +1,31 @@ +-- Returns all non-sensitive user data for a given email hash + +CREATE OR REPLACE FUNCTION get_user_info_by_email_hash(p_email_hash TEXT) +RETURNS TABLE ( + user_id UUID, + username TEXT, + discriminator SMALLINT, + email_encrypted TEXT, + phone_encrypted TEXT, + language_id INTEGER, + display_role TEXT, + created_at TIMESTAMPTZ, + updated_at TIMESTAMPTZ, + last_login_at TIMESTAMPTZ, + deleted_at TIMESTAMPTZ +) AS $$ + SELECT + user_id, + username, + discriminator, + email_encrypted, + phone_encrypted, + language_id, + display_role, + created_at, + updated_at, + last_login_at, + deleted_at + FROM users + WHERE email_hash = p_email_hash; +$$ LANGUAGE sql STABLE; diff --git a/database/functions/is_email_available.sql b/database/functions/is_email_available.sql index 03f2d3f..b6b89ad 100644 --- a/database/functions/is_email_available.sql +++ b/database/functions/is_email_available.sql @@ -1,8 +1,23 @@ CREATE OR REPLACE FUNCTION is_email_available( - p_email_hash TEXT + p_verification_token TEXT ) RETURNS BOOLEAN AS $$ - SELECT NOT EXISTS ( - SELECT 1 FROM users WHERE email_hash = p_email_hash +DECLARE + v_email_hash TEXT; +BEGIN + -- Retrieve the email_hash from pending_users using the verification_token + SELECT email_hash INTO v_email_hash + FROM pending_users + WHERE verification_token = p_verification_token; + + -- If not found, return false + IF v_email_hash IS NULL THEN + RETURN FALSE; + END IF; + + -- Check if email_hash exists in users + RETURN NOT EXISTS ( + SELECT 1 FROM users WHERE email_hash = v_email_hash ); -$$ LANGUAGE sql; +END; +$$ LANGUAGE plpgsql; diff --git a/database/functions/is_verification_token_valid.sql b/database/functions/is_verification_token_valid.sql new file mode 100644 index 0000000..91aeac2 --- /dev/null +++ b/database/functions/is_verification_token_valid.sql @@ -0,0 +1,29 @@ +CREATE OR REPLACE FUNCTION is_verification_token_valid(p_verification_token TEXT) +RETURNS BOOLEAN AS $$ +DECLARE + v_email_hash TEXT; +BEGIN + -- Get email_hash of the token + SELECT email_hash INTO v_email_hash + FROM pending_users + WHERE verification_token = p_verification_token; + + IF v_email_hash IS NULL THEN + RETURN FALSE; + END IF; + + -- Check that this token is the most recent and not expired + RETURN EXISTS ( + SELECT 1 + FROM pending_users + WHERE email_hash = v_email_hash + AND verification_token = p_verification_token + AND created_at = ( + SELECT MAX(created_at) + FROM pending_users + WHERE email_hash = v_email_hash + ) + AND created_at >= NOW() - INTERVAL '24 hours' + ); +END; +$$ LANGUAGE plpgsql STABLE; diff --git a/database/functions/update_last_login_at.sql b/database/functions/update_last_login_at.sql new file mode 100644 index 0000000..1e9cbe3 --- /dev/null +++ b/database/functions/update_last_login_at.sql @@ -0,0 +1,11 @@ +CREATE OR REPLACE FUNCTION update_last_login_at() +RETURNS TRIGGER AS $$ +BEGIN + IF NEW.token_type = 'access' THEN + UPDATE users + SET last_login_at = current_timestamp + WHERE user_id = NEW.user_id; + END IF; + RETURN NEW; +END; +$$ LANGUAGE plpgsql; diff --git a/database/functions/update_updated_at.sql b/database/functions/update_updated_at.sql new file mode 100644 index 0000000..e9af93b --- /dev/null +++ b/database/functions/update_updated_at.sql @@ -0,0 +1,7 @@ +CREATE OR REPLACE FUNCTION update_updated_at() +RETURNS TRIGGER AS $$ +BEGIN + NEW.updated_at := current_timestamp; + RETURN NEW; +END; +$$ LANGUAGE plpgsql; diff --git a/database/procedures/create_pending_user.sql b/database/procedures/create_pending_user.sql new file mode 100644 index 0000000..151eec4 --- /dev/null +++ b/database/procedures/create_pending_user.sql @@ -0,0 +1,18 @@ +CREATE OR REPLACE PROCEDURE create_pending_user( + p_email_encrypted TEXT, + p_email_hash TEXT, + p_verification_token TEXT +) +AS $$ +BEGIN + INSERT INTO pending_users ( + email_encrypted, + email_hash, + verification_token + ) VALUES ( + p_email_encrypted, + p_email_hash, + p_verification_token + ); +END; +$$ LANGUAGE plpgsql; diff --git a/database/procedures/create_user_session.sql b/database/procedures/create_user_session.sql new file mode 100644 index 0000000..8df8d26 --- /dev/null +++ b/database/procedures/create_user_session.sql @@ -0,0 +1,77 @@ +CREATE OR REPLACE PROCEDURE create_user_session_token( + p_user_id UUID, + p_session_token TEXT, + p_device_info JSONB, + p_ip_address INET, + p_user_agent TEXT +) +LANGUAGE plpgsql +AS $$ +BEGIN + -- Expire old access tokens for the user + UPDATE user_sessions + SET expires_at = NOW(), updated_at = NOW() + WHERE user_id = p_user_id + AND token_type = 'access' + AND expires_at > NOW(); + + -- Insert new session token + INSERT INTO user_sessions ( + user_id, + token, + token_type, + device_info, + ip_address, + user_agent, + expires_at + ) + VALUES ( + p_user_id, + p_session_token, + 'access', + p_device_info, + p_ip_address, + p_user_agent, + NOW() + INTERVAL '1 hour' + ); +END; +$$; + +CREATE OR REPLACE PROCEDURE create_user_refresh_token( + p_user_id UUID, + p_refresh_token TEXT, + p_device_info JSONB, + p_ip_address INET, + p_user_agent TEXT +) +LANGUAGE plpgsql +AS $$ +BEGIN + -- Expire old refresh tokens + UPDATE user_sessions + SET expires_at = NOW(), updated_at = NOW() + WHERE user_id = p_user_id + AND token_type = 'refresh' + AND expires_at > NOW(); + + -- Insert new refresh token + INSERT INTO user_sessions ( + user_id, + token, + token_type, + device_info, + ip_address, + user_agent, + expires_at + ) + VALUES ( + p_user_id, + p_refresh_token, + 'refresh', + p_device_info, + p_ip_address, + p_user_agent, + NOW() + INTERVAL '7 days' + ); +END; +$$; diff --git a/database/procedures/expire_all_user_sessions.sql b/database/procedures/expire_all_user_sessions.sql new file mode 100644 index 0000000..fd40e31 --- /dev/null +++ b/database/procedures/expire_all_user_sessions.sql @@ -0,0 +1,19 @@ +CREATE OR REPLACE PROCEDURE expire_all_user_sessions( + p_token TEXT +) +AS $$ +DECLARE + user_id UUID; +BEGIN + SELECT us.user_id INTO user_id + FROM user_sessions us + WHERE us.token = p_token + AND us.expires_at > NOW(); + + IF user_id IS NOT NULL THEN + UPDATE user_sessions + SET expires_at = NOW() + WHERE user_id = user_id; + END IF; +END; +$$ LANGUAGE plpgsql; diff --git a/database/procedures/handle_successful_login.sql b/database/procedures/handle_successful_login.sql index 19a96dc..76172ec 100644 --- a/database/procedures/handle_successful_login.sql +++ b/database/procedures/handle_successful_login.sql @@ -7,7 +7,7 @@ CREATE OR REPLACE PROCEDURE handle_successful_login( AS $$ BEGIN -- Update login timestamp - UPDATE users SET last_login_at = NOW(), updated_at = NOW() + UPDATE users SET last_login_at = NOW() WHERE user_id = p_user_id; -- Log success diff --git a/database/procedures/log_login_attempt.sql b/database/procedures/log_login_attempt.sql index cdcff7e..8d14d90 100644 --- a/database/procedures/log_login_attempt.sql +++ b/database/procedures/log_login_attempt.sql @@ -5,9 +5,9 @@ CREATE OR REPLACE PROCEDURE log_login_attempt( p_user_agent TEXT, p_success BOOLEAN ) -LANGUAGE plpgsql AS $$ +AS $$ BEGIN INSERT INTO login_attempts (user_id, ip_address, user_agent, success) VALUES (p_user_id, p_ip_address, p_user_agent, p_success); END; -$$; +$$ LANGUAGE plpgsql; diff --git a/database/procedures/register_user.sql b/database/procedures/register_user.sql index 5931b3f..e8155cd 100644 --- a/database/procedures/register_user.sql +++ b/database/procedures/register_user.sql @@ -1,32 +1,53 @@ --- Register a new user +-- Register a new user using a verified pending_user's token CREATE OR REPLACE PROCEDURE register_user( + p_verification_token TEXT, p_username TEXT, - p_email_encrypted TEXT, - p_email_hash TEXT, + p_discriminator SMALLINT, p_password_hash TEXT, - p_phone_encrypted TEXT, - p_phone_hash TEXT, - p_language_id INTEGER + p_language_id INTEGER, + p_otp_secret TEXT ) -LANGUAGE plpgsql AS $$ +AS $$ +DECLARE + v_email_encrypted TEXT; + v_email_hash TEXT; + v_user_id UUID; BEGIN + -- Retrieve email_encrypted and email_hash from pending_users + SELECT email_encrypted, email_hash + INTO v_email_encrypted, v_email_hash + FROM pending_users + WHERE verification_token = p_verification_token; + + -- Insert new user and get user_id INSERT INTO users ( username, + discriminator, email_encrypted, email_hash, password_hash, - phone_encrypted, - phone_hash, language_id ) VALUES ( p_username, - p_email_encrypted, - p_email_hash, + p_discriminator, + v_email_encrypted, + v_email_hash, p_password_hash, - p_phone_encrypted, - p_phone_hash, p_language_id + ) + RETURNING user_id INTO v_user_id; + + -- Insert authentication secret for the user + INSERT INTO user_authentication_methods ( + user_id, + user_authentication_method_secret + ) VALUES ( + v_user_id, + p_otp_secret ); + + -- Delete the pending_user entry + DELETE FROM pending_users WHERE verification_token = p_verification_token; END; -$$; +$$ LANGUAGE plpgsql; diff --git a/database/schema.sql b/database/schema.sql index a791efa..54e4576 100644 --- a/database/schema.sql +++ b/database/schema.sql @@ -22,7 +22,7 @@ CREATE TYPE payment_status AS ENUM ( 'cancelled' -- Payment cancelled or failed ); -CREATE TYPE authentication_method AS ENUM ('TOTP', 'WebAuthn', 'Email'); +CREATE TYPE authentication_method AS ENUM ('HOTP', 'TOTP', 'WebAuthn', 'Email'); CREATE TYPE moderation_action_type AS ENUM ('approve', 'reject', 'delete'); CREATE TYPE moderation_target_type AS ENUM ('user', 'product', 'comment'); @@ -50,24 +50,23 @@ CREATE TABLE users ( discriminator SMALLINT NOT NULL CHECK (discriminator >= 0 AND discriminator <= 9999), -- 4-digit tag email_encrypted TEXT NOT NULL CHECK (email_encrypted <> ''), -- Encrypted email must not be empty email_hash TEXT UNIQUE NOT NULL CHECK (email_hash ~ '^[a-f0-9]{64}$'), -- SHA-256 hash of email - is_email_verified BOOLEAN DEFAULT FALSE, password_hash TEXT NOT NULL CHECK (password_hash ~ '^\$argon2id\$v=\d+\$m=\d+,t=\d+,p=\d+\$[a-zA-Z0-9+\/=]+\$[a-zA-Z0-9+\/=]+$'), -- Argon2id hash format phone_encrypted TEXT CHECK (phone_encrypted IS NULL OR phone_encrypted <> ''), -- Encrypted phone can be NULL or cannot be empty phone_hash TEXT UNIQUE CHECK (phone_hash ~ '^[a-f0-9]{64}$'), -- SHA-256 hash of phone language_id INTEGER REFERENCES languages (language_id) ON DELETE SET NULL, display_role TEXT, -- For badges/icons like "owner", "verified seller", etc. created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp, + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp), last_login_at TIMESTAMPTZ CHECK (last_login_at <= current_timestamp), deleted_at TIMESTAMPTZ CHECK (deleted_at <= current_timestamp), UNIQUE (username, discriminator) ); CREATE TABLE pending_users ( - pending_user_id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), + pending_user_id INTEGER GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY, email_encrypted TEXT NOT NULL CHECK (email_encrypted <> ''), -- Encrypted email must not be empty email_hash TEXT NOT NULL CHECK (email_hash ~ '^[a-f0-9]{64}$'), -- SHA-256 hash of email - verification_token TEXT NOT NULL UNIQUE CHECK (verification_token ~ '^[a-zA-Z0-9]{32}$'), -- 32-character alphanumeric token + verification_token TEXT NOT NULL UNIQUE CHECK (verification_token ~ '^[A-Za-z0-9_-]{43,64}$'), -- Base64 URL-safe token created_at TIMESTAMPTZ DEFAULT current_timestamp ); @@ -77,27 +76,20 @@ CREATE TABLE user_permissions ( permission TEXT NOT NULL, granted BOOLEAN DEFAULT TRUE, created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp) ); CREATE TABLE user_sessions ( user_session_id INTEGER GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY, user_id UUID NOT NULL REFERENCES users (user_id) ON DELETE CASCADE, token TEXT NOT NULL UNIQUE, + token_type TEXT NOT NULL CHECK (token_type IN ('access', 'refresh')), device_info TEXT, ip_address INET, + user_agent TEXT, expires_at TIMESTAMPTZ NOT NULL, created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp -); - -CREATE TABLE email_verifications ( - email_verification_id INTEGER GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY, - user_id UUID NOT NULL REFERENCES users (user_id) ON DELETE CASCADE, - token TEXT NOT NULL UNIQUE, - is_verified BOOLEAN DEFAULT FALSE, - created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp) ); CREATE TABLE password_resets ( @@ -106,17 +98,18 @@ CREATE TABLE password_resets ( token TEXT NOT NULL UNIQUE, expires_at TIMESTAMPTZ NOT NULL, created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp) ); CREATE TABLE user_authentication_methods ( user_authentication_method_id INTEGER GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY, user_id UUID NOT NULL REFERENCES users (user_id) ON DELETE CASCADE, - user_authentication_method_secret TEXT NOT NULL, -- Base32 encoded secret for TOTP + user_authentication_method_secret TEXT NOT NULL, -- Base32 encoded secret for TOTP or HOTP is_enabled BOOLEAN DEFAULT FALSE, - authentication_method AUTHENTICATION_METHOD NOT NULL, + authentication_method AUTHENTICATION_METHOD DEFAULT 'TOTP', -- Default to TOTP + is_preferred BOOLEAN DEFAULT FALSE, -- Whether this is the preferred method for 2FA created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp) ); CREATE TABLE login_attempts ( @@ -138,7 +131,7 @@ CREATE TABLE products ( image_url TEXT, is_enabled BOOLEAN DEFAULT TRUE, created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp) ); CREATE TABLE product_categories ( @@ -146,7 +139,7 @@ CREATE TABLE product_categories ( product_category_name TEXT NOT NULL UNIQUE, product_category_description TEXT, created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp) ); CREATE TABLE product_variants ( @@ -156,7 +149,7 @@ CREATE TABLE product_variants ( is_test BOOLEAN DEFAULT FALSE, price_override NUMERIC(10, 2) CHECK (price_override >= 0), created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp) ); CREATE TABLE product_images ( @@ -166,7 +159,7 @@ CREATE TABLE product_images ( image_url TEXT NOT NULL, is_primary BOOLEAN DEFAULT FALSE, created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp) ); CREATE TABLE product_likes ( @@ -174,7 +167,7 @@ CREATE TABLE product_likes ( user_id UUID NOT NULL REFERENCES users (user_id) ON DELETE CASCADE, product_id INTEGER NOT NULL REFERENCES products (product_id) ON DELETE CASCADE, created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp, + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp), UNIQUE (user_id, product_id) ); @@ -185,7 +178,7 @@ CREATE TABLE product_comments ( content TEXT NOT NULL, is_moderated BOOLEAN DEFAULT FALSE, created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp) ); CREATE TABLE moderation_actions ( @@ -196,7 +189,7 @@ CREATE TABLE moderation_actions ( target_type MODERATION_TARGET_TYPE NOT NULL, reason TEXT, created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp) ); -- Cart & Order Tables @@ -206,7 +199,7 @@ CREATE TABLE carts ( user_id UUID REFERENCES users (user_id) ON DELETE SET NULL, session_token TEXT UNIQUE, -- For anonymous carts created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp) ); CREATE TABLE cart_items ( @@ -215,7 +208,7 @@ CREATE TABLE cart_items ( product_variant_id INTEGER NOT NULL REFERENCES product_variants (product_variant_id) ON DELETE CASCADE, quantity INTEGER NOT NULL CHECK (quantity > 0), created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp, + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp), UNIQUE (cart_id, product_variant_id) ); @@ -227,7 +220,7 @@ CREATE TABLE orders ( total_price NUMERIC(10, 2) NOT NULL CHECK (total_price >= 0), order_status ORDER_STATUS NOT NULL DEFAULT 'pending', created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp) ); CREATE TABLE order_items ( @@ -237,7 +230,7 @@ CREATE TABLE order_items ( quantity INTEGER NOT NULL CHECK (quantity > 0), price NUMERIC(10, 2) NOT NULL CHECK (price >= 0), created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp, + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp), UNIQUE (order_id, product_variant_id) ); @@ -247,10 +240,10 @@ CREATE TABLE order_status_histories ( order_status_history ORDER_STATUS NOT NULL, changed_at TIMESTAMPTZ DEFAULT current_timestamp, created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp) ); -CREATE TABLE order_delivery_infos ( +CREATE TABLE order_delivery_informations ( order_delivery_info_id INTEGER GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY, order_id INTEGER NOT NULL REFERENCES orders (order_id) ON DELETE CASCADE, delivery_address TEXT NOT NULL, @@ -258,7 +251,7 @@ CREATE TABLE order_delivery_infos ( delivery_type DELIVERY_TYPE NOT NULL, estimated_delivery_time TIMESTAMPTZ, created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp) ); CREATE TABLE order_timestamps ( @@ -269,7 +262,7 @@ CREATE TABLE order_timestamps ( sent_at TIMESTAMPTZ, received_at TIMESTAMPTZ, created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp) ); -- Promotions & Loyalty @@ -283,7 +276,7 @@ CREATE TABLE discount_codes ( max_uses INTEGER CHECK (max_uses > 0), expiration_date TIMESTAMPTZ, created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp) ); CREATE TABLE user_discounts ( @@ -292,7 +285,7 @@ CREATE TABLE user_discounts ( discount_code_id INTEGER NOT NULL REFERENCES discount_codes (discount_code_id) ON DELETE CASCADE, used_at TIMESTAMPTZ DEFAULT current_timestamp, created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp, + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp), UNIQUE (user_id, discount_code_id) ); @@ -304,7 +297,7 @@ CREATE TABLE loyalty_programs ( reward TEXT NOT NULL, -- e.g., "1 free" is_active BOOLEAN DEFAULT TRUE, created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp) ); CREATE TABLE user_loyalty_progress ( @@ -314,7 +307,7 @@ CREATE TABLE user_loyalty_progress ( quantity INTEGER NOT NULL CHECK (quantity >= 0), last_updated TIMESTAMPTZ DEFAULT current_timestamp, created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp) ); -- Internationalization (i18n) @@ -325,7 +318,7 @@ CREATE TABLE translations ( language_id INTEGER NOT NULL REFERENCES languages (language_id) ON DELETE CASCADE, translation_value TEXT NOT NULL, created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp, + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp), UNIQUE (translation_key, language_id) ); @@ -336,7 +329,7 @@ CREATE TABLE product_translations ( product_name TEXT NOT NULL, product_description TEXT, created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp, + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp), UNIQUE (product_id, language_id) ); @@ -347,7 +340,7 @@ CREATE TABLE category_translations ( category_name TEXT NOT NULL, category_description TEXT, created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp, + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp), UNIQUE (category_id, language_id) ); @@ -359,7 +352,7 @@ CREATE TABLE metrics_events ( event_type TEXT NOT NULL, event_data JSONB NOT NULL, created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp) ); CREATE TABLE admin_accounts ( @@ -369,7 +362,7 @@ CREATE TABLE admin_accounts ( is_active BOOLEAN DEFAULT TRUE, target_type ADMIN_ACTION_TARGET_TYPE NOT NULL, created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp, + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp), UNIQUE (user_id, admin_account_role) ); @@ -381,7 +374,7 @@ CREATE TABLE admin_actions ( target_type TEXT NOT NULL CHECK (target_type IN ('user', 'product', 'comment', 'order')), details JSONB, created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp) ); -- Support & Feedback @@ -392,7 +385,7 @@ CREATE TABLE contact_messages ( contact_email TEXT NOT NULL, content TEXT NOT NULL, created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp) ); CREATE TABLE feedbacks ( @@ -402,7 +395,7 @@ CREATE TABLE feedbacks ( rating INTEGER NOT NULL CHECK (rating >= 1 AND rating <= 5), comment TEXT, created_at TIMESTAMPTZ DEFAULT current_timestamp, - updated_at TIMESTAMPTZ DEFAULT current_timestamp + updated_at TIMESTAMPTZ CHECK (updated_at <= current_timestamp) ); CREATE INDEX idx_users_email_hash ON users (email_hash); diff --git a/database/tests/schema.test.sql b/database/tests/schema.test.sql index 27fc190..0b2582f 100644 --- a/database/tests/schema.test.sql +++ b/database/tests/schema.test.sql @@ -19,10 +19,11 @@ SELECT has_type('admin_action_target_type', 'Type exists'); -- Verify that the schema has the expected tables +SELECT has_table('languages', 'Table exists'); SELECT has_table('users', 'Table exists'); +SELECT has_table('pending_users', 'Table exists'); SELECT has_table('user_permissions', 'Table exists'); SELECT has_table('user_sessions', 'Table exists'); -SELECT has_table('email_verifications', 'Table exists'); SELECT has_table('password_resets', 'Table exists'); SELECT has_table('user_authentication_methods', 'Table exists'); SELECT has_table('login_attempts', 'Table exists'); @@ -38,13 +39,12 @@ SELECT has_table('cart_items', 'Table exists'); SELECT has_table('orders', 'Table exists'); SELECT has_table('order_items', 'Table exists'); SELECT has_table('order_status_histories', 'Table exists'); -SELECT has_table('order_delivery_infos', 'Table exists'); +SELECT has_table('order_delivery_informations', 'Table exists'); SELECT has_table('order_timestamps', 'Table exists'); SELECT has_table('discount_codes', 'Table exists'); SELECT has_table('user_discounts', 'Table exists'); SELECT has_table('loyalty_programs', 'Table exists'); SELECT has_table('user_loyalty_progress', 'Table exists'); -SELECT has_table('languages', 'Table exists'); SELECT has_table('translations', 'Table exists'); SELECT has_table('product_translations', 'Table exists'); SELECT has_table('category_translations', 'Table exists'); diff --git a/database/tests/seed_data.test.sql b/database/tests/seed_data.test.sql index 3f2be5b..9f744d9 100644 --- a/database/tests/seed_data.test.sql +++ b/database/tests/seed_data.test.sql @@ -7,7 +7,8 @@ SELECT plan(3); SELECT is( ( SELECT count(*)::INT FROM languages - WHERE iso_code = 'fr' + WHERE + iso_code = 'fr' AND english_name = 'French' AND native_name = 'Français' ), @@ -17,7 +18,8 @@ SELECT is( SELECT is( ( SELECT count(*)::INT FROM languages - WHERE iso_code = 'en' + WHERE + iso_code = 'en' AND english_name = 'English' AND native_name = 'English' ), @@ -27,7 +29,8 @@ SELECT is( SELECT is( ( SELECT count(*)::INT FROM languages - WHERE iso_code = 'es' + WHERE + iso_code = 'es' AND english_name = 'Spanish' AND native_name = 'Español' ), diff --git a/database/triggers/update_last_login_at.sql b/database/triggers/update_last_login_at.sql new file mode 100644 index 0000000..e1ed9db --- /dev/null +++ b/database/triggers/update_last_login_at.sql @@ -0,0 +1,4 @@ +CREATE TRIGGER tr_update_last_login_at +AFTER INSERT ON user_sessions +FOR EACH ROW +EXECUTE FUNCTION update_last_login_at(); diff --git a/database/triggers/update_updated_at.sql b/database/triggers/update_updated_at.sql new file mode 100644 index 0000000..d5d45e1 --- /dev/null +++ b/database/triggers/update_updated_at.sql @@ -0,0 +1,149 @@ +CREATE TRIGGER tr_set_updated_at_users +BEFORE UPDATE ON users +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_user_sessions +BEFORE UPDATE ON user_sessions +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_password_resets +BEFORE UPDATE ON password_resets +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_user_authentication_methods +BEFORE UPDATE ON user_authentication_methods +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_products +BEFORE UPDATE ON products +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_product_categories +BEFORE UPDATE ON product_categories +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_product_variants +BEFORE UPDATE ON product_variants +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_product_images +BEFORE UPDATE ON product_images +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_product_likes +BEFORE UPDATE ON product_likes +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_product_comments +BEFORE UPDATE ON product_comments +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_moderation_actions +BEFORE UPDATE ON moderation_actions +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_carts +BEFORE UPDATE ON carts +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_cart_items +BEFORE UPDATE ON cart_items +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_orders +BEFORE UPDATE ON orders +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_order_items +BEFORE UPDATE ON order_items +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_order_status_histories +BEFORE UPDATE ON order_status_histories +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_order_delivery_informations +BEFORE UPDATE ON order_delivery_informations +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_order_timestamps +BEFORE UPDATE ON order_timestamps +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_discount_codes +BEFORE UPDATE ON discount_codes +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_user_discounts +BEFORE UPDATE ON user_discounts +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_loyalty_programs +BEFORE UPDATE ON loyalty_programs +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_user_loyalty_progress +BEFORE UPDATE ON user_loyalty_progress +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_translations +BEFORE UPDATE ON translations +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_product_translations +BEFORE UPDATE ON product_translations +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_category_translations +BEFORE UPDATE ON category_translations +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_metrics_events +BEFORE UPDATE ON metrics_events +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_admin_accounts +BEFORE UPDATE ON admin_accounts +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_admin_actions +BEFORE UPDATE ON admin_actions +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_contact_messages +BEFORE UPDATE ON contact_messages +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); + +CREATE TRIGGER tr_set_updated_at_feedbacks +BEFORE UPDATE ON feedbacks +FOR EACH ROW +EXECUTE FUNCTION update_updated_at(); diff --git a/scripts/flatten-sql.sh b/scripts/flatten-sql.sh index 1d6e16d..f52b9f2 100755 --- a/scripts/flatten-sql.sh +++ b/scripts/flatten-sql.sh @@ -17,6 +17,7 @@ mkdir -p "$DEST_DIR" find "$SRC_DIR" -type f -name "*.sql" ! -name "*.session.sql" ! -name "*.test.sql" | while read -r file; do rel_path="${file#"$SRC_DIR"/}" new_name=$(echo "$rel_path" | sed 's|/|_|g') - cp "$file" "$DEST_DIR/$new_name" - echo "✅ Copied: $file → $DEST_DIR/$new_name" + depth=$(echo "$rel_path" | awk -F'/' '{print NF-1}') + cp "$file" "$DEST_DIR/${depth}${new_name}" + echo "✅ Copied: $file → $DEST_DIR/${depth}${new_name}" done diff --git a/scripts/rebuild-db.sh b/scripts/rebuild-db.sh index 20b814a..3aa825c 100755 --- a/scripts/rebuild-db.sh +++ b/scripts/rebuild-db.sh @@ -17,7 +17,7 @@ dropdb -h /run/postgresql -U "$DB_USER" "$DB_NAME" || true createdb -h /run/postgresql -U "$DB_USER" "$DB_NAME" # Execute all flattened SQL files (excluding nested ones) -find "$FLATTENED_SQL_DIR" -maxdepth 1 -name "*.sql" | while read -r file; do +find "$FLATTENED_SQL_DIR" -maxdepth 1 -name "*.sql" | sort | while read -r file; do echo "📄 Running $file..." psql -h /run/postgresql -U "$DB_USER" -d "$DB_NAME" -f "$file" done