diff --git a/Dockerfile b/Dockerfile
new file mode 100644
index 0000000..67828dd
--- /dev/null
+++ b/Dockerfile
@@ -0,0 +1,37 @@
+FROM php:8.3-apache
+
+# Install PHP extensions for MySQL/MariaDB
+RUN docker-php-ext-install pdo pdo_mysql mysqli
+
+# Enable Apache modules
+RUN a2enmod rewrite headers
+
+# Configure Apache
+RUN echo "ServerName localhost" >> /etc/apache2/apache2.conf
+
+# Set working directory
+WORKDIR /var/www/html
+
+# Configure PHP for production
+RUN mv "$PHP_INI_DIR/php.ini-production" "$PHP_INI_DIR/php.ini"
+
+# Custom PHP settings
+RUN echo "expose_php = Off" >> "$PHP_INI_DIR/conf.d/custom.ini" && \
+ echo "display_errors = Off" >> "$PHP_INI_DIR/conf.d/custom.ini" && \
+ echo "log_errors = On" >> "$PHP_INI_DIR/conf.d/custom.ini" && \
+ echo "error_log = /var/log/php_errors.log" >> "$PHP_INI_DIR/conf.d/custom.ini"
+
+# Copy application files
+COPY webapp/ /var/www/html/
+
+# Copy database scripts for potential import use
+COPY database/ /opt/geofeed/database/
+
+# Set permissions
+RUN chown -R www-data:www-data /var/www/html
+
+# Expose port 80
+EXPOSE 80
+
+# Start Apache
+CMD ["apache2-foreground"]
diff --git a/README.md b/README.md
new file mode 100644
index 0000000..44958b8
--- /dev/null
+++ b/README.md
@@ -0,0 +1,277 @@
+# Geofeed Manager
+
+A complete solution for managing RFC 8805 compliant IP geolocation feeds (geofeeds). This system provides a modern web interface for managing geofeed entries, stores data in MariaDB/MySQL, and automatically exports to BunnyCDN via n8n workflows.
+
+## Features
+
+- **Modern Apple-esque UI** - Clean, responsive interface for managing geofeed entries
+- **RFC 8805 Compliant** - Generates valid geofeed CSV files per the specification
+- **CRUD Operations** - Create, read, update, and delete geofeed entries
+- **Search & Filter** - Find entries by IP prefix, city, region, or country
+- **Audit Logging** - Track all changes to your geofeed
+- **Automated Export** - n8n workflow exports to BunnyCDN hourly
+- **CSRF Protection** - Secure form submissions
+
+## Directory Structure
+
+```
+geofeed-manager/
+├── database/
+│ ├── schema.sql # Database schema
+│ └── import_csv.php # CSV import utility
+├── webapp/
+│ ├── config.php # Configuration & helpers
+│ ├── api.php # RESTful API endpoints
+│ └── index.php # Main web interface
+└── n8n/
+ └── geofeed-export-workflow.json # n8n workflow
+```
+
+## Installation (Docker)
+
+### Quick Start
+
+1. **Clone and configure:**
+
+```bash
+# Copy environment template
+cp .env.example .env
+
+# Edit with your passwords
+nano .env
+```
+
+2. **Start the containers:**
+
+```bash
+docker compose up -d
+```
+
+3. **Import your existing geofeed:**
+
+```bash
+chmod +x import-geofeed.sh
+./import-geofeed.sh https://store.prpl.uk/geofeed.csv
+```
+
+4. **Access the web interface:**
+
+- Web App: http://localhost:8080
+- phpMyAdmin (optional): http://localhost:8081
+
+### With phpMyAdmin (for database admin)
+
+```bash
+docker compose --profile admin up -d
+```
+
+### Container Details
+
+| Service | Port | Description |
+|---------|------|-------------|
+| webapp | 8080 | PHP web interface |
+| mariadb | 3306 | MariaDB database (exposed for n8n) |
+| phpmyadmin | 8081 | Database admin (optional) |
+
+### Connecting n8n to the Database
+
+In n8n, create a MySQL credential with:
+- **Host:** Your server IP or hostname (not `localhost` unless n8n is on the same machine)
+- **Port:** 3306 (or your configured `DB_PORT`)
+- **Database:** geofeed_manager
+- **User:** geofeed (or your configured `DB_USER`)
+- **Password:** Your configured `DB_PASSWORD`
+
+---
+
+## Installation (Manual)
+
+### 1. Database Setup
+
+Create the database and tables:
+
+```bash
+mysql -u root -p < database/schema.sql
+```
+
+### 2. Import Existing Geofeed (Optional)
+
+```bash
+export DB_HOST=localhost
+export DB_NAME=geofeed_manager
+export DB_USER=your_user
+export DB_PASS=your_password
+
+php database/import_csv.php https://store.prpl.uk/geofeed.csv
+```
+
+### 3. Web Application Setup
+
+1. Copy the `webapp/` directory to your web server:
+
+```bash
+cp -r webapp/ /var/www/html/geofeed/
+```
+
+2. Configure your web server (Apache example):
+
+```apache
+
+ ServerName geofeed.yourdomain.com
+ DocumentRoot /var/www/html/geofeed
+
+
+ AllowOverride All
+ Require all granted
+
+
+```
+
+3. Set environment variables or update `config.php`:
+
+```bash
+export DB_HOST=localhost
+export DB_NAME=geofeed_manager
+export DB_USER=your_user
+export DB_PASS=your_password
+```
+
+### 4. n8n Workflow Setup
+
+1. In n8n, go to **Settings > Environment Variables** and add:
+ - `BUNNY_STORAGE_ZONE` - Your BunnyCDN storage zone name
+ - `BUNNY_API_KEY` - Your BunnyCDN Storage API key
+
+2. Create MySQL credentials in n8n:
+ - Go to **Credentials**
+ - Add new **MySQL** credential
+ - Configure with your database details
+ - Note the credential ID
+
+3. Import the workflow:
+ - Go to **Workflows**
+ - Click **Import from File**
+ - Select `n8n/geofeed-export-workflow.json`
+
+4. Update credential references:
+ - Open the imported workflow
+ - For each MySQL node, select your MySQL credential
+ - Save the workflow
+
+5. Activate the workflow to start hourly exports
+
+## API Reference
+
+### List Entries
+```
+GET api.php?action=list&page=1&limit=25&search=term&country=GB
+```
+
+### Get Single Entry
+```
+GET api.php?action=get&id=123
+```
+
+### Create Entry
+```
+POST api.php?action=create
+Content-Type: application/json
+
+{
+ "ip_prefix": "192.168.1.0/24",
+ "country_code": "GB",
+ "region_code": "GB-ENG",
+ "city": "London",
+ "postal_code": "EC1A 1BB",
+ "notes": "Main office",
+ "csrf_token": "..."
+}
+```
+
+### Update Entry
+```
+POST api.php?action=update
+Content-Type: application/json
+
+{
+ "id": 123,
+ "ip_prefix": "192.168.1.0/24",
+ "country_code": "GB",
+ "region_code": "GB-ENG",
+ "city": "Manchester",
+ "postal_code": "M1 1AA",
+ "csrf_token": "..."
+}
+```
+
+### Delete Entry
+```
+POST api.php?action=delete
+Content-Type: application/json
+
+{
+ "id": 123,
+ "csrf_token": "..."
+}
+```
+
+### Export CSV
+```
+GET api.php?action=export&format=download
+```
+
+### Get Statistics
+```
+GET api.php?action=stats
+```
+
+## Geofeed Format (RFC 8805)
+
+Each line in the exported CSV follows this format:
+
+```
+ip_prefix,country_code,region_code,city,postal_code
+```
+
+Example:
+```csv
+# Geofeed - Generated by Geofeed Manager
+# Format: ip_prefix,country_code,region_code,city,postal_code
+192.168.1.0/24,GB,GB-ENG,London,EC1A 1BB
+10.0.0.0/8,US,US-CA,San Francisco,94105
+2001:db8::/32,DE,DE-BY,Munich,80331
+```
+
+## BunnyCDN Setup
+
+1. Create a Storage Zone in BunnyCDN
+2. Get your Storage API key from the FTP & API Access section
+3. The workflow uploads to: `https://storage.bunnycdn.com/{zone}/geofeed.csv`
+4. Your public URL will be: `https://{zone}.b-cdn.net/geofeed.csv`
+
+## Security Considerations
+
+- Always use HTTPS in production
+- Keep your database credentials secure
+- Consider adding authentication to the web interface
+- The CSRF token helps prevent cross-site attacks
+- Input validation is performed on all fields
+
+## Troubleshooting
+
+### Import fails with "Invalid IP prefix"
+Ensure your IP prefixes are in valid CIDR notation (e.g., `192.168.1.0/24`)
+
+### n8n workflow fails
+- Check that environment variables are set correctly
+- Verify MySQL credentials are configured
+- Check BunnyCDN API key permissions
+
+### Web interface shows database error
+- Verify database credentials in config.php
+- Ensure the database and tables exist
+- Check MySQL/MariaDB is running
+
+## License
+
+MIT License - Feel free to use and modify as needed.
diff --git a/database/import_csv.php b/database/import_csv.php
new file mode 100644
index 0000000..148340d
--- /dev/null
+++ b/database/import_csv.php
@@ -0,0 +1,288 @@
+#!/usr/bin/env php
+ getenv('DB_HOST') ?: 'localhost',
+ 'db_name' => getenv('DB_NAME') ?: 'geofeed_manager',
+ 'db_user' => getenv('DB_USER') ?: 'root',
+ 'db_pass' => getenv('DB_PASS') ?: '',
+ 'default_csv_url' => 'https://store.prpl.uk/geofeed.csv'
+];
+
+// Parse command line arguments
+$csvPath = $argv[1] ?? null;
+$dryRun = in_array('--dry-run', $argv);
+
+echo "╔══════════════════════════════════════════════════════════════╗\n";
+echo "║ Geofeed CSV to SQL Import Utility ║\n";
+echo "╚══════════════════════════════════════════════════════════════╝\n\n";
+
+if ($dryRun) {
+ echo "🔍 DRY RUN MODE - No changes will be made to the database\n\n";
+}
+
+// Fetch or read CSV data
+$csvData = '';
+if ($csvPath && file_exists($csvPath)) {
+ echo "📁 Reading from local file: $csvPath\n";
+ $csvData = file_get_contents($csvPath);
+} elseif ($csvPath && filter_var($csvPath, FILTER_VALIDATE_URL)) {
+ echo "🌐 Fetching from URL: $csvPath\n";
+ $csvData = fetchFromUrl($csvPath);
+} else {
+ echo "🌐 Fetching from default URL: {$config['default_csv_url']}\n";
+ $csvData = fetchFromUrl($config['default_csv_url']);
+}
+
+if (empty($csvData)) {
+ die("❌ Error: Could not fetch or read CSV data\n");
+}
+
+echo "✅ CSV data retrieved successfully\n\n";
+
+// Parse CSV
+$lines = explode("\n", $csvData);
+$entries = [];
+$lineNum = 0;
+$errors = [];
+
+foreach ($lines as $line) {
+ $lineNum++;
+ $line = trim($line);
+
+ // Skip empty lines and comments
+ if (empty($line) || strpos($line, '#') === 0) {
+ continue;
+ }
+
+ // Parse CSV line
+ $parts = str_getcsv($line);
+
+ // Geofeed format: ip_prefix,country_code,region,city,postal_code
+ if (count($parts) < 1) {
+ $errors[] = "Line $lineNum: Empty or invalid format";
+ continue;
+ }
+
+ $entry = [
+ 'ip_prefix' => trim($parts[0] ?? ''),
+ 'country_code' => strtoupper(trim($parts[1] ?? '')),
+ 'region_code' => strtoupper(trim($parts[2] ?? '')),
+ 'city' => trim($parts[3] ?? ''),
+ 'postal_code' => trim($parts[4] ?? '')
+ ];
+
+ // Validate IP prefix
+ if (!isValidIpPrefix($entry['ip_prefix'])) {
+ $errors[] = "Line $lineNum: Invalid IP prefix '{$entry['ip_prefix']}'";
+ continue;
+ }
+
+ // Validate country code (if provided)
+ if (!empty($entry['country_code']) && !preg_match('/^[A-Z]{2}$/', $entry['country_code'])) {
+ $errors[] = "Line $lineNum: Invalid country code '{$entry['country_code']}'";
+ continue;
+ }
+
+ // Clean up empty values
+ foreach ($entry as $key => $value) {
+ if ($value === '') {
+ $entry[$key] = null;
+ }
+ }
+
+ $entries[] = $entry;
+}
+
+echo "📊 Parsing Results:\n";
+echo " ├── Total lines processed: $lineNum\n";
+echo " ├── Valid entries found: " . count($entries) . "\n";
+echo " └── Errors encountered: " . count($errors) . "\n\n";
+
+if (count($errors) > 0) {
+ echo "⚠️ Validation Errors (showing first 10):\n";
+ foreach (array_slice($errors, 0, 10) as $error) {
+ echo " └── $error\n";
+ }
+ if (count($errors) > 10) {
+ echo " └── ... and " . (count($errors) - 10) . " more errors\n";
+ }
+ echo "\n";
+}
+
+if (count($entries) === 0) {
+ die("❌ No valid entries to import\n");
+}
+
+// Display sample entries
+echo "📋 Sample Entries (first 5):\n";
+echo str_repeat("─", 80) . "\n";
+printf("%-25s %-4s %-10s %-20s %-10s\n", "IP Prefix", "CC", "Region", "City", "Postal");
+echo str_repeat("─", 80) . "\n";
+foreach (array_slice($entries, 0, 5) as $entry) {
+ printf("%-25s %-4s %-10s %-20s %-10s\n",
+ substr($entry['ip_prefix'], 0, 25),
+ $entry['country_code'] ?? '-',
+ substr($entry['region_code'] ?? '-', 0, 10),
+ substr($entry['city'] ?? '-', 0, 20),
+ substr($entry['postal_code'] ?? '-', 0, 10)
+ );
+}
+echo str_repeat("─", 80) . "\n\n";
+
+if ($dryRun) {
+ echo "🔍 DRY RUN COMPLETE - Would have imported " . count($entries) . " entries\n";
+ exit(0);
+}
+
+// Connect to database
+echo "🔗 Connecting to database...\n";
+try {
+ $pdo = new PDO(
+ "mysql:host={$config['db_host']};dbname={$config['db_name']};charset=utf8mb4",
+ $config['db_user'],
+ $config['db_pass'],
+ [
+ PDO::ATTR_ERRMODE => PDO::ERRMODE_EXCEPTION,
+ PDO::ATTR_DEFAULT_FETCH_MODE => PDO::FETCH_ASSOC
+ ]
+ );
+ echo "✅ Database connection established\n\n";
+} catch (PDOException $e) {
+ die("❌ Database connection failed: " . $e->getMessage() . "\n");
+}
+
+// Import entries
+echo "📥 Importing entries...\n";
+$inserted = 0;
+$updated = 0;
+$failed = 0;
+
+$stmt = $pdo->prepare("
+ INSERT INTO geofeed_entries (ip_prefix, country_code, region_code, city, postal_code)
+ VALUES (:ip_prefix, :country_code, :region_code, :city, :postal_code)
+ ON DUPLICATE KEY UPDATE
+ country_code = VALUES(country_code),
+ region_code = VALUES(region_code),
+ city = VALUES(city),
+ postal_code = VALUES(postal_code),
+ updated_at = CURRENT_TIMESTAMP
+");
+
+$pdo->beginTransaction();
+
+try {
+ foreach ($entries as $entry) {
+ try {
+ $stmt->execute([
+ ':ip_prefix' => $entry['ip_prefix'],
+ ':country_code' => $entry['country_code'],
+ ':region_code' => $entry['region_code'],
+ ':city' => $entry['city'],
+ ':postal_code' => $entry['postal_code']
+ ]);
+
+ if ($stmt->rowCount() === 1) {
+ $inserted++;
+ } elseif ($stmt->rowCount() === 2) {
+ $updated++;
+ }
+ } catch (PDOException $e) {
+ $failed++;
+ if ($failed <= 5) {
+ echo " ⚠️ Failed to import {$entry['ip_prefix']}: " . $e->getMessage() . "\n";
+ }
+ }
+ }
+
+ $pdo->commit();
+
+ echo "\n✅ Import Complete:\n";
+ echo " ├── Inserted: $inserted\n";
+ echo " ├── Updated: $updated\n";
+ echo " └── Failed: $failed\n\n";
+
+} catch (Exception $e) {
+ $pdo->rollBack();
+ die("❌ Import failed: " . $e->getMessage() . "\n");
+}
+
+// Log the import
+$pdo->prepare("
+ INSERT INTO geofeed_audit_log (entry_id, action, new_values, changed_by)
+ VALUES (NULL, 'INSERT', :details, 'import_script')
+")->execute([
+ ':details' => json_encode([
+ 'type' => 'bulk_import',
+ 'inserted' => $inserted,
+ 'updated' => $updated,
+ 'failed' => $failed,
+ 'source' => $csvPath ?? $config['default_csv_url']
+ ])
+]);
+
+echo "🎉 Import process completed successfully!\n";
+
+// Helper functions
+function fetchFromUrl($url) {
+ $ch = curl_init();
+ curl_setopt_array($ch, [
+ CURLOPT_URL => $url,
+ CURLOPT_RETURNTRANSFER => true,
+ CURLOPT_FOLLOWLOCATION => true,
+ CURLOPT_TIMEOUT => 30,
+ CURLOPT_SSL_VERIFYPEER => true,
+ CURLOPT_USERAGENT => 'Geofeed-Importer/1.0'
+ ]);
+
+ $response = curl_exec($ch);
+ $httpCode = curl_getinfo($ch, CURLINFO_HTTP_CODE);
+ $error = curl_error($ch);
+ curl_close($ch);
+
+ if ($httpCode !== 200) {
+ echo "⚠️ HTTP $httpCode response received\n";
+ }
+
+ if ($error) {
+ echo "⚠️ cURL error: $error\n";
+ return false;
+ }
+
+ return $response;
+}
+
+function isValidIpPrefix($prefix) {
+ // Check if it's a valid IP or CIDR notation
+ if (strpos($prefix, '/') !== false) {
+ list($ip, $cidr) = explode('/', $prefix);
+
+ // Validate CIDR
+ if (!is_numeric($cidr)) {
+ return false;
+ }
+
+ // IPv4
+ if (filter_var($ip, FILTER_VALIDATE_IP, FILTER_FLAG_IPV4)) {
+ return $cidr >= 0 && $cidr <= 32;
+ }
+
+ // IPv6
+ if (filter_var($ip, FILTER_VALIDATE_IP, FILTER_FLAG_IPV6)) {
+ return $cidr >= 0 && $cidr <= 128;
+ }
+
+ return false;
+ }
+
+ // Single IP address
+ return filter_var($prefix, FILTER_VALIDATE_IP) !== false;
+}
diff --git a/database/schema.sql b/database/schema.sql
new file mode 100644
index 0000000..3c11b29
--- /dev/null
+++ b/database/schema.sql
@@ -0,0 +1,51 @@
+-- Geofeed Manager Database Schema
+-- For MariaDB/MySQL
+
+CREATE DATABASE IF NOT EXISTS geofeed_manager;
+USE geofeed_manager;
+
+-- Main geofeed entries table
+CREATE TABLE IF NOT EXISTS geofeed_entries (
+ id INT AUTO_INCREMENT PRIMARY KEY,
+ ip_prefix VARCHAR(50) NOT NULL,
+ country_code CHAR(2) DEFAULT NULL,
+ region_code VARCHAR(10) DEFAULT NULL,
+ city VARCHAR(255) DEFAULT NULL,
+ postal_code VARCHAR(50) DEFAULT NULL,
+ notes TEXT DEFAULT NULL,
+ created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
+ updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
+ UNIQUE KEY unique_prefix (ip_prefix),
+ INDEX idx_country (country_code),
+ INDEX idx_region (region_code),
+ INDEX idx_city (city)
+) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
+
+-- Audit log for tracking changes
+CREATE TABLE IF NOT EXISTS geofeed_audit_log (
+ id INT AUTO_INCREMENT PRIMARY KEY,
+ entry_id INT,
+ action ENUM('INSERT', 'UPDATE', 'DELETE') NOT NULL,
+ old_values JSON DEFAULT NULL,
+ new_values JSON DEFAULT NULL,
+ changed_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
+ changed_by VARCHAR(255) DEFAULT NULL,
+ INDEX idx_entry (entry_id),
+ INDEX idx_action (action),
+ INDEX idx_changed_at (changed_at)
+) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
+
+-- Settings table for app configuration
+CREATE TABLE IF NOT EXISTS geofeed_settings (
+ setting_key VARCHAR(100) PRIMARY KEY,
+ setting_value TEXT,
+ updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP
+) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
+
+-- Insert default settings
+INSERT INTO geofeed_settings (setting_key, setting_value) VALUES
+('bunny_cdn_storage_zone', ''),
+('bunny_cdn_api_key', ''),
+('bunny_cdn_file_path', '/geofeed.csv'),
+('last_export_at', NULL)
+ON DUPLICATE KEY UPDATE setting_key = setting_key;
diff --git a/docker-compose.yml b/docker-compose.yml
new file mode 100644
index 0000000..d149d52
--- /dev/null
+++ b/docker-compose.yml
@@ -0,0 +1,74 @@
+version: '3.8'
+
+services:
+ # MariaDB Database
+ mariadb:
+ image: mariadb:11
+ container_name: geofeed-db
+ restart: unless-stopped
+ environment:
+ MARIADB_ROOT_PASSWORD: ${DB_ROOT_PASSWORD:-geofeed_root_secret}
+ MARIADB_DATABASE: ${DB_NAME:-geofeed_manager}
+ MARIADB_USER: ${DB_USER:-geofeed}
+ MARIADB_PASSWORD: ${DB_PASSWORD:-geofeed_secret}
+ volumes:
+ - mariadb_data:/var/lib/mysql
+ - ./database/schema.sql:/docker-entrypoint-initdb.d/01-schema.sql:ro
+ ports:
+ - "${DB_PORT:-3306}:3306"
+ networks:
+ - geofeed-network
+ healthcheck:
+ test: ["CMD", "healthcheck.sh", "--connect", "--innodb_initialized"]
+ interval: 10s
+ timeout: 5s
+ retries: 5
+ start_period: 30s
+
+ # PHP Application
+ webapp:
+ build:
+ context: .
+ dockerfile: Dockerfile
+ container_name: geofeed-webapp
+ restart: unless-stopped
+ environment:
+ DB_HOST: mariadb
+ DB_NAME: ${DB_NAME:-geofeed_manager}
+ DB_USER: ${DB_USER:-geofeed}
+ DB_PASS: ${DB_PASSWORD:-geofeed_secret}
+ ports:
+ - "${WEB_PORT:-8080}:80"
+ depends_on:
+ mariadb:
+ condition: service_healthy
+ networks:
+ - geofeed-network
+
+ # Optional: phpMyAdmin for database management
+ phpmyadmin:
+ image: phpmyadmin:latest
+ container_name: geofeed-phpmyadmin
+ restart: unless-stopped
+ environment:
+ PMA_HOST: mariadb
+ PMA_USER: ${DB_USER:-geofeed}
+ PMA_PASSWORD: ${DB_PASSWORD:-geofeed_secret}
+ UPLOAD_LIMIT: 64M
+ ports:
+ - "${PMA_PORT:-8081}:80"
+ depends_on:
+ mariadb:
+ condition: service_healthy
+ networks:
+ - geofeed-network
+ profiles:
+ - admin
+
+volumes:
+ mariadb_data:
+ driver: local
+
+networks:
+ geofeed-network:
+ driver: bridge
diff --git a/import-geofeed.sh b/import-geofeed.sh
new file mode 100644
index 0000000..2e4bd46
--- /dev/null
+++ b/import-geofeed.sh
@@ -0,0 +1,36 @@
+#!/bin/bash
+# Geofeed Import Script
+# Usage: ./import-geofeed.sh [csv_url_or_path]
+
+set -e
+
+CSV_SOURCE="${1:-https://store.prpl.uk/geofeed.csv}"
+
+echo "========================================"
+echo " Geofeed Import Script"
+echo "========================================"
+echo ""
+
+# Check if docker compose is running
+if ! docker compose ps | grep -q "geofeed-db.*running"; then
+ echo "Error: MariaDB container is not running."
+ echo "Please start the containers first with: docker compose up -d"
+ exit 1
+fi
+
+echo "Importing geofeed from: $CSV_SOURCE"
+echo ""
+
+# Run the import script inside a temporary PHP container
+docker run --rm \
+ --network geofeed-manager_geofeed-network \
+ -e DB_HOST=mariadb \
+ -e DB_NAME="${DB_NAME:-geofeed_manager}" \
+ -e DB_USER="${DB_USER:-geofeed}" \
+ -e DB_PASS="${DB_PASSWORD:-geofeed_secret}" \
+ -v "$(pwd)/database:/scripts:ro" \
+ php:8.3-cli \
+ sh -c "docker-php-ext-install pdo pdo_mysql > /dev/null 2>&1 && php /scripts/import_csv.php '$CSV_SOURCE'"
+
+echo ""
+echo "Import complete!"
diff --git a/n8n/geofeed-export-workflow.json b/n8n/geofeed-export-workflow.json
new file mode 100644
index 0000000..8f23242
--- /dev/null
+++ b/n8n/geofeed-export-workflow.json
@@ -0,0 +1,303 @@
+{
+ "name": "Geofeed Export to BunnyCDN",
+ "nodes": [
+ {
+ "parameters": {
+ "rule": {
+ "interval": [
+ {
+ "field": "hours",
+ "hoursInterval": 1
+ }
+ ]
+ }
+ },
+ "id": "schedule-trigger",
+ "name": "Hourly Trigger",
+ "type": "n8n-nodes-base.scheduleTrigger",
+ "typeVersion": 1.1,
+ "position": [240, 300]
+ },
+ {
+ "parameters": {
+ "operation": "executeQuery",
+ "query": "SELECT ip_prefix, IFNULL(country_code, '') as country_code, IFNULL(region_code, '') as region_code, IFNULL(city, '') as city, IFNULL(postal_code, '') as postal_code FROM geofeed_entries ORDER BY ip_prefix",
+ "options": {}
+ },
+ "id": "mysql-query",
+ "name": "Query Geofeed Entries",
+ "type": "n8n-nodes-base.mySql",
+ "typeVersion": 2.3,
+ "position": [460, 300],
+ "credentials": {
+ "mySql": {
+ "id": "YOUR_MYSQL_CREDENTIAL_ID",
+ "name": "MariaDB Geofeed"
+ }
+ }
+ },
+ {
+ "parameters": {
+ "jsCode": "// Build RFC 8805 compliant CSV\nconst items = $input.all();\n\nif (items.length === 0) {\n throw new Error('No entries found in database');\n}\n\n// CSV Header comments\nlet csv = '# Geofeed - Generated by Geofeed Manager\\r\\n';\ncsv += '# Format: ip_prefix,country_code,region_code,city,postal_code\\r\\n';\ncsv += `# Generated: ${new Date().toISOString()}\\r\\n`;\ncsv += `# Total Entries: ${items.length}\\r\\n`;\n\n// Process each entry\nfor (const item of items) {\n const row = item.json;\n \n // Build CSV line - RFC 8805 format\n // Escape any commas in city names\n const city = (row.city || '').replace(/,/g, '');\n const postalCode = (row.postal_code || '').replace(/,/g, '');\n \n csv += `${row.ip_prefix},${row.country_code},${row.region_code},${city},${postalCode}\\r\\n`;\n}\n\n// Return single item with CSV content\nreturn [{\n json: {\n csv: csv,\n entryCount: items.length,\n generatedAt: new Date().toISOString()\n }\n}];"
+ },
+ "id": "code-build-csv",
+ "name": "Build CSV Content",
+ "type": "n8n-nodes-base.code",
+ "typeVersion": 2,
+ "position": [680, 300]
+ },
+ {
+ "parameters": {
+ "method": "PUT",
+ "url": "=https://storage.bunnycdn.com/{{ $env.BUNNY_STORAGE_ZONE }}/geofeed.csv",
+ "sendHeaders": true,
+ "headerParameters": {
+ "parameters": [
+ {
+ "name": "AccessKey",
+ "value": "={{ $env.BUNNY_API_KEY }}"
+ },
+ {
+ "name": "Content-Type",
+ "value": "text/csv; charset=utf-8"
+ }
+ ]
+ },
+ "sendBody": true,
+ "contentType": "raw",
+ "body": "={{ $json.csv }}",
+ "options": {
+ "response": {
+ "response": {
+ "fullResponse": true,
+ "responseFormat": "text"
+ }
+ }
+ }
+ },
+ "id": "http-upload-bunny",
+ "name": "Upload to BunnyCDN",
+ "type": "n8n-nodes-base.httpRequest",
+ "typeVersion": 4.2,
+ "position": [900, 300]
+ },
+ {
+ "parameters": {
+ "conditions": {
+ "options": {
+ "caseSensitive": true,
+ "leftValue": "",
+ "typeValidation": "loose"
+ },
+ "conditions": [
+ {
+ "id": "check-upload-success",
+ "leftValue": "={{ $json.statusCode }}",
+ "rightValue": 201,
+ "operator": {
+ "type": "number",
+ "operation": "equals"
+ }
+ }
+ ],
+ "combinator": "and"
+ },
+ "options": {}
+ },
+ "id": "if-upload-success",
+ "name": "Check Upload Success",
+ "type": "n8n-nodes-base.if",
+ "typeVersion": 2,
+ "position": [1120, 300]
+ },
+ {
+ "parameters": {
+ "operation": "executeQuery",
+ "query": "INSERT INTO geofeed_audit_log (entry_id, action, new_values, changed_by) VALUES (NULL, 'INSERT', JSON_OBJECT('type', 'csv_export', 'status', 'success', 'timestamp', NOW()), 'n8n_workflow')",
+ "options": {}
+ },
+ "id": "mysql-log-success",
+ "name": "Log Export Success",
+ "type": "n8n-nodes-base.mySql",
+ "typeVersion": 2.3,
+ "position": [1340, 200],
+ "credentials": {
+ "mySql": {
+ "id": "YOUR_MYSQL_CREDENTIAL_ID",
+ "name": "MariaDB Geofeed"
+ }
+ }
+ },
+ {
+ "parameters": {
+ "operation": "executeQuery",
+ "query": "UPDATE geofeed_settings SET setting_value = NOW() WHERE setting_key = 'last_export_at'",
+ "options": {}
+ },
+ "id": "mysql-update-timestamp",
+ "name": "Update Last Export Time",
+ "type": "n8n-nodes-base.mySql",
+ "typeVersion": 2.3,
+ "position": [1560, 200],
+ "credentials": {
+ "mySql": {
+ "id": "YOUR_MYSQL_CREDENTIAL_ID",
+ "name": "MariaDB Geofeed"
+ }
+ }
+ },
+ {
+ "parameters": {
+ "operation": "executeQuery",
+ "query": "INSERT INTO geofeed_audit_log (entry_id, action, new_values, changed_by) VALUES (NULL, 'INSERT', JSON_OBJECT('type', 'csv_export', 'status', 'failed', 'timestamp', NOW()), 'n8n_workflow')",
+ "options": {}
+ },
+ "id": "mysql-log-failure",
+ "name": "Log Export Failure",
+ "type": "n8n-nodes-base.mySql",
+ "typeVersion": 2.3,
+ "position": [1340, 400],
+ "credentials": {
+ "mySql": {
+ "id": "YOUR_MYSQL_CREDENTIAL_ID",
+ "name": "MariaDB Geofeed"
+ }
+ }
+ },
+ {
+ "parameters": {
+ "errorMessage": "=Failed to upload geofeed to BunnyCDN"
+ },
+ "id": "stop-error",
+ "name": "Stop and Error",
+ "type": "n8n-nodes-base.stopAndError",
+ "typeVersion": 1,
+ "position": [1560, 400]
+ },
+ {
+ "parameters": {},
+ "id": "no-op-complete",
+ "name": "Export Complete",
+ "type": "n8n-nodes-base.noOp",
+ "typeVersion": 1,
+ "position": [1780, 200]
+ }
+ ],
+ "connections": {
+ "Hourly Trigger": {
+ "main": [
+ [
+ {
+ "node": "Query Geofeed Entries",
+ "type": "main",
+ "index": 0
+ }
+ ]
+ ]
+ },
+ "Query Geofeed Entries": {
+ "main": [
+ [
+ {
+ "node": "Build CSV Content",
+ "type": "main",
+ "index": 0
+ }
+ ]
+ ]
+ },
+ "Build CSV Content": {
+ "main": [
+ [
+ {
+ "node": "Upload to BunnyCDN",
+ "type": "main",
+ "index": 0
+ }
+ ]
+ ]
+ },
+ "Upload to BunnyCDN": {
+ "main": [
+ [
+ {
+ "node": "Check Upload Success",
+ "type": "main",
+ "index": 0
+ }
+ ]
+ ]
+ },
+ "Check Upload Success": {
+ "main": [
+ [
+ {
+ "node": "Log Export Success",
+ "type": "main",
+ "index": 0
+ }
+ ],
+ [
+ {
+ "node": "Log Export Failure",
+ "type": "main",
+ "index": 0
+ }
+ ]
+ ]
+ },
+ "Log Export Success": {
+ "main": [
+ [
+ {
+ "node": "Update Last Export Time",
+ "type": "main",
+ "index": 0
+ }
+ ]
+ ]
+ },
+ "Update Last Export Time": {
+ "main": [
+ [
+ {
+ "node": "Export Complete",
+ "type": "main",
+ "index": 0
+ }
+ ]
+ ]
+ },
+ "Log Export Failure": {
+ "main": [
+ [
+ {
+ "node": "Stop and Error",
+ "type": "main",
+ "index": 0
+ }
+ ]
+ ]
+ }
+ },
+ "pinData": {},
+ "settings": {
+ "executionOrder": "v1"
+ },
+ "staticData": null,
+ "tags": [
+ {
+ "name": "geofeed",
+ "createdAt": "2024-01-01T00:00:00.000Z",
+ "updatedAt": "2024-01-01T00:00:00.000Z"
+ },
+ {
+ "name": "bunnycdn",
+ "createdAt": "2024-01-01T00:00:00.000Z",
+ "updatedAt": "2024-01-01T00:00:00.000Z"
+ }
+ ],
+ "triggerCount": 0,
+ "updatedAt": "2024-01-01T00:00:00.000Z",
+ "versionId": "1"
+}
diff --git a/webapp/api.php b/webapp/api.php
new file mode 100644
index 0000000..1ba14b9
--- /dev/null
+++ b/webapp/api.php
@@ -0,0 +1,457 @@
+ 'Invalid action'], 400);
+ }
+} catch (Exception $e) {
+ jsonResponse(['error' => $e->getMessage()], 500);
+}
+
+/**
+ * List entries with pagination and filtering
+ */
+function handleList($db) {
+ $page = max(1, intval($_GET['page'] ?? 1));
+ $limit = min(100, max(10, intval($_GET['limit'] ?? ITEMS_PER_PAGE)));
+ $offset = ($page - 1) * $limit;
+
+ $where = ['1=1'];
+ $params = [];
+
+ // Filtering
+ if (!empty($_GET['country'])) {
+ $where[] = 'country_code = :country';
+ $params[':country'] = strtoupper($_GET['country']);
+ }
+
+ if (!empty($_GET['search'])) {
+ $where[] = '(ip_prefix LIKE :search OR city LIKE :search2 OR region_code LIKE :search3)';
+ $searchTerm = '%' . $_GET['search'] . '%';
+ $params[':search'] = $searchTerm;
+ $params[':search2'] = $searchTerm;
+ $params[':search3'] = $searchTerm;
+ }
+
+ $whereClause = implode(' AND ', $where);
+
+ // Get total count
+ $countStmt = $db->prepare("SELECT COUNT(*) as total FROM geofeed_entries WHERE $whereClause");
+ $countStmt->execute($params);
+ $total = $countStmt->fetch()['total'];
+
+ // Get entries
+ $sql = "SELECT * FROM geofeed_entries WHERE $whereClause ORDER BY created_at DESC LIMIT :limit OFFSET :offset";
+ $stmt = $db->prepare($sql);
+
+ foreach ($params as $key => $value) {
+ $stmt->bindValue($key, $value);
+ }
+ $stmt->bindValue(':limit', $limit, PDO::PARAM_INT);
+ $stmt->bindValue(':offset', $offset, PDO::PARAM_INT);
+ $stmt->execute();
+
+ $entries = $stmt->fetchAll();
+
+ jsonResponse([
+ 'success' => true,
+ 'data' => $entries,
+ 'pagination' => [
+ 'page' => $page,
+ 'limit' => $limit,
+ 'total' => $total,
+ 'pages' => ceil($total / $limit)
+ ]
+ ]);
+}
+
+/**
+ * Get single entry
+ */
+function handleGet($db) {
+ $id = intval($_GET['id'] ?? 0);
+
+ if (!$id) {
+ jsonResponse(['error' => 'Invalid ID'], 400);
+ }
+
+ $stmt = $db->prepare("SELECT * FROM geofeed_entries WHERE id = :id");
+ $stmt->execute([':id' => $id]);
+ $entry = $stmt->fetch();
+
+ if (!$entry) {
+ jsonResponse(['error' => 'Entry not found'], 404);
+ }
+
+ jsonResponse(['success' => true, 'data' => $entry]);
+}
+
+/**
+ * Create new entry
+ */
+function handleCreate($db) {
+ if ($_SERVER['REQUEST_METHOD'] !== 'POST') {
+ jsonResponse(['error' => 'Method not allowed'], 405);
+ }
+
+ $input = json_decode(file_get_contents('php://input'), true);
+
+ // Validate CSRF
+ if (!validateCSRFToken($input['csrf_token'] ?? '')) {
+ jsonResponse(['error' => 'Invalid CSRF token'], 403);
+ }
+
+ // Validate required fields
+ if (empty($input['ip_prefix'])) {
+ jsonResponse(['error' => 'IP prefix is required'], 400);
+ }
+
+ if (!isValidIpPrefix($input['ip_prefix'])) {
+ jsonResponse(['error' => 'Invalid IP prefix format'], 400);
+ }
+
+ // Validate optional fields
+ $countryCode = strtoupper(trim($input['country_code'] ?? ''));
+ if (!empty($countryCode) && !isValidCountryCode($countryCode)) {
+ jsonResponse(['error' => 'Invalid country code (must be 2 letters)'], 400);
+ }
+
+ $regionCode = strtoupper(trim($input['region_code'] ?? ''));
+ if (!empty($regionCode) && !isValidRegionCode($regionCode)) {
+ jsonResponse(['error' => 'Invalid region code (format: XX-YYY)'], 400);
+ }
+
+ // Check for duplicate
+ $checkStmt = $db->prepare("SELECT id FROM geofeed_entries WHERE ip_prefix = :prefix");
+ $checkStmt->execute([':prefix' => $input['ip_prefix']]);
+ if ($checkStmt->fetch()) {
+ jsonResponse(['error' => 'An entry with this IP prefix already exists'], 409);
+ }
+
+ // Insert entry
+ $stmt = $db->prepare("
+ INSERT INTO geofeed_entries (ip_prefix, country_code, region_code, city, postal_code, notes)
+ VALUES (:ip_prefix, :country_code, :region_code, :city, :postal_code, :notes)
+ ");
+
+ $stmt->execute([
+ ':ip_prefix' => trim($input['ip_prefix']),
+ ':country_code' => $countryCode ?: null,
+ ':region_code' => $regionCode ?: null,
+ ':city' => trim($input['city'] ?? '') ?: null,
+ ':postal_code' => trim($input['postal_code'] ?? '') ?: null,
+ ':notes' => trim($input['notes'] ?? '') ?: null
+ ]);
+
+ $id = $db->lastInsertId();
+
+ // Log the action
+ logAction($db, $id, 'INSERT', null, $input);
+
+ jsonResponse(['success' => true, 'id' => $id, 'message' => 'Entry created successfully'], 201);
+}
+
+/**
+ * Update existing entry
+ */
+function handleUpdate($db) {
+ if ($_SERVER['REQUEST_METHOD'] !== 'POST') {
+ jsonResponse(['error' => 'Method not allowed'], 405);
+ }
+
+ $input = json_decode(file_get_contents('php://input'), true);
+ $id = intval($input['id'] ?? 0);
+
+ if (!$id) {
+ jsonResponse(['error' => 'Invalid ID'], 400);
+ }
+
+ // Validate CSRF
+ if (!validateCSRFToken($input['csrf_token'] ?? '')) {
+ jsonResponse(['error' => 'Invalid CSRF token'], 403);
+ }
+
+ // Get existing entry
+ $checkStmt = $db->prepare("SELECT * FROM geofeed_entries WHERE id = :id");
+ $checkStmt->execute([':id' => $id]);
+ $oldEntry = $checkStmt->fetch();
+
+ if (!$oldEntry) {
+ jsonResponse(['error' => 'Entry not found'], 404);
+ }
+
+ // Validate fields
+ if (empty($input['ip_prefix'])) {
+ jsonResponse(['error' => 'IP prefix is required'], 400);
+ }
+
+ if (!isValidIpPrefix($input['ip_prefix'])) {
+ jsonResponse(['error' => 'Invalid IP prefix format'], 400);
+ }
+
+ $countryCode = strtoupper(trim($input['country_code'] ?? ''));
+ if (!empty($countryCode) && !isValidCountryCode($countryCode)) {
+ jsonResponse(['error' => 'Invalid country code'], 400);
+ }
+
+ $regionCode = strtoupper(trim($input['region_code'] ?? ''));
+ if (!empty($regionCode) && !isValidRegionCode($regionCode)) {
+ jsonResponse(['error' => 'Invalid region code'], 400);
+ }
+
+ // Check for duplicate (excluding current entry)
+ $dupStmt = $db->prepare("SELECT id FROM geofeed_entries WHERE ip_prefix = :prefix AND id != :id");
+ $dupStmt->execute([':prefix' => $input['ip_prefix'], ':id' => $id]);
+ if ($dupStmt->fetch()) {
+ jsonResponse(['error' => 'Another entry with this IP prefix already exists'], 409);
+ }
+
+ // Update entry
+ $stmt = $db->prepare("
+ UPDATE geofeed_entries SET
+ ip_prefix = :ip_prefix,
+ country_code = :country_code,
+ region_code = :region_code,
+ city = :city,
+ postal_code = :postal_code,
+ notes = :notes
+ WHERE id = :id
+ ");
+
+ $stmt->execute([
+ ':id' => $id,
+ ':ip_prefix' => trim($input['ip_prefix']),
+ ':country_code' => $countryCode ?: null,
+ ':region_code' => $regionCode ?: null,
+ ':city' => trim($input['city'] ?? '') ?: null,
+ ':postal_code' => trim($input['postal_code'] ?? '') ?: null,
+ ':notes' => trim($input['notes'] ?? '') ?: null
+ ]);
+
+ // Log the action
+ logAction($db, $id, 'UPDATE', $oldEntry, $input);
+
+ jsonResponse(['success' => true, 'message' => 'Entry updated successfully']);
+}
+
+/**
+ * Delete entry
+ */
+function handleDelete($db) {
+ if ($_SERVER['REQUEST_METHOD'] !== 'POST') {
+ jsonResponse(['error' => 'Method not allowed'], 405);
+ }
+
+ $input = json_decode(file_get_contents('php://input'), true);
+ $id = intval($input['id'] ?? 0);
+
+ if (!$id) {
+ jsonResponse(['error' => 'Invalid ID'], 400);
+ }
+
+ // Validate CSRF
+ if (!validateCSRFToken($input['csrf_token'] ?? '')) {
+ jsonResponse(['error' => 'Invalid CSRF token'], 403);
+ }
+
+ // Get existing entry for logging
+ $checkStmt = $db->prepare("SELECT * FROM geofeed_entries WHERE id = :id");
+ $checkStmt->execute([':id' => $id]);
+ $oldEntry = $checkStmt->fetch();
+
+ if (!$oldEntry) {
+ jsonResponse(['error' => 'Entry not found'], 404);
+ }
+
+ // Delete entry
+ $stmt = $db->prepare("DELETE FROM geofeed_entries WHERE id = :id");
+ $stmt->execute([':id' => $id]);
+
+ // Log the action
+ logAction($db, $id, 'DELETE', $oldEntry, null);
+
+ jsonResponse(['success' => true, 'message' => 'Entry deleted successfully']);
+}
+
+/**
+ * Export entries as CSV
+ */
+function handleExport($db) {
+ $stmt = $db->query("SELECT ip_prefix, country_code, region_code, city, postal_code FROM geofeed_entries ORDER BY ip_prefix");
+ $entries = $stmt->fetchAll();
+
+ // Build CSV content (RFC 8805 format)
+ $csv = "# Geofeed - Generated by Geofeed Manager\r\n";
+ $csv .= "# Format: ip_prefix,country_code,region_code,city,postal_code\r\n";
+ $csv .= "# Generated: " . date('c') . "\r\n";
+
+ foreach ($entries as $entry) {
+ $csv .= implode(',', [
+ $entry['ip_prefix'],
+ $entry['country_code'] ?? '',
+ $entry['region_code'] ?? '',
+ $entry['city'] ?? '',
+ $entry['postal_code'] ?? ''
+ ]) . "\r\n";
+ }
+
+ // Return as downloadable or as JSON based on format param
+ if (($_GET['format'] ?? '') === 'download') {
+ header('Content-Type: text/csv; charset=utf-8');
+ header('Content-Disposition: attachment; filename="geofeed.csv"');
+ echo $csv;
+ exit;
+ }
+
+ jsonResponse([
+ 'success' => true,
+ 'csv' => $csv,
+ 'count' => count($entries)
+ ]);
+}
+
+/**
+ * Get statistics
+ */
+function handleStats($db) {
+ $stats = [];
+
+ // Total entries
+ $stmt = $db->query("SELECT COUNT(*) as count FROM geofeed_entries");
+ $stats['total_entries'] = $stmt->fetch()['count'];
+
+ // Entries by country (top 10)
+ $stmt = $db->query("
+ SELECT country_code, COUNT(*) as count
+ FROM geofeed_entries
+ WHERE country_code IS NOT NULL AND country_code != ''
+ GROUP BY country_code
+ ORDER BY count DESC
+ LIMIT 10
+ ");
+ $stats['by_country'] = $stmt->fetchAll();
+
+ // Recent changes
+ $stmt = $db->query("
+ SELECT action, COUNT(*) as count, DATE(changed_at) as date
+ FROM geofeed_audit_log
+ WHERE changed_at >= DATE_SUB(NOW(), INTERVAL 7 DAY)
+ GROUP BY action, DATE(changed_at)
+ ORDER BY date DESC
+ ");
+ $stats['recent_changes'] = $stmt->fetchAll();
+
+ // IPv4 vs IPv6
+ $stmt = $db->query("
+ SELECT
+ SUM(CASE WHEN ip_prefix LIKE '%:%' THEN 1 ELSE 0 END) as ipv6,
+ SUM(CASE WHEN ip_prefix NOT LIKE '%:%' THEN 1 ELSE 0 END) as ipv4
+ FROM geofeed_entries
+ ");
+ $stats['ip_versions'] = $stmt->fetch();
+
+ jsonResponse(['success' => true, 'data' => $stats]);
+}
+
+/**
+ * Search entries
+ */
+function handleSearch($db) {
+ $query = trim($_GET['q'] ?? '');
+
+ if (strlen($query) < 2) {
+ jsonResponse(['error' => 'Search query too short'], 400);
+ }
+
+ $searchTerm = '%' . $query . '%';
+
+ $stmt = $db->prepare("
+ SELECT * FROM geofeed_entries
+ WHERE ip_prefix LIKE :q1
+ OR city LIKE :q2
+ OR region_code LIKE :q3
+ OR country_code LIKE :q4
+ ORDER BY ip_prefix
+ LIMIT 50
+ ");
+
+ $stmt->execute([
+ ':q1' => $searchTerm,
+ ':q2' => $searchTerm,
+ ':q3' => $searchTerm,
+ ':q4' => $searchTerm
+ ]);
+
+ jsonResponse(['success' => true, 'data' => $stmt->fetchAll()]);
+}
+
+/**
+ * Log action to audit table
+ */
+function logAction($db, $entryId, $action, $oldValues, $newValues) {
+ $stmt = $db->prepare("
+ INSERT INTO geofeed_audit_log (entry_id, action, old_values, new_values, changed_by)
+ VALUES (:entry_id, :action, :old_values, :new_values, :changed_by)
+ ");
+
+ $stmt->execute([
+ ':entry_id' => $entryId,
+ ':action' => $action,
+ ':old_values' => $oldValues ? json_encode($oldValues) : null,
+ ':new_values' => $newValues ? json_encode($newValues) : null,
+ ':changed_by' => $_SERVER['REMOTE_ADDR'] ?? 'system'
+ ]);
+}
diff --git a/webapp/config.php b/webapp/config.php
new file mode 100644
index 0000000..ecd0fe9
--- /dev/null
+++ b/webapp/config.php
@@ -0,0 +1,109 @@
+ PDO::ERRMODE_EXCEPTION,
+ PDO::ATTR_DEFAULT_FETCH_MODE => PDO::FETCH_ASSOC,
+ PDO::ATTR_EMULATE_PREPARES => false
+ ]
+ );
+ } catch (PDOException $e) {
+ die(json_encode(['error' => 'Database connection failed']));
+ }
+ }
+
+ return $pdo;
+}
+
+// CSRF Protection
+function generateCSRFToken() {
+ if (empty($_SESSION['csrf_token'])) {
+ $_SESSION['csrf_token'] = bin2hex(random_bytes(32));
+ }
+ return $_SESSION['csrf_token'];
+}
+
+function validateCSRFToken($token) {
+ return isset($_SESSION['csrf_token']) && hash_equals($_SESSION['csrf_token'], $token);
+}
+
+// JSON Response helper
+function jsonResponse($data, $statusCode = 200) {
+ http_response_code($statusCode);
+ header('Content-Type: application/json');
+ echo json_encode($data);
+ exit;
+}
+
+// Input sanitization
+function sanitizeInput($input) {
+ if (is_array($input)) {
+ return array_map('sanitizeInput', $input);
+ }
+ return htmlspecialchars(trim($input), ENT_QUOTES, 'UTF-8');
+}
+
+// IP prefix validation
+function isValidIpPrefix($prefix) {
+ if (strpos($prefix, '/') !== false) {
+ list($ip, $cidr) = explode('/', $prefix);
+
+ if (!is_numeric($cidr)) {
+ return false;
+ }
+
+ if (filter_var($ip, FILTER_VALIDATE_IP, FILTER_FLAG_IPV4)) {
+ return $cidr >= 0 && $cidr <= 32;
+ }
+
+ if (filter_var($ip, FILTER_VALIDATE_IP, FILTER_FLAG_IPV6)) {
+ return $cidr >= 0 && $cidr <= 128;
+ }
+
+ return false;
+ }
+
+ return filter_var($prefix, FILTER_VALIDATE_IP) !== false;
+}
+
+// Country code validation
+function isValidCountryCode($code) {
+ if (empty($code)) return true;
+ return preg_match('/^[A-Z]{2}$/i', $code);
+}
+
+// Region code validation (ISO 3166-2)
+function isValidRegionCode($code) {
+ if (empty($code)) return true;
+ return preg_match('/^[A-Z]{2}-[A-Z0-9]{1,3}$/i', $code);
+}
diff --git a/webapp/index.php b/webapp/index.php
new file mode 100644
index 0000000..ff5c6ee
--- /dev/null
+++ b/webapp/index.php
@@ -0,0 +1,1197 @@
+
+
+
+
+
+ Geofeed Manager
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+ Are you sure you want to delete the entry for ? This action cannot be undone.
+
+
+
+
+
+
+
+
+
+
+
+