c77_secure_db

PostgreSQL extension for secure database operations with tamper detection and transaction control.

Overview

The c77_secure_db extension provides a comprehensive set of functions to ensure data integrity and prevent unauthorized modification of data in PostgreSQL tables. It implements content hashing to detect tampering and enforces all modifications to go through a secure function rather than direct SQL commands.

Key features:

  • Prevents direct table modifications (INSERT, UPDATE, DELETE) through triggers
  • Calculates and verifies content hashes to detect data tampering
  • Automatically manages timestamps (created_at, updated_at, deleted_at)
  • Provides soft delete functionality
  • Supports verification of data integrity across entire tables
  • Handles batch operations efficiently

Requirements

  • PostgreSQL 11 or higher
  • pgcrypto extension

Installation

From Source

  1. Clone the repository:
git clone https://github.com/yourusername/c77_secure_db.git
cd c77_secure_db
  1. Build and install the extension:
make
make install
  1. Create the extension in your database:
CREATE EXTENSION pgcrypto;  -- required dependency
CREATE EXTENSION c77_secure_db;

Manual Installation

If you don't want to use make, you can manually install the extension:

  1. Copy c77_secure_db.control to your PostgreSQL shared extension directory:
cp c77_secure_db.control $(pg_config --sharedir)/extension/
  1. Copy the SQL file to your PostgreSQL extension directory:
cp c77_secure_db--1.0.0.sql $(pg_config --sharedir)/extension/
  1. Create the extension in your database:
CREATE EXTENSION pgcrypto;  -- required dependency
CREATE EXTENSION c77_secure_db;

Usage

Setting Up a Secure Schema

  1. Create a schema for your secure tables:
CREATE SCHEMA secure_data;
  1. Register the schema with the secure database system:
SELECT c77_manage_secure_schemas('add', 'secure_data');
  1. Apply triggers to existing tables in the schema:
SELECT c77_apply_prevent_triggers('secure_data');

Creating Secure Tables

When creating tables in your secure schema, include the required columns for security and auditing:

CREATE TABLE secure_data.sensitive_data (
    id BIGSERIAL PRIMARY KEY,
    name TEXT NOT NULL,
    description TEXT,
    content_hash TEXT,
    hash_version INTEGER DEFAULT 1,
    created_at TIMESTAMPTZ DEFAULT NOW(),
    updated_at TIMESTAMPTZ DEFAULT NOW(),
    deleted_at TIMESTAMPTZ DEFAULT NULL
);

The triggers will be automatically applied to new tables in registered schemas.

Performing Secure Operations

Instead of using direct SQL commands, use the c77_secure_db_operation function:

-- Insert
SELECT c77_secure_db_operation(
    jsonb_build_object(
        'schema_name', 'secure_data',
        'table_name', 'sensitive_data',
        'operation', 'insert',
        'data', jsonb_build_object(
            'name', 'Example Entry',
            'description', 'This is a test'
        )
    )
);

-- Update
SELECT c77_secure_db_operation(
    jsonb_build_object(
        'schema_name', 'secure_data',
        'table_name', 'sensitive_data',
        'operation', 'update',
        'primary_key', 'id',
        'data', jsonb_build_object(
            'id', 1,
            'name', 'Updated Example',
            'description', 'This has been updated'
        )
    )
);

-- Delete (soft delete if deleted_at column exists)
SELECT c77_secure_db_operation(
    jsonb_build_object(
        'schema_name', 'secure_data',
        'table_name', 'sensitive_data',
        'operation', 'delete',
        'primary_key', 'id',
        'data', jsonb_build_object(
            'id', 1
        )
    )
);

Generating Operation Templates

You can generate operation templates for any table:

SELECT c77_get_operation_template('secure_data', 'sensitive_data', 'insert');

This will generate a complete SQL template that you can copy and modify.

Verifying Data Integrity

To check if a record has been tampered with:

SELECT c77_check_freshness(
    'secure_data', 
    'sensitive_data', 
    jsonb_build_object('id', 1, 'name', 'Example Entry', 'description', 'This is a test')
);

To verify content hashes for all records in a table:

SELECT c77_verify_content_hashes('secure_data', 'sensitive_data');

To fix any hash mismatches:

SELECT c77_verify_content_hashes('secure_data', 'sensitive_data', true);

Function Reference

Main Functions

  • c77_secure_db_operation(jsonb): Securely performs database operations
  • c77_verify_content_hashes(text, text, boolean, integer): Verifies content hashes for all records in a table
  • c77_check_freshness(text, text, jsonb): Verifies if a record has been modified
  • c77_calculate_content_hash(text, text, jsonb): Calculates a content hash for a record
  • c77_get_operation_template(text, text, text): Generates a template for secure operations
  • c77_manage_secure_schemas(text, text): Manages secure schemas

Support Functions

  • c77_prevent_direct_modification(): Trigger function to prevent direct modifications
  • c77_apply_prevent_triggers(text): Applies prevention triggers to all tables in a schema
  • c77_auto_apply_prevent_triggers(): Event trigger function for automatically applying triggers

Integration with Application Frameworks

Laravel Integration

This extension can be paired with a Laravel integration package to provide a seamless experience. Check out the Laravel integration guide for more details.

Security Considerations

  • The myapp.allow_direct_modification setting controls whether direct modifications are allowed. This extension manages this setting internally and resets it after each operation.
  • Ensure that only trusted users have permission to execute the functions in this extension.
  • For maximum security, consider revoking direct INSERT, UPDATE, and DELETE permissions on secure tables for application users.

License

This project is licensed under the MIT License - see the LICENSE file for details.

Contributing

Contributions are welcome! Please feel free to submit a Pull Request.

Description
Secure database operations extension for PostgreSQL
Readme 137 KiB
Languages
PLpgSQL 100%