1909 lines
50 KiB
Markdown
1909 lines
50 KiB
Markdown
# c77_secure_db Usage Guide
|
|
|
|
**Version**: 2.0
|
|
**Date**: January 2025
|
|
**PostgreSQL Compatibility**: 14+
|
|
|
|
## Table of Contents
|
|
|
|
1. [Overview](#overview)
|
|
2. [Core Concepts](#core-concepts)
|
|
3. [Installation and Setup](#installation-and-setup)
|
|
4. [Basic Operations](#basic-operations)
|
|
5. [Advanced Features](#advanced-features)
|
|
6. [RBAC Integration](#rbac-integration)
|
|
7. [Framework Integration](#framework-integration)
|
|
8. [Monitoring and Maintenance](#monitoring-and-maintenance)
|
|
9. [Security Best Practices](#security-best-practices)
|
|
10. [Troubleshooting](#troubleshooting)
|
|
11. [API Reference](#api-reference)
|
|
12. [Examples and Use Cases](#examples-and-use-cases)
|
|
|
|
## Overview
|
|
|
|
The c77_secure_db extension provides enterprise-grade database security through:
|
|
|
|
- **Token-based authorization**: No session variable bypasses
|
|
- **Content hash verification**: SHA-256 tamper detection
|
|
- **Comprehensive audit logging**: Every operation tracked
|
|
- **Optional RBAC integration**: Works with c77_rbac extension
|
|
- **Automatic schema protection**: Triggers applied automatically
|
|
- **Framework-agnostic design**: Works with any application stack
|
|
|
|
### Key Benefits
|
|
|
|
- **Database-level security**: Cannot be bypassed by application bugs
|
|
- **Tamper detection**: Cryptographic verification of data integrity
|
|
- **Complete audit trail**: Compliance-ready operation logging
|
|
- **High performance**: Optimized for production workloads
|
|
- **Easy integration**: Minimal changes to existing applications
|
|
|
|
## Core Concepts
|
|
|
|
### 1. Secure Schemas
|
|
|
|
Schemas registered with c77_secure_db have automatic trigger protection:
|
|
|
|
```sql
|
|
-- Register a schema as secure
|
|
SELECT c77_secure_db_manage_secure_schemas('add', 'myapp');
|
|
|
|
-- All tables in this schema are automatically protected
|
|
```
|
|
|
|
### 2. Authorization Tokens
|
|
|
|
Short-lived, single-use tokens authorize legitimate operations:
|
|
|
|
- **5-second expiration**: Prevents replay attacks
|
|
- **Single-use**: Cannot be reused
|
|
- **Session-specific**: Tied to database session
|
|
- **Automatic cleanup**: Expired tokens removed automatically
|
|
|
|
### 3. Content Hashing
|
|
|
|
SHA-256 hashes detect unauthorized data modifications:
|
|
|
|
```sql
|
|
-- Hash is automatically calculated and stored
|
|
{
|
|
"content_hash": "a1b2c3d4...",
|
|
"hash_version": 1
|
|
}
|
|
```
|
|
|
|
### 4. Audit Trail
|
|
|
|
Every operation is logged with complete context:
|
|
|
|
```sql
|
|
SELECT * FROM c77_secure_db_operation_audit
|
|
WHERE created_at > now() - interval '1 hour';
|
|
```
|
|
|
|
## Installation and Setup
|
|
|
|
### Prerequisites
|
|
|
|
```sql
|
|
-- Required extensions
|
|
CREATE EXTENSION IF NOT EXISTS pgcrypto;
|
|
|
|
-- Optional: For advanced permissions
|
|
CREATE EXTENSION IF NOT EXISTS c77_rbac;
|
|
```
|
|
|
|
### Installation
|
|
|
|
```bash
|
|
# Copy extension files
|
|
sudo cp c77_secure_db.control $(pg_config --sharedir)/extension/
|
|
sudo cp c77_secure_db--1.0.sql $(pg_config --sharedir)/extension/
|
|
```
|
|
|
|
```sql
|
|
-- Install the extension
|
|
CREATE EXTENSION c77_secure_db;
|
|
|
|
-- Verify installation
|
|
SELECT c77_secure_db_health_check();
|
|
```
|
|
|
|
### Initial Setup
|
|
|
|
```sql
|
|
-- Create application user
|
|
CREATE USER myapp_user WITH PASSWORD 'secure_password';
|
|
GRANT c77_secure_db_user TO myapp_user;
|
|
|
|
-- Create and secure your schema
|
|
CREATE SCHEMA myapp;
|
|
SELECT c77_secure_db_manage_secure_schemas('add', 'myapp');
|
|
```
|
|
|
|
### Security Validation
|
|
|
|
**CRITICAL**: Always run security tests after installation:
|
|
|
|
```sql
|
|
SELECT c77_secure_db_run_all_tests();
|
|
-- Must return: "overall_status": "ALL_TESTS_PASSED"
|
|
```
|
|
|
|
## Basic Operations
|
|
|
|
### Table Creation
|
|
|
|
Secure tables require specific columns for security functionality:
|
|
|
|
```sql
|
|
CREATE TABLE myapp.users (
|
|
-- Your business columns
|
|
id BIGSERIAL PRIMARY KEY,
|
|
name TEXT NOT NULL,
|
|
email TEXT UNIQUE NOT NULL,
|
|
phone TEXT,
|
|
|
|
-- Required security columns
|
|
content_hash TEXT, -- SHA-256 hash for tamper detection
|
|
hash_version INTEGER DEFAULT 1, -- Hash version for migration support
|
|
created_at TIMESTAMPTZ DEFAULT NOW(), -- Creation timestamp
|
|
updated_at TIMESTAMPTZ DEFAULT NOW(), -- Last modification timestamp
|
|
deleted_at TIMESTAMPTZ -- Soft delete timestamp (optional)
|
|
);
|
|
```
|
|
|
|
### INSERT Operations
|
|
|
|
```sql
|
|
-- Basic insert
|
|
SELECT c77_secure_db_operation(jsonb_build_object(
|
|
'schema_name', 'myapp',
|
|
'table_name', 'users',
|
|
'operation', 'insert',
|
|
'data', jsonb_build_object(
|
|
'name', 'John Doe',
|
|
'email', 'john@example.com',
|
|
'phone', '+1-555-0123'
|
|
)
|
|
));
|
|
|
|
-- Response includes operation details
|
|
{
|
|
"success": true,
|
|
"operation": "insert",
|
|
"schema_name": "myapp",
|
|
"table_name": "users",
|
|
"rows_affected": 1,
|
|
"content_hash": "a1b2c3d4e5f6...",
|
|
"execution_time_ms": 12,
|
|
"operation_id": "550e8400-e29b-41d4-a716-446655440000",
|
|
"timestamp": "2025-01-26T10:30:00Z"
|
|
}
|
|
```
|
|
|
|
### UPDATE Operations
|
|
|
|
```sql
|
|
-- Update requires primary key in data
|
|
SELECT c77_secure_db_operation(jsonb_build_object(
|
|
'schema_name', 'myapp',
|
|
'table_name', 'users',
|
|
'operation', 'update',
|
|
'data', jsonb_build_object(
|
|
'id', 1, -- Primary key required
|
|
'name', 'John Smith', -- Updated values
|
|
'phone', '+1-555-9999'
|
|
)
|
|
));
|
|
|
|
-- Only specified fields are updated
|
|
-- content_hash and updated_at are automatically recalculated
|
|
```
|
|
|
|
### UPSERT Operations
|
|
|
|
```sql
|
|
-- Insert or update based on primary key conflict
|
|
SELECT c77_secure_db_operation(jsonb_build_object(
|
|
'schema_name', 'myapp',
|
|
'table_name', 'users',
|
|
'operation', 'upsert',
|
|
'data', jsonb_build_object(
|
|
'id', 1, -- If exists: update
|
|
'name', 'John Updated', -- If not exists: insert
|
|
'email', 'john.updated@example.com'
|
|
)
|
|
));
|
|
```
|
|
|
|
### DELETE Operations
|
|
|
|
```sql
|
|
-- Soft delete (recommended - preserves data)
|
|
SELECT c77_secure_db_operation(jsonb_build_object(
|
|
'schema_name', 'myapp',
|
|
'table_name', 'users',
|
|
'operation', 'soft_delete', -- Sets deleted_at timestamp
|
|
'data', jsonb_build_object('id', 1)
|
|
));
|
|
|
|
-- Hard delete (permanent removal)
|
|
SELECT c77_secure_db_operation(jsonb_build_object(
|
|
'schema_name', 'myapp',
|
|
'table_name', 'users',
|
|
'operation', 'delete', -- Permanently removes record
|
|
'data', jsonb_build_object('id', 1)
|
|
));
|
|
```
|
|
|
|
## Advanced Features
|
|
|
|
### Content Hash Customization
|
|
|
|
Exclude specific columns from hash calculation:
|
|
|
|
```sql
|
|
-- Add comment to content_hash column
|
|
COMMENT ON COLUMN myapp.users.content_hash IS
|
|
'{"exclude_hash_columns": ["last_login", "login_count", "view_count"]}';
|
|
|
|
-- These columns won't affect the content hash
|
|
-- Useful for frequently updated metadata
|
|
```
|
|
|
|
### Bulk Operations
|
|
|
|
For processing multiple records efficiently:
|
|
|
|
```sql
|
|
-- Bulk freshness verification
|
|
SELECT c77_secure_db_check_freshness_bulk(
|
|
'myapp',
|
|
'users',
|
|
'[
|
|
{"id": 1, "name": "John Doe", "email": "john@example.com"},
|
|
{"id": 2, "name": "Jane Smith", "email": "jane@example.com"},
|
|
{"id": 3, "name": "Bob Johnson", "email": "bob@example.com"}
|
|
]'::jsonb
|
|
);
|
|
|
|
-- Returns summary and individual results
|
|
{
|
|
"success": true,
|
|
"total_records": 3,
|
|
"fresh_records": 2, -- Not tampered with
|
|
"stale_records": 1, -- Hash mismatch detected
|
|
"error_records": 0,
|
|
"results": [...], -- Individual check results
|
|
"timestamp": "2025-01-26T10:30:00Z"
|
|
}
|
|
```
|
|
|
|
### Data Integrity Verification
|
|
|
|
```sql
|
|
-- Check if a specific record has been tampered with
|
|
SELECT c77_secure_db_check_freshness(
|
|
'myapp',
|
|
'users',
|
|
jsonb_build_object(
|
|
'id', 1,
|
|
'name', 'John Doe',
|
|
'email', 'john@example.com',
|
|
'phone', '+1-555-0123'
|
|
)
|
|
);
|
|
|
|
-- Response indicates if data is fresh
|
|
{
|
|
"success": true,
|
|
"id": "1",
|
|
"fresh": true, -- false if tampered
|
|
"stored_hash": "a1b2c3d4...",
|
|
"calculated_hash": "a1b2c3d4...", -- Should match stored_hash
|
|
"hash_version": 1,
|
|
"timestamp": "2025-01-26T10:30:00Z"
|
|
}
|
|
```
|
|
|
|
### Hash Verification and Repair
|
|
|
|
```sql
|
|
-- Verify all records in a table
|
|
SELECT c77_secure_db_verify_content_hashes('myapp', 'users');
|
|
|
|
-- Fix hash mismatches (recalculates correct hashes)
|
|
SELECT c77_secure_db_verify_content_hashes('myapp', 'users', true);
|
|
|
|
-- Process in smaller batches for large tables
|
|
SELECT c77_secure_db_verify_content_hashes('myapp', 'users', false, 500);
|
|
|
|
-- Response shows verification results
|
|
{
|
|
"success": true,
|
|
"total_records": 10000,
|
|
"mismatch_count": 3,
|
|
"fixed_count": 3, -- If fix_mismatches = true
|
|
"mismatches": [ -- Details of problematic records
|
|
{
|
|
"primary_key_value": "123",
|
|
"stored_hash": "old_hash...",
|
|
"calculated_hash": "correct_hash...",
|
|
"hash_version": 1
|
|
}
|
|
],
|
|
"timestamp": "2025-01-26T10:30:00Z"
|
|
}
|
|
```
|
|
|
|
### Operation Templates
|
|
|
|
Generate ready-to-use SQL templates:
|
|
|
|
```sql
|
|
-- Get template for insert operation
|
|
SELECT c77_secure_db_get_operation_template('myapp', 'users', 'insert');
|
|
|
|
-- Returns formatted SQL template:
|
|
-- INSERT operation template for myapp.users
|
|
SELECT c77_secure_db_operation(
|
|
'{
|
|
"schema_name": "myapp",
|
|
"table_name": "users",
|
|
"operation": "insert",
|
|
"data": {
|
|
"name": "",
|
|
"email": "",
|
|
"phone": ""
|
|
}
|
|
}'::jsonb
|
|
);
|
|
|
|
-- Get template for update operation
|
|
SELECT c77_secure_db_get_operation_template('myapp', 'users', 'update');
|
|
```
|
|
|
|
## RBAC Integration
|
|
|
|
When c77_rbac extension is installed, you can add permission-based security:
|
|
|
|
### Setup RBAC Permissions
|
|
|
|
```sql
|
|
-- Define features (permissions) for secure database operations
|
|
SELECT c77_rbac_grant_feature('user_manager', 'secure_db_insert');
|
|
SELECT c77_rbac_grant_feature('user_manager', 'secure_db_update');
|
|
SELECT c77_rbac_grant_feature('user_manager', 'secure_db_delete');
|
|
|
|
-- Read-only role gets limited permissions
|
|
SELECT c77_rbac_grant_feature('user_viewer', 'secure_db_read');
|
|
|
|
-- Assign users to roles with scopes
|
|
SELECT c77_rbac_assign_subject('123', 'user_manager', 'department', 'engineering');
|
|
SELECT c77_rbac_assign_subject('456', 'user_viewer', 'department', 'sales');
|
|
```
|
|
|
|
### Using RBAC-Protected Operations
|
|
|
|
```sql
|
|
-- Set user context (typically done in application middleware)
|
|
SET "c77_rbac.external_id" TO '123';
|
|
|
|
-- Use secure operation with RBAC checking
|
|
SELECT c77_secure_db_operation(
|
|
jsonb_build_object(
|
|
'schema_name', 'myapp',
|
|
'table_name', 'users',
|
|
'operation', 'insert',
|
|
'data', jsonb_build_object(
|
|
'name', 'Jane Doe',
|
|
'email', 'jane@example.com'
|
|
)
|
|
),
|
|
true, -- check_rbac = true
|
|
'secure_db_insert', -- required_feature
|
|
'department', -- scope_type (optional)
|
|
'engineering' -- scope_id (optional)
|
|
);
|
|
|
|
-- Response includes RBAC information
|
|
{
|
|
"success": true,
|
|
"operation": "insert",
|
|
"rbac_check_performed": true,
|
|
"rbac_user_id": "123",
|
|
"required_feature": "secure_db_insert",
|
|
...
|
|
}
|
|
```
|
|
|
|
### RBAC Error Handling
|
|
|
|
```sql
|
|
-- Insufficient permissions response
|
|
{
|
|
"success": false,
|
|
"error": "Insufficient permissions",
|
|
"required_feature": "secure_db_delete",
|
|
"user_id": "456",
|
|
"timestamp": "2025-01-26T10:30:00Z"
|
|
}
|
|
|
|
-- Missing user context response
|
|
{
|
|
"success": false,
|
|
"error": "RBAC enabled but no user context set",
|
|
"hint": "Set c77_rbac.external_id session variable",
|
|
"timestamp": "2025-01-26T10:30:00Z"
|
|
}
|
|
```
|
|
|
|
### Recommended RBAC Features
|
|
|
|
```sql
|
|
-- Standard secure database features
|
|
secure_db_insert -- Create new records
|
|
secure_db_update -- Modify existing records
|
|
secure_db_delete -- Remove records (soft delete)
|
|
secure_db_hard_delete -- Permanently remove records
|
|
secure_db_read -- Read operations (freshness checks)
|
|
secure_db_admin -- Administrative operations (hash verification)
|
|
```
|
|
|
|
## Framework Integration
|
|
|
|
### Laravel Integration
|
|
|
|
#### Middleware Setup
|
|
|
|
```php
|
|
<?php
|
|
// app/Http/Middleware/SecureDbMiddleware.php
|
|
namespace App\Http\Middleware;
|
|
|
|
use Closure;
|
|
use Illuminate\Http\Request;
|
|
use Illuminate\Support\Facades\DB;
|
|
use Illuminate\Support\Facades\Auth;
|
|
|
|
class SecureDbMiddleware
|
|
{
|
|
public function handle(Request $request, Closure $next)
|
|
{
|
|
// Set RBAC user context if authenticated
|
|
if (Auth::check()) {
|
|
DB::statement('SET "c77_rbac.external_id" TO ?', [Auth::id()]);
|
|
}
|
|
|
|
return $next($request);
|
|
}
|
|
}
|
|
```
|
|
|
|
#### Service Class
|
|
|
|
```php
|
|
<?php
|
|
// app/Services/SecureDbService.php
|
|
namespace App\Services;
|
|
|
|
use Illuminate\Support\Facades\DB;
|
|
use Exception;
|
|
|
|
class SecureDbService
|
|
{
|
|
public function secureOperation(array $data, bool $checkRbac = false, string $requiredFeature = null): array
|
|
{
|
|
$result = DB::selectOne(
|
|
'SELECT c77_secure_db_operation(?, ?, ?) as result',
|
|
[
|
|
json_encode($data),
|
|
$checkRbac,
|
|
$requiredFeature
|
|
]
|
|
);
|
|
|
|
$response = json_decode($result->result, true);
|
|
|
|
if (!$response['success']) {
|
|
throw new Exception($response['error'] ?? 'Secure operation failed');
|
|
}
|
|
|
|
return $response;
|
|
}
|
|
|
|
public function insert(string $table, array $data, bool $checkRbac = false): array
|
|
{
|
|
return $this->secureOperation([
|
|
'schema_name' => config('database.secure_schema', 'myapp'),
|
|
'table_name' => $table,
|
|
'operation' => 'insert',
|
|
'data' => $data
|
|
], $checkRbac, 'secure_db_insert');
|
|
}
|
|
|
|
public function update(string $table, array $data, bool $checkRbac = false): array
|
|
{
|
|
return $this->secureOperation([
|
|
'schema_name' => config('database.secure_schema', 'myapp'),
|
|
'table_name' => $table,
|
|
'operation' => 'update',
|
|
'data' => $data
|
|
], $checkRbac, 'secure_db_update');
|
|
}
|
|
|
|
public function softDelete(string $table, int $id, bool $checkRbac = false): array
|
|
{
|
|
return $this->secureOperation([
|
|
'schema_name' => config('database.secure_schema', 'myapp'),
|
|
'table_name' => $table,
|
|
'operation' => 'soft_delete',
|
|
'data' => ['id' => $id]
|
|
], $checkRbac, 'secure_db_delete');
|
|
}
|
|
|
|
public function checkFreshness(string $table, array $data): array
|
|
{
|
|
$result = DB::selectOne(
|
|
'SELECT c77_secure_db_check_freshness(?, ?, ?) as result',
|
|
[
|
|
config('database.secure_schema', 'myapp'),
|
|
$table,
|
|
json_encode($data)
|
|
]
|
|
);
|
|
|
|
return json_decode($result->result, true);
|
|
}
|
|
}
|
|
```
|
|
|
|
#### Model Integration
|
|
|
|
```php
|
|
<?php
|
|
// app/Models/User.php
|
|
namespace App\Models;
|
|
|
|
use Illuminate\Foundation\Auth\User as Authenticatable;
|
|
use App\Services\SecureDbService;
|
|
|
|
class User extends Authenticatable
|
|
{
|
|
protected $table = 'myapp.users';
|
|
|
|
protected $fillable = [
|
|
'name', 'email', 'phone'
|
|
];
|
|
|
|
protected $secureDb;
|
|
|
|
public function __construct(array $attributes = [])
|
|
{
|
|
parent::__construct($attributes);
|
|
$this->secureDb = app(SecureDbService::class);
|
|
}
|
|
|
|
// Override save to use secure operations
|
|
public function save(array $options = [])
|
|
{
|
|
$checkRbac = $options['check_rbac'] ?? true;
|
|
|
|
if ($this->exists) {
|
|
// Update existing record
|
|
$data = array_merge(['id' => $this->getKey()], $this->getDirty());
|
|
$result = $this->secureDb->update('users', $data, $checkRbac);
|
|
} else {
|
|
// Insert new record
|
|
$result = $this->secureDb->insert('users', $this->getAttributes(), $checkRbac);
|
|
if (isset($result['data']['id'])) {
|
|
$this->setAttribute($this->getKeyName(), $result['data']['id']);
|
|
}
|
|
}
|
|
|
|
$this->exists = true;
|
|
$this->wasRecentlyCreated = !isset($data);
|
|
|
|
return true;
|
|
}
|
|
|
|
// Soft delete using secure operations
|
|
public function delete()
|
|
{
|
|
if (!$this->exists) {
|
|
return false;
|
|
}
|
|
|
|
$this->secureDb->softDelete('users', $this->getKey(), true);
|
|
|
|
return true;
|
|
}
|
|
|
|
// Check if model data is fresh (not tampered)
|
|
public function isFresh(): bool
|
|
{
|
|
$result = $this->secureDb->checkFreshness('users', $this->getAttributes());
|
|
return $result['success'] && $result['fresh'];
|
|
}
|
|
}
|
|
```
|
|
|
|
#### Controller Example
|
|
|
|
```php
|
|
<?php
|
|
// app/Http/Controllers/UserController.php
|
|
namespace App\Http\Controllers;
|
|
|
|
use App\Http\Controllers\Controller;
|
|
use App\Services\SecureDbService;
|
|
use Illuminate\Http\Request;
|
|
|
|
class UserController extends Controller
|
|
{
|
|
protected $secureDb;
|
|
|
|
public function __construct(SecureDbService $secureDb)
|
|
{
|
|
$this->secureDb = $secureDb;
|
|
}
|
|
|
|
public function store(Request $request)
|
|
{
|
|
$validated = $request->validate([
|
|
'name' => 'required|string|max:255',
|
|
'email' => 'required|email|unique:myapp.users,email',
|
|
'phone' => 'nullable|string'
|
|
]);
|
|
|
|
try {
|
|
$result = $this->secureDb->insert('users', $validated, true);
|
|
|
|
return response()->json([
|
|
'success' => true,
|
|
'message' => 'User created successfully',
|
|
'operation_id' => $result['operation_id'],
|
|
'user_id' => $result['data']['id'] ?? null
|
|
]);
|
|
|
|
} catch (Exception $e) {
|
|
return response()->json([
|
|
'success' => false,
|
|
'error' => $e->getMessage()
|
|
], 400);
|
|
}
|
|
}
|
|
|
|
public function update(Request $request, int $id)
|
|
{
|
|
$validated = $request->validate([
|
|
'name' => 'sometimes|string|max:255',
|
|
'email' => 'sometimes|email|unique:myapp.users,email,' . $id,
|
|
'phone' => 'nullable|string'
|
|
]);
|
|
|
|
$validated['id'] = $id;
|
|
|
|
try {
|
|
$result = $this->secureDb->update('users', $validated, true);
|
|
|
|
return response()->json([
|
|
'success' => true,
|
|
'message' => 'User updated successfully',
|
|
'operation_id' => $result['operation_id']
|
|
]);
|
|
|
|
} catch (Exception $e) {
|
|
return response()->json([
|
|
'success' => false,
|
|
'error' => $e->getMessage()
|
|
], 400);
|
|
}
|
|
}
|
|
|
|
public function destroy(int $id)
|
|
{
|
|
try {
|
|
$result = $this->secureDb->softDelete('users', $id, true);
|
|
|
|
return response()->json([
|
|
'success' => true,
|
|
'message' => 'User deleted successfully',
|
|
'operation_id' => $result['operation_id']
|
|
]);
|
|
|
|
} catch (Exception $e) {
|
|
return response()->json([
|
|
'success' => false,
|
|
'error' => $e->getMessage()
|
|
], 400);
|
|
}
|
|
}
|
|
|
|
public function verifyIntegrity(int $id)
|
|
{
|
|
// Get user data from regular table query
|
|
$user = DB::table('myapp.users')->where('id', $id)->first();
|
|
|
|
if (!$user) {
|
|
return response()->json(['error' => 'User not found'], 404);
|
|
}
|
|
|
|
// Check if data has been tampered with
|
|
$freshness = $this->secureDb->checkFreshness('users', (array) $user);
|
|
|
|
return response()->json([
|
|
'user_id' => $id,
|
|
'is_fresh' => $freshness['fresh'],
|
|
'hash_match' => $freshness['stored_hash'] === $freshness['calculated_hash'],
|
|
'last_verified' => now()
|
|
]);
|
|
}
|
|
}
|
|
```
|
|
|
|
### Node.js/Express Integration
|
|
|
|
```javascript
|
|
// services/secureDbService.js
|
|
const { Pool } = require('pg');
|
|
|
|
class SecureDbService {
|
|
constructor(pool) {
|
|
this.pool = pool;
|
|
}
|
|
|
|
async secureOperation(data, checkRbac = false, requiredFeature = null) {
|
|
const client = await this.pool.connect();
|
|
|
|
try {
|
|
const result = await client.query(
|
|
'SELECT c77_secure_db_operation($1, $2, $3) as result',
|
|
[JSON.stringify(data), checkRbac, requiredFeature]
|
|
);
|
|
|
|
const response = JSON.parse(result.rows[0].result);
|
|
|
|
if (!response.success) {
|
|
throw new Error(response.error);
|
|
}
|
|
|
|
return response;
|
|
} finally {
|
|
client.release();
|
|
}
|
|
}
|
|
|
|
async setUserContext(userId) {
|
|
const client = await this.pool.connect();
|
|
try {
|
|
await client.query('SET "c77_rbac.external_id" TO $1', [userId.toString()]);
|
|
} finally {
|
|
client.release();
|
|
}
|
|
}
|
|
|
|
async insert(table, data, checkRbac = false) {
|
|
return this.secureOperation({
|
|
schema_name: process.env.SECURE_SCHEMA || 'myapp',
|
|
table_name: table,
|
|
operation: 'insert',
|
|
data: data
|
|
}, checkRbac, 'secure_db_insert');
|
|
}
|
|
|
|
async update(table, data, checkRbac = false) {
|
|
return this.secureOperation({
|
|
schema_name: process.env.SECURE_SCHEMA || 'myapp',
|
|
table_name: table,
|
|
operation: 'update',
|
|
data: data
|
|
}, checkRbac, 'secure_db_update');
|
|
}
|
|
|
|
async softDelete(table, id, checkRbac = false) {
|
|
return this.secureOperation({
|
|
schema_name: process.env.SECURE_SCHEMA || 'myapp',
|
|
table_name: table,
|
|
operation: 'soft_delete',
|
|
data: { id: id }
|
|
}, checkRbac, 'secure_db_delete');
|
|
}
|
|
|
|
async checkFreshness(table, data) {
|
|
const client = await this.pool.connect();
|
|
|
|
try {
|
|
const result = await client.query(
|
|
'SELECT c77_secure_db_check_freshness($1, $2, $3) as result',
|
|
[process.env.SECURE_SCHEMA || 'myapp', table, JSON.stringify(data)]
|
|
);
|
|
|
|
return JSON.parse(result.rows[0].result);
|
|
} finally {
|
|
client.release();
|
|
}
|
|
}
|
|
}
|
|
|
|
module.exports = SecureDbService;
|
|
```
|
|
|
|
```javascript
|
|
// middleware/secureDbMiddleware.js
|
|
const secureDbMiddleware = (secureDbService) => {
|
|
return async (req, res, next) => {
|
|
if (req.user && req.user.id) {
|
|
try {
|
|
await secureDbService.setUserContext(req.user.id);
|
|
} catch (error) {
|
|
console.error('Failed to set user context:', error);
|
|
}
|
|
}
|
|
next();
|
|
};
|
|
};
|
|
|
|
module.exports = secureDbMiddleware;
|
|
```
|
|
|
|
### Django Integration
|
|
|
|
```python
|
|
# services/secure_db_service.py
|
|
import json
|
|
from django.db import connection
|
|
from django.conf import settings
|
|
|
|
class SecureDbService:
|
|
def __init__(self):
|
|
self.schema = getattr(settings, 'SECURE_SCHEMA', 'myapp')
|
|
|
|
def secure_operation(self, data, check_rbac=False, required_feature=None):
|
|
with connection.cursor() as cursor:
|
|
cursor.execute(
|
|
"SELECT c77_secure_db_operation(%s, %s, %s) as result",
|
|
[json.dumps(data), check_rbac, required_feature]
|
|
)
|
|
result = cursor.fetchone()[0]
|
|
response = json.loads(result)
|
|
|
|
if not response['success']:
|
|
raise Exception(response.get('error', 'Secure operation failed'))
|
|
|
|
return response
|
|
|
|
def set_user_context(self, user_id):
|
|
with connection.cursor() as cursor:
|
|
cursor.execute('SET "c77_rbac.external_id" TO %s', [str(user_id)])
|
|
|
|
def insert(self, table, data, check_rbac=False):
|
|
return self.secure_operation({
|
|
'schema_name': self.schema,
|
|
'table_name': table,
|
|
'operation': 'insert',
|
|
'data': data
|
|
}, check_rbac, 'secure_db_insert')
|
|
|
|
def update(self, table, data, check_rbac=False):
|
|
return self.secure_operation({
|
|
'schema_name': self.schema,
|
|
'table_name': table,
|
|
'operation': 'update',
|
|
'data': data
|
|
}, check_rbac, 'secure_db_update')
|
|
|
|
def soft_delete(self, table, record_id, check_rbac=False):
|
|
return self.secure_operation({
|
|
'schema_name': self.schema,
|
|
'table_name': table,
|
|
'operation': 'soft_delete',
|
|
'data': {'id': record_id}
|
|
}, check_rbac, 'secure_db_delete')
|
|
|
|
def check_freshness(self, table, data):
|
|
with connection.cursor() as cursor:
|
|
cursor.execute(
|
|
"SELECT c77_secure_db_check_freshness(%s, %s, %s) as result",
|
|
[self.schema, table, json.dumps(data)]
|
|
)
|
|
result = cursor.fetchone()[0]
|
|
return json.loads(result)
|
|
```
|
|
|
|
```python
|
|
# middleware/secure_db_middleware.py
|
|
from django.utils.deprecation import MiddlewareMixin
|
|
from .services.secure_db_service import SecureDbService
|
|
|
|
class SecureDbMiddleware(MiddlewareMixin):
|
|
def __init__(self, get_response):
|
|
self.get_response = get_response
|
|
self.secure_db = SecureDbService()
|
|
super().__init__(get_response)
|
|
|
|
def process_request(self, request):
|
|
if hasattr(request, 'user') and request.user.is_authenticated:
|
|
try:
|
|
self.secure_db.set_user_context(request.user.id)
|
|
except Exception as e:
|
|
# Log error but don't block request
|
|
print(f"Failed to set user context: {e}")
|
|
```
|
|
|
|
## Monitoring and Maintenance
|
|
|
|
### Health Monitoring
|
|
|
|
```sql
|
|
-- System health check
|
|
SELECT c77_secure_db_health_check();
|
|
|
|
-- Returns comprehensive status
|
|
{
|
|
"success": true,
|
|
"extension_version": "2.0",
|
|
"rbac_available": true,
|
|
"secure_schemas_count": 3,
|
|
"active_tokens": 0, -- Should usually be 0
|
|
"recent_operations_1h": 1247,
|
|
"recent_errors_1h": 2,
|
|
"error_rate_1h": 0.16, -- Percentage
|
|
"timestamp": "2025-01-26T10:30:00Z"
|
|
}
|
|
```
|
|
|
|
### Performance Monitoring
|
|
|
|
```sql
|
|
-- Average execution time over last hour
|
|
SELECT
|
|
operation_type,
|
|
count(*) as operation_count,
|
|
avg(execution_time_ms) as avg_time_ms,
|
|
max(execution_time_ms) as max_time_ms,
|
|
percentile_cont(0.95) WITHIN GROUP (ORDER BY execution_time_ms) as p95_time_ms
|
|
FROM c77_secure_db_operation_audit
|
|
WHERE created_at > now() - interval '1 hour'
|
|
AND execution_time_ms IS NOT NULL
|
|
GROUP BY operation_type
|
|
ORDER BY avg_time_ms DESC;
|
|
|
|
-- Error analysis
|
|
SELECT
|
|
error_message,
|
|
count(*) as error_count,
|
|
array_agg(DISTINCT user_name) as affected_users
|
|
FROM c77_secure_db_operation_audit
|
|
WHERE created_at > now() - interval '24 hours'
|
|
AND success = false
|
|
GROUP BY error_message
|
|
ORDER BY error_count DESC;
|
|
|
|
-- User activity analysis
|
|
SELECT
|
|
user_name,
|
|
count(*) as total_operations,
|
|
count(*) FILTER (WHERE success = false) as failed_operations,
|
|
array_agg(DISTINCT operation_type) as operation_types
|
|
FROM c77_secure_db_operation_audit
|
|
WHERE created_at > now() - interval '24 hours'
|
|
GROUP BY user_name
|
|
ORDER BY total_operations DESC
|
|
LIMIT 20;
|
|
```
|
|
|
|
### Maintenance Tasks
|
|
|
|
#### Daily Maintenance
|
|
|
|
```sql
|
|
-- Clean up expired tokens
|
|
SELECT c77_secure_db_cleanup_expired_tokens();
|
|
|
|
-- Archive old audit logs (optional - adjust retention as needed)
|
|
DELETE FROM c77_secure_db_operation_audit
|
|
WHERE created_at < now() - interval '90 days';
|
|
|
|
-- Vacuum audit table
|
|
VACUUM ANALYZE c77_secure_db_operation_audit;
|
|
|
|
-- Update table statistics
|
|
ANALYZE c77_secure_db_auth_tokens;
|
|
ANALYZE c77_secure_db_secure_schemas;
|
|
```
|
|
|
|
#### Weekly Maintenance
|
|
|
|
```sql
|
|
-- Comprehensive hash verification on critical tables
|
|
SELECT c77_secure_db_verify_content_hashes('myapp', 'users');
|
|
SELECT c77_secure_db_verify_content_hashes('myapp', 'orders');
|
|
SELECT c77_secure_db_verify_content_hashes('myapp', 'transactions');
|
|
|
|
-- Performance review
|
|
SELECT
|
|
schema_name,
|
|
table_name,
|
|
count(*) as operation_count,
|
|
avg(execution_time_ms) as avg_execution_time
|
|
FROM c77_secure_db_operation_audit
|
|
WHERE created_at > now() - interval '7 days'
|
|
GROUP BY schema_name, table_name
|
|
HAVING avg(execution_time_ms) > 100 -- Flag slow operations
|
|
ORDER BY avg_execution_time DESC;
|
|
```
|
|
|
|
#### Monthly Maintenance
|
|
|
|
```sql
|
|
-- Full system test
|
|
SELECT c77_secure_db_run_all_tests();
|
|
|
|
-- Security audit - unusual patterns
|
|
SELECT
|
|
user_name,
|
|
operation_type,
|
|
count(*) as frequency,
|
|
min(created_at) as first_occurrence,
|
|
max(created_at) as last_occurrence
|
|
FROM c77_secure_db_operation_audit
|
|
WHERE created_at > now() - interval '30 days'
|
|
AND user_name IS NOT NULL
|
|
GROUP BY user_name, operation_type
|
|
HAVING count(*) > 1000 -- Flag high-frequency operations
|
|
ORDER BY frequency DESC;
|
|
|
|
-- Schema integrity check
|
|
SELECT
|
|
schema_name,
|
|
count(*) as table_count,
|
|
array_agg(table_name) as tables
|
|
FROM information_schema.tables t
|
|
WHERE EXISTS (
|
|
SELECT 1 FROM c77_secure_db_secure_schemas s
|
|
WHERE s.schema_name = t.table_schema
|
|
)
|
|
GROUP BY schema_name;
|
|
```
|
|
|
|
### Automated Monitoring Setup
|
|
|
|
#### PostgreSQL pg_cron Integration
|
|
|
|
```sql
|
|
-- Set up automated maintenance (requires pg_cron extension)
|
|
SELECT cron.schedule('secure-db-cleanup', '0 2 * * *', 'SELECT c77_secure_db_cleanup_expired_tokens();');
|
|
SELECT cron.schedule('secure-db-health-check', '*/15 * * * *', 'SELECT c77_secure_db_health_check();');
|
|
SELECT cron.schedule('secure-db-weekly-verify', '0 3 * * 0', 'SELECT c77_secure_db_verify_content_hashes(''myapp'', ''users'');');
|
|
```
|
|
|
|
#### Application-Level Monitoring
|
|
|
|
```php
|
|
// Laravel scheduled task (app/Console/Kernel.php)
|
|
protected function schedule(Schedule $schedule)
|
|
{
|
|
// Daily cleanup
|
|
$schedule->call(function () {
|
|
DB::select('SELECT c77_secure_db_cleanup_expired_tokens()');
|
|
})->daily()->at('02:00');
|
|
|
|
// Health check every 15 minutes
|
|
$schedule->call(function () {
|
|
$health = DB::selectOne('SELECT c77_secure_db_health_check() as result');
|
|
$status = json_decode($health->result, true);
|
|
|
|
// Alert if error rate > 5%
|
|
if ($status['error_rate_1h'] > 5) {
|
|
Log::critical('High error rate detected in c77_secure_db', $status);
|
|
// Send alert to monitoring system
|
|
}
|
|
})->everyFifteenMinutes();
|
|
}
|
|
```
|
|
|
|
## Security Best Practices
|
|
|
|
### 1. Never Use Direct SQL
|
|
|
|
```sql
|
|
-- ❌ NEVER DO THIS - Will be blocked by triggers
|
|
INSERT INTO myapp.users (name, email) VALUES ('John', 'john@example.com');
|
|
UPDATE myapp.users SET email = 'new@example.com' WHERE id = 1;
|
|
DELETE FROM myapp.users WHERE id = 1;
|
|
|
|
-- ✅ ALWAYS DO THIS - Use secure operations
|
|
SELECT c77_secure_db_operation(jsonb_build_object(
|
|
'schema_name', 'myapp',
|
|
'table_name', 'users',
|
|
'operation', 'insert',
|
|
'data', jsonb_build_object('name', 'John', 'email', 'john@example.com')
|
|
));
|
|
```
|
|
|
|
### 2. Implement Regular Integrity Checks
|
|
|
|
```sql
|
|
-- Schedule regular freshness verification
|
|
CREATE OR REPLACE FUNCTION verify_critical_tables()
|
|
RETURNS void LANGUAGE plpgsql AS $
|
|
BEGIN
|
|
-- Check users table
|
|
PERFORM c77_secure_db_verify_content_hashes('myapp', 'users');
|
|
|
|
-- Check financial data
|
|
PERFORM c77_secure_db_verify_content_hashes('myapp', 'transactions');
|
|
|
|
-- Check audit trails
|
|
PERFORM c77_secure_db_verify_content_hashes('myapp', 'audit_logs');
|
|
|
|
-- Log completion
|
|
RAISE NOTICE 'Integrity verification completed at %', now();
|
|
END;
|
|
$;
|
|
|
|
-- Run weekly
|
|
SELECT cron.schedule('integrity-check', '0 1 * * 0', 'SELECT verify_critical_tables();');
|
|
```
|
|
|
|
### 3. Monitor Audit Logs
|
|
|
|
```sql
|
|
-- Create monitoring view for suspicious activity
|
|
CREATE OR REPLACE VIEW security_alerts AS
|
|
SELECT
|
|
'High Error Rate' as alert_type,
|
|
user_name,
|
|
count(*) as error_count,
|
|
array_agg(DISTINCT error_message) as errors
|
|
FROM c77_secure_db_operation_audit
|
|
WHERE created_at > now() - interval '1 hour'
|
|
AND success = false
|
|
GROUP BY user_name
|
|
HAVING count(*) > 10
|
|
|
|
UNION ALL
|
|
|
|
SELECT
|
|
'Unusual Activity Pattern' as alert_type,
|
|
user_name,
|
|
count(*) as operation_count,
|
|
array_agg(DISTINCT operation_type) as operations
|
|
FROM c77_secure_db_operation_audit
|
|
WHERE created_at > now() - interval '1 hour'
|
|
GROUP BY user_name
|
|
HAVING count(*) > 100;
|
|
|
|
-- Check for alerts
|
|
SELECT * FROM security_alerts;
|
|
```
|
|
|
|
### 4. Secure Token Management
|
|
|
|
```sql
|
|
-- Monitor for token buildup (indicates possible issues)
|
|
SELECT
|
|
count(*) as total_tokens,
|
|
count(*) FILTER (WHERE expires_at < now()) as expired_tokens,
|
|
count(*) FILTER (WHERE used = true) as used_tokens,
|
|
max(created_at) as newest_token
|
|
FROM c77_secure_db_auth_tokens;
|
|
|
|
-- Alert if too many active tokens (threshold: 100)
|
|
DO $
|
|
DECLARE
|
|
v_token_count INTEGER;
|
|
BEGIN
|
|
SELECT count(*) INTO v_token_count
|
|
FROM c77_secure_db_auth_tokens
|
|
WHERE expires_at > now() AND used = false;
|
|
|
|
IF v_token_count > 100 THEN
|
|
RAISE WARNING 'High number of active tokens detected: %', v_token_count;
|
|
END IF;
|
|
END $;
|
|
```
|
|
|
|
### 5. Access Control Best Practices
|
|
|
|
```sql
|
|
-- Create application-specific roles
|
|
CREATE ROLE myapp_read_only;
|
|
CREATE ROLE myapp_operator;
|
|
CREATE ROLE myapp_administrator;
|
|
|
|
-- Grant secure database roles
|
|
GRANT c77_secure_db_readonly TO myapp_read_only;
|
|
GRANT c77_secure_db_user TO myapp_operator;
|
|
GRANT c77_secure_db_admin TO myapp_administrator;
|
|
|
|
-- Grant to your application users
|
|
GRANT myapp_operator TO myapp_user;
|
|
GRANT myapp_read_only TO myapp_reporting_user;
|
|
GRANT myapp_administrator TO myapp_admin_user;
|
|
|
|
-- Revoke dangerous permissions
|
|
REVOKE ALL ON c77_secure_db_auth_tokens FROM PUBLIC;
|
|
REVOKE ALL ON c77_secure_db_operation_audit FROM PUBLIC;
|
|
```
|
|
|
|
## Troubleshooting
|
|
|
|
### Common Error Messages
|
|
|
|
#### "Direct modifications are not allowed"
|
|
|
|
**Error:**
|
|
```
|
|
ERROR: Direct modifications not allowed on secure table myapp.users. Use c77_secure_db_operation() function.
|
|
```
|
|
|
|
**Cause:** Attempting to use direct SQL (INSERT, UPDATE, DELETE) on a secure table.
|
|
|
|
**Solution:**
|
|
```sql
|
|
-- Instead of:
|
|
INSERT INTO myapp.users (name) VALUES ('John');
|
|
|
|
-- Use:
|
|
SELECT c77_secure_db_operation(jsonb_build_object(
|
|
'schema_name', 'myapp',
|
|
'table_name', 'users',
|
|
'operation', 'insert',
|
|
'data', jsonb_build_object('name', 'John')
|
|
));
|
|
```
|
|
|
|
#### "RBAC enabled but no user context set"
|
|
|
|
**Error:**
|
|
```json
|
|
{
|
|
"success": false,
|
|
"error": "RBAC enabled but no user context set",
|
|
"hint": "Set c77_rbac.external_id session variable"
|
|
}
|
|
```
|
|
|
|
**Cause:** RBAC checking is enabled but user context is not set.
|
|
|
|
**Solution:**
|
|
```sql
|
|
-- Set user context before operation
|
|
SET "c77_rbac.external_id" TO '123';
|
|
|
|
-- Or disable RBAC checking
|
|
SELECT c77_secure_db_operation(
|
|
jsonb_build_object(...),
|
|
false -- check_rbac = false
|
|
);
|
|
```
|
|
|
|
#### "Insufficient permissions"
|
|
|
|
**Error:**
|
|
```json
|
|
{
|
|
"success": false,
|
|
"error": "Insufficient permissions",
|
|
"required_feature": "secure_db_delete",
|
|
"user_id": "456"
|
|
}
|
|
```
|
|
|
|
**Cause:** User doesn't have the required RBAC permission.
|
|
|
|
**Solution:**
|
|
```sql
|
|
-- Grant the required feature to user's role
|
|
SELECT c77_rbac_grant_feature('user_role', 'secure_db_delete');
|
|
|
|
-- Or assign user to a role that has the permission
|
|
SELECT c77_rbac_assign_subject('456', 'admin_role', 'global', 'all');
|
|
```
|
|
|
|
#### "Primary key required for update operation"
|
|
|
|
**Error:**
|
|
```json
|
|
{
|
|
"success": false,
|
|
"error": "Primary key \"id\" required for update operation"
|
|
}
|
|
```
|
|
|
|
**Cause:** UPDATE operation doesn't include the primary key in the data.
|
|
|
|
**Solution:**
|
|
```sql
|
|
-- Include primary key in data
|
|
SELECT c77_secure_db_operation(jsonb_build_object(
|
|
'schema_name', 'myapp',
|
|
'table_name', 'users',
|
|
'operation', 'update',
|
|
'data', jsonb_build_object(
|
|
'id', 123, -- Primary key required
|
|
'name', 'Updated Name'
|
|
)
|
|
));
|
|
```
|
|
|
|
### Diagnostic Commands
|
|
|
|
#### Check Extension Status
|
|
|
|
```sql
|
|
-- Verify extension is installed
|
|
SELECT extname, extversion FROM pg_extension WHERE extname = 'c77_secure_db';
|
|
|
|
-- Check health
|
|
SELECT c77_secure_db_health_check();
|
|
|
|
-- Run security tests
|
|
SELECT c77_secure_db_test_security();
|
|
```
|
|
|
|
#### Check Schema Registration
|
|
|
|
```sql
|
|
-- List secure schemas
|
|
SELECT c77_secure_db_manage_secure_schemas('list');
|
|
|
|
-- Check if triggers are applied
|
|
SELECT
|
|
schemaname,
|
|
tablename,
|
|
count(*) as trigger_count
|
|
FROM pg_triggers
|
|
WHERE tgname LIKE 'c77_secure_db_%'
|
|
GROUP BY schemaname, tablename;
|
|
```
|
|
|
|
#### Analyze Recent Operations
|
|
|
|
```sql
|
|
-- Check recent operations
|
|
SELECT
|
|
operation_type,
|
|
success,
|
|
error_message,
|
|
user_name,
|
|
created_at
|
|
FROM c77_secure_db_operation_audit
|
|
WHERE created_at > now() - interval '1 hour'
|
|
ORDER BY created_at DESC
|
|
LIMIT 20;
|
|
|
|
-- Check for patterns in failures
|
|
SELECT
|
|
error_message,
|
|
count(*) as frequency,
|
|
array_agg(DISTINCT user_name) as affected_users
|
|
FROM c77_secure_db_operation_audit
|
|
WHERE success = false
|
|
AND created_at > now() - interval '24 hours'
|
|
GROUP BY error_message
|
|
ORDER BY frequency DESC;
|
|
```
|
|
|
|
#### Debug Token Issues
|
|
|
|
```sql
|
|
-- Check active tokens
|
|
SELECT
|
|
token,
|
|
session_id,
|
|
operation_type,
|
|
created_at,
|
|
expires_at,
|
|
used,
|
|
(expires_at > now()) as is_valid
|
|
FROM c77_secure_db_auth_tokens
|
|
ORDER BY created_at DESC;
|
|
|
|
-- Clean up if needed
|
|
SELECT c77_secure_db_cleanup_expired_tokens();
|
|
```
|
|
|
|
### Performance Troubleshooting
|
|
|
|
#### Slow Operations
|
|
|
|
```sql
|
|
-- Identify slow operations
|
|
SELECT
|
|
operation_type,
|
|
schema_name,
|
|
table_name,
|
|
avg(execution_time_ms) as avg_time,
|
|
max(execution_time_ms) as max_time,
|
|
count(*) as operation_count
|
|
FROM c77_secure_db_operation_audit
|
|
WHERE created_at > now() - interval '24 hours'
|
|
AND execution_time_ms IS NOT NULL
|
|
GROUP BY operation_type, schema_name, table_name
|
|
HAVING avg(execution_time_ms) > 100
|
|
ORDER BY avg_time DESC;
|
|
|
|
-- Check for missing indexes
|
|
SELECT
|
|
schemaname,
|
|
tablename,
|
|
attname,
|
|
n_distinct,
|
|
correlation
|
|
FROM pg_stats
|
|
WHERE schemaname IN (
|
|
SELECT schema_name FROM c77_secure_db_secure_schemas
|
|
)
|
|
AND (n_distinct > 100 OR correlation < 0.1);
|
|
```
|
|
|
|
#### Hash Verification Performance
|
|
|
|
```sql
|
|
-- Test hash calculation performance
|
|
DO $
|
|
DECLARE
|
|
start_time TIMESTAMP;
|
|
end_time TIMESTAMP;
|
|
test_data JSONB := '{"name": "Test User", "email": "test@example.com", "description": "This is a test record with some data"}';
|
|
calculated_hash TEXT;
|
|
BEGIN
|
|
start_time := clock_timestamp();
|
|
|
|
-- Calculate hash 1000 times
|
|
FOR i IN 1..1000 LOOP
|
|
calculated_hash := c77_secure_db_calculate_content_hash('myapp', 'users', test_data);
|
|
END LOOP;
|
|
|
|
end_time := clock_timestamp();
|
|
|
|
RAISE NOTICE 'Hash calculation performance: % operations in % ms (avg: % ms per operation)',
|
|
1000,
|
|
EXTRACT(milliseconds FROM (end_time - start_time)),
|
|
EXTRACT(milliseconds FROM (end_time - start_time)) / 1000;
|
|
END $;
|
|
```
|
|
|
|
## API Reference
|
|
|
|
### Core Functions
|
|
|
|
#### c77_secure_db_operation()
|
|
|
|
**Purpose:** Main function for secure database operations
|
|
|
|
**Signatures:**
|
|
```sql
|
|
c77_secure_db_operation(p_json_data JSONB) RETURNS JSONB
|
|
c77_secure_db_operation(p_json_data JSONB, p_check_rbac BOOLEAN, p_required_feature TEXT, p_scope_type TEXT, p_scope_id TEXT) RETURNS JSONB
|
|
```
|
|
|
|
**Parameters:**
|
|
- `p_json_data`: Operation configuration (required)
|
|
- `p_check_rbac`: Enable RBAC checking (default: false)
|
|
- `p_required_feature`: Required RBAC feature (optional)
|
|
- `p_scope_type`: RBAC scope type (optional)
|
|
- `p_scope_id`: RBAC scope identifier (optional)
|
|
|
|
**JSON Data Structure:**
|
|
```json
|
|
{
|
|
"schema_name": "myapp", // Required: target schema
|
|
"table_name": "users", // Required: target table
|
|
"operation": "insert", // Required: insert|update|upsert|delete|soft_delete
|
|
"data": { // Required: operation data
|
|
"name": "John Doe",
|
|
"email": "john@example.com"
|
|
},
|
|
"primary_key": "id" // Optional: primary key column (default: "id")
|
|
}
|
|
```
|
|
|
|
**Response Structure:**
|
|
```json
|
|
{
|
|
"success": true,
|
|
"operation": "insert",
|
|
"schema_name": "myapp",
|
|
"table_name": "users",
|
|
"rows_affected": 1,
|
|
"content_hash": "a1b2c3d4...",
|
|
"execution_time_ms": 12,
|
|
"operation_id": "550e8400-e29b-41d4-a716-446655440000",
|
|
"rbac_check_performed": false,
|
|
"timestamp": "2025-01-26T10:30:00Z"
|
|
}
|
|
```
|
|
|
|
#### c77_secure_db_check_freshness()
|
|
|
|
**Purpose:** Verify if a record has been tampered with
|
|
|
|
**Signature:**
|
|
```sql
|
|
c77_secure_db_check_freshness(p_schema_name TEXT, p_table_name TEXT, p_data JSONB) RETURNS JSONB
|
|
```
|
|
|
|
**Parameters:**
|
|
- `p_schema_name`: Target schema name
|
|
- `p_table_name`: Target table name
|
|
- `p_data`: Record data to verify (must include primary key)
|
|
|
|
**Example:**
|
|
```sql
|
|
SELECT c77_secure_db_check_freshness(
|
|
'myapp',
|
|
'users',
|
|
'{"id": 1, "name": "John Doe", "email": "john@example.com"}'::jsonb
|
|
);
|
|
```
|
|
|
|
#### c77_secure_db_verify_content_hashes()
|
|
|
|
**Purpose:** Verify content hashes for all records in a table
|
|
|
|
**Signature:**
|
|
```sql
|
|
c77_secure_db_verify_content_hashes(p_schema_name TEXT, p_table_name TEXT, p_fix_mismatches BOOLEAN DEFAULT false, p_batch_size INTEGER DEFAULT 1000) RETURNS JSONB
|
|
```
|
|
|
|
**Parameters:**
|
|
- `p_schema_name`: Target schema name
|
|
- `p_table_name`: Target table name
|
|
- `p_fix_mismatches`: Whether to fix hash mismatches (default: false)
|
|
- `p_batch_size`: Processing batch size (default: 1000)
|
|
|
|
### Schema Management Functions
|
|
|
|
#### c77_secure_db_manage_secure_schemas()
|
|
|
|
**Purpose:** Manage the registry of secure schemas
|
|
|
|
**Signature:**
|
|
```sql
|
|
c77_secure_db_manage_secure_schemas(p_operation TEXT, p_schema_name TEXT DEFAULT NULL) RETURNS JSONB
|
|
```
|
|
|
|
**Operations:**
|
|
- `'list'`: List all secure schemas
|
|
- `'add'`: Add schema to secure registry
|
|
- `'remove'`: Remove schema from secure registry
|
|
|
|
**Examples:**
|
|
```sql
|
|
-- List secure schemas
|
|
SELECT c77_secure_db_manage_secure_schemas('list');
|
|
|
|
-- Add schema
|
|
SELECT c77_secure_db_manage_secure_schemas('add', 'myapp');
|
|
|
|
-- Remove schema
|
|
SELECT c77_secure_db_manage_secure_schemas('remove', 'myapp');
|
|
```
|
|
|
|
### Utility Functions
|
|
|
|
#### c77_secure_db_get_operation_template()
|
|
|
|
**Purpose:** Generate SQL templates for operations
|
|
|
|
**Signature:**
|
|
```sql
|
|
c77_secure_db_get_operation_template(p_schema_name TEXT, p_table_name TEXT, p_operation TEXT) RETURNS TEXT
|
|
```
|
|
|
|
#### c77_secure_db_health_check()
|
|
|
|
**Purpose:** System health and status check
|
|
|
|
**Signature:**
|
|
```sql
|
|
c77_secure_db_health_check() RETURNS JSONB
|
|
```
|
|
|
|
#### c77_secure_db_cleanup_expired_tokens()
|
|
|
|
**Purpose:** Clean up expired authorization tokens
|
|
|
|
**Signature:**
|
|
```sql
|
|
c77_secure_db_cleanup_expired_tokens() RETURNS INTEGER
|
|
```
|
|
|
|
### Testing Functions
|
|
|
|
#### c77_secure_db_run_all_tests()
|
|
|
|
**Purpose:** Run comprehensive test suite
|
|
|
|
**Signature:**
|
|
```sql
|
|
c77_secure_db_run_all_tests() RETURNS JSONB
|
|
```
|
|
|
|
#### c77_secure_db_test_security()
|
|
|
|
**Purpose:** Run security-specific tests
|
|
|
|
**Signature:**
|
|
```sql
|
|
c77_secure_db_test_security() RETURNS JSONB
|
|
```
|
|
|
|
#### c77_secure_db_test_rbac_integration()
|
|
|
|
**Purpose:** Test RBAC integration
|
|
|
|
**Signature:**
|
|
```sql
|
|
c77_secure_db_test_rbac_integration() RETURNS JSONB
|
|
```
|
|
|
|
## Examples and Use Cases
|
|
|
|
### E-commerce Platform
|
|
|
|
```sql
|
|
-- Set up e-commerce schema
|
|
CREATE SCHEMA ecommerce;
|
|
SELECT c77_secure_db_manage_secure_schemas('add', 'ecommerce');
|
|
|
|
-- Create secure tables
|
|
CREATE TABLE ecommerce.customers (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
email TEXT UNIQUE NOT NULL,
|
|
first_name TEXT,
|
|
last_name TEXT,
|
|
phone TEXT,
|
|
-- Security columns
|
|
content_hash TEXT,
|
|
hash_version INTEGER DEFAULT 1,
|
|
created_at TIMESTAMPTZ DEFAULT NOW(),
|
|
updated_at TIMESTAMPTZ DEFAULT NOW(),
|
|
deleted_at TIMESTAMPTZ
|
|
);
|
|
|
|
CREATE TABLE ecommerce.orders (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
customer_id BIGINT REFERENCES ecommerce.customers(id),
|
|
total_amount DECIMAL(10,2),
|
|
status TEXT DEFAULT 'pending',
|
|
-- Security columns
|
|
content_hash TEXT,
|
|
hash_version INTEGER DEFAULT 1,
|
|
created_at TIMESTAMPTZ DEFAULT NOW(),
|
|
updated_at TIMESTAMPTZ DEFAULT NOW(),
|
|
deleted_at TIMESTAMPTZ
|
|
);
|
|
|
|
-- RBAC setup for e-commerce
|
|
SELECT c77_rbac_grant_feature('customer_service', 'secure_db_read');
|
|
SELECT c77_rbac_grant_feature('customer_service', 'secure_db_update');
|
|
SELECT c77_rbac_grant_feature('order_manager', 'secure_db_insert');
|
|
SELECT c77_rbac_grant_feature('order_manager', 'secure_db_update');
|
|
SELECT c77_rbac_grant_feature('finance_team', 'secure_db_read');
|
|
|
|
-- Create customer
|
|
SELECT c77_secure_db_operation(jsonb_build_object(
|
|
'schema_name', 'ecommerce',
|
|
'table_name', 'customers',
|
|
'operation', 'insert',
|
|
'data', jsonb_build_object(
|
|
'email', 'customer@example.com',
|
|
'first_name', 'John',
|
|
'last_name', 'Doe',
|
|
'phone', '+1-555-0123'
|
|
)
|
|
));
|
|
|
|
-- Create order with RBAC
|
|
SET "c77_rbac.external_id" TO '123'; -- Order manager user
|
|
SELECT c77_secure_db_operation(
|
|
jsonb_build_object(
|
|
'schema_name', 'ecommerce',
|
|
'table_name', 'orders',
|
|
'operation', 'insert',
|
|
'data', jsonb_build_object(
|
|
'customer_id', 1,
|
|
'total_amount', 99.99,
|
|
'status', 'confirmed'
|
|
)
|
|
),
|
|
true, -- check_rbac
|
|
'secure_db_insert' -- required_feature
|
|
);
|
|
|
|
-- Update order status
|
|
SELECT c77_secure_db_operation(
|
|
jsonb_build_object(
|
|
'schema_name', 'ecommerce',
|
|
'table_name', 'orders',
|
|
'operation', 'update',
|
|
'data', jsonb_build_object(
|
|
'id', 1,
|
|
'status', 'shipped'
|
|
)
|
|
),
|
|
true,
|
|
'secure_db_update'
|
|
);
|
|
```
|
|
|
|
### Healthcare System
|
|
|
|
```sql
|
|
-- Healthcare schema with strict audit requirements
|
|
CREATE SCHEMA healthcare;
|
|
SELECT c77_secure_db_manage_secure_schemas('add', 'healthcare');
|
|
|
|
CREATE TABLE healthcare.patients (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
medical_record_number TEXT UNIQUE NOT NULL,
|
|
first_name TEXT NOT NULL,
|
|
last_name TEXT NOT NULL,
|
|
date_of_birth DATE,
|
|
ssn TEXT, -- Sensitive data
|
|
-- Security columns
|
|
content_hash TEXT,
|
|
hash_version INTEGER DEFAULT 1,
|
|
created_at TIMESTAMPTZ DEFAULT NOW(),
|
|
updated_at TIMESTAMPTZ DEFAULT NOW(),
|
|
deleted_at TIMESTAMPTZ
|
|
);
|
|
|
|
-- Exclude frequently changing fields from hash
|
|
COMMENT ON COLUMN healthcare.patients.content_hash IS
|
|
'{"exclude_hash_columns": ["last_access_date", "access_count"]}';
|
|
|
|
-- RBAC for healthcare
|
|
SELECT c77_rbac_grant_feature('doctor', 'secure_db_insert');
|
|
SELECT c77_rbac_grant_feature('doctor', 'secure_db_update');
|
|
SELECT c77_rbac_grant_feature('doctor', 'secure_db_read');
|
|
SELECT c77_rbac_grant_feature('nurse', 'secure_db_read');
|
|
SELECT c77_rbac_grant_feature('nurse', 'secure_db_update');
|
|
SELECT c77_rbac_grant_feature('admin', 'secure_db_admin');
|
|
|
|
-- Department-based access
|
|
SELECT c77_rbac_assign_subject('doctor_001', 'doctor', 'department', 'cardiology');
|
|
SELECT c77_rbac_assign_subject('nurse_001', 'nurse', 'department', 'cardiology');
|
|
|
|
-- Create patient record
|
|
SET "c77_rbac.external_id" TO 'doctor_001';
|
|
SELECT c77_secure_db_operation(
|
|
jsonb_build_object(
|
|
'schema_name', 'healthcare',
|
|
'table_name', 'patients',
|
|
'operation', 'insert',
|
|
'data', jsonb_build_object(
|
|
'medical_record_number', 'MRN-2025-001',
|
|
'first_name', 'Jane',
|
|
'last_name', 'Smith',
|
|
'date_of_birth', '1985-03-15',
|
|
'ssn', '123-45-6789'
|
|
)
|
|
),
|
|
true,
|
|
'secure_db_insert',
|
|
'department',
|
|
'cardiology'
|
|
);
|
|
|
|
-- Regular integrity check for compliance
|
|
SELECT c77_secure_db_verify_content_hashes('healthcare', 'patients');
|
|
|
|
-- Audit report for compliance
|
|
SELECT
|
|
user_name as healthcare_user,
|
|
operation_type,
|
|
count(*) as operation_count,
|
|
min(created_at) as first_access,
|
|
max(created_at) as last_access
|
|
FROM c77_secure_db_operation_audit
|
|
WHERE schema_name = 'healthcare'
|
|
AND created_at > now() - interval '30 days'
|
|
GROUP BY user_name, operation_type
|
|
ORDER BY operation_count DESC;
|
|
```
|
|
|
|
### Financial Services
|
|
|
|
```sql
|
|
-- Financial services with high security requirements
|
|
CREATE SCHEMA finance;
|
|
SELECT c77_secure_db_manage_secure_schemas('add', 'finance');
|
|
|
|
CREATE TABLE finance.accounts (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
account_number TEXT UNIQUE NOT NULL,
|
|
account_type TEXT NOT NULL,
|
|
balance DECIMAL(15,2) DEFAULT 0.00,
|
|
customer_id BIGINT,
|
|
status TEXT DEFAULT 'active',
|
|
-- Security columns
|
|
content_hash TEXT,
|
|
hash_version INTEGER DEFAULT 1,
|
|
created_at TIMESTAMPTZ DEFAULT NOW(),
|
|
updated_at TIMESTAMPTZ DEFAULT NOW(),
|
|
deleted_at TIMESTAMPTZ
|
|
);
|
|
|
|
CREATE TABLE finance.transactions (
|
|
id BIGSERIAL PRIMARY KEY,
|
|
account_id BIGINT REFERENCES finance.accounts(id),
|
|
transaction_type TEXT NOT NULL,
|
|
amount DECIMAL(15,2) NOT NULL,
|
|
description TEXT,
|
|
reference_number TEXT UNIQUE,
|
|
-- Security columns
|
|
content_hash TEXT,
|
|
hash_version INTEGER DEFAULT 1,
|
|
created_at TIMESTAMPTZ DEFAULT NOW(),
|
|
updated_at TIMESTAMPTZ DEFAULT NOW(),
|
|
deleted_at TIMESTAMPTZ
|
|
);
|
|
|
|
-- Financial RBAC - very restrictive
|
|
SELECT c77_rbac_grant_feature('teller', 'secure_db_read');
|
|
SELECT c77_rbac_grant_feature('teller', 'secure_db_insert'); -- Deposits/withdrawals only
|
|
SELECT c77_rbac_grant_feature('account_manager', 'secure_db_read');
|
|
SELECT c77_rbac_grant_feature('account_manager', 'secure_db_update');
|
|
SELECT c77_rbac_grant_feature('supervisor', 'secure_db_delete');
|
|
SELECT c77_rbac_grant_feature('auditor', 'secure_db_admin');
|
|
|
|
-- Branch-based access control
|
|
SELECT c77_rbac_assign_subject('teller_001', 'teller', 'branch', 'downtown');
|
|
SELECT c77_rbac_assign_subject('manager_001', 'account_manager', 'branch', 'downtown');
|
|
|
|
-- Record transaction with full audit trail
|
|
SET "c77_rbac.external_id" TO 'teller_001';
|
|
SELECT c77_secure_db_operation(
|
|
jsonb_build_object(
|
|
'schema_name', 'finance',
|
|
'table_name', 'transactions',
|
|
'operation', 'insert',
|
|
'data', jsonb_build_object(
|
|
'account_id', 1001,
|
|
'transaction_type', 'deposit',
|
|
'amount', 500.00,
|
|
'description', 'Cash deposit',
|
|
'reference_number', 'TXN-' || extract(epoch from now())::bigint
|
|
)
|
|
),
|
|
true,
|
|
'secure_db_insert',
|
|
'branch',
|
|
'downtown'
|
|
);
|
|
|
|
-- Daily integrity verification for financial data
|
|
DO $
|
|
DECLARE
|
|
v_accounts_result JSONB;
|
|
v_transactions_result JSONB;
|
|
BEGIN
|
|
-- Verify accounts
|
|
SELECT c77_secure_db_verify_content_hashes('finance', 'accounts') INTO v_accounts_result;
|
|
|
|
-- Verify transactions
|
|
SELECT c77_secure_db_verify_content_hashes('finance', 'transactions') INTO v_transactions_result;
|
|
|
|
-- Alert if any mismatches found
|
|
IF (v_accounts_result->>'mismatch_count')::INTEGER > 0 THEN
|
|
RAISE EXCEPTION 'CRITICAL: Account data integrity compromise detected!';
|
|
END IF;
|
|
|
|
IF (v_transactions_result->>'mismatch_count')::INTEGER > 0 THEN
|
|
RAISE EXCEPTION 'CRITICAL: Transaction data integrity compromise detected!';
|
|
END IF;
|
|
|
|
RAISE NOTICE 'Financial data integrity verification passed';
|
|
END $;
|
|
```
|
|
|
|
---
|
|
|
|
This comprehensive usage guide covers all aspects of the c77_secure_db extension from basic setup to advanced enterprise scenarios. The document serves as both a tutorial for new users and a reference for experienced developers implementing secure database operations in production environments. |