207 lines
6.0 KiB
JavaScript
207 lines
6.0 KiB
JavaScript
const db = require('./db');
|
|
const logger = require('../utils/logger');
|
|
|
|
const initDatabase = async () => {
|
|
const client = await db.getClient();
|
|
|
|
try {
|
|
await client.query('BEGIN');
|
|
|
|
// Create enum types
|
|
await client.query(`
|
|
DO $$ BEGIN
|
|
CREATE TYPE resource_type AS ENUM (
|
|
'food_bank',
|
|
'community_meal',
|
|
'hamper',
|
|
'pantry',
|
|
'soup_kitchen',
|
|
'mobile_food',
|
|
'grocery_program',
|
|
'other'
|
|
);
|
|
EXCEPTION
|
|
WHEN duplicate_object THEN null;
|
|
END $$;
|
|
`);
|
|
|
|
await client.query(`
|
|
DO $$ BEGIN
|
|
CREATE TYPE data_source AS ENUM (
|
|
'informalberta',
|
|
'ab211',
|
|
'edmonton_foodbank_pdf',
|
|
'manual'
|
|
);
|
|
EXCEPTION
|
|
WHEN duplicate_object THEN null;
|
|
END $$;
|
|
`);
|
|
|
|
// Create main resources table
|
|
await client.query(`
|
|
CREATE TABLE IF NOT EXISTS food_resources (
|
|
id SERIAL PRIMARY KEY,
|
|
name VARCHAR(500) NOT NULL,
|
|
description TEXT,
|
|
resource_type resource_type DEFAULT 'other',
|
|
|
|
-- Location info
|
|
address VARCHAR(500),
|
|
city VARCHAR(100),
|
|
province VARCHAR(50) DEFAULT 'Alberta',
|
|
postal_code VARCHAR(10),
|
|
latitude DECIMAL(10, 8),
|
|
longitude DECIMAL(11, 8),
|
|
|
|
-- Contact info
|
|
phone VARCHAR(50),
|
|
email VARCHAR(255),
|
|
website VARCHAR(500),
|
|
|
|
-- Operating info
|
|
hours_of_operation TEXT,
|
|
eligibility TEXT,
|
|
services_offered TEXT,
|
|
|
|
-- Meta info
|
|
source data_source NOT NULL,
|
|
source_url VARCHAR(500),
|
|
source_id VARCHAR(100),
|
|
|
|
-- Timestamps
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
|
last_verified_at TIMESTAMP WITH TIME ZONE,
|
|
|
|
-- Status
|
|
is_active BOOLEAN DEFAULT true,
|
|
|
|
-- Unique constraint on source + source_id
|
|
UNIQUE(source, source_id)
|
|
);
|
|
`);
|
|
|
|
// Create indexes
|
|
await client.query(`
|
|
CREATE INDEX IF NOT EXISTS idx_food_resources_city ON food_resources(city);
|
|
CREATE INDEX IF NOT EXISTS idx_food_resources_type ON food_resources(resource_type);
|
|
CREATE INDEX IF NOT EXISTS idx_food_resources_active ON food_resources(is_active);
|
|
CREATE INDEX IF NOT EXISTS idx_food_resources_location ON food_resources(latitude, longitude);
|
|
`);
|
|
|
|
// Create scrape logs table
|
|
await client.query(`
|
|
CREATE TABLE IF NOT EXISTS scrape_logs (
|
|
id SERIAL PRIMARY KEY,
|
|
source data_source NOT NULL,
|
|
started_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
|
completed_at TIMESTAMP WITH TIME ZONE,
|
|
status VARCHAR(50) DEFAULT 'running',
|
|
records_found INTEGER DEFAULT 0,
|
|
records_added INTEGER DEFAULT 0,
|
|
records_updated INTEGER DEFAULT 0,
|
|
error_message TEXT
|
|
);
|
|
`);
|
|
|
|
// Create listing update requests table
|
|
await client.query(`
|
|
CREATE TABLE IF NOT EXISTS listing_update_requests (
|
|
id SERIAL PRIMARY KEY,
|
|
resource_id INTEGER REFERENCES food_resources(id) ON DELETE CASCADE,
|
|
submitter_email VARCHAR(255) NOT NULL,
|
|
submitter_name VARCHAR(255),
|
|
|
|
-- Proposed changes (null = no change requested)
|
|
proposed_name VARCHAR(500),
|
|
proposed_description TEXT,
|
|
proposed_resource_type resource_type,
|
|
proposed_address VARCHAR(500),
|
|
proposed_city VARCHAR(100),
|
|
proposed_phone VARCHAR(50),
|
|
proposed_email VARCHAR(255),
|
|
proposed_website VARCHAR(500),
|
|
proposed_hours_of_operation TEXT,
|
|
proposed_eligibility TEXT,
|
|
proposed_services_offered TEXT,
|
|
|
|
additional_notes TEXT,
|
|
|
|
status VARCHAR(20) DEFAULT 'pending',
|
|
admin_notes TEXT,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
|
reviewed_at TIMESTAMP WITH TIME ZONE,
|
|
reviewed_by VARCHAR(100)
|
|
);
|
|
`);
|
|
|
|
// Create index for listing update requests
|
|
await client.query(`
|
|
CREATE INDEX IF NOT EXISTS idx_listing_update_requests_status ON listing_update_requests(status);
|
|
CREATE INDEX IF NOT EXISTS idx_listing_update_requests_resource ON listing_update_requests(resource_id);
|
|
`);
|
|
|
|
// Create listing submissions table (for new listings submitted by users)
|
|
await client.query(`
|
|
CREATE TABLE IF NOT EXISTS listing_submissions (
|
|
id SERIAL PRIMARY KEY,
|
|
submitter_email VARCHAR(255) NOT NULL,
|
|
submitter_name VARCHAR(255),
|
|
|
|
-- Proposed listing data
|
|
name VARCHAR(500) NOT NULL,
|
|
description TEXT,
|
|
resource_type resource_type DEFAULT 'other',
|
|
address VARCHAR(500),
|
|
city VARCHAR(100),
|
|
phone VARCHAR(50),
|
|
email VARCHAR(255),
|
|
website VARCHAR(500),
|
|
hours_of_operation TEXT,
|
|
eligibility TEXT,
|
|
services_offered TEXT,
|
|
|
|
additional_notes TEXT,
|
|
|
|
status VARCHAR(20) DEFAULT 'pending',
|
|
admin_notes TEXT,
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
|
reviewed_at TIMESTAMP WITH TIME ZONE,
|
|
reviewed_by VARCHAR(100),
|
|
created_resource_id INTEGER REFERENCES food_resources(id)
|
|
);
|
|
`);
|
|
|
|
// Create indexes for listing submissions
|
|
await client.query(`
|
|
CREATE INDEX IF NOT EXISTS idx_listing_submissions_status ON listing_submissions(status);
|
|
`);
|
|
|
|
await client.query('COMMIT');
|
|
logger.info('Database initialized successfully');
|
|
|
|
} catch (error) {
|
|
await client.query('ROLLBACK');
|
|
logger.error('Database initialization failed', { error: error.message });
|
|
throw error;
|
|
} finally {
|
|
client.release();
|
|
}
|
|
};
|
|
|
|
// Run if called directly
|
|
if (require.main === module) {
|
|
initDatabase()
|
|
.then(() => {
|
|
logger.info('Database setup complete');
|
|
process.exit(0);
|
|
})
|
|
.catch((err) => {
|
|
logger.error('Database setup failed', { error: err.message });
|
|
process.exit(1);
|
|
});
|
|
}
|
|
|
|
module.exports = { initDatabase };
|