1
0
mirror of https://github.com/juanfont/headscale.git synced 2025-11-10 01:20:58 +01:00
juanfont.headscale/hscontrol/db/schema.sql
Kristoffer Dalby d49ae71a80
db: use partial unique index for pre_auth_keys.prefix
This commit fixes the UNIQUE constraint on the pre_auth_keys.prefix
column to allow multiple legacy keys (with NULL or empty prefix) while
still enforcing uniqueness for new bcrypt-based keys.

Changes:
- Modified migration to create partial unique index with WHERE clause
- Updated schema.sql to match migration
- Added comprehensive test (TestMultipleLegacyKeysAllowed) to verify:
  * Multiple legacy keys with empty prefix can coexist
  * New bcrypt keys have unique prefixes
  * Duplicate non-empty prefixes are rejected
- Fixed lint issues (errcheck, intrange)
- Fixed hardening: position-based parsing instead of separator-based
- Added validation for empty string, length, separator, and character set

The partial index uses:
  WHERE prefix IS NOT NULL AND prefix != ''

This allows unlimited legacy keys (backward compatibility) while
preventing duplicate prefixes for new keys (security).

🤖 Generated with [Claude Code](https://claude.com/claude-code)

Co-Authored-By: Claude <noreply@anthropic.com>
2025-11-02 15:26:55 +01:00

114 lines
3.4 KiB
SQL

-- This file is the representation of the SQLite schema of Headscale.
-- It is the "source of truth" and is used to validate any migrations
-- that are run against the database to ensure it ends in the expected state.
CREATE TABLE migrations(id text,PRIMARY KEY(id));
CREATE TABLE users(
id integer PRIMARY KEY AUTOINCREMENT,
name text,
display_name text,
email text,
provider_identifier text,
provider text,
profile_pic_url text,
created_at datetime,
updated_at datetime,
deleted_at datetime
);
CREATE INDEX idx_users_deleted_at ON users(deleted_at);
-- The following three UNIQUE indexes work together to enforce the user identity model:
--
-- 1. Users can be either local (provider_identifier is NULL) or from external providers (provider_identifier set)
-- 2. Each external provider identifier must be unique across the system
-- 3. Local usernames must be unique among local users
-- 4. The same username can exist across different providers with different identifiers
--
-- Examples:
-- - Can create local user "alice" (provider_identifier=NULL)
-- - Can create external user "alice" with GitHub (name="alice", provider_identifier="alice_github")
-- - Can create external user "alice" with Google (name="alice", provider_identifier="alice_google")
-- - Cannot create another local user "alice" (blocked by idx_name_no_provider_identifier)
-- - Cannot create another user with provider_identifier="alice_github" (blocked by idx_provider_identifier)
-- - Cannot create user "bob" with provider_identifier="alice_github" (blocked by idx_name_provider_identifier)
CREATE UNIQUE INDEX idx_provider_identifier ON users(
provider_identifier
) WHERE provider_identifier IS NOT NULL;
CREATE UNIQUE INDEX idx_name_provider_identifier ON users(
name,
provider_identifier
);
CREATE UNIQUE INDEX idx_name_no_provider_identifier ON users(
name
) WHERE provider_identifier IS NULL;
CREATE TABLE pre_auth_keys(
id integer PRIMARY KEY AUTOINCREMENT,
key text,
prefix text,
hash blob,
user_id integer,
reusable numeric,
ephemeral numeric DEFAULT false,
used numeric DEFAULT false,
tags text,
expiration datetime,
created_at datetime,
CONSTRAINT fk_pre_auth_keys_user FOREIGN KEY(user_id) REFERENCES users(id) ON DELETE SET NULL
);
CREATE UNIQUE INDEX idx_pre_auth_keys_prefix ON pre_auth_keys(prefix) WHERE prefix IS NOT NULL AND prefix != '';
CREATE TABLE api_keys(
id integer PRIMARY KEY AUTOINCREMENT,
prefix text,
hash blob,
expiration datetime,
last_seen datetime,
created_at datetime
);
CREATE UNIQUE INDEX idx_api_keys_prefix ON api_keys(prefix);
CREATE TABLE nodes(
id integer PRIMARY KEY AUTOINCREMENT,
machine_key text,
node_key text,
disco_key text,
endpoints text,
host_info text,
ipv4 text,
ipv6 text,
hostname text,
given_name varchar(63),
user_id integer,
register_method text,
forced_tags text,
auth_key_id integer,
last_seen datetime,
expiry datetime,
approved_routes text,
created_at datetime,
updated_at datetime,
deleted_at datetime,
CONSTRAINT fk_nodes_user FOREIGN KEY(user_id) REFERENCES users(id) ON DELETE CASCADE,
CONSTRAINT fk_nodes_auth_key FOREIGN KEY(auth_key_id) REFERENCES pre_auth_keys(id)
);
CREATE TABLE policies(
id integer PRIMARY KEY AUTOINCREMENT,
data text,
created_at datetime,
updated_at datetime,
deleted_at datetime
);
CREATE INDEX idx_policies_deleted_at ON policies(deleted_at);