postgres-service/init/01-init.sql

85 lines
3.3 KiB
SQL

-- PostgreSQL Initialization Script
-- This script will be executed when the PostgreSQL container is first created
-- Create extensions
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
CREATE EXTENSION IF NOT EXISTS "pg_stat_statements";
CREATE EXTENSION IF NOT EXISTS "pgcrypto";
-- Create roles
CREATE ROLE readonly;
GRANT CONNECT ON DATABASE postgres TO readonly;
GRANT USAGE ON SCHEMA public TO readonly;
GRANT SELECT ON ALL TABLES IN SCHEMA public TO readonly;
ALTER DEFAULT PRIVILEGES IN SCHEMA public GRANT SELECT ON TABLES TO readonly;
CREATE ROLE readwrite;
GRANT CONNECT ON DATABASE postgres TO readwrite;
GRANT USAGE, CREATE ON SCHEMA public TO readwrite;
GRANT SELECT, INSERT, UPDATE, DELETE ON ALL TABLES IN SCHEMA public TO readwrite;
ALTER DEFAULT PRIVILEGES IN SCHEMA public GRANT SELECT, INSERT, UPDATE, DELETE ON TABLES TO readwrite;
GRANT USAGE ON ALL SEQUENCES IN SCHEMA public TO readwrite;
ALTER DEFAULT PRIVILEGES IN SCHEMA public GRANT USAGE ON SEQUENCES TO readwrite;
-- Create sample users
CREATE USER sample_readonly WITH PASSWORD 'readonly_password';
GRANT readonly TO sample_readonly;
CREATE USER sample_readwrite WITH PASSWORD 'readwrite_password';
GRANT readwrite TO sample_readwrite;
-- Create sample schema and tables
CREATE SCHEMA IF NOT EXISTS sample;
CREATE TABLE IF NOT EXISTS sample.users (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
username VARCHAR(50) NOT NULL UNIQUE,
email VARCHAR(100) NOT NULL UNIQUE,
password_hash VARCHAR(100) NOT NULL,
first_name VARCHAR(50),
last_name VARCHAR(50),
is_active BOOLEAN DEFAULT TRUE,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
CREATE TABLE IF NOT EXISTS sample.posts (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
user_id UUID NOT NULL REFERENCES sample.users(id) ON DELETE CASCADE,
title VARCHAR(200) NOT NULL,
content TEXT,
is_published BOOLEAN DEFAULT FALSE,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
-- Create indexes
CREATE INDEX IF NOT EXISTS idx_users_username ON sample.users(username);
CREATE INDEX IF NOT EXISTS idx_users_email ON sample.users(email);
CREATE INDEX IF NOT EXISTS idx_posts_user_id ON sample.posts(user_id);
CREATE INDEX IF NOT EXISTS idx_posts_created_at ON sample.posts(created_at);
-- Insert sample data
INSERT INTO sample.users (username, email, password_hash, first_name, last_name)
VALUES
('johndoe', 'john.doe@example.com', crypt('password123', gen_salt('bf')), 'John', 'Doe'),
('janedoe', 'jane.doe@example.com', crypt('password123', gen_salt('bf')), 'Jane', 'Doe')
ON CONFLICT (username) DO NOTHING;
-- Get user IDs for sample posts
DO $$
DECLARE
john_id UUID;
jane_id UUID;
BEGIN
SELECT id INTO john_id FROM sample.users WHERE username = 'johndoe';
SELECT id INTO jane_id FROM sample.users WHERE username = 'janedoe';
INSERT INTO sample.posts (user_id, title, content, is_published)
VALUES
(john_id, 'First Post', 'This is my first post content.', TRUE),
(john_id, 'Second Post', 'This is my second post content.', FALSE),
(jane_id, 'Hello World', 'Hello world post content.', TRUE)
ON CONFLICT DO NOTHING;
END $$;