├── .github
├── actions
│ ├── setup-environment
│ │ └── action.yml
│ └── setup-integration-tests
│ │ └── action.yml
├── linters
│ └── .jscpd.json
└── workflows
│ ├── lint.yml
│ └── test.yml
├── .gitignore
├── CODE_OF_CONDUCT.md
├── LICENSE
├── Makefile
├── README.md
├── SECURITY.md
├── extension
├── README.md
├── keyhippo--1.2.5.sql
└── keyhippo.control
├── flake.lock
├── flake.nix
├── supabase
├── .gitignore
├── config.toml
├── migrations
│ └── 20240816164943_remote_schema.sql
└── seed.sql
└── tests
├── bench.sql
├── reset.sql
└── tests.sql
/.github/actions/setup-environment/action.yml:
--------------------------------------------------------------------------------
1 | name: "Setup Environment"
2 |
3 | description: "Installs dependencies using nix and magic cache"
4 |
5 | runs:
6 | using: "composite"
7 | steps:
8 | - uses: DeterminateSystems/nix-installer-action@main
9 | - uses: DeterminateSystems/magic-nix-cache-action@main
10 | - name: Install environment dependencies
11 | working-directory: ./
12 | shell: bash
13 | run: nix develop --command echo "dev env setup successfully"
14 |
--------------------------------------------------------------------------------
/.github/actions/setup-integration-tests/action.yml:
--------------------------------------------------------------------------------
1 | name: "Setup Integration Tests"
2 |
3 | description: "Caches Docker images, sets up Supabase CLI, starts Supabase"
4 |
5 | runs:
6 | using: "composite"
7 | steps:
8 | - name: Cache Docker images
9 | uses: ScribeMD/docker-cache@0.5.0
10 | with:
11 | key: docker-${{ runner.os }}-${{ hashFiles('./flake.lock') }}
12 |
13 | - name: Setup Supabase CLI
14 | uses: supabase/setup-cli@v1
15 | with:
16 | version: latest
17 |
18 | - name: Start Supabase
19 | working-directory: ./
20 | shell: bash
21 | run: |
22 | supabase start
23 | eval "$(supabase status -o env)"
24 | echo "SUPABASE_URL=${API_URL}" >> "$GITHUB_ENV"
25 | echo "SUPABASE_ANON_KEY=${ANON_KEY}" >> "$GITHUB_ENV"
26 |
--------------------------------------------------------------------------------
/.github/linters/.jscpd.json:
--------------------------------------------------------------------------------
1 | {
2 | "maxLines": 0,
3 | "maxSize": 0,
4 | "threshold": 0,
5 | "reporters": ["consoleFull", "console"],
6 | "ignore": [".git", "**/tests/**/*.sql"],
7 | "gitignore": true,
8 | "blame": true,
9 | "ignoreCase": true
10 | }
11 |
--------------------------------------------------------------------------------
/.github/workflows/lint.yml:
--------------------------------------------------------------------------------
1 | ---
2 | name: Lint
3 |
4 | on: # yamllint disable-line rule:truthy
5 | push: null
6 | pull_request: null
7 |
8 | permissions: {}
9 |
10 | jobs:
11 | build:
12 | name: lint
13 | runs-on: ubuntu-latest
14 |
15 | permissions:
16 | contents: read
17 | packages: read
18 | # To report GitHub Actions status checks
19 | statuses: write
20 |
21 | steps:
22 | - name: Checkout code
23 | uses: actions/checkout@v4
24 | with:
25 | # super-linter needs the full git history to get the
26 | # list of files that changed across commits
27 | fetch-depth: 0
28 |
29 | - name: Super-linter
30 | uses: super-linter/super-linter/slim@v7.0.0 # x-release-please-version
31 | env:
32 | # To report GitHub Actions status checks
33 | GITHUB_TOKEN: ${{ secrets.GITHUB_TOKEN }}
34 | VALIDATE_TYPESCRIPT_STANDARD: false
35 | VALIDATE_SQLFLUFF: false
36 |
--------------------------------------------------------------------------------
/.github/workflows/test.yml:
--------------------------------------------------------------------------------
1 | name: "Test"
2 |
3 | on:
4 | push:
5 | paths-ignore:
6 | - "**.md"
7 | branches:
8 | - main
9 | pull_request:
10 | types: [opened, synchronize]
11 |
12 | permissions:
13 | contents: read
14 | issues: write
15 | pull-requests: write
16 | checks: write
17 | statuses: write
18 |
19 | jobs:
20 | integration-tests:
21 | runs-on: ubuntu-latest
22 | steps:
23 | - name: Checkout repository
24 | uses: actions/checkout@v4
25 | - uses: ./.github/actions/setup-environment
26 | - uses: ./.github/actions/setup-integration-tests
27 | - name: Run tests
28 | working-directory: ./
29 | run: nix develop --command make test
30 |
--------------------------------------------------------------------------------
/.gitignore:
--------------------------------------------------------------------------------
1 | # See https://help.github.com/articles/ignoring-files/ for more about ignoring files.
2 |
3 | # dependencies
4 | node_modules
5 | /.pnp
6 | .pnp.js
7 |
8 | # testing
9 | **/coverage/**
10 |
11 | # production
12 | /build
13 |
14 | # misc
15 | .DS_Store
16 | *.pem
17 |
18 | # debug
19 | npm-debug.log*
20 |
21 | # local env files
22 | .env*.local
23 |
24 | # typescript
25 | *.tsbuildinfo
26 |
27 | .env.development
28 |
--------------------------------------------------------------------------------
/CODE_OF_CONDUCT.md:
--------------------------------------------------------------------------------
1 | # Contributor Code of Conduct
2 |
3 | Let's keep it simple.
4 |
5 | 1. Be professional
6 | 2. All contributions are welcome
7 |
--------------------------------------------------------------------------------
/LICENSE:
--------------------------------------------------------------------------------
1 | MIT License
2 |
3 | Copyright (c) 2024 Integrated Reasoning
4 |
5 | Permission is hereby granted, free of charge, to any person obtaining a copy
6 | of this software and associated documentation files (the "Software"), to deal
7 | in the Software without restriction, including without limitation the rights
8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
9 | copies of the Software, and to permit persons to whom the Software is
10 | furnished to do so, subject to the following conditions:
11 |
12 | The above copyright notice and this permission notice shall be included in all
13 | copies or substantial portions of the Software.
14 |
15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE
21 | SOFTWARE.
22 |
--------------------------------------------------------------------------------
/Makefile:
--------------------------------------------------------------------------------
1 | # Directory paths
2 | SRC_DIR := src
3 | TEST_DIR := tests
4 | BUILD_DIR := dist
5 | PG_HOST := localhost
6 | PG_PORT := 54322
7 | PG_USER := postgres
8 | PG_DB := postgres
9 | PG_PASSWORD := postgres
10 |
11 | # Default goal
12 | .DEFAULT_GOAL := help
13 |
14 | # Help target
15 | .PHONY: help
16 | help:
17 | @echo "Available targets:"
18 | @echo " setup-supabase - Set up Supabase for testing"
19 | @echo " test - Run tests"
20 | @echo " pg_tap - Run pg_tap tests"
21 |
22 | # Set up Supabase
23 | .PHONY: setup-supabase
24 | setup-supabase:
25 | @echo "Setting up Supabase..."
26 | @cd tests && \
27 | supabase start && \
28 | eval $$(supabase status -o env) && \
29 | echo "SUPABASE_URL=$$API_URL" > .env.test && \
30 | echo "SUPABASE_ANON_KEY=$$ANON_KEY" >> .env.test && \
31 | echo "SUPABASE_SERVICE_ROLE_KEY=$$SERVICE_ROLE_KEY" >> .env.test
32 | @echo "CREATE EXTENSION IF NOT EXISTS pgcrypto;" > create_schema.sql
33 | @echo "CREATE EXTENSION IF NOT EXISTS pgjwt;" >> create_schema.sql
34 | @echo "CREATE SCHEMA IF NOT EXISTS keyhippo;" >> create_schema.sql
35 | PGPASSWORD=$(PG_PASSWORD) psql -h $(PG_HOST) -p $(PG_PORT) -U $(PG_USER) -d $(PG_DB) -v ON_ERROR_STOP=1 -f create_schema.sql
36 | @for file in $$(find extension/ -type f -name "keyhippo*--*.sql" | sort -V); do \
37 | echo "Applying migration: $$file" ; \
38 | PGPASSWORD=$(PG_PASSWORD) psql -h $(PG_HOST) -p $(PG_PORT) -U $(PG_USER) -d $(PG_DB) -v ON_ERROR_STOP=1 -f "$$file"; \
39 | done
40 |
41 | # Apply integration test migrations
42 | .PHONY: apply-integration-test-migrations
43 | apply-integration-test-migrations:
44 | @echo "Applying integration test migrations..."
45 | @echo "CREATE TABLE public.test_accounts (" > create_test_accounts.sql
46 | @echo " id uuid PRIMARY KEY DEFAULT uuid_generate_v4 ()," >> create_test_accounts.sql
47 | @echo " user_id uuid NOT NULL," >> create_test_accounts.sql
48 | @echo " name text NOT NULL," >> create_test_accounts.sql
49 | @echo " email text NOT NULL UNIQUE," >> create_test_accounts.sql
50 | @echo " created_at timestamptz DEFAULT now()" >> create_test_accounts.sql
51 | @echo ");" >> create_test_accounts.sql
52 | @echo "" >> create_test_accounts.sql
53 | @echo "ALTER TABLE public.test_accounts ENABLE ROW LEVEL SECURITY;" >> create_test_accounts.sql
54 | @echo "" >> create_test_accounts.sql
55 | @echo "CREATE POLICY \"Users can access their own test account\" ON public.test_accounts TO anon, authenticated" >> create_test_accounts.sql
56 | @echo " USING ((COALESCE(auth.uid (), (SELECT user_id FROM keyhippo.current_user_context ())) = user_id));" >> create_test_accounts.sql
57 | @echo "" >> create_test_accounts.sql
58 | @echo "GRANT SELECT ON public.test_accounts TO anon, authenticated;" >> create_test_accounts.sql
59 | @echo "GRANT INSERT, UPDATE, DELETE ON public.test_accounts TO authenticated;" >> create_test_accounts.sql
60 | PGPASSWORD=$(PG_PASSWORD) psql -h $(PG_HOST) -p $(PG_PORT) -U $(PG_USER) -d $(PG_DB) -v ON_ERROR_STOP=1 -f create_test_accounts.sql
61 |
62 | # Run pg_tap tests
63 | .PHONY: pg_tap
64 | pg_tap:
65 | @echo "Running pg_tap tests..."
66 | PGPASSWORD=$(PG_PASSWORD) psql -h $(PG_HOST) -p $(PG_PORT) -U $(PG_USER) -d $(PG_DB) -v ON_ERROR_STOP=1 -f $(TEST_DIR)/tests.sql
67 |
68 | # Run benchmark
69 | .PHONY: benchmark
70 | benchmark:
71 | @echo "Running benchmark..."
72 | PGPASSWORD=$(PG_PASSWORD) psql -h $(PG_HOST) -p $(PG_PORT) -U $(PG_USER) -d $(PG_DB) -v ON_ERROR_STOP=1 -f $(TEST_DIR)/bench.sql
73 |
74 | # Run tests with coverage (including Supabase setup and migrations)
75 | .PHONY: test
76 | test: setup-supabase apply-integration-test-migrations pg_tap
77 | @echo "Running tests..."
78 |
--------------------------------------------------------------------------------
/README.md:
--------------------------------------------------------------------------------
1 | # KeyHippo
2 |
3 | KeyHippo extends Supabase's Row Level Security (RLS) to support API key authentication and Role-Based Access Control (RBAC) directly in Postgres.
4 |
5 |
6 |
7 |
8 | 
9 | [](LICENSE-MIT)
10 | [](https://github.com/marketplace/actions/super-linter)
11 |
12 |
13 |
14 | ## Core Functionality
15 |
16 | KeyHippo enables API key authentication and fine-grained access control in Supabase applications while preserving Row Level Security policies. It handles both session-based and API key authentication using SQL and introduces an RBAC system for managing permissions.
17 |
18 | Features:
19 |
20 | - **API Key Management:**
21 |
22 | - Secure key issuance and validation
23 | - Key rotation and revocation
24 | - Automatic key expiration
25 | - Claims-based metadata
26 | - HTTP notifications for key events
27 |
28 | - **Role-Based Access Control (RBAC):**
29 | - Hierarchical group-based permissions
30 | - Built-in roles (admin, user)
31 | - Fine-grained permission management
32 | - Default role assignment for new users
33 |
34 | ## Quick Start
35 |
36 | ### Database Setup
37 |
38 | 1. Create a new Supabase migration for the KeyHippo extension:
39 |
40 | ```bash
41 | supabase migration new add_keyhippo_extension
42 | ```
43 |
44 | 2. Copy the contents of `extension/keyhippo--1.2.5.sql` into the newly created migration file in the `supabase/migrations` directory.
45 |
46 | 3. Apply the migration to install the extension:
47 |
48 | ```bash
49 | supabase migration up
50 | ```
51 |
52 | 4. For projects with existing users:
53 |
54 | ```sql
55 | SELECT keyhippo.initialize_existing_project();
56 | ```
57 |
58 | This will:
59 |
60 | - Create default groups (Admin Group, User Group)
61 | - Create default roles (Admin, User)
62 | - Set up default permissions
63 | - Create a default scope
64 | - Assign the User role to existing users (when using initialize_existing_project)
65 |
66 | ## Application Integration
67 |
68 | KeyHippo integrates with your Supabase application in two main ways:
69 |
70 | 1. **Direct SQL Access**: Use KeyHippo functions through your application's database connection
71 | 2. **REST API**: Access via PostgREST endpoints (requires valid API key in x-api-key header)
72 |
73 | ### Key Management
74 |
75 | ```sql
76 | -- Generate a new API key
77 | SELECT * FROM keyhippo.create_api_key('Primary API Key', 'default');
78 |
79 | -- Verify an API key (internal use)
80 | SELECT * FROM keyhippo.verify_api_key('your-api-key');
81 |
82 | -- Get key metadata in RLS policies
83 | SELECT keyhippo.key_data();
84 |
85 | -- Revoke an API key
86 | SELECT keyhippo.revoke_api_key('key-id-uuid');
87 |
88 | -- Rotate an existing key
89 | SELECT * FROM keyhippo.rotate_api_key('key-id-uuid');
90 |
91 | -- Update key claims
92 | SELECT keyhippo.update_key_claims('key-id-uuid', '{"custom": "data"}'::jsonb);
93 | ```
94 |
95 | ### HTTP Integration
96 |
97 | KeyHippo supports HTTP notifications for:
98 |
99 | - Key expiry events
100 | - Audit log events
101 | - Installation tracking
102 |
103 | Configure endpoints through keyhippo_internal.config:
104 |
105 | ```sql
106 | -- Set audit log endpoint
107 | UPDATE keyhippo_internal.config
108 | SET value = 'https://your-endpoint.com/audit'
109 | WHERE key = 'audit_log_endpoint';
110 |
111 | -- Enable HTTP logging
112 | SELECT keyhippo_internal.enable_audit_log_notify();
113 | ```
114 |
115 | ### RLS Policy Implementation
116 |
117 | Example of a policy supporting both authentication methods and RBAC:
118 |
119 | ```sql
120 | CREATE POLICY "owner_access"
121 | ON "public"."resource_table"
122 | FOR SELECT
123 | USING (
124 | auth.uid() = resource_table.owner_id
125 | AND keyhippo.authorize('manage_resources')
126 | );
127 | ```
128 |
129 | This policy grants access when:
130 |
131 | 1. The user is authenticated (via session token or API key)
132 | 2. They are the owner of the resource
133 | 3. They have the 'manage_resources' permission
134 |
135 | ### RBAC Management
136 |
137 | Create a new group, role, and assign permissions:
138 |
139 | ```sql
140 | -- Create a new group
141 | SELECT keyhippo_rbac.create_group('Developers', 'Group for developer users') AS group_id;
142 |
143 | -- Create a new role (role_type can be 'admin' or 'user')
144 | SELECT keyhippo_rbac.create_role('Developer', 'Developer role', group_id, 'user'::keyhippo.app_role) AS role_id;
145 |
146 | -- Assign permissions to the role (using valid app_permission enum values)
147 | SELECT keyhippo_rbac.assign_permission_to_role(role_id, 'manage_api_keys'::keyhippo.app_permission);
148 |
149 | -- Assign the role to a user
150 | SELECT keyhippo_rbac.assign_role_to_user(auth.uid(), group_id, role_id);
151 | ```
152 |
153 | Available permissions:
154 |
155 | - manage_groups
156 | - manage_roles
157 | - manage_permissions
158 | - manage_scopes
159 | - manage_user_attributes
160 | - manage_api_keys
161 |
162 | ### Impersonation Functionality
163 |
164 | KeyHippo provides secure user impersonation for debugging purposes:
165 |
166 | ```sql
167 | -- Login as another user (requires postgres role)
168 | CALL keyhippo_impersonation.login_as_user('');
169 |
170 | -- Login as anonymous user (requires postgres role)
171 | CALL keyhippo_impersonation.login_as_anon();
172 |
173 | -- Perform actions as the impersonated user
174 | -- The session will automatically expire after 1 hour
175 |
176 | -- End impersonation session
177 | CALL keyhippo_impersonation.logout();
178 | ```
179 |
180 | **Features:**
181 |
182 | - Requires postgres role for impersonation
183 | - Automatic session expiration (1 hour)
184 | - Audit logging of impersonation events
185 | - Support for anonymous user impersonation
186 |
187 | ## Architecture
188 |
189 | ### Database Schema
190 |
191 | KeyHippo organizes its functionality across several schemas:
192 |
193 | - **keyhippo**: Main schema for API key management and core functions
194 | - **keyhippo_rbac**: Role-Based Access Control functionality
195 | - **keyhippo_internal**: Internal configuration and utilities
196 | - **keyhippo_impersonation**: User impersonation functionality
197 |
198 | ### API Key Management
199 |
200 | KeyHippo provides API key management with the following features:
201 |
202 | **Key Operations:**
203 |
204 | ```sql
205 | -- Create a new API key
206 | SELECT * FROM keyhippo.create_api_key('My API Key', 'default');
207 |
208 | -- Revoke an existing key
209 | SELECT keyhippo.revoke_api_key('key-id-uuid');
210 |
211 | -- Rotate an existing key
212 | SELECT * FROM keyhippo.rotate_api_key('key-id-uuid');
213 |
214 | -- Update key claims
215 | SELECT keyhippo.update_key_claims('key-id-uuid', '{"custom": "data"}'::jsonb);
216 | ```
217 |
218 | **Integration:**
219 |
220 | ```sql
221 | -- Get current key data in RLS policies
222 | SELECT keyhippo.key_data();
223 |
224 | -- Check authorization in RLS policies
225 | SELECT keyhippo.authorize('manage_api_keys');
226 |
227 | -- Get current user context
228 | SELECT * FROM keyhippo.current_user_context();
229 | ```
230 |
231 | ## Role-Based Access Control (RBAC)
232 |
233 | KeyHippo provides a RBAC system that integrates with Postgres RLS policies:
234 |
235 | ### RBAC Components
236 |
237 | - **Groups:** Logical grouping of users (e.g., "Admin Group", "User Group")
238 | - **Roles:** Assigned to users within groups, with role types:
239 | - 'admin': Full system access
240 | - 'user': Limited access based on assigned permissions
241 | - **Permissions:** Built-in permissions:
242 | - manage_groups
243 | - manage_roles
244 | - manage_permissions
245 | - manage_scopes
246 | - manage_user_attributes
247 | - manage_api_keys
248 |
249 | ### Default Setup
250 |
251 | On initialization, KeyHippo creates:
252 |
253 | 1. Default groups: "Admin Group" and "User Group"
254 | 2. Default roles: "Admin" (admin type) and "User" (user type)
255 | 3. Admin role gets all permissions
256 | 4. User role gets 'manage_api_keys' permission
257 | 5. New users automatically get the "User" role
258 |
259 | ### Usage Example
260 |
261 | ```sql
262 | -- Check if user has permission in RLS policy
263 | SELECT keyhippo.authorize('manage_api_keys');
264 |
265 | -- Get current user's permissions
266 | SELECT permissions FROM keyhippo.current_user_context();
267 | ```
268 |
269 | ## Impersonation
270 |
271 | KeyHippo provides user impersonation functionality to assist with debugging and maintnence tasks.
272 |
273 | ### Usage
274 |
275 | ```sql
276 | -- Start impersonation (requires postgres role)
277 | CALL keyhippo_impersonation.login_as_user('');
278 |
279 | -- Impersonate anonymous user
280 | CALL keyhippo_impersonation.login_as_anon();
281 |
282 | -- End impersonation session
283 | CALL keyhippo_impersonation.logout();
284 | ```
285 |
286 | ### Security Controls
287 |
288 | - Only postgres role can initiate impersonation
289 | - Sessions automatically expire after 1 hour
290 | - All actions during impersonation are logged
291 | - Original role is preserved and restored on logout
292 | - State tracking prevents session manipulation
293 |
294 | ### Integration with RLS
295 |
296 | KeyHippo's authentication and authorization integrate with Supabase's Row Level Security policies. Use auth.uid() to get the current user's ID and keyhippo.authorize() to check permissions within your RLS policies.
297 |
298 | **Example RLS Policy:**
299 |
300 | ```sql
301 | CREATE POLICY "user_can_view_own_data" ON "public"."user_data"
302 | FOR SELECT USING (
303 | auth.uid() = user_data.user_id
304 | AND keyhippo.authorize('manage_api_keys')
305 | );
306 | ```
307 |
308 | Note: The example uses 'manage_api_keys' as it's one of the built-in permissions. Your application can define additional permissions as needed.
309 |
310 | ## Star History
311 |
312 | [](https://star-history.com/#integrated-reasoning/KeyHippo&Timeline)
313 |
314 | ## Contribution
315 |
316 | We welcome community contributions. For guidance, see our Contributing Guide.
317 |
318 | ## Licensing
319 |
320 | KeyHippo is distributed under the MIT license. See the LICENSE file for details.
321 |
322 | ## Development
323 |
324 | ### Setting Up Development Environment
325 |
326 | 1. Install Nix (if not already installed):
327 |
328 | For Linux/macOS (multi-user installation recommended):
329 |
330 | ```bash
331 | sh <(curl -L https://nixos.org/nix/install) --daemon
332 | ```
333 |
334 | For single-user installation:
335 |
336 | ```bash
337 | sh <(curl -L https://nixos.org/nix/install) --no-daemon
338 | ```
339 |
340 | 2. Clone the repository:
341 |
342 | ```bash
343 | git clone https://github.com/integrated-reasoning/KeyHippo.git
344 | cd KeyHippo
345 | ```
346 |
347 | 3. Enter the Nix development shell:
348 |
349 | ```bash
350 | nix develop
351 | ```
352 |
353 | 4. Set up the local Supabase instance:
354 |
355 | ```bash
356 | make setup-supabase
357 | ```
358 |
359 | ### Running Tests
360 |
361 | KeyHippo uses pgTAP for testing. To run the test suite:
362 |
363 | ```bash
364 | # Run all tests
365 | make test
366 |
367 | # Run pgTAP tests specifically
368 | make pg_tap
369 | ```
370 |
371 | The test suite verifies:
372 |
373 | - API key management functionality
374 | - RBAC system operations
375 | - Impersonation features
376 | - Security controls
377 | - Integration with RLS policies
378 |
379 | ## Support & Community
380 |
381 | For technical support and discussions:
382 |
383 | - Open an issue on our [GitHub repository](https://github.com/integrated-reasoning/KeyHippo/issues)
384 | - Follow us on [Twitter](https://x.com/keyhippo) for updates
385 | - Visit [keyhippo.com](https://keyhippo.com)
386 |
--------------------------------------------------------------------------------
/SECURITY.md:
--------------------------------------------------------------------------------
1 | # Security Policy for KeyHippo
2 |
3 | ## Supported Versions
4 |
5 | The following table outlines the versions of KeyHippo that are currently supported with security updates:
6 |
7 | | Version | Supported |
8 | | ------- | ------------------ |
9 | | 0.1.x | :white_check_mark: |
10 | | < 0.1.0 | :x: |
11 |
12 | ## Reporting a Vulnerability
13 |
14 | To report a vulnerability in KeyHippo, please follow the guidelines below:
15 |
16 | 1. **Where to Report:**
17 |
18 | - Vulnerabilities should be reported via email to our security team at [hello@integrated-reasoning.com](mailto:hello@integrated-reasoning.com). Please include as much detail as possible, including the version of KeyHippo you are using, the nature of the vulnerability, and any steps to reproduce the issue.
19 |
20 | 2. **Response Time:**
21 |
22 | - You can expect an acknowledgment of your report within 24 hours of submission. Our team will investigate the issue and provide you with regular updates on the progress. We aim to provide a full assessment and remediation plan within 2 business days.
23 |
24 | 3. **What to Expect:**
25 | - If the vulnerability is accepted, we will work on a patch and release a security update as soon as possible. You will be notified once the fix is available, and your name or alias will be credited in the release notes unless you wish to remain anonymous.
26 | - If the vulnerability is declined, we will provide a detailed explanation as to why it does not meet the criteria for a security issue or why it cannot be addressed.
27 |
28 | Your participation in identifying and reporting vulnerabilities is greatly appreciated and helps us maintain the security and integrity of KeyHippo.
29 |
--------------------------------------------------------------------------------
/extension/README.md:
--------------------------------------------------------------------------------
1 | # KeyHippo PostgreSQL Extension
2 |
3 | KeyHippo extends Supabase's Row Level Security (RLS) to support API key authentication and Role-Based Access Control (RBAC) directly in Postgres.
4 |
5 | ## Installation
6 |
7 | Install the KeyHippo extension in your PostgreSQL database:
8 |
9 | ```sql
10 | select dbdev.install('keyhippo@keyhippo');
11 | create extension "keyhippo@keyhippo" version '1.2.5';
12 | ```
13 |
14 | For updates, visit the [KeyHippo extension catalog entry](https://database.dev/keyhippo/keyhippo).
15 |
16 | ## Core Features
17 |
18 | ### API Key Authentication
19 |
20 | KeyHippo enables secure API key management directly in Postgres. Each API key is hashed for storage, ensuring plaintext keys are never exposed.
21 |
22 | ### Unified RLS Policies
23 |
24 | With KeyHippo, session tokens and API keys can coexist under unified RLS policies, simplifying authentication logic.
25 |
26 | ### Role-Based Access Control (RBAC)
27 |
28 | Define fine-grained access control through groups, roles, and permissions that integrate seamlessly with your database.
29 |
30 | ### Impersonation
31 |
32 | Administrators can impersonate users for troubleshooting or support tasks without compromising security.
33 |
34 | ## Usage
35 |
36 | ### API Key Management
37 |
38 | Generate an API key for an authenticated user:
39 |
40 | ```sql
41 | SELECT * FROM keyhippo.create_api_key('Primary API Key', 'default');
42 | ```
43 |
44 | Revoke an API key:
45 |
46 | ```sql
47 | SELECT keyhippo.revoke_api_key('');
48 | ```
49 |
50 | Rotate an API key (revoke the old one, create a new one):
51 |
52 | ```sql
53 | SELECT * FROM keyhippo.rotate_api_key('');
54 | ```
55 |
56 | Full usage details can be found on [GitHub](https://github.com/integrated-reasoning/KeyHippo/blob/main/README.md).
57 |
58 | ## Integration with Supabase
59 |
60 | KeyHippo integrates with Supabase and PostgREST, enabling API key and RBAC functionality within your existing stack.
61 |
62 | ## Security Highlights
63 |
64 | - **Hashed Keys:** Only key hashes are stored, ensuring plaintext keys are unavailable after creation.
65 | - **Scoped Permissions:** API keys include scoping to restrict their usage.
66 | - **Session Interoperability:** Works alongside session-based authentication.
67 |
68 | ## Contribution
69 |
70 | Contributions are welcome. See our [Contributing Guide](https://github.com/integrated-reasoning/KeyHippo/blob/main/CONTRIBUTING.md) for details.
71 |
72 | ## License
73 |
74 | KeyHippo is distributed under the MIT license. See the [LICENSE](https://github.com/integrated-reasoning/KeyHippo/blob/main/LICENSE) file for more information.
75 |
76 | ## Support
77 |
78 | For technical issues, open a GitHub issue. For commercial support, visit [keyhippo.com](https://keyhippo.com).
79 |
--------------------------------------------------------------------------------
/extension/keyhippo--1.2.5.sql:
--------------------------------------------------------------------------------
1 | /*
2 | * Copyright (c) 2024 Integrated Reasoning, Inc.
3 | *
4 | * Permission is hereby granted, free of charge, to any person obtaining a copy
5 | * of this software and associated documentation files (the "Software"), to deal
6 | * in the Software without restriction, including without limitation the rights
7 | * to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
8 | * copies of the Software, and to permit persons to whom the Software is
9 | * furnished to do so, subject to the following conditions:
10 | *
11 | * The above copyright notice and this permission notice shall be included in all
12 | * copies or substantial portions of the Software.
13 | *
14 | * THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
15 | * IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
16 | * FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
17 | * AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
18 | * LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
19 | * OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE
20 | * SOFTWARE.
21 | *
22 | * ██╗ ██╗███████╗██╗ ██╗██╗ ██╗██╗██████╗ ██████╗ ██████╗
23 | * ██║ ██╔╝██╔════╝╚██╗ ██╔╝██║ ██║██║██╔══██╗██╔══██╗██╔═══██╗
24 | * █████╔╝ █████╗ ╚████╔╝ ███████║██║██████╔╝██████╔╝██║ ██║
25 | * ██╔═██╗ ██╔══╝ ╚██╔╝ ██╔══██║██║██╔═══╝ ██╔═══╝ ██║ ██║
26 | * ██║ ██╗███████╗ ██║ ██║ ██║██║██║ ██║ ╚██████╔╝
27 | * ╚═╝ ╚═╝╚══════╝ ╚═╝ ╚═╝ ╚═╝╚═╝╚═╝ ╚═╝ ╚═════╝
28 | */
29 | -- Create KeyHippo schema
30 | CREATE SCHEMA IF NOT EXISTS keyhippo;
31 |
32 | -- Create KeyHippo internal schema
33 | CREATE SCHEMA IF NOT EXISTS keyhippo_internal;
34 |
35 | -- Create RBAC schema
36 | CREATE SCHEMA IF NOT EXISTS keyhippo_rbac;
37 |
38 | -- Create Impersonation schema
39 | CREATE SCHEMA IF NOT EXISTS keyhippo_impersonation;
40 |
41 | -- Ensure required extensions are installed
42 | CREATE EXTENSION IF NOT EXISTS pgcrypto;
43 |
44 | CREATE EXTENSION IF NOT EXISTS pg_net;
45 |
46 | CREATE EXTENSION IF NOT EXISTS pg_cron;
47 |
48 | -- Create custom types
49 | CREATE TYPE keyhippo.app_permission AS ENUM (
50 | 'manage_groups',
51 | 'manage_roles',
52 | 'manage_permissions',
53 | 'manage_scopes',
54 | 'manage_user_attributes',
55 | 'manage_api_keys'
56 | );
57 |
58 | CREATE TYPE keyhippo.app_role AS ENUM (
59 | 'admin',
60 | 'user'
61 | );
62 |
63 | -- Create config table
64 | CREATE TABLE keyhippo_internal.config (
65 | key text PRIMARY KEY,
66 | value text NOT NULL,
67 | description text
68 | );
69 |
70 | -- Create RBAC tables
71 | CREATE TABLE keyhippo_rbac.groups (
72 | id uuid PRIMARY KEY DEFAULT gen_random_uuid (),
73 | name text UNIQUE NOT NULL,
74 | description text
75 | );
76 |
77 | CREATE TABLE keyhippo_rbac.roles (
78 | id uuid PRIMARY KEY DEFAULT gen_random_uuid (),
79 | name text NOT NULL,
80 | description text,
81 | group_id uuid NOT NULL REFERENCES keyhippo_rbac.groups (id) ON DELETE CASCADE,
82 | role_type keyhippo.app_role NOT NULL DEFAULT 'user',
83 | UNIQUE (name, group_id)
84 | );
85 |
86 | CREATE TABLE keyhippo_rbac.permissions (
87 | id uuid PRIMARY KEY DEFAULT gen_random_uuid (),
88 | name keyhippo.app_permission UNIQUE NOT NULL,
89 | description text
90 | );
91 |
92 | CREATE TABLE keyhippo_rbac.role_permissions (
93 | id bigint GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY,
94 | role_id uuid NOT NULL REFERENCES keyhippo_rbac.roles (id) ON DELETE CASCADE,
95 | permission_id uuid NOT NULL REFERENCES keyhippo_rbac.permissions (id) ON DELETE CASCADE,
96 | UNIQUE (role_id, permission_id)
97 | );
98 |
99 | CREATE TABLE keyhippo_rbac.user_group_roles (
100 | user_id uuid NOT NULL REFERENCES auth.users (id) ON DELETE CASCADE,
101 | group_id uuid NOT NULL REFERENCES keyhippo_rbac.groups (id) ON DELETE CASCADE,
102 | role_id uuid NOT NULL REFERENCES keyhippo_rbac.roles (id) ON DELETE CASCADE,
103 | PRIMARY KEY (user_id, group_id, role_id)
104 | );
105 |
106 | -- Create KeyHippo tables
107 | CREATE TABLE keyhippo.scopes (
108 | id uuid PRIMARY KEY DEFAULT gen_random_uuid (),
109 | name text NOT NULL UNIQUE,
110 | description text
111 | );
112 |
113 | CREATE TABLE keyhippo.scope_permissions (
114 | id uuid PRIMARY KEY DEFAULT gen_random_uuid (),
115 | scope_id uuid NOT NULL REFERENCES keyhippo.scopes (id),
116 | permission_id uuid NOT NULL REFERENCES keyhippo_rbac.permissions (id),
117 | UNIQUE (scope_id, permission_id)
118 | );
119 |
120 | CREATE TABLE keyhippo.api_key_metadata (
121 | id uuid PRIMARY KEY,
122 | user_id uuid NOT NULL REFERENCES auth.users (id) ON DELETE CASCADE,
123 | scope_id uuid REFERENCES keyhippo.scopes (id),
124 | description text,
125 | prefix text NOT NULL UNIQUE,
126 | created_at timestamptz NOT NULL DEFAULT now(),
127 | last_used_at timestamptz,
128 | expires_at timestamptz NOT NULL DEFAULT (now() + interval '100 years'),
129 | is_revoked boolean NOT NULL DEFAULT FALSE,
130 | claims jsonb DEFAULT '{}' ::jsonb
131 | );
132 |
133 | CREATE TABLE keyhippo.api_key_secrets (
134 | key_metadata_id uuid PRIMARY KEY REFERENCES keyhippo.api_key_metadata (id) ON DELETE CASCADE,
135 | key_hash text NOT NULL
136 | );
137 |
138 | CREATE TABLE keyhippo.audit_log (
139 | id uuid PRIMARY KEY DEFAULT gen_random_uuid (),
140 | timestamp timestamptz NOT NULL DEFAULT now(),
141 | action text NOT NULL,
142 | table_name text,
143 | data jsonb,
144 | user_id uuid,
145 | function_name text
146 | );
147 |
148 | CREATE OR REPLACE FUNCTION keyhippo.log_table_change ()
149 | RETURNS TRIGGER
150 | AS $$
151 | DECLARE
152 | v_data jsonb;
153 | v_user_id uuid;
154 | BEGIN
155 | -- Get the current user ID
156 | SELECT
157 | user_id INTO v_user_id
158 | FROM
159 | keyhippo.current_user_context ();
160 | -- Prepare the data JSON
161 | IF (TG_OP = 'DELETE') THEN
162 | v_data := jsonb_build_object('old_data', to_jsonb (OLD));
163 | ELSIF (TG_OP = 'UPDATE') THEN
164 | v_data := jsonb_build_object('old_data', to_jsonb (OLD), 'new_data', to_jsonb (NEW));
165 | ELSIF (TG_OP = 'INSERT') THEN
166 | v_data := jsonb_build_object('new_data', to_jsonb (NEW));
167 | END IF;
168 | -- Insert into audit_log
169 | INSERT INTO keyhippo.audit_log (action, table_name, data, user_id)
170 | VALUES (TG_OP, TG_TABLE_NAME, v_data, v_user_id);
171 | RETURN NEW;
172 | END;
173 | $$
174 | LANGUAGE plpgsql
175 | SET search_path = pg_temp
176 | SECURITY DEFINER;
177 |
178 | CREATE TRIGGER keyhippo_audit_rbac_groups
179 | AFTER INSERT OR UPDATE OR DELETE ON keyhippo_rbac.groups
180 | FOR EACH ROW
181 | EXECUTE FUNCTION keyhippo.log_table_change ();
182 |
183 | CREATE TRIGGER keyhippo_audit_rbac_roles
184 | AFTER INSERT OR UPDATE OR DELETE ON keyhippo_rbac.roles
185 | FOR EACH ROW
186 | EXECUTE FUNCTION keyhippo.log_table_change ();
187 |
188 | CREATE TRIGGER keyhippo_audit_rbac_permissions
189 | AFTER INSERT OR UPDATE OR DELETE ON keyhippo_rbac.permissions
190 | FOR EACH ROW
191 | EXECUTE FUNCTION keyhippo.log_table_change ();
192 |
193 | CREATE TRIGGER keyhippo_audit_rbac_role_permissions
194 | AFTER INSERT OR UPDATE OR DELETE ON keyhippo_rbac.role_permissions
195 | FOR EACH ROW
196 | EXECUTE FUNCTION keyhippo.log_table_change ();
197 |
198 | CREATE TRIGGER keyhippo_audit_rbac_user_group_roles
199 | AFTER INSERT OR UPDATE OR DELETE ON keyhippo_rbac.user_group_roles
200 | FOR EACH ROW
201 | EXECUTE FUNCTION keyhippo.log_table_change ();
202 |
203 | CREATE TRIGGER keyhippo_audit_scopes
204 | AFTER INSERT OR UPDATE OR DELETE ON keyhippo.scopes
205 | FOR EACH ROW
206 | EXECUTE FUNCTION keyhippo.log_table_change ();
207 |
208 | CREATE TRIGGER keyhippo_audit_scope_permissions
209 | AFTER INSERT OR UPDATE OR DELETE ON keyhippo.scope_permissions
210 | FOR EACH ROW
211 | EXECUTE FUNCTION keyhippo.log_table_change ();
212 |
213 | CREATE TRIGGER keyhippo_audit_api_key_metadata
214 | AFTER INSERT OR UPDATE OR DELETE ON keyhippo.api_key_metadata
215 | FOR EACH ROW
216 | EXECUTE FUNCTION keyhippo.log_table_change ();
217 |
218 | CREATE OR REPLACE FUNCTION keyhippo_internal.notify_audit_change ()
219 | RETURNS TRIGGER
220 | AS $$
221 | DECLARE
222 | v_payload jsonb;
223 | v_request_id bigint;
224 | v_endpoint text;
225 | v_installation_uuid uuid;
226 | v_enable_http_logging boolean;
227 | BEGIN
228 | SELECT
229 | value::boolean INTO v_enable_http_logging
230 | FROM
231 | keyhippo_internal.config
232 | WHERE
233 | key = 'enable_http_logging';
234 | -- Only proceed if HTTP logging is enabled
235 | IF v_enable_http_logging THEN
236 | -- Get the endpoint and configuration from the config table
237 | SELECT
238 | value INTO v_endpoint
239 | FROM
240 | keyhippo_internal.config
241 | WHERE
242 | key = 'audit_log_endpoint';
243 | SELECT
244 | value::uuid INTO v_installation_uuid
245 | FROM
246 | keyhippo_internal.config
247 | WHERE
248 | key = 'installation_uuid';
249 | -- Prepare the payload
250 | v_payload = jsonb_build_object('id', NEW.id, 'timestamp', NEW.timestamp, 'action', NEW.action, 'table_name', NEW.table_name, 'user_id', NEW.user_id, 'function_name', NEW.function_name, 'data', NEW.data, 'installation_uuid', v_installation_uuid);
251 | -- Make the HTTP request
252 | SELECT
253 | net.http_post (v_endpoint, v_payload, headers := '{"Content-Type": "application/json"}'::jsonb) INTO v_request_id;
254 | -- Log the request_id (optional, for debugging)
255 | RAISE NOTICE 'HTTP Request ID: %', v_request_id;
256 | END IF;
257 | RETURN NEW;
258 | END;
259 | $$
260 | LANGUAGE plpgsql
261 | SET search_path = pg_temp
262 | SECURITY DEFINER;
263 |
264 | -- Function to enable the audit_log_notify trigger
265 | CREATE OR REPLACE FUNCTION keyhippo_internal.enable_audit_log_notify ()
266 | RETURNS VOID
267 | LANGUAGE plpgsql
268 | SET search_path = pg_temp
269 | SECURITY DEFINER
270 | AS $$
271 | BEGIN
272 | -- Create the trigger
273 | CREATE OR REPLACE TRIGGER keyhippo_audit_log_notify
274 | AFTER INSERT ON keyhippo.audit_log
275 | FOR EACH ROW
276 | EXECUTE FUNCTION keyhippo_internal.notify_audit_change ( );
277 | -- Update the config to enable HTTP logging
278 | UPDATE
279 | keyhippo_internal.config
280 | SET
281 | value = 'true'
282 | WHERE
283 | key = 'enable_http_logging';
284 | -- If the config doesn't exist, insert it
285 | INSERT INTO keyhippo_internal.config (key, value, description)
286 | VALUES ('enable_http_logging', 'true', 'Flag to enable/disable HTTP logging')
287 | ON CONFLICT (key)
288 | DO NOTHING;
289 | END;
290 | $$;
291 |
292 | -- Function to disable the audit_log_notify trigger
293 | CREATE OR REPLACE FUNCTION keyhippo_internal.disable_audit_log_notify ()
294 | RETURNS VOID
295 | LANGUAGE plpgsql
296 | SECURITY DEFINER
297 | SET search_path = pg_temp
298 | AS $$
299 | BEGIN
300 | -- Drop the trigger if it exists
301 | DROP TRIGGER IF EXISTS keyhippo_audit_log_notify ON keyhippo.audit_log;
302 | -- Update the config to disable HTTP logging
303 | UPDATE
304 | keyhippo_internal.config
305 | SET
306 | value = 'false'
307 | WHERE
308 | key = 'enable_http_logging';
309 | -- If the config doesn't exist, insert it
310 | INSERT INTO keyhippo_internal.config (key, value, description)
311 | VALUES ('enable_http_logging', 'false', 'Flag to enable/disable HTTP logging')
312 | ON CONFLICT (key)
313 | DO NOTHING;
314 | END;
315 | $$;
316 |
317 | CREATE OR REPLACE FUNCTION keyhippo.notify_expiring_key ()
318 | RETURNS TRIGGER
319 | LANGUAGE plpgsql
320 | SECURITY DEFINER
321 | SET search_path = pg_temp
322 | AS $$
323 | DECLARE
324 | v_endpoint text;
325 | v_installation_uuid uuid;
326 | v_payload jsonb;
327 | v_enable_notifications boolean;
328 | v_notification_hours int;
329 | v_request_id bigint;
330 | v_response_status int;
331 | v_response_body text;
332 | BEGIN
333 | RAISE LOG 'notify_expiring_key triggered for key: %', NEW.id;
334 | -- Check if notifications are enabled
335 | SELECT
336 | value::boolean INTO v_enable_notifications
337 | FROM
338 | keyhippo_internal.config
339 | WHERE
340 | key = 'enable_key_expiry_notifications';
341 | IF NOT v_enable_notifications THEN
342 | RAISE LOG 'Key expiry notifications are disabled';
343 | RETURN NEW;
344 | END IF;
345 | -- Get the notification hours from config
346 | SELECT
347 | value::int INTO v_notification_hours
348 | FROM
349 | keyhippo_internal.config
350 | WHERE
351 | key = 'key_expiry_notification_hours';
352 | RAISE LOG 'Notification hours: %, Key expires at: %, Current time: %', v_notification_hours, NEW.expires_at, NOW();
353 | -- If the key is about to expire within the specified hours
354 | IF NEW.expires_at <= NOW() + (v_notification_hours || ' hours')::interval AND (OLD.expires_at IS NULL OR OLD.expires_at > NOW() + (v_notification_hours || ' hours')::interval) THEN
355 | RAISE LOG 'Key % is expiring soon, preparing notification', NEW.id;
356 | -- Get the endpoint and installation UUID from the config table
357 | SELECT
358 | value INTO v_endpoint
359 | FROM
360 | keyhippo_internal.config
361 | WHERE
362 | key = 'audit_log_endpoint';
363 | SELECT
364 | value::uuid INTO v_installation_uuid
365 | FROM
366 | keyhippo_internal.config
367 | WHERE
368 | key = 'installation_uuid';
369 | -- Prepare the payload
370 | v_payload := jsonb_build_object('event', 'expiring_key', 'installation_uuid', v_installation_uuid, 'timestamp', now(), 'expiring_key', jsonb_build_object('id', NEW.id, 'user_id', NEW.user_id, 'description', NEW.description, 'expires_at', NEW.expires_at));
371 | RAISE LOG 'Sending notification to endpoint: % with payload: %', v_endpoint, v_payload;
372 | -- Send the notification with error handling
373 | BEGIN
374 | SELECT
375 | (result).status,
376 | (result).content::text,
377 | (result).id INTO v_response_status,
378 | v_response_body,
379 | v_request_id
380 | FROM
381 | net.http_post (url := v_endpoint, body := v_payload, headers := jsonb_build_object('Content-Type', 'application/json')) AS result;
382 | RAISE LOG 'Notification sent. Request ID: %, Status: %, Response: %', v_request_id, v_response_status, v_response_body;
383 | IF v_response_status < 200 OR v_response_status >= 300 THEN
384 | RAISE EXCEPTION 'HTTP request failed with status %', v_response_status;
385 | END IF;
386 | EXCEPTION
387 | WHEN OTHERS THEN
388 | RAISE LOG 'Error sending notification: %', SQLERRM;
389 | END;
390 | -- Insert into audit_log
391 | INSERT INTO keyhippo.audit_log (action, table_name, data)
392 | VALUES ('expiring_key', TG_TABLE_NAME, v_payload);
393 | RAISE LOG 'Audit log entry created for expiring key %', NEW.id;
394 | ELSE
395 | RAISE LOG 'Key % is not expiring soon, no notification sent', NEW.id;
396 | END IF;
397 | RETURN NEW;
398 | END;
399 |
400 | $$;
401 |
402 | CREATE OR REPLACE FUNCTION keyhippo.notify_expiring_key ()
403 | RETURNS TRIGGER
404 | LANGUAGE plpgsql
405 | SECURITY DEFINER
406 | SET search_path = pg_temp
407 | AS $$
408 | DECLARE
409 | v_endpoint text;
410 | v_installation_uuid uuid;
411 | v_payload jsonb;
412 | v_enable_notifications boolean;
413 | v_notification_hours int;
414 | v_request_id bigint;
415 | BEGIN
416 | RAISE LOG 'notify_expiring_key triggered for key: %', NEW.id;
417 | -- Check if notifications are enabled
418 | SELECT
419 | value::boolean INTO v_enable_notifications
420 | FROM
421 | keyhippo_internal.config
422 | WHERE
423 | key = 'enable_key_expiry_notifications';
424 | IF NOT v_enable_notifications THEN
425 | RAISE LOG 'Key expiry notifications are disabled';
426 | RETURN NEW;
427 | END IF;
428 | -- Get the notification hours from config
429 | SELECT
430 | value::int INTO v_notification_hours
431 | FROM
432 | keyhippo_internal.config
433 | WHERE
434 | key = 'key_expiry_notification_hours';
435 | RAISE LOG 'Notification hours: %, Key expires at: %, Current time: %', v_notification_hours, NEW.expires_at, NOW();
436 | -- If the key is about to expire within the specified hours
437 | IF NEW.expires_at <= NOW() + (v_notification_hours || ' hours')::interval AND (OLD.expires_at IS NULL OR OLD.expires_at > NOW() + (v_notification_hours || ' hours')::interval) THEN
438 | RAISE LOG 'Key % is expiring soon, preparing notification', NEW.id;
439 | -- Get the endpoint and installation UUID from the config table
440 | SELECT
441 | value INTO v_endpoint
442 | FROM
443 | keyhippo_internal.config
444 | WHERE
445 | key = 'audit_log_endpoint';
446 | SELECT
447 | value::uuid INTO v_installation_uuid
448 | FROM
449 | keyhippo_internal.config
450 | WHERE
451 | key = 'installation_uuid';
452 | -- Prepare the payload
453 | v_payload := jsonb_build_object('event', 'expiring_key', 'installation_uuid', v_installation_uuid, 'timestamp', now(), 'expiring_key', jsonb_build_object('id', NEW.id, 'user_id', NEW.user_id, 'description', NEW.description, 'expires_at', NEW.expires_at));
454 | RAISE LOG 'Sending notification to endpoint: % with payload: %', v_endpoint, v_payload;
455 | -- Send the notification
456 | SELECT
457 | net.http_post (url := v_endpoint, body := v_payload, headers := jsonb_build_object('Content-Type', 'application/json')) INTO v_request_id;
458 | RAISE LOG 'Notification sent. Request ID: %', v_request_id;
459 | -- Insert into audit_log
460 | INSERT INTO keyhippo.audit_log (action, table_name, data)
461 | VALUES ('expiring_key', TG_TABLE_NAME, v_payload);
462 | RAISE LOG 'Audit log entry created for expiring key %', NEW.id;
463 | ELSE
464 | RAISE LOG 'Key % is not expiring soon, no notification sent', NEW.id;
465 | END IF;
466 | RETURN NEW;
467 | END;
468 | $$;
469 |
470 | CREATE TRIGGER keyhippo_notify_expiring_key_trigger
471 | BEFORE UPDATE OF expires_at ON keyhippo.api_key_metadata
472 | FOR EACH ROW
473 | EXECUTE FUNCTION keyhippo.notify_expiring_key ();
474 |
475 | CREATE OR REPLACE FUNCTION keyhippo.update_expiring_keys ()
476 | RETURNS VOID
477 | LANGUAGE plpgsql
478 | SECURITY DEFINER
479 | SET search_path = pg_temp
480 | AS $$
481 | BEGIN
482 | -- Update expires_at for keys that are about to expire
483 | UPDATE
484 | keyhippo.api_key_metadata
485 | SET
486 | expires_at = expires_at
487 | WHERE
488 | expires_at <= NOW() + INTERVAL '1 day'
489 | AND is_revoked = FALSE;
490 | END;
491 | $$;
492 |
493 | SELECT
494 | cron.schedule ('0 * * * *', $$
495 | SELECT
496 | keyhippo.update_expiring_keys ();
497 |
498 | $$);
499 |
500 | CREATE OR REPLACE FUNCTION keyhippo.is_authorized (target_resource regclass, required_permission text)
501 | RETURNS boolean
502 | AS $$
503 | DECLARE
504 | v_user_id uuid;
505 | v_user_id_text text;
506 | v_is_authorized boolean;
507 | BEGIN
508 | -- Get the current user ID from the JWT claim
509 | v_user_id_text := current_setting('request.jwt.claim.sub', TRUE);
510 | -- If no user ID is found or it's an empty string, return false
511 | IF v_user_id_text IS NULL OR v_user_id_text = '' THEN
512 | RETURN FALSE;
513 | END IF;
514 | -- Try to cast the user ID to UUID
515 | BEGIN
516 | v_user_id := v_user_id_text::uuid;
517 | EXCEPTION
518 | WHEN invalid_text_representation THEN
519 | -- If casting fails, return false
520 | RETURN FALSE;
521 | END;
522 | -- Check if the user has the required permission
523 | SELECT
524 | EXISTS (
525 | SELECT
526 | 1
527 | FROM
528 | keyhippo_rbac.user_group_roles ugr
529 | JOIN keyhippo_rbac.role_permissions rp ON ugr.role_id = rp.role_id
530 | JOIN keyhippo_rbac.permissions p ON rp.permission_id = p.id
531 | WHERE
532 | ugr.user_id = v_user_id
533 | AND p.name = required_permission) INTO v_is_authorized;
534 | RETURN v_is_authorized;
535 | END;
536 |
537 | $$
538 | LANGUAGE plpgsql
539 | SET search_path = pg_temp
540 | SECURITY DEFINER;
541 |
542 | -- Create Impersonation table
543 | CREATE TABLE IF NOT EXISTS keyhippo_impersonation.impersonation_state (
544 | impersonated_user_id uuid PRIMARY KEY,
545 | original_role name NOT NULL,
546 | impersonation_time timestamp with time zone DEFAULT CURRENT_TIMESTAMP
547 | );
548 |
549 | -- Create indexes
550 | CREATE INDEX idx_api_key_metadata_user_id ON keyhippo.api_key_metadata (user_id);
551 |
552 | CREATE INDEX idx_user_group_roles_user_id ON keyhippo_rbac.user_group_roles (user_id);
553 |
554 | CREATE INDEX idx_roles_name ON keyhippo_rbac.roles (name);
555 |
556 | CREATE INDEX idx_api_key_metadata_scope_id ON keyhippo.api_key_metadata (scope_id);
557 |
558 | CREATE INDEX idx_scope_permissions_permission_id ON keyhippo.scope_permissions (permission_id);
559 |
560 | CREATE INDEX idx_role_permissions_permission_id ON keyhippo_rbac.role_permissions (permission_id);
561 |
562 | CREATE INDEX idx_roles_group_id ON keyhippo_rbac.roles (group_id);
563 |
564 | CREATE INDEX idx_user_group_roles_group_id ON keyhippo_rbac.user_group_roles (group_id);
565 |
566 | CREATE INDEX idx_user_group_roles_role_id ON keyhippo_rbac.user_group_roles (role_id);
567 |
568 | -- Authorization function
569 | CREATE OR REPLACE FUNCTION keyhippo.authorize (requested_permission keyhippo.app_permission)
570 | RETURNS boolean
571 | AS $$
572 | DECLARE
573 | bind_permissions int;
574 | user_role keyhippo.app_role;
575 | BEGIN
576 | -- Fetch user role from the JWT
577 | SELECT
578 | (current_setting('request.jwt.claims', TRUE)::jsonb ->> 'user_role')::keyhippo.app_role INTO user_role;
579 | SELECT
580 | COUNT(*) INTO bind_permissions
581 | FROM
582 | keyhippo_rbac.role_permissions rp
583 | JOIN keyhippo_rbac.roles r ON rp.role_id = r.id
584 | JOIN keyhippo_rbac.permissions p ON rp.permission_id = p.id
585 | WHERE
586 | p.name = requested_permission
587 | AND r.role_type = user_role;
588 | RETURN bind_permissions > 0;
589 | END;
590 | $$
591 | LANGUAGE plpgsql
592 | STABLE
593 | SECURITY DEFINER SET search_path = '';
594 |
595 | -- Function to create an API key
596 | CREATE OR REPLACE FUNCTION keyhippo.create_api_key (key_description text, scope_name text DEFAULT NULL)
597 | RETURNS TABLE (
598 | api_key text,
599 | api_key_id uuid)
600 | LANGUAGE plpgsql
601 | SECURITY DEFINER
602 | SET search_path = keyhippo
603 | AS $$
604 | DECLARE
605 | random_bytes bytea;
606 | new_api_key text;
607 | new_api_key_id uuid;
608 | authenticated_user_id uuid;
609 | prefix text;
610 | scope_id uuid;
611 | BEGIN
612 | -- Get the authenticated user ID
613 | SELECT
614 | user_id INTO authenticated_user_id
615 | FROM
616 | keyhippo.current_user_context ();
617 | -- Check if the user is authenticated
618 | IF authenticated_user_id IS NULL THEN
619 | RAISE EXCEPTION 'Unauthorized: User not authenticated';
620 | END IF;
621 | -- Validate key description
622 | IF LENGTH(key_description) > 255 OR key_description !~ '^[a-zA-Z0-9_ \-]*$' THEN
623 | RAISE EXCEPTION '[KeyHippo] Invalid key description';
624 | END IF;
625 | -- Handle scope
626 | IF scope_name IS NULL THEN
627 | scope_id := NULL;
628 | ELSE
629 | SELECT
630 | id INTO scope_id
631 | FROM
632 | keyhippo.scopes
633 | WHERE
634 | name = scope_name;
635 | IF scope_id IS NULL THEN
636 | RAISE EXCEPTION '[KeyHippo] Invalid scope';
637 | END IF;
638 | END IF;
639 | -- Generate API key
640 | random_bytes := extensions.gen_random_bytes(64);
641 | new_api_key := encode(extensions.digest(random_bytes, 'sha512'), 'hex');
642 | new_api_key_id := gen_random_uuid ();
643 | prefix := encode(extensions.gen_random_bytes(24), 'base64');
644 | -- Insert metadata
645 | INSERT INTO keyhippo.api_key_metadata (id, user_id, description, prefix, scope_id)
646 | VALUES (new_api_key_id, authenticated_user_id, key_description, prefix, scope_id);
647 | -- Store hash
648 | INSERT INTO keyhippo.api_key_secrets (key_metadata_id, key_hash)
649 | VALUES (new_api_key_id, encode(extensions.digest(new_api_key, 'sha512'), 'hex'));
650 | RETURN QUERY
651 | SELECT
652 | prefix || new_api_key,
653 | new_api_key_id;
654 | END;
655 | $$;
656 |
657 | -- Function to verify an API key
658 | CREATE OR REPLACE FUNCTION keyhippo.verify_api_key (api_key text)
659 | RETURNS TABLE (
660 | user_id uuid,
661 | scope_id uuid,
662 | permissions text[])
663 | LANGUAGE plpgsql
664 | SECURITY DEFINER
665 | SET search_path = keyhippo,
666 | keyhippo_rbac
667 | AS $$
668 | DECLARE
669 | metadata_id uuid;
670 | prefix_part text;
671 | key_part text;
672 | stored_key_hash text;
673 | computed_hash text;
674 | v_user_id uuid;
675 | v_scope_id uuid;
676 | BEGIN
677 | -- Split and verify API key
678 | IF LENGTH(api_key) <= 128 THEN
679 | RAISE EXCEPTION 'Invalid API key format';
680 | END IF;
681 | prefix_part :=
682 | LEFT (api_key,
683 | LENGTH(api_key) - 128);
684 | key_part :=
685 | RIGHT (api_key,
686 | 128);
687 | -- Retrieve metadata
688 | SELECT
689 | m.id,
690 | m.user_id,
691 | m.scope_id INTO metadata_id,
692 | v_user_id,
693 | v_scope_id
694 | FROM
695 | keyhippo.api_key_metadata m
696 | WHERE
697 | m.prefix = prefix_part
698 | AND NOT m.is_revoked
699 | AND m.expires_at > NOW();
700 | IF metadata_id IS NULL THEN
701 | RETURN;
702 | END IF;
703 | -- Verify key hash
704 | SELECT
705 | key_hash INTO stored_key_hash
706 | FROM
707 | keyhippo.api_key_secrets
708 | WHERE
709 | key_metadata_id = metadata_id;
710 | computed_hash := encode(extensions.digest(key_part, 'sha512'), 'hex');
711 | IF computed_hash = stored_key_hash THEN
712 | -- Check if the transaction is not read-only before performing UPDATE
713 | IF current_setting('transaction_read_only', TRUE) = 'off' THEN
714 | -- Update last_used_at if necessary
715 | UPDATE
716 | keyhippo.api_key_metadata
717 | SET
718 | last_used_at = NOW()
719 | WHERE
720 | id = metadata_id
721 | AND (last_used_at IS NULL
722 | OR last_used_at < NOW() - INTERVAL '1 minute');
723 | ELSE
724 | -- Log that the UPDATE was skipped due to read-only transaction
725 | RAISE LOG 'verify_api_key() - Skipping last_used_at update for api_key_metadata_id: % due to read-only transaction.', metadata_id;
726 | END IF;
727 | -- Return user_id, scope_id, and permissions
728 | RETURN QUERY
729 | SELECT
730 | v_user_id,
731 | v_scope_id,
732 | ARRAY_AGG(DISTINCT p.name::text)
733 | FROM
734 | keyhippo.api_key_metadata akm
735 | LEFT JOIN keyhippo.scope_permissions sp ON akm.scope_id = sp.scope_id
736 | LEFT JOIN keyhippo_rbac.permissions p ON sp.permission_id = p.id
737 | WHERE
738 | akm.id = metadata_id
739 | GROUP BY
740 | v_user_id,
741 | v_scope_id;
742 | END IF;
743 | END;
744 | $$;
745 |
746 | -- Function to get user_id and scope from API key or JWT
747 | CREATE OR REPLACE FUNCTION keyhippo.current_user_context ()
748 | RETURNS TABLE (
749 | user_id uuid,
750 | scope_id uuid,
751 | permissions text[])
752 | LANGUAGE plpgsql
753 | SECURITY DEFINER
754 | SET search_path = keyhippo_impersonation,
755 | keyhippo_rbac,
756 | keyhippo
757 | AS $$
758 | DECLARE
759 | api_key text;
760 | v_user_id uuid;
761 | v_scope_id uuid;
762 | v_permissions text[];
763 | BEGIN
764 | -- First try API key authentication
765 | api_key := current_setting('request.headers', TRUE)::json ->> 'x-api-key';
766 | IF api_key IS NOT NULL THEN
767 | SELECT
768 | vak.user_id,
769 | vak.scope_id,
770 | vak.permissions INTO v_user_id,
771 | v_scope_id,
772 | v_permissions
773 | FROM
774 | keyhippo.verify_api_key (api_key) vak;
775 | IF v_user_id IS NOT NULL THEN
776 | RETURN QUERY
777 | SELECT
778 | v_user_id,
779 | v_scope_id,
780 | v_permissions;
781 | RETURN;
782 | END IF;
783 | END IF;
784 | -- Then try auth.uid()
785 | v_user_id := auth.uid ();
786 | -- If that fails, check for impersonation
787 | IF v_user_id IS NULL THEN
788 | SELECT
789 | impersonated_user_id INTO v_user_id
790 | FROM
791 | impersonation_state
792 | WHERE
793 | original_role = 'postgres'
794 | ORDER BY
795 | impersonation_time DESC
796 | LIMIT 1;
797 | END IF;
798 | -- If we have a user_id through any method, get their permissions
799 | IF v_user_id IS NOT NULL THEN
800 | SELECT
801 | ARRAY_AGG(DISTINCT p.name::text) INTO v_permissions
802 | FROM
803 | keyhippo_rbac.user_group_roles ugr
804 | JOIN keyhippo_rbac.role_permissions rp ON ugr.role_id = rp.role_id
805 | JOIN keyhippo_rbac.permissions p ON rp.permission_id = p.id
806 | WHERE
807 | ugr.user_id = v_user_id;
808 | RETURN QUERY
809 | SELECT
810 | v_user_id,
811 | NULL::uuid,
812 | COALESCE(v_permissions, ARRAY[]::text[]);
813 | END IF;
814 | END;
815 | $$;
816 |
817 | -- Function to revoke an API key
818 | CREATE OR REPLACE FUNCTION keyhippo.revoke_api_key (api_key_id uuid)
819 | RETURNS boolean
820 | LANGUAGE plpgsql
821 | SECURITY DEFINER
822 | SET search_path = keyhippo
823 | AS $$
824 | DECLARE
825 | success boolean;
826 | c_user_id uuid;
827 | c_scope_id uuid;
828 | BEGIN
829 | SELECT
830 | user_id,
831 | scope_id INTO c_user_id,
832 | c_scope_id
833 | FROM
834 | keyhippo.current_user_context ();
835 | IF c_user_id IS NULL THEN
836 | RAISE EXCEPTION 'Unauthorized';
837 | END IF;
838 | -- Update to set is_revoked only if it's not already revoked
839 | -- and the user has permission (either they created the key or it's within their scope)
840 | UPDATE
841 | keyhippo.api_key_metadata
842 | SET
843 | is_revoked = TRUE
844 | WHERE
845 | id = api_key_id
846 | AND ((user_id = c_user_id
847 | AND scope_id IS NULL)
848 | OR (scope_id = c_scope_id))
849 | AND is_revoked = FALSE
850 | RETURNING
851 | TRUE INTO success;
852 | IF success THEN
853 | -- Delete the secret hash to ensure it's no longer usable
854 | DELETE FROM keyhippo.api_key_secrets
855 | WHERE key_metadata_id = api_key_id;
856 | END IF;
857 | RETURN COALESCE(success, FALSE);
858 | END;
859 | $$;
860 |
861 | -- Function to rotate an API key
862 | CREATE OR REPLACE FUNCTION keyhippo.rotate_api_key (old_api_key_id uuid)
863 | RETURNS TABLE (
864 | new_api_key text,
865 | new_api_key_id uuid)
866 | LANGUAGE plpgsql
867 | SECURITY DEFINER
868 | SET search_path = keyhippo
869 | AS $$
870 | DECLARE
871 | c_user_id uuid;
872 | c_scope_id uuid;
873 | key_description text;
874 | key_scope_id uuid;
875 | BEGIN
876 | SELECT
877 | user_id,
878 | scope_id INTO c_user_id,
879 | c_scope_id
880 | FROM
881 | keyhippo.current_user_context ();
882 | IF c_user_id IS NULL THEN
883 | RAISE EXCEPTION 'Unauthorized: User not authenticated';
884 | END IF;
885 | -- Retrieve the description and scope, and ensure the key is not revoked
886 | SELECT
887 | ak.description,
888 | ak.scope_id INTO key_description,
889 | key_scope_id
890 | FROM
891 | keyhippo.api_key_metadata ak
892 | WHERE
893 | ak.id = old_api_key_id
894 | AND ((ak.user_id = c_user_id
895 | AND ak.scope_id IS NULL)
896 | OR (ak.scope_id = c_scope_id))
897 | AND ak.is_revoked = FALSE;
898 | IF key_description IS NULL THEN
899 | RAISE EXCEPTION 'Unauthorized: Invalid or inactive API key';
900 | END IF;
901 | -- Revoke the old key
902 | PERFORM
903 | keyhippo.revoke_api_key (old_api_key_id);
904 | -- Create a new key with the same description and scope
905 | RETURN QUERY
906 | SELECT
907 | *
908 | FROM
909 | keyhippo.create_api_key (key_description, (
910 | SELECT
911 | name
912 | FROM keyhippo.scopes
913 | WHERE
914 | id = key_scope_id));
915 | END;
916 | $$;
917 |
918 | -- RBAC management functions
919 | CREATE OR REPLACE FUNCTION keyhippo_rbac.create_group (p_name text, p_description text)
920 | RETURNS uuid
921 | LANGUAGE plpgsql
922 | SECURITY INVOKER
923 | SET search_path = keyhippo_rbac
924 | AS $$
925 | DECLARE
926 | v_group_id uuid;
927 | BEGIN
928 | INSERT INTO keyhippo_rbac.groups (name, description)
929 | VALUES (p_name, p_description)
930 | RETURNING
931 | id INTO v_group_id;
932 | RETURN v_group_id;
933 | END;
934 | $$;
935 |
936 | CREATE OR REPLACE FUNCTION keyhippo_rbac.create_role (p_name text, p_description text, p_group_id uuid, p_role_type keyhippo.app_role)
937 | RETURNS uuid
938 | LANGUAGE plpgsql
939 | SECURITY INVOKER
940 | SET search_path = keyhippo_rbac
941 | AS $$
942 | DECLARE
943 | v_role_id uuid;
944 | BEGIN
945 | INSERT INTO keyhippo_rbac.roles (name, description, group_id, role_type)
946 | VALUES (p_name, p_description, p_group_id, p_role_type)
947 | RETURNING
948 | id INTO v_role_id;
949 | RETURN v_role_id;
950 | END;
951 | $$;
952 |
953 | CREATE OR REPLACE FUNCTION keyhippo_rbac.assign_role_to_user (p_user_id uuid, p_group_id uuid, p_role_id uuid)
954 | RETURNS VOID
955 | LANGUAGE plpgsql
956 | SECURITY INVOKER
957 | SET search_path = keyhippo_rbac
958 | AS $$
959 | BEGIN
960 | INSERT INTO keyhippo_rbac.user_group_roles (user_id, group_id, role_id)
961 | VALUES (p_user_id, p_group_id, p_role_id)
962 | ON CONFLICT (user_id, group_id, role_id)
963 | DO NOTHING;
964 | END;
965 | $$;
966 |
967 | CREATE OR REPLACE FUNCTION keyhippo_rbac.assign_permission_to_role (p_role_id uuid, p_permission_name keyhippo.app_permission)
968 | RETURNS VOID
969 | LANGUAGE plpgsql
970 | SECURITY INVOKER
971 | SET search_path = keyhippo_rbac
972 | AS $$
973 | DECLARE
974 | v_permission_id uuid;
975 | BEGIN
976 | SELECT
977 | id INTO v_permission_id
978 | FROM
979 | keyhippo_rbac.permissions
980 | WHERE
981 | name = p_permission_name;
982 | IF v_permission_id IS NULL THEN
983 | RAISE EXCEPTION 'Permission % not found', p_permission_name;
984 | END IF;
985 | INSERT INTO keyhippo_rbac.role_permissions (role_id, permission_id)
986 | VALUES (p_role_id, v_permission_id)
987 | ON CONFLICT (role_id, permission_id)
988 | DO NOTHING;
989 | END;
990 | $$;
991 |
992 | -- Impersonation functions
993 | CREATE OR REPLACE PROCEDURE keyhippo_impersonation.login_as_user (user_id uuid)
994 | LANGUAGE plpgsql
995 | SECURITY INVOKER
996 | SET search_path = keyhippo_impersonation
997 | AS $$
998 | DECLARE
999 | auth_user auth.users%ROWTYPE;
1000 | CURRENT_ROLE NAME;
1001 | BEGIN
1002 | -- Ensure only postgres user can call this procedure
1003 | IF CURRENT_USER != 'postgres' THEN
1004 | RAISE EXCEPTION 'Unauthorized';
1005 | END IF;
1006 | -- Get current role before impersonation
1007 | SELECT
1008 | CURRENT_ROLE INTO CURRENT_ROLE;
1009 | -- Fetch the user based on UUID
1010 | SELECT
1011 | * INTO auth_user
1012 | FROM
1013 | auth.users
1014 | WHERE
1015 | id = user_id;
1016 | IF NOT FOUND THEN
1017 | RAISE EXCEPTION 'User with ID % does not exist', user_id;
1018 | END IF;
1019 | -- Set JWT claims using parameterized queries
1020 | PERFORM
1021 | set_config('request.jwt.claim.sub', auth_user.id::text, TRUE);
1022 | PERFORM
1023 | set_config('request.jwt.claim.role', COALESCE(auth_user.role, 'authenticated'), TRUE);
1024 | IF auth_user.email IS NOT NULL THEN
1025 | PERFORM
1026 | set_config('request.jwt.claim.email', auth_user.email, TRUE);
1027 | END IF;
1028 | IF auth_user.raw_app_meta_data IS NOT NULL THEN
1029 | PERFORM
1030 | set_config('request.jwt.claims', JSON_STRIP_NULLS (JSON_BUILD_OBJECT('app_metadata', auth_user.raw_app_meta_data))::text, TRUE);
1031 | END IF;
1032 | -- Track impersonation state
1033 | INSERT INTO keyhippo_impersonation.impersonation_state (impersonated_user_id, original_role)
1034 | VALUES (user_id, CURRENT_ROLE)
1035 | ON CONFLICT (impersonated_user_id)
1036 | DO UPDATE SET
1037 | original_role = EXCLUDED.original_role, impersonation_time = CURRENT_TIMESTAMP;
1038 | -- Set role
1039 | EXECUTE FORMAT('SET ROLE %I', COALESCE(auth_user.role, 'authenticated'));
1040 | -- Set session timeout
1041 | PERFORM
1042 | set_config('session.impersonation_expires', (NOW() + INTERVAL '1 hour')::text, TRUE);
1043 | -- Log the impersonation for debugging
1044 | RAISE NOTICE 'Impersonation successful. User ID: %, Role: %, JWT Claims: %', auth_user.id, COALESCE(auth_user.role, 'authenticated'), current_setting('request.jwt.claims', TRUE);
1045 | END;
1046 | $$;
1047 |
1048 | CREATE OR REPLACE PROCEDURE keyhippo_impersonation.login_as_anon ()
1049 | LANGUAGE plpgsql
1050 | SECURITY INVOKER
1051 | SET search_path = keyhippo_impersonation
1052 | AS $$
1053 | DECLARE
1054 | CURRENT_ROLE NAME;
1055 | ANON_USER_ID uuid := '00000000-0000-0000-0000-000000000000'::uuid;
1056 | BEGIN
1057 | -- Ensure only postgres user can call this procedure
1058 | IF CURRENT_USER != 'postgres' THEN
1059 | RAISE EXCEPTION 'Unauthorized';
1060 | END IF;
1061 | -- Get current role before impersonation
1062 | SELECT
1063 | CURRENT_ROLE INTO CURRENT_ROLE;
1064 | -- Set JWT claims for anonymous login
1065 | PERFORM
1066 | set_config('request.jwt.claim.sub', 'anon', TRUE);
1067 | PERFORM
1068 | set_config('request.jwt.claim.role', 'anon', TRUE);
1069 | PERFORM
1070 | set_config('request.jwt.claim.email', '', TRUE);
1071 | PERFORM
1072 | set_config('request.jwt.claims', json_build_object('sub', 'anon', 'role', 'anon')::text, TRUE);
1073 | -- Track impersonation state
1074 | DELETE FROM keyhippo_impersonation.impersonation_state
1075 | WHERE impersonated_user_id = ANON_USER_ID;
1076 | INSERT INTO keyhippo_impersonation.impersonation_state (impersonated_user_id, original_role)
1077 | VALUES (ANON_USER_ID, CURRENT_ROLE);
1078 | -- Set role to anon
1079 | SET ROLE anon;
1080 | -- Set session timeout
1081 | PERFORM
1082 | set_config('session.impersonation_expires', (NOW() + INTERVAL '1 hour')::text, TRUE);
1083 | RAISE NOTICE 'Anonymous login successful. Impersonated user ID: %, Original role: %, Session expires: %', ANON_USER_ID, CURRENT_ROLE, current_setting('session.impersonation_expires', TRUE);
1084 | END;
1085 | $$;
1086 |
1087 | CREATE OR REPLACE FUNCTION keyhippo_impersonation.get_and_cleanup_impersonation ()
1088 | RETURNS text
1089 | LANGUAGE plpgsql
1090 | SECURITY DEFINER
1091 | SET search_path = keyhippo_impersonation
1092 | AS $$
1093 | DECLARE
1094 | v_original_role text;
1095 | BEGIN
1096 | -- Get the original role
1097 | SELECT
1098 | original_role::text INTO v_original_role
1099 | FROM
1100 | impersonation_state
1101 | WHERE
1102 | original_role = 'postgres'
1103 | ORDER BY
1104 | impersonation_time DESC
1105 | LIMIT 1;
1106 | IF v_original_role IS NULL THEN
1107 | RAISE EXCEPTION 'Current user is not being impersonated';
1108 | END IF;
1109 | -- Clean up state
1110 | DELETE FROM impersonation_state
1111 | WHERE original_role = 'postgres';
1112 | RETURN v_original_role;
1113 | END;
1114 | $$;
1115 |
1116 | CREATE OR REPLACE PROCEDURE keyhippo_impersonation.logout ()
1117 | LANGUAGE plpgsql
1118 | SECURITY INVOKER
1119 | SET search_path = keyhippo_impersonation
1120 | AS $$
1121 | DECLARE
1122 | v_original_role text;
1123 | BEGIN
1124 | IF current_setting('session.impersonation_expires', TRUE) IS NULL THEN
1125 | RAISE EXCEPTION 'Not in an impersonation session';
1126 | END IF;
1127 | -- Get original role and cleanup state
1128 | v_original_role := keyhippo_impersonation.get_and_cleanup_impersonation ();
1129 | -- Clear JWT claims
1130 | PERFORM
1131 | set_config('request.jwt.claim.sub', '', TRUE);
1132 | PERFORM
1133 | set_config('request.jwt.claim.role', '', TRUE);
1134 | PERFORM
1135 | set_config('request.jwt.claim.email', '', TRUE);
1136 | PERFORM
1137 | set_config('request.jwt.claims', '', TRUE);
1138 | -- Reset role
1139 | EXECUTE FORMAT('SET ROLE %I', v_original_role);
1140 | -- Clear session
1141 | PERFORM
1142 | set_config('session.impersonation_expires', '', TRUE);
1143 | RAISE NOTICE 'Logout successful. Original role: %', v_original_role;
1144 | END;
1145 | $$;
1146 |
1147 | CREATE OR REPLACE FUNCTION keyhippo_impersonation.generate_random_user_data ()
1148 | RETURNS TABLE (
1149 | id uuid,
1150 | email text,
1151 | encrypted_password text,
1152 | email_confirmed_at timestamptz,
1153 | last_sign_in_at timestamptz,
1154 | raw_app_meta_data jsonb,
1155 | raw_user_meta_data jsonb,
1156 | is_super_admin boolean,
1157 | created_at timestamptz,
1158 | updated_at timestamptz,
1159 | phone text,
1160 | phone_confirmed_at timestamptz,
1161 | confirmation_token text,
1162 | confirmation_sent_at timestamptz,
1163 | recovery_token text,
1164 | recovery_sent_at timestamptz,
1165 | email_change_token_new text,
1166 | email_change text,
1167 | email_change_sent_at timestamptz,
1168 | aud text,
1169 | banned_until timestamptz,
1170 | ROLE text
1171 | )
1172 | AS $$
1173 | DECLARE
1174 | random_string text;
1175 | BEGIN
1176 | id := gen_random_uuid ();
1177 | random_string := encode(gen_random_bytes(8), 'hex');
1178 | email := random_string || '@example.com';
1179 | encrypted_password := crypt('password', gen_salt('bf'));
1180 | email_confirmed_at := now() - (random() * interval '90 days');
1181 | last_sign_in_at := now() - (random() * interval '30 days');
1182 | raw_app_meta_data := jsonb_build_object('provider', 'email', 'providers', ARRAY['email']);
1183 | raw_user_meta_data := jsonb_build_object('name', 'Test User ' || random_string);
1184 | is_super_admin := FALSE;
1185 | created_at := now() - (random() * interval '180 days');
1186 | updated_at := created_at + (random() * (now() - created_at));
1187 | phone := '+1' || lpad(floor(random() * 10000000000)::text, 10, '0');
1188 | phone_confirmed_at := NULL;
1189 | confirmation_token := encode(gen_random_bytes(32), 'hex');
1190 | confirmation_sent_at := created_at;
1191 | recovery_token := NULL;
1192 | recovery_sent_at := NULL;
1193 | email_change_token_new := NULL;
1194 | email_change := NULL;
1195 | email_change_sent_at := NULL;
1196 | aud := 'authenticated';
1197 | banned_until := NULL;
1198 | RETURN NEXT;
1199 | END;
1200 | $$
1201 | LANGUAGE plpgsql
1202 | SECURITY INVOKER SET search_path = keyhippo_impersonation VOLATILE;
1203 |
1204 | -- Function to create a new auth.user for testing
1205 | CREATE OR REPLACE FUNCTION keyhippo_impersonation.generate_new_user ()
1206 | RETURNS uuid
1207 | AS $$
1208 | DECLARE
1209 | new_user_id uuid;
1210 | BEGIN
1211 | INSERT INTO auth.users (id, email, encrypted_password, email_confirmed_at, last_sign_in_at, raw_app_meta_data, raw_user_meta_data, is_super_admin, created_at, updated_at, phone, phone_confirmed_at, confirmation_token, confirmation_sent_at, recovery_token, recovery_sent_at, email_change_token_new, email_change, email_change_sent_at, aud, banned_until, ROLE)
1212 | SELECT
1213 | *
1214 | FROM
1215 | keyhippo_impersonation.generate_random_user_data ()
1216 | RETURNING
1217 | id INTO new_user_id;
1218 | -- The default role assignment should be handled by the trigger automatically
1219 | RETURN new_user_id;
1220 | END;
1221 | $$
1222 | LANGUAGE plpgsql
1223 | VOLATILE SET search_path = keyhippo_impersonation
1224 | SECURITY DEFINER;
1225 |
1226 | -- Function to update claims
1227 | CREATE OR REPLACE FUNCTION keyhippo.update_key_claims (key_id uuid, new_claims jsonb)
1228 | RETURNS void
1229 | LANGUAGE plpgsql
1230 | SECURITY DEFINER
1231 | SET search_path = keyhippo
1232 | AS $$
1233 | DECLARE
1234 | c_user_id uuid;
1235 | c_scope_id uuid;
1236 | BEGIN
1237 | -- Get current user context
1238 | SELECT
1239 | user_id,
1240 | scope_id INTO c_user_id,
1241 | c_scope_id
1242 | FROM
1243 | keyhippo.current_user_context ();
1244 | IF c_user_id IS NULL THEN
1245 | RAISE EXCEPTION 'Unauthorized';
1246 | END IF;
1247 | -- Update claims if user has permission
1248 | UPDATE
1249 | keyhippo.api_key_metadata
1250 | SET
1251 | claims = new_claims
1252 | WHERE
1253 | id = key_id
1254 | AND ((user_id = c_user_id
1255 | AND scope_id IS NULL)
1256 | OR (scope_id = c_scope_id));
1257 | END;
1258 | $$;
1259 |
1260 | -- Function to get key_data
1261 | CREATE OR REPLACE FUNCTION keyhippo.key_data ()
1262 | RETURNS jsonb
1263 | LANGUAGE plpgsql
1264 | SECURITY DEFINER
1265 | SET search_path = public, private, keyhippo
1266 | AS $$
1267 | DECLARE
1268 | api_key text;
1269 | key_metadata jsonb;
1270 | BEGIN
1271 | -- Get API key from request header
1272 | api_key := current_setting('request.headers', TRUE)::json ->> 'x-api-key';
1273 | -- If no API key, return null
1274 | IF api_key IS NULL THEN
1275 | RETURN NULL;
1276 | END IF;
1277 | -- Get key metadata including claims
1278 | SELECT
1279 | jsonb_build_object('id', akm.id, 'description', akm.description, 'claims', akm.claims) INTO key_metadata
1280 | FROM
1281 | keyhippo.api_key_metadata akm
1282 | WHERE
1283 | akm.prefix =
1284 | LEFT (api_key, LENGTH(api_key) - 128)
1285 | AND NOT akm.is_revoked
1286 | AND akm.expires_at > NOW();
1287 | RETURN key_metadata;
1288 | END;
1289 | $$;
1290 |
1291 | -- RLS Policies
1292 | ALTER TABLE keyhippo_internal.config ENABLE ROW LEVEL SECURITY;
1293 |
1294 | ALTER TABLE keyhippo_rbac.groups ENABLE ROW LEVEL SECURITY;
1295 |
1296 | ALTER TABLE keyhippo_rbac.roles ENABLE ROW LEVEL SECURITY;
1297 |
1298 | ALTER TABLE keyhippo_rbac.permissions ENABLE ROW LEVEL SECURITY;
1299 |
1300 | ALTER TABLE keyhippo_rbac.role_permissions ENABLE ROW LEVEL SECURITY;
1301 |
1302 | ALTER TABLE keyhippo_rbac.user_group_roles ENABLE ROW LEVEL SECURITY;
1303 |
1304 | ALTER TABLE keyhippo.scopes ENABLE ROW LEVEL SECURITY;
1305 |
1306 | ALTER TABLE keyhippo.scope_permissions ENABLE ROW LEVEL SECURITY;
1307 |
1308 | ALTER TABLE keyhippo.api_key_metadata ENABLE ROW LEVEL SECURITY;
1309 |
1310 | ALTER TABLE keyhippo.api_key_secrets ENABLE ROW LEVEL SECURITY;
1311 |
1312 | ALTER TABLE keyhippo_impersonation.impersonation_state ENABLE ROW LEVEL SECURITY;
1313 |
1314 | -- Create RLS policies
1315 | CREATE POLICY config_access_policy ON keyhippo_internal.config
1316 | USING (CURRENT_USER = 'postgres');
1317 |
1318 | CREATE POLICY groups_access_policy ON keyhippo_rbac.groups
1319 | FOR ALL TO authenticated
1320 | USING (keyhippo.authorize ('manage_groups'))
1321 | WITH CHECK (keyhippo.authorize ('manage_groups'));
1322 |
1323 | CREATE POLICY roles_access_policy ON keyhippo_rbac.roles
1324 | FOR ALL TO authenticated
1325 | USING (keyhippo.authorize ('manage_roles'))
1326 | WITH CHECK (keyhippo.authorize ('manage_roles'));
1327 |
1328 | CREATE POLICY permissions_access_policy ON keyhippo_rbac.permissions
1329 | FOR ALL TO authenticated
1330 | USING (keyhippo.authorize ('manage_permissions'))
1331 | WITH CHECK (keyhippo.authorize ('manage_permissions'));
1332 |
1333 | CREATE POLICY role_permissions_access_policy ON keyhippo_rbac.role_permissions
1334 | FOR ALL TO authenticated
1335 | USING (keyhippo.authorize ('manage_roles'))
1336 | WITH CHECK (keyhippo.authorize ('manage_roles'));
1337 |
1338 | CREATE POLICY user_group_roles_access_policy ON keyhippo_rbac.user_group_roles
1339 | FOR ALL TO authenticated
1340 | USING (keyhippo.authorize ('manage_roles'))
1341 | WITH CHECK (keyhippo.authorize ('manage_roles'));
1342 |
1343 | CREATE POLICY scopes_access_policy ON keyhippo.scopes
1344 | FOR ALL TO authenticated
1345 | USING (keyhippo.authorize ('manage_scopes'))
1346 | WITH CHECK (keyhippo.authorize ('manage_scopes'));
1347 |
1348 | CREATE POLICY scope_permissions_access_policy ON keyhippo.scope_permissions
1349 | FOR ALL TO authenticated
1350 | USING (keyhippo.authorize ('manage_scopes'))
1351 | WITH CHECK (keyhippo.authorize ('manage_scopes'));
1352 |
1353 | CREATE POLICY api_key_metadata_access_policy ON keyhippo.api_key_metadata
1354 | FOR ALL TO authenticated
1355 | USING (user_id = (
1356 | SELECT
1357 | auth.uid ())
1358 | OR keyhippo.authorize ('manage_api_keys'));
1359 |
1360 | CREATE POLICY api_key_secrets_no_access_policy ON keyhippo.api_key_secrets
1361 | FOR ALL TO authenticated
1362 | USING (FALSE);
1363 |
1364 | CREATE POLICY impersonation_state_access ON keyhippo_impersonation.impersonation_state
1365 | USING (CURRENT_USER = 'postgres'
1366 | OR (CURRENT_USER = 'anon' AND impersonated_user_id = '00000000-0000-0000-0000-000000000000'::uuid)
1367 | OR impersonated_user_id::text = CURRENT_USER);
1368 |
1369 | -- Grants and Permissions
1370 | GRANT USAGE ON SCHEMA keyhippo TO authenticated, anon;
1371 |
1372 | GRANT USAGE ON SCHEMA keyhippo_internal TO postgres;
1373 |
1374 | GRANT ALL PRIVILEGES ON keyhippo_internal.config TO postgres;
1375 |
1376 | GRANT USAGE ON SCHEMA keyhippo_rbac TO authenticated, anon;
1377 |
1378 | -- Grant EXECUTE on functions
1379 | GRANT EXECUTE ON FUNCTION keyhippo.create_api_key (text, text) TO authenticated;
1380 |
1381 | GRANT EXECUTE ON FUNCTION keyhippo.verify_api_key (text) TO authenticated;
1382 |
1383 | GRANT EXECUTE ON FUNCTION keyhippo.current_user_context () TO authenticated;
1384 |
1385 | GRANT EXECUTE ON FUNCTION keyhippo.revoke_api_key (uuid) TO authenticated;
1386 |
1387 | GRANT EXECUTE ON FUNCTION keyhippo.rotate_api_key (uuid) TO authenticated;
1388 |
1389 | GRANT EXECUTE ON FUNCTION keyhippo.authorize (keyhippo.app_permission) TO authenticated, anon;
1390 |
1391 | GRANT EXECUTE ON FUNCTION keyhippo_rbac.create_group (text, text) TO authenticated;
1392 |
1393 | GRANT EXECUTE ON FUNCTION keyhippo_rbac.create_role (text, text, uuid, keyhippo.app_role) TO authenticated;
1394 |
1395 | GRANT EXECUTE ON FUNCTION keyhippo_rbac.assign_role_to_user (uuid, uuid, uuid) TO authenticated;
1396 |
1397 | GRANT EXECUTE ON FUNCTION keyhippo_rbac.assign_permission_to_role (uuid, keyhippo.app_permission) TO authenticated;
1398 |
1399 | GRANT EXECUTE ON FUNCTION keyhippo.key_data () TO authenticated, authenticator, anon;
1400 |
1401 | GRANT EXECUTE ON FUNCTION keyhippo.update_key_claims (uuid, jsonb) TO authenticated;
1402 |
1403 | -- Grant SELECT, INSERT, UPDATE, DELETE on tables
1404 | GRANT SELECT, INSERT, UPDATE, DELETE ON ALL TABLES IN SCHEMA keyhippo TO authenticated;
1405 |
1406 | GRANT SELECT, INSERT, UPDATE, DELETE ON ALL TABLES IN SCHEMA keyhippo_rbac TO authenticated;
1407 |
1408 | -- Revoke all permissions on api_key_secrets from authenticated users
1409 | REVOKE ALL ON TABLE keyhippo.api_key_secrets FROM authenticated;
1410 |
1411 | -- Grant necessary permissions to service_role
1412 | GRANT ALL ON ALL TABLES IN SCHEMA keyhippo TO service_role;
1413 |
1414 | GRANT ALL ON ALL TABLES IN SCHEMA keyhippo_rbac TO service_role;
1415 |
1416 | -- Grant necessary permissions for impersonation
1417 | GRANT USAGE ON SCHEMA keyhippo_impersonation TO postgres, authenticated, anon;
1418 |
1419 | GRANT ALL ON TABLE keyhippo_impersonation.impersonation_state TO postgres;
1420 |
1421 | GRANT EXECUTE ON PROCEDURE keyhippo_impersonation.login_as_user (UUID) TO postgres;
1422 |
1423 | GRANT EXECUTE ON PROCEDURE keyhippo_impersonation.login_as_anon () TO postgres;
1424 |
1425 | GRANT EXECUTE ON FUNCTION keyhippo_impersonation.get_and_cleanup_impersonation () TO authenticated, anon;
1426 |
1427 | GRANT EXECUTE ON PROCEDURE keyhippo_impersonation.logout () TO authenticated, anon;
1428 |
1429 | GRANT SELECT, DELETE ON keyhippo_impersonation.impersonation_state TO anon;
1430 |
1431 | -- Function to send initial installation notification
1432 | CREATE OR REPLACE FUNCTION keyhippo_internal.send_installation_notification ()
1433 | RETURNS VOID
1434 | LANGUAGE plpgsql
1435 | SECURITY DEFINER
1436 | SET search_path = keyhippo_internal
1437 | AS $$
1438 | DECLARE
1439 | v_installation_uuid uuid;
1440 | v_endpoint text;
1441 | v_payload jsonb;
1442 | v_should_send boolean;
1443 | BEGIN
1444 | -- Get installation UUID and endpoint from config
1445 | SELECT
1446 | value::uuid INTO v_installation_uuid
1447 | FROM
1448 | keyhippo_internal.config
1449 | WHERE
1450 | key = 'installation_uuid';
1451 | SELECT
1452 | value INTO v_endpoint
1453 | FROM
1454 | keyhippo_internal.config
1455 | WHERE
1456 | key = 'audit_log_endpoint';
1457 | -- Check if we should send the notification
1458 | SELECT
1459 | value::boolean INTO v_should_send
1460 | FROM
1461 | keyhippo_internal.config
1462 | WHERE
1463 | key = 'send_installation_notification';
1464 | IF v_should_send THEN
1465 | -- Prepare the payload
1466 | v_payload := jsonb_build_object('event', 'installation', 'installation_uuid', v_installation_uuid, 'timestamp', now());
1467 | -- Send the notification
1468 | PERFORM
1469 | net.http_post (url := v_endpoint, body := v_payload, headers := jsonb_build_object('Content-Type', 'application/json'));
1470 | -- Update the config to prevent future notifications
1471 | UPDATE
1472 | keyhippo_internal.config
1473 | SET
1474 | value = 'false'
1475 | WHERE
1476 | key = 'send_installation_notification';
1477 | END IF;
1478 | END;
1479 | $$;
1480 |
1481 | -- Initialization function
1482 | CREATE OR REPLACE FUNCTION keyhippo.initialize_keyhippo ()
1483 | RETURNS VOID
1484 | LANGUAGE plpgsql
1485 | SECURITY DEFINER
1486 | SET search_path = keyhippo, keyhippo_internal, keyhippo_rbac
1487 | AS $$
1488 | DECLARE
1489 | admin_group_id uuid;
1490 | admin_role_id uuid;
1491 | installation_uuid uuid;
1492 | user_group_id uuid;
1493 | user_role_id uuid;
1494 | BEGIN
1495 | -- Add configurations for key expiry notifications
1496 | INSERT INTO keyhippo_internal.config (key, value, description)
1497 | VALUES ('key_expiry_notification_hours', '72', 'Number of hours before key expiry to send notification'),
1498 | ('enable_key_expiry_notifications', 'true', 'Flag to enable/disable key expiry notifications')
1499 | ON CONFLICT (key)
1500 | DO UPDATE SET
1501 | value = EXCLUDED.value, description = EXCLUDED.description;
1502 | -- Upsert the default value for the audit log endpoint
1503 | INSERT INTO keyhippo_internal.config (key, value, description)
1504 | VALUES ('audit_log_endpoint', 'https://app.keyhippo.com/api/ingest', 'Endpoint for sending audit log notifications')
1505 | ON CONFLICT (key)
1506 | DO UPDATE SET
1507 | value = EXCLUDED.value, description = EXCLUDED.description;
1508 | -- Generate and store installation UUID
1509 | installation_uuid := gen_random_uuid ();
1510 | INSERT INTO keyhippo_internal.config (key, value, description)
1511 | VALUES ('installation_uuid', installation_uuid::text, 'Unique identifier for this KeyHippo installation')
1512 | ON CONFLICT (key)
1513 | DO UPDATE SET
1514 | value = EXCLUDED.value, description = EXCLUDED.description;
1515 | -- Set HTTP logging to false by default
1516 | INSERT INTO keyhippo_internal.config (key, value, description)
1517 | VALUES ('enable_http_logging', 'false', 'Flag to enable/disable HTTP logging')
1518 | ON CONFLICT (key)
1519 | DO UPDATE SET
1520 | value = EXCLUDED.value, description = EXCLUDED.description;
1521 | -- Create default groups
1522 | INSERT INTO keyhippo_rbac.groups (name, description)
1523 | VALUES ('Admin Group', 'Group for administrators'),
1524 | ('User Group', 'Group for regular users')
1525 | ON CONFLICT (name)
1526 | DO NOTHING;
1527 | -- Fetch group IDs
1528 | SELECT
1529 | id INTO admin_group_id
1530 | FROM
1531 | keyhippo_rbac.groups
1532 | WHERE
1533 | name = 'Admin Group';
1534 | SELECT
1535 | id INTO user_group_id
1536 | FROM
1537 | keyhippo_rbac.groups
1538 | WHERE
1539 | name = 'User Group';
1540 | -- Create default roles
1541 | INSERT INTO keyhippo_rbac.roles (name, description, group_id, role_type)
1542 | VALUES ('Admin', 'Administrator role', admin_group_id, 'admin'),
1543 | ('User', 'Regular user role', user_group_id, 'user')
1544 | ON CONFLICT (name, group_id)
1545 | DO NOTHING;
1546 | -- Fetch role IDs
1547 | SELECT
1548 | id INTO admin_role_id
1549 | FROM
1550 | keyhippo_rbac.roles
1551 | WHERE
1552 | name = 'Admin'
1553 | AND group_id = admin_group_id;
1554 | SELECT
1555 | id INTO user_role_id
1556 | FROM
1557 | keyhippo_rbac.roles
1558 | WHERE
1559 | name = 'User'
1560 | AND group_id = user_group_id;
1561 | -- Create default permissions
1562 | INSERT INTO keyhippo_rbac.permissions (name, description)
1563 | VALUES ('manage_groups', 'Manage groups'),
1564 | ('manage_roles', 'Manage roles'),
1565 | ('manage_permissions', 'Manage permissions'),
1566 | ('manage_scopes', 'Manage scopes'),
1567 | ('manage_api_keys', 'Manage API keys'),
1568 | ('manage_user_attributes', 'Manage user attributes')
1569 | ON CONFLICT (name)
1570 | DO NOTHING;
1571 | -- Assign all permissions to the Admin role
1572 | INSERT INTO keyhippo_rbac.role_permissions (role_id, permission_id)
1573 | SELECT
1574 | admin_role_id,
1575 | id
1576 | FROM
1577 | keyhippo_rbac.permissions
1578 | ON CONFLICT (role_id,
1579 | permission_id)
1580 | DO NOTHING;
1581 | -- Assign manage_api_keys permission to the User role
1582 | INSERT INTO keyhippo_rbac.role_permissions (role_id, permission_id)
1583 | SELECT
1584 | user_role_id,
1585 | id
1586 | FROM
1587 | keyhippo_rbac.permissions
1588 | WHERE
1589 | name = 'manage_api_keys'
1590 | ON CONFLICT (role_id,
1591 | permission_id)
1592 | DO NOTHING;
1593 | -- Create a default scope
1594 | INSERT INTO keyhippo.scopes (name, description)
1595 | VALUES ('default', 'Default scope for API keys')
1596 | ON CONFLICT (name)
1597 | DO NOTHING;
1598 | -- Set up the send_installation_notification config if it doesn't exist
1599 | INSERT INTO keyhippo_internal.config (key, value, description)
1600 | VALUES ('send_installation_notification', 'true', 'Flag to send initial installation notification')
1601 | ON CONFLICT (key)
1602 | DO NOTHING;
1603 | -- This ensures we don't overwrite an existing value
1604 | -- Send the installation notification only if the config is set to true
1605 | IF (
1606 | SELECT
1607 | value::boolean
1608 | FROM
1609 | keyhippo_internal.config
1610 | WHERE
1611 | key = 'send_installation_notification') THEN
1612 | PERFORM
1613 | keyhippo_internal.send_installation_notification ();
1614 | END IF;
1615 | END;
1616 | $$;
1617 |
1618 | -- Function to assign the default user role to a new user
1619 | CREATE OR REPLACE FUNCTION keyhippo.assign_default_role ()
1620 | RETURNS TRIGGER
1621 | LANGUAGE plpgsql
1622 | SECURITY DEFINER
1623 | SET search_path = keyhippo_rbac
1624 | AS $$
1625 | DECLARE
1626 | user_group_id uuid;
1627 | user_role_id uuid;
1628 | BEGIN
1629 | SELECT
1630 | id INTO user_group_id
1631 | FROM
1632 | keyhippo_rbac.groups
1633 | WHERE
1634 | name = 'User Group';
1635 | SELECT
1636 | id INTO user_role_id
1637 | FROM
1638 | keyhippo_rbac.roles
1639 | WHERE
1640 | name = 'User'
1641 | AND group_id = user_group_id;
1642 | INSERT INTO keyhippo_rbac.user_group_roles (user_id, group_id, role_id)
1643 | VALUES (NEW.id, user_group_id, user_role_id)
1644 | ON CONFLICT (user_id, group_id, role_id)
1645 | DO NOTHING;
1646 | RETURN NEW;
1647 | END;
1648 | $$;
1649 |
1650 | -- Create a trigger to assign the default role to new users
1651 | CREATE TRIGGER keyhippo_assign_default_role_trigger
1652 | AFTER INSERT ON auth.users
1653 | FOR EACH ROW
1654 | EXECUTE FUNCTION keyhippo.assign_default_role ();
1655 |
1656 | -- Function to initialize KeyHippo for an existing Supabase project
1657 | CREATE OR REPLACE FUNCTION keyhippo.initialize_existing_project ()
1658 | RETURNS VOID
1659 | LANGUAGE plpgsql
1660 | SECURITY DEFINER
1661 | SET search_path = keyhippo, keyhippo_rbac
1662 | AS $$
1663 | DECLARE
1664 | user_record RECORD;
1665 | user_group_id uuid;
1666 | user_role_id uuid;
1667 | BEGIN
1668 | -- Initialize KeyHippo
1669 | PERFORM
1670 | keyhippo.initialize_keyhippo ();
1671 | -- Get the User Group and Role IDs
1672 | SELECT
1673 | id INTO user_group_id
1674 | FROM
1675 | keyhippo_rbac.groups
1676 | WHERE
1677 | name = 'User Group';
1678 | SELECT
1679 | id INTO user_role_id
1680 | FROM
1681 | keyhippo_rbac.roles
1682 | WHERE
1683 | name = 'User'
1684 | AND group_id = user_group_id;
1685 | -- Assign the default role to all existing users
1686 | FOR user_record IN
1687 | SELECT
1688 | id
1689 | FROM
1690 | auth.users LOOP
1691 | INSERT INTO keyhippo_rbac.user_group_roles (user_id, group_id, role_id)
1692 | VALUES (user_record.id, user_group_id, user_role_id)
1693 | ON CONFLICT (user_id, group_id, role_id)
1694 | DO NOTHING;
1695 | END LOOP;
1696 | END;
1697 | $$;
1698 |
1699 | -- Run the initialization function
1700 | SELECT
1701 | keyhippo.initialize_keyhippo ();
1702 |
1703 | CREATE OR REPLACE FUNCTION keyhippo.check_request ()
1704 | RETURNS void
1705 | LANGUAGE plpgsql
1706 | SECURITY DEFINER
1707 | SET search_path = pg_temp
1708 | AS $$
1709 | DECLARE
1710 | ctx record;
1711 | BEGIN
1712 | IF CURRENT_ROLE <> 'anon' THEN
1713 | -- If not using the anon role, allow the request to pass
1714 | RETURN;
1715 | END IF;
1716 | -- Check if the provided API key is valid
1717 | SELECT
1718 | * INTO ctx
1719 | FROM
1720 | keyhippo.current_user_context ();
1721 | IF ctx.user_id IS NULL THEN
1722 | -- No valid API key found, raise an error
1723 | RAISE EXCEPTION 'No registered API key found in x-api-key header.';
1724 | END IF;
1725 | END;
1726 | $$;
1727 |
1728 | -- Set as pre-request check for PostgREST
1729 | ALTER ROLE authenticator SET pgrst.db_pre_request = 'keyhippo.check_request';
1730 |
1731 | -- Grant necessary permissions for check_request
1732 | GRANT ALL ON FUNCTION keyhippo.check_request () TO authenticated, service_role, anon;
1733 |
1734 | -- Notify PostgREST to reload configuration
1735 | NOTIFY pgrst,
1736 | 'reload config';
1737 |
--------------------------------------------------------------------------------
/extension/keyhippo.control:
--------------------------------------------------------------------------------
1 | # keyhippo extension
2 | comment = 'RLS-compatible API keys for PostgreSQL'
3 | default_version = '1.2.5'
4 | module_pathname = '$libdir/keyhippo/extension'
5 | relocatable = true
6 |
--------------------------------------------------------------------------------
/flake.lock:
--------------------------------------------------------------------------------
1 | {
2 | "nodes": {
3 | "flake-utils": {
4 | "locked": {
5 | "lastModified": 1652776076,
6 | "narHash": "sha256-gzTw/v1vj4dOVbpBSJX4J0DwUR6LIyXo7/SuuTJp1kM=",
7 | "owner": "numtide",
8 | "repo": "flake-utils",
9 | "rev": "04c1b180862888302ddfb2e3ad9eaa63afc60cf8",
10 | "type": "github"
11 | },
12 | "original": {
13 | "owner": "numtide",
14 | "ref": "v1.0.0",
15 | "repo": "flake-utils",
16 | "type": "github"
17 | }
18 | },
19 | "gitignore": {
20 | "inputs": {
21 | "nixpkgs": ["nixpkgs"]
22 | },
23 | "locked": {
24 | "lastModified": 1709087332,
25 | "narHash": "sha256-HG2cCnktfHsKV0s4XW83gU3F57gaTljL9KNSuG6bnQs=",
26 | "owner": "hercules-ci",
27 | "repo": "gitignore.nix",
28 | "rev": "637db329424fd7e46cf4185293b9cc8c88c95394",
29 | "type": "github"
30 | },
31 | "original": {
32 | "owner": "hercules-ci",
33 | "repo": "gitignore.nix",
34 | "type": "github"
35 | }
36 | },
37 | "nixpkgs": {
38 | "locked": {
39 | "lastModified": 1723743279,
40 | "narHash": "sha256-dMWeZbhe+EQyhz5DlvGCl5yGgjLumVVb646ljXxk8rY=",
41 | "owner": "NixOS",
42 | "repo": "nixpkgs",
43 | "rev": "e88a41614f835a544a15421b75cedc4ec45cb3d7",
44 | "type": "github"
45 | },
46 | "original": {
47 | "owner": "NixOS",
48 | "ref": "master",
49 | "repo": "nixpkgs",
50 | "type": "github"
51 | }
52 | },
53 | "root": {
54 | "inputs": {
55 | "flake-utils": "flake-utils",
56 | "gitignore": "gitignore",
57 | "nixpkgs": "nixpkgs"
58 | }
59 | }
60 | },
61 | "root": "root",
62 | "version": 7
63 | }
64 |
--------------------------------------------------------------------------------
/flake.nix:
--------------------------------------------------------------------------------
1 | {
2 | description = "Issue API keys for your Supabase app with one line of SQL";
3 |
4 | inputs = {
5 | nixpkgs.url = "github:NixOS/nixpkgs/master";
6 | flake-utils.url = "github:numtide/flake-utils/v1.0.0";
7 | gitignore = {
8 | url = "github:hercules-ci/gitignore.nix";
9 | inputs.nixpkgs.follows = "nixpkgs";
10 | };
11 | };
12 |
13 | outputs = inputs: with inputs;
14 | flake-utils.lib.eachDefaultSystem (system:
15 | let
16 | pkgs = import nixpkgs {
17 | inherit system;
18 | overlays = [ ];
19 | };
20 | buildInputs = with pkgs; [
21 | supabase-cli
22 | ];
23 | in
24 | rec
25 | {
26 | devShell = pkgs.mkShell {
27 | inherit buildInputs;
28 | };
29 | }
30 | );
31 | }
32 |
--------------------------------------------------------------------------------
/supabase/.gitignore:
--------------------------------------------------------------------------------
1 | # Supabase
2 | .branches
3 | .temp
4 | .env
5 |
--------------------------------------------------------------------------------
/supabase/config.toml:
--------------------------------------------------------------------------------
1 | # A string used to distinguish different Supabase projects on the same host. Defaults to the
2 | # working directory name when running `supabase init`.
3 | project_id = "client"
4 |
5 | [api]
6 | enabled = true
7 | # Port to use for the API URL.
8 | port = 54321
9 | # Schemas to expose in your API. Tables, views and stored procedures in this schema will get API
10 | # endpoints. `public` is always included.
11 | schemas = ["public", "graphql_public", "keyhippo", "keyhippo_rbac", "keyhippo_impersonation"]
12 | # Extra schemas to add to the search_path of every request. `public` is always included.
13 | extra_search_path = ["public", "extensions"]
14 | # The maximum number of rows returns from a view, table, or stored procedure. Limits payload size
15 | # for accidental or malicious requests.
16 | max_rows = 1000
17 |
18 | [api.tls]
19 | enabled = false
20 |
21 | [db]
22 | # Port to use for the local database URL.
23 | port = 54322
24 | # Port used by db diff command to initialize the shadow database.
25 | shadow_port = 54320
26 | # The database major version to use. This has to be the same as your remote database's. Run `SHOW
27 | # server_version;` on the remote database to check.
28 | major_version = 15
29 |
30 | [db.pooler]
31 | enabled = false
32 | # Port to use for the local connection pooler.
33 | port = 54329
34 | # Specifies when a server connection can be reused by other clients.
35 | # Configure one of the supported pooler modes: `transaction`, `session`.
36 | pool_mode = "transaction"
37 | # How many server connections to allow per user/database pair.
38 | default_pool_size = 20
39 | # Maximum number of client connections allowed.
40 | max_client_conn = 100
41 |
42 | [realtime]
43 | enabled = true
44 | # Bind realtime via either IPv4 or IPv6. (default: IPv4)
45 | # ip_version = "IPv6"
46 | # The maximum length in bytes of HTTP request headers. (default: 4096)
47 | # max_header_length = 4096
48 |
49 | [studio]
50 | enabled = true
51 | # Port to use for Supabase Studio.
52 | port = 54323
53 | # External URL of the API server that frontend connects to.
54 | api_url = "http://127.0.0.1"
55 | # OpenAI API Key to use for Supabase AI in the Supabase Studio.
56 | openai_api_key = "env(OPENAI_API_KEY)"
57 |
58 | # Email testing server. Emails sent with the local dev setup are not actually sent - rather, they
59 | # are monitored, and you can view the emails that would have been sent from the web interface.
60 | [inbucket]
61 | enabled = true
62 | # Port to use for the email testing server web interface.
63 | port = 54324
64 | # Uncomment to expose additional ports for testing user applications that send emails.
65 | # smtp_port = 54325
66 | # pop3_port = 54326
67 |
68 | [storage]
69 | enabled = true
70 | # The maximum file size allowed (e.g. "5MB", "500KB").
71 | file_size_limit = "50MiB"
72 |
73 | [storage.image_transformation]
74 | enabled = true
75 |
76 | # Uncomment to configure local storage buckets
77 | # [storage.buckets.images]
78 | # public = false
79 | # file_size_limit = "50MiB"
80 | # allowed_mime_types = ["image/png", "image/jpeg"]
81 | # objects_path = "./images"
82 |
83 | [auth]
84 | enabled = true
85 | # The base URL of your website. Used as an allow-list for redirects and for constructing URLs used
86 | # in emails.
87 | site_url = "http://127.0.0.1:3000"
88 | # A list of *exact* URLs that auth providers are permitted to redirect to post authentication.
89 | additional_redirect_urls = ["https://127.0.0.1:3000"]
90 | # How long tokens are valid for, in seconds. Defaults to 3600 (1 hour), maximum 604,800 (1 week).
91 | jwt_expiry = 3600
92 | # If disabled, the refresh token will never expire.
93 | enable_refresh_token_rotation = true
94 | # Allows refresh tokens to be reused after expiry, up to the specified interval in seconds.
95 | # Requires enable_refresh_token_rotation = true.
96 | refresh_token_reuse_interval = 10
97 | # Allow/disallow new user signups to your project.
98 | enable_signup = true
99 | # Allow/disallow anonymous sign-ins to your project.
100 | enable_anonymous_sign_ins = true
101 | # Allow/disallow testing manual linking of accounts
102 | enable_manual_linking = false
103 |
104 | [auth.email]
105 | # Allow/disallow new user signups via email to your project.
106 | enable_signup = true
107 | # If enabled, a user will be required to confirm any email change on both the old, and new email
108 | # addresses. If disabled, only the new email is required to confirm.
109 | double_confirm_changes = true
110 | # If enabled, users need to confirm their email address before signing in.
111 | enable_confirmations = false
112 | # Controls the minimum amount of time that must pass before sending another signup confirmation or password reset email.
113 | max_frequency = "1s"
114 |
115 | # Use a production-ready SMTP server
116 | # [auth.email.smtp]
117 | # host = "smtp.sendgrid.net"
118 | # port = 587
119 | # user = "apikey"
120 | # pass = "env(SENDGRID_API_KEY)"
121 | # admin_email = "admin@email.com"
122 | # sender_name = "Admin"
123 |
124 | # Uncomment to customize email template
125 | # [auth.email.template.invite]
126 | # subject = "You have been invited"
127 | # content_path = "./supabase/templates/invite.html"
128 |
129 | [auth.sms]
130 | # Allow/disallow new user signups via SMS to your project.
131 | enable_signup = true
132 | # If enabled, users need to confirm their phone number before signing in.
133 | enable_confirmations = false
134 | # Template for sending OTP to users
135 | template = "Your code is {{ .Code }} ."
136 | # Controls the minimum amount of time that must pass before sending another sms otp.
137 | max_frequency = "5s"
138 |
139 | # Use pre-defined map of phone number to OTP for testing.
140 | # [auth.sms.test_otp]
141 | # 4152127777 = "123456"
142 |
143 | # Configure logged in session timeouts.
144 | # [auth.sessions]
145 | # Force log out after the specified duration.
146 | # timebox = "24h"
147 | # Force log out if the user has been inactive longer than the specified duration.
148 | # inactivity_timeout = "8h"
149 |
150 | # This hook runs before a token is issued and allows you to add additional claims based on the authentication method used.
151 | # [auth.hook.custom_access_token]
152 | # enabled = true
153 | # uri = "pg-functions:////"
154 |
155 | # Configure one of the supported SMS providers: `twilio`, `twilio_verify`, `messagebird`, `textlocal`, `vonage`.
156 | [auth.sms.twilio]
157 | enabled = false
158 | account_sid = ""
159 | message_service_sid = ""
160 | # DO NOT commit your Twilio auth token to git. Use environment variable substitution instead:
161 | auth_token = "env(SUPABASE_AUTH_SMS_TWILIO_AUTH_TOKEN)"
162 |
163 | [auth.mfa]
164 | # Control how many MFA factors can be enrolled at once per user.
165 | max_enrolled_factors = 10
166 |
167 | # Control use of MFA via App Authenticator (TOTP)
168 | [auth.mfa.totp]
169 | enroll_enabled = true
170 | verify_enabled = true
171 |
172 | # Configure Multi-factor-authentication via Phone Messaging
173 | # [auth.mfa.phone]
174 | # enroll_enabled = true
175 | # verify_enabled = true
176 | # otp_length = 6
177 | # template = "Your code is {{ .Code }} ."
178 | # max_frequency = "10s"
179 |
180 | # Use an external OAuth provider. The full list of providers are: `apple`, `azure`, `bitbucket`,
181 | # `discord`, `facebook`, `github`, `gitlab`, `google`, `keycloak`, `linkedin_oidc`, `notion`, `twitch`,
182 | # `twitter`, `slack`, `spotify`, `workos`, `zoom`.
183 | [auth.external.apple]
184 | enabled = false
185 | client_id = ""
186 | # DO NOT commit your OAuth provider secret to git. Use environment variable substitution instead:
187 | secret = "env(SUPABASE_AUTH_EXTERNAL_APPLE_SECRET)"
188 | # Overrides the default auth redirectUrl.
189 | redirect_uri = ""
190 | # Overrides the default auth provider URL. Used to support self-hosted gitlab, single-tenant Azure,
191 | # or any other third-party OIDC providers.
192 | url = ""
193 | # If enabled, the nonce check will be skipped. Required for local sign in with Google auth.
194 | skip_nonce_check = false
195 |
196 | # Use Firebase Auth as a third-party provider alongside Supabase Auth.
197 | [auth.third_party.firebase]
198 | enabled = false
199 | # project_id = "my-firebase-project"
200 |
201 | # Use Auth0 as a third-party provider alongside Supabase Auth.
202 | [auth.third_party.auth0]
203 | enabled = false
204 | # tenant = "my-auth0-tenant"
205 | # tenant_region = "us"
206 |
207 | # Use AWS Cognito (Amplify) as a third-party provider alongside Supabase Auth.
208 | [auth.third_party.aws_cognito]
209 | enabled = false
210 | # user_pool_id = "my-user-pool-id"
211 | # user_pool_region = "us-east-1"
212 |
213 | [edge_runtime]
214 | enabled = true
215 | # Configure one of the supported request policies: `oneshot`, `per_worker`.
216 | # Use `oneshot` for hot reload, or `per_worker` for load testing.
217 | policy = "oneshot"
218 | inspector_port = 8083
219 |
220 | [analytics]
221 | enabled = true
222 | port = 54327
223 | # Configure one of the supported backends: `postgres`, `bigquery`.
224 | backend = "postgres"
225 |
226 | # Experimental features may be deprecated any time
227 | [experimental]
228 | # Configures Postgres storage engine to use OrioleDB (S3)
229 | orioledb_version = ""
230 | # Configures S3 bucket URL, eg. .s3-.amazonaws.com
231 | s3_host = "env(S3_HOST)"
232 | # Configures S3 bucket region, eg. us-east-1
233 | s3_region = "env(S3_REGION)"
234 | # Configures AWS_ACCESS_KEY_ID for S3 bucket
235 | s3_access_key = "env(S3_ACCESS_KEY)"
236 | # Configures AWS_SECRET_ACCESS_KEY for S3 bucket
237 | s3_secret_key = "env(S3_SECRET_KEY)"
238 |
--------------------------------------------------------------------------------
/supabase/migrations/20240816164943_remote_schema.sql:
--------------------------------------------------------------------------------
1 | SET statement_timeout = 0;
2 |
3 | SET lock_timeout = 0;
4 |
5 | SET idle_in_transaction_session_timeout = 0;
6 |
7 | SET client_encoding = 'UTF8';
8 |
9 | SET standard_conforming_strings = ON;
10 |
11 | SELECT
12 | pg_catalog.set_config('search_path', '', FALSE);
13 |
14 | SET check_function_bodies = FALSE;
15 |
16 | SET xmloption = content;
17 |
18 | SET client_min_messages = warning;
19 |
20 | SET row_security = OFF;
21 |
22 | COMMENT ON SCHEMA "public" IS 'standard public schema';
23 |
24 | CREATE EXTENSION IF NOT EXISTS "pg_graphql" WITH SCHEMA "graphql";
25 |
26 | CREATE EXTENSION IF NOT EXISTS "pg_stat_statements" WITH SCHEMA "extensions";
27 |
28 | CREATE EXTENSION IF NOT EXISTS "pgcrypto" WITH SCHEMA "extensions";
29 |
30 | CREATE EXTENSION IF NOT EXISTS "pgjwt" WITH SCHEMA "extensions";
31 |
32 | CREATE EXTENSION IF NOT EXISTS "supabase_vault" WITH SCHEMA "vault";
33 |
34 | CREATE EXTENSION IF NOT EXISTS "uuid-ossp" WITH SCHEMA "extensions";
35 |
36 | ALTER PUBLICATION "supabase_realtime" OWNER TO "postgres";
37 |
38 | GRANT USAGE ON SCHEMA "public" TO "postgres";
39 |
40 | GRANT USAGE ON SCHEMA "public" TO "anon";
41 |
42 | GRANT USAGE ON SCHEMA "public" TO "authenticated";
43 |
44 | GRANT USAGE ON SCHEMA "public" TO "service_role";
45 |
46 | ALTER DEFAULT PRIVILEGES FOR ROLE "postgres" IN SCHEMA "public" GRANT ALL ON SEQUENCES TO "postgres";
47 |
48 | ALTER DEFAULT PRIVILEGES FOR ROLE "postgres" IN SCHEMA "public" GRANT ALL ON SEQUENCES TO "anon";
49 |
50 | ALTER DEFAULT PRIVILEGES FOR ROLE "postgres" IN SCHEMA "public" GRANT ALL ON SEQUENCES TO "authenticated";
51 |
52 | ALTER DEFAULT PRIVILEGES FOR ROLE "postgres" IN SCHEMA "public" GRANT ALL ON SEQUENCES TO "service_role";
53 |
54 | ALTER DEFAULT PRIVILEGES FOR ROLE "postgres" IN SCHEMA "public" GRANT ALL ON FUNCTIONS TO "postgres";
55 |
56 | ALTER DEFAULT PRIVILEGES FOR ROLE "postgres" IN SCHEMA "public" GRANT ALL ON FUNCTIONS TO "anon";
57 |
58 | ALTER DEFAULT PRIVILEGES FOR ROLE "postgres" IN SCHEMA "public" GRANT ALL ON FUNCTIONS TO "authenticated";
59 |
60 | ALTER DEFAULT PRIVILEGES FOR ROLE "postgres" IN SCHEMA "public" GRANT ALL ON FUNCTIONS TO "service_role";
61 |
62 | ALTER DEFAULT PRIVILEGES FOR ROLE "postgres" IN SCHEMA "public" GRANT ALL ON TABLES TO "postgres";
63 |
64 | ALTER DEFAULT PRIVILEGES FOR ROLE "postgres" IN SCHEMA "public" GRANT ALL ON TABLES TO "anon";
65 |
66 | ALTER DEFAULT PRIVILEGES FOR ROLE "postgres" IN SCHEMA "public" GRANT ALL ON TABLES TO "authenticated";
67 |
68 | ALTER DEFAULT PRIVILEGES FOR ROLE "postgres" IN SCHEMA "public" GRANT ALL ON TABLES TO "service_role";
69 |
70 | RESET ALL;
71 |
--------------------------------------------------------------------------------
/supabase/seed.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/integrated-reasoning/KeyHippo/f335bc455d5248fc3b597c460bada32747c83366/supabase/seed.sql
--------------------------------------------------------------------------------
/tests/bench.sql:
--------------------------------------------------------------------------------
1 | BEGIN;
2 | SET search_path TO keyhippo, keyhippo_rbac, public, auth;
3 | -- Create test users and set up authentication
4 | DO $$
5 | DECLARE
6 | user1_id uuid := gen_random_uuid ();
7 | user2_id uuid := gen_random_uuid ();
8 | admin_group_id uuid;
9 | admin_role_id uuid;
10 | BEGIN
11 | -- Insert users with explicit IDs
12 | INSERT INTO auth.users (id, email)
13 | VALUES (user1_id, 'user1@example.com'),
14 | (user2_id, 'user2@example.com');
15 | -- Store user IDs as settings for later use
16 | PERFORM
17 | set_config('test.user1_id', user1_id::text, TRUE);
18 | PERFORM
19 | set_config('test.user2_id', user2_id::text, TRUE);
20 | -- Initialize KeyHippo (this creates default groups and roles)
21 | PERFORM
22 | keyhippo.initialize_keyhippo ();
23 | -- Get the Admin Group and Role IDs
24 | SELECT
25 | id INTO admin_group_id
26 | FROM
27 | keyhippo_rbac.groups
28 | WHERE
29 | name = 'Admin Group';
30 | SELECT
31 | id INTO admin_role_id
32 | FROM
33 | keyhippo_rbac.roles
34 | WHERE
35 | name = 'Admin'
36 | AND group_id = admin_group_id;
37 | -- Assign admin role to user1
38 | INSERT INTO keyhippo_rbac.user_group_roles (user_id, group_id, role_id)
39 | VALUES (user1_id, admin_group_id, admin_role_id)
40 | ON CONFLICT (user_id, group_id, role_id)
41 | DO NOTHING;
42 | -- Set up authentication for user1
43 | PERFORM
44 | set_config('request.jwt.claim.sub', user1_id::text, TRUE);
45 | PERFORM
46 | set_config('request.jwt.claims', json_build_object('sub', user1_id, 'role', 'authenticated', 'user_role', 'admin')::text, TRUE);
47 | END
48 | $$;
49 | -- Function to calculate performance statistics
50 | CREATE OR REPLACE FUNCTION calculate_performance_stats (execution_times double precision[])
51 | RETURNS jsonb
52 | AS $$
53 | DECLARE
54 | stats jsonb;
55 | p99_time double precision;
56 | BEGIN
57 | SELECT
58 | percentile_cont(0.99) WITHIN GROUP (ORDER BY t) INTO p99_time
59 | FROM
60 | unnest(execution_times) t;
61 | SELECT
62 | jsonb_build_object('min_time', MIN(t), 'max_time', MAX(t), 'avg_time', AVG(t), 'median_time', percentile_cont(0.5) WITHIN GROUP (ORDER BY t), 'stddev_time', stddev(t), 'percentile_90', percentile_cont(0.9) WITHIN GROUP (ORDER BY t), 'percentile_95', percentile_cont(0.95) WITHIN GROUP (ORDER BY t), 'percentile_99', p99_time, 'p99_ops_per_second', 1 / p99_time) INTO stats
63 | FROM
64 | unnest(execution_times) t;
65 | RETURN stats;
66 | END;
67 | $$
68 | LANGUAGE plpgsql;
69 | -- Performance test function
70 | CREATE OR REPLACE FUNCTION run_performance_test (iterations integer DEFAULT 1000)
71 | RETURNS jsonb
72 | AS $$
73 | DECLARE
74 | start_time timestamp;
75 | end_time timestamp;
76 | user_id uuid := current_setting('test.user1_id')::uuid;
77 | created_api_key text;
78 | execution_times double precision[];
79 | i integer;
80 | test_group_id uuid;
81 | test_role_id uuid;
82 | test_scope_id uuid;
83 | results jsonb := '{}'::jsonb;
84 | BEGIN
85 | -- Test 1: RBAC authorization
86 | FOR i IN 1..iterations LOOP
87 | start_time := clock_timestamp();
88 | PERFORM
89 | keyhippo.authorize ('manage_groups');
90 | end_time := clock_timestamp();
91 | execution_times := array_append(execution_times, EXTRACT(EPOCH FROM (end_time - start_time)));
92 | END LOOP;
93 | results := results || jsonb_build_object('RBAC authorization', calculate_performance_stats (execution_times));
94 | -- Test 2: Create group
95 | execution_times := ARRAY[]::double precision[];
96 | FOR i IN 1..iterations LOOP
97 | start_time := clock_timestamp();
98 | SELECT
99 | keyhippo_rbac.create_group ('Test Group ' || i::text, 'Test group description') INTO test_group_id;
100 | end_time := clock_timestamp();
101 | execution_times := array_append(execution_times, EXTRACT(EPOCH FROM (end_time - start_time)));
102 | END LOOP;
103 | results := results || jsonb_build_object('Create group', calculate_performance_stats (execution_times));
104 | -- Test 3: Create role
105 | execution_times := ARRAY[]::double precision[];
106 | FOR i IN 1..iterations LOOP
107 | start_time := clock_timestamp();
108 | SELECT
109 | keyhippo_rbac.create_role ('Test Role ' || i::text, 'Test role description', test_group_id, 'user'::keyhippo.app_role) INTO test_role_id;
110 | end_time := clock_timestamp();
111 | execution_times := array_append(execution_times, EXTRACT(EPOCH FROM (end_time - start_time)));
112 | END LOOP;
113 | results := results || jsonb_build_object('Create role', calculate_performance_stats (execution_times));
114 | -- Test 4: Assign role to user
115 | execution_times := ARRAY[]::double precision[];
116 | FOR i IN 1..iterations LOOP
117 | start_time := clock_timestamp();
118 | PERFORM
119 | keyhippo_rbac.assign_role_to_user (user_id, test_group_id, test_role_id);
120 | end_time := clock_timestamp();
121 | execution_times := array_append(execution_times, EXTRACT(EPOCH FROM (end_time - start_time)));
122 | END LOOP;
123 | results := results || jsonb_build_object('Assign role to user', calculate_performance_stats (execution_times));
124 | -- Test 5: API key creation
125 | execution_times := ARRAY[]::double precision[];
126 | FOR i IN 1..iterations LOOP
127 | start_time := clock_timestamp();
128 | SELECT
129 | api_key INTO created_api_key
130 | FROM
131 | keyhippo.create_api_key ('Performance Test Key ' || i::text);
132 | end_time := clock_timestamp();
133 | execution_times := array_append(execution_times, EXTRACT(EPOCH FROM (end_time - start_time)));
134 | END LOOP;
135 | results := results || jsonb_build_object('API key creation', calculate_performance_stats (execution_times));
136 | -- Test 6: API key verification
137 | execution_times := ARRAY[]::double precision[];
138 | FOR i IN 1..iterations LOOP
139 | start_time := clock_timestamp();
140 | PERFORM
141 | keyhippo.verify_api_key (created_api_key);
142 | end_time := clock_timestamp();
143 | execution_times := array_append(execution_times, EXTRACT(EPOCH FROM (end_time - start_time)));
144 | END LOOP;
145 | results := results || jsonb_build_object('API key verification', calculate_performance_stats (execution_times));
146 | -- Test 7: Create scope
147 | execution_times := ARRAY[]::double precision[];
148 | FOR i IN 1..iterations LOOP
149 | start_time := clock_timestamp();
150 | INSERT INTO keyhippo.scopes (name, description)
151 | VALUES ('test_scope_' || i::text, 'Test scope description')
152 | RETURNING
153 | id INTO test_scope_id;
154 | end_time := clock_timestamp();
155 | execution_times := array_append(execution_times, EXTRACT(EPOCH FROM (end_time - start_time)));
156 | END LOOP;
157 | results := results || jsonb_build_object('Create scope', calculate_performance_stats (execution_times));
158 | RETURN results;
159 | END;
160 | $$
161 | LANGUAGE plpgsql;
162 | -- Run performance tests and display results as JSON
163 | SELECT
164 | run_performance_test (10000)::text AS performance_results;
165 | -- Clean up
166 | DROP FUNCTION run_performance_test (integer);
167 | DROP FUNCTION calculate_performance_stats (double precision[]);
168 | ROLLBACK;
169 |
--------------------------------------------------------------------------------
/tests/reset.sql:
--------------------------------------------------------------------------------
1 | -- KeyHippo Database Reset Script
2 | -- Drop schemas
3 | DROP TABLE IF EXISTS public.test_accounts CASCADE;
4 |
5 | DROP SCHEMA IF EXISTS keyhippo CASCADE;
6 |
7 | DROP SCHEMA IF EXISTS keyhippo_internal CASCADE;
8 |
9 | DROP SCHEMA IF EXISTS keyhippo_rbac CASCADE;
10 |
11 | DROP SCHEMA IF EXISTS keyhippo_impersonation CASCADE;
12 |
13 | -- Drop custom types
14 | DROP TYPE IF EXISTS keyhippo.app_permission CASCADE;
15 |
16 | DROP TYPE IF EXISTS keyhippo.app_role CASCADE;
17 |
18 | -- Drop the trigger on auth.users
19 | DROP TRIGGER IF EXISTS assign_default_role_trigger ON auth.users;
20 |
21 | -- Notify PostgREST to reload configuration
22 | NOTIFY pgrst,
23 | 'reload config';
24 |
--------------------------------------------------------------------------------
/tests/tests.sql:
--------------------------------------------------------------------------------
1 | BEGIN;
2 | SET search_path TO keyhippo, keyhippo_rbac, public, auth;
3 | -- Enable audit log trigger
4 | SELECT
5 | keyhippo_internal.enable_audit_log_notify ();
6 | -- Create test users and set up authentication
7 | DO $$
8 | DECLARE
9 | user1_id uuid := gen_random_uuid ();
10 | user2_id uuid := gen_random_uuid ();
11 | admin_group_id uuid;
12 | admin_role_id uuid;
13 | BEGIN
14 | -- Insert users with explicit IDs
15 | INSERT INTO auth.users (id, email)
16 | VALUES (user1_id, 'user1@example.com'),
17 | (user2_id, 'user2@example.com');
18 | -- Store user IDs as settings for later use
19 | PERFORM
20 | set_config('test.user1_id', user1_id::text, TRUE);
21 | PERFORM
22 | set_config('test.user2_id', user2_id::text, TRUE);
23 | -- Initialize KeyHippo (this creates default groups and roles)
24 | PERFORM
25 | keyhippo.initialize_keyhippo ();
26 | -- Get the Admin Group and Role IDs
27 | SELECT
28 | id INTO admin_group_id
29 | FROM
30 | keyhippo_rbac.groups
31 | WHERE
32 | name = 'Admin Group';
33 | SELECT
34 | id INTO admin_role_id
35 | FROM
36 | keyhippo_rbac.roles
37 | WHERE
38 | name = 'Admin'
39 | AND group_id = admin_group_id;
40 | -- Assign admin role to user1
41 | -- Set up authentication for user1
42 | PERFORM
43 | set_config('request.jwt.claim.sub', user1_id::text, TRUE);
44 | PERFORM
45 | set_config('request.jwt.claims', json_build_object('sub', user1_id, 'role', 'authenticated', 'user_role', 'admin')::text, TRUE);
46 | END
47 | $$;
48 | -- Switch to authenticated role
49 | SET ROLE authenticated;
50 | -- Test RBAC initialization
51 | DO $$
52 | DECLARE
53 | group_count integer;
54 | role_count integer;
55 | permission_count integer;
56 | admin_role_permissions integer;
57 | user_role_permissions integer;
58 | BEGIN
59 | RAISE NOTICE 'Current user: %', CURRENT_USER;
60 | RAISE NOTICE 'Current role: %', CURRENT_ROLE;
61 | -- Check groups
62 | SELECT
63 | COUNT(*) INTO group_count
64 | FROM
65 | keyhippo_rbac.groups;
66 | RAISE NOTICE 'Number of groups: %', group_count;
67 | RAISE NOTICE 'Group names: %', array_agg(name)
68 | FROM
69 | keyhippo_rbac.groups;
70 | -- Check if the current user has permissions to see the groups
71 | RAISE NOTICE 'Can select from groups: %', EXISTS (
72 | SELECT
73 | 1
74 | FROM
75 | information_schema.table_privileges
76 | WHERE
77 | table_schema = 'keyhippo_rbac'
78 | AND table_name = 'groups'
79 | AND privilege_type = 'SELECT'
80 | AND grantee = CURRENT_USER);
81 | ASSERT group_count = 2,
82 | 'Two default groups should be created';
83 | SELECT
84 | COUNT(*) INTO role_count
85 | FROM
86 | keyhippo_rbac.roles;
87 | ASSERT role_count = 2,
88 | 'Two default roles should be created';
89 | SELECT
90 | COUNT(*) INTO permission_count
91 | FROM
92 | keyhippo_rbac.permissions;
93 | ASSERT permission_count = 6,
94 | 'Six default permissions should be created';
95 | SELECT
96 | COUNT(*) INTO admin_role_permissions
97 | FROM
98 | keyhippo_rbac.role_permissions rp
99 | JOIN keyhippo_rbac.roles r ON rp.role_id = r.id
100 | WHERE
101 | r.name = 'Admin';
102 | ASSERT admin_role_permissions = 6,
103 | 'Admin role should have all 6 permissions';
104 | SELECT
105 | COUNT(*) INTO user_role_permissions
106 | FROM
107 | keyhippo_rbac.role_permissions rp
108 | JOIN keyhippo_rbac.roles r ON rp.role_id = r.id
109 | WHERE
110 | r.name = 'User';
111 | ASSERT user_role_permissions = 1,
112 | 'User role should have 1 permission (manage_api_keys)';
113 | END
114 | $$;
115 | -- Test create_api_key function
116 | DO $$
117 | DECLARE
118 | created_key_result record;
119 | key_count bigint;
120 | BEGIN
121 | SELECT
122 | * INTO created_key_result
123 | FROM
124 | keyhippo.create_api_key ('Test API Key');
125 | ASSERT created_key_result.api_key IS NOT NULL,
126 | 'create_api_key executes successfully for authenticated user';
127 | ASSERT created_key_result.api_key_id IS NOT NULL,
128 | 'create_api_key returns a valid API key ID';
129 | SELECT
130 | COUNT(*) INTO key_count
131 | FROM
132 | keyhippo.api_key_metadata
133 | WHERE
134 | description = 'Test API Key'
135 | AND user_id = current_setting('test.user1_id')::uuid;
136 | ASSERT key_count = 1,
137 | 'An API key should be created with the given name for the authenticated user';
138 | END
139 | $$;
140 | -- Test verify_api_key function
141 | DO $$
142 | DECLARE
143 | created_key_result record;
144 | verified_key_result record;
145 | BEGIN
146 | SELECT
147 | * INTO created_key_result
148 | FROM
149 | keyhippo.create_api_key ('Verify Test Key');
150 | SELECT
151 | * INTO verified_key_result
152 | FROM
153 | keyhippo.verify_api_key (created_key_result.api_key);
154 | ASSERT verified_key_result.user_id = current_setting('test.user1_id')::uuid,
155 | 'verify_api_key should return the correct user_id';
156 | ASSERT verified_key_result.scope_id IS NULL,
157 | 'verify_api_key should return NULL scope_id for default key';
158 | ASSERT array_length(verified_key_result.permissions, 1) > 0,
159 | 'verify_api_key should return permissions';
160 | END
161 | $$;
162 | -- Test revoke_api_key function
163 | DO $$
164 | DECLARE
165 | created_key_result record;
166 | revoke_result boolean;
167 | key_is_revoked boolean;
168 | BEGIN
169 | SELECT
170 | * INTO created_key_result
171 | FROM
172 | keyhippo.create_api_key ('Revoke Test Key');
173 | SELECT
174 | * INTO revoke_result
175 | FROM
176 | keyhippo.revoke_api_key (created_key_result.api_key_id);
177 | ASSERT revoke_result = TRUE,
178 | 'revoke_api_key should return TRUE for successful revocation';
179 | SELECT
180 | is_revoked INTO key_is_revoked
181 | FROM
182 | keyhippo.api_key_metadata
183 | WHERE
184 | id = created_key_result.api_key_id;
185 | ASSERT key_is_revoked = TRUE,
186 | 'API key should be marked as revoked';
187 | END
188 | $$;
189 | -- Test rotate_api_key function
190 | DO $$
191 | DECLARE
192 | created_key_result record;
193 | rotated_key_result record;
194 | old_key_revoked boolean;
195 | BEGIN
196 | SELECT
197 | * INTO created_key_result
198 | FROM
199 | keyhippo.create_api_key ('Rotate Test Key');
200 | SELECT
201 | * INTO rotated_key_result
202 | FROM
203 | keyhippo.rotate_api_key (created_key_result.api_key_id);
204 | ASSERT rotated_key_result.new_api_key IS NOT NULL,
205 | 'rotate_api_key should return a new API key';
206 | ASSERT rotated_key_result.new_api_key_id IS NOT NULL,
207 | 'rotate_api_key should return a new API key ID';
208 | ASSERT rotated_key_result.new_api_key_id != created_key_result.api_key_id,
209 | 'New API key ID should be different from the old one';
210 | SELECT
211 | is_revoked INTO old_key_revoked
212 | FROM
213 | keyhippo.api_key_metadata
214 | WHERE
215 | id = created_key_result.api_key_id;
216 | ASSERT old_key_revoked = TRUE,
217 | 'Old API key should be revoked after rotation';
218 | END
219 | $$;
220 | -- Test authorize function
221 | DO $$
222 | DECLARE
223 | authorized boolean;
224 | BEGIN
225 | SELECT
226 | * INTO authorized
227 | FROM
228 | keyhippo.authorize ('manage_api_keys');
229 | ASSERT authorized = TRUE,
230 | 'User should be authorized to manage API keys';
231 | SELECT
232 | * INTO authorized
233 | FROM
234 | keyhippo.authorize ('manage_groups');
235 | ASSERT authorized = TRUE,
236 | 'Admin user should be authorized to manage groups';
237 | END
238 | $$;
239 | -- Test RBAC functions
240 | DO $$
241 | DECLARE
242 | t_group_id uuid;
243 | t_role_id uuid;
244 | t_user_id uuid := current_setting('test.user1_id')::uuid;
245 | BEGIN
246 | -- Test create_group
247 | SELECT
248 | * INTO t_group_id
249 | FROM
250 | keyhippo_rbac.create_group ('Test Group', 'A test group');
251 | ASSERT t_group_id IS NOT NULL,
252 | 'create_group should return a valid group ID';
253 | -- Test create_role
254 | SELECT
255 | * INTO t_role_id
256 | FROM
257 | keyhippo_rbac.create_role ('Test Role', 'A test role', t_group_id, 'user');
258 | ASSERT t_role_id IS NOT NULL,
259 | 'create_role should return a valid role ID';
260 | -- Test assign_role_to_user
261 | PERFORM
262 | keyhippo_rbac.assign_role_to_user (t_user_id, t_group_id, t_role_id);
263 | ASSERT EXISTS (
264 | SELECT
265 | 1
266 | FROM
267 | keyhippo_rbac.user_group_roles
268 | WHERE
269 | user_id = t_user_id
270 | AND group_id = t_group_id
271 | AND role_id = t_role_id),
272 | 'assign_role_to_user should assign the role to the user';
273 | -- Test assign_permission_to_role
274 | PERFORM
275 | keyhippo_rbac.assign_permission_to_role (t_role_id, 'manage_api_keys');
276 | ASSERT EXISTS (
277 | SELECT
278 | 1
279 | FROM
280 | keyhippo_rbac.role_permissions rp
281 | JOIN keyhippo_rbac.permissions p ON rp.permission_id = p.id
282 | WHERE
283 | rp.role_id = t_role_id
284 | AND p.name = 'manage_api_keys'),
285 | 'assign_permission_to_role should assign the permission to the role';
286 | END
287 | $$;
288 | -- Test key expiry notification
289 | SET ROLE postgres;
290 | DO $$
291 | DECLARE
292 | v_api_key_id uuid;
293 | v_api_key text;
294 | v_user_id uuid;
295 | v_notification_sent boolean := FALSE;
296 | v_audit_log_entry jsonb;
297 | BEGIN
298 | -- Set expiry notification time to 2 hours for testing purposes
299 | UPDATE
300 | keyhippo_internal.config
301 | SET
302 | value = '2'
303 | WHERE
304 | key = 'key_expiry_notification_hours';
305 | -- Ensure notifications are enabled
306 | UPDATE
307 | keyhippo_internal.config
308 | SET
309 | value = 'true'
310 | WHERE
311 | key = 'enable_key_expiry_notifications';
312 | -- Create a test user
313 | INSERT INTO auth.users (id, email)
314 | VALUES (gen_random_uuid (), 'testuser@example.com')
315 | RETURNING
316 | id INTO v_user_id;
317 | -- Login as the test user
318 | PERFORM
319 | set_config('request.jwt.claim.sub', v_user_id::text, TRUE);
320 | PERFORM
321 | set_config('request.jwt.claims', json_build_object('sub', v_user_id, 'role', 'authenticated')::text, TRUE);
322 | -- Create a test API key using the real create_api_key function
323 | SELECT
324 | api_key,
325 | api_key_id INTO v_api_key,
326 | v_api_key_id
327 | FROM
328 | keyhippo.create_api_key ('Test Expiring Key');
329 | RAISE NOTICE 'Created API key with ID: %', v_api_key_id;
330 | -- Logout
331 | PERFORM
332 | set_config('request.jwt.claim.sub', '', TRUE);
333 | PERFORM
334 | set_config('request.jwt.claims', '', TRUE);
335 | -- Update the expiry to trigger the notification
336 | UPDATE
337 | keyhippo.api_key_metadata
338 | SET
339 | expires_at = NOW() + INTERVAL '1 hour'
340 | WHERE
341 | id = v_api_key_id;
342 | RAISE NOTICE 'Updated API key expiry';
343 | -- Check if a notification was logged
344 | SELECT
345 | EXISTS (
346 | SELECT
347 | 1
348 | FROM
349 | keyhippo.audit_log
350 | WHERE
351 | action = 'expiring_key'
352 | AND (data ->> 'expiring_key')::jsonb ->> 'id' = v_api_key_id::text
353 | AND timestamp > NOW() - INTERVAL '1 minute') INTO v_notification_sent;
354 | IF v_notification_sent THEN
355 | RAISE NOTICE 'Notification sent for key %', v_api_key_id;
356 | -- Fetch and display the audit log entry
357 | SELECT
358 | data INTO v_audit_log_entry
359 | FROM
360 | keyhippo.audit_log
361 | WHERE
362 | action = 'expiring_key'
363 | AND (data ->> 'expiring_key')::jsonb ->> 'id' = v_api_key_id::text
364 | ORDER BY
365 | timestamp DESC
366 | LIMIT 1;
367 | RAISE NOTICE 'Audit log entry: %', v_audit_log_entry;
368 | ELSE
369 | RAISE NOTICE 'No notification found for key %', v_api_key_id;
370 | -- Display recent audit log entries for debugging
371 | RAISE NOTICE 'Recent audit log entries:';
372 | FOR v_audit_log_entry IN (
373 | SELECT
374 | data
375 | FROM
376 | keyhippo.audit_log
377 | WHERE
378 | timestamp > NOW() - INTERVAL '5 minutes'
379 | ORDER BY
380 | timestamp DESC
381 | LIMIT 5)
382 | LOOP
383 | RAISE NOTICE '%', v_audit_log_entry;
384 | END LOOP;
385 | END IF;
386 | -- Cleanup
387 | DELETE FROM keyhippo.api_key_metadata
388 | WHERE id = v_api_key_id;
389 | DELETE FROM auth.users
390 | WHERE id = v_user_id;
391 | -- Assert the result
392 | ASSERT v_notification_sent,
393 | 'An expiry notification should have been sent';
394 | EXCEPTION
395 | WHEN OTHERS THEN
396 | -- Cleanup in case of error
397 | IF v_api_key_id IS NOT NULL THEN
398 | DELETE FROM keyhippo.api_key_metadata
399 | WHERE id = v_api_key_id;
400 | END IF;
401 | IF v_user_id IS NOT NULL THEN
402 | DELETE FROM auth.users
403 | WHERE id = v_user_id;
404 | END IF;
405 | RAISE;
406 | END
407 | $$;
408 | -- Clean up
409 | ROLLBACK;
410 |
--------------------------------------------------------------------------------