CREATE TABLE accounts ( email TEXT PRIMARY KEY NOT NULL, created TIMESTAMP NOT NULL DEFAULT NOW() ); CREATE TABLE os_images ( id TEXT PRIMARY KEY NOT NULL, template_image_file_name TEXT NOT NULL, description TEXT NOT NULL ); CREATE TABLE vm_sizes ( id TEXT PRIMARY KEY NOT NULL, dollars_per_month NUMERIC(8, 2) NOT NULL, vcpus INTEGER NOT NULL, memory_mb INTEGER NOT NULL, bandwidth_gb_per_month INTEGER NOT NULL ); CREATE TABLE ssh_public_keys ( email TEXT REFERENCES accounts(email) ON DELETE RESTRICT, name TEXT NOT NULL, content TEXT NOT NULL, created TIMESTAMP NOT NULL DEFAULT NOW(), PRIMARY KEY (email, name) ); CREATE TABLE vms ( id TEXT PRIMARY KEY NOT NULL, email TEXT REFERENCES accounts(email) ON DELETE RESTRICT, os TEXT REFERENCES os_images(id) ON DELETE RESTRICT, size TEXT REFERENCES vm_sizes(id) ON DELETE RESTRICT, last_seen_ipv4 TEXT, last_seen_ipv6 TEXT, created TIMESTAMP NOT NULL DEFAULT NOW(), deleted TIMESTAMP, UNIQUE (id, email) ); CREATE TABLE vm_ssh_public_key ( ssh_public_key_name TEXT NOT NULL, email TEXT NOT NULL, vm_id TEXT NOT NULL, FOREIGN KEY (email, ssh_public_key_name) REFERENCES ssh_public_keys(email, name) ON DELETE CASCADE, FOREIGN KEY (email, vm_id) REFERENCES vms(email, id) ON DELETE CASCADE, PRIMARY KEY (email, vm_id, ssh_public_key_name) ); CREATE TABLE payments ( email TEXT REFERENCES accounts(email) ON DELETE RESTRICT, created TIMESTAMP NOT NULL DEFAULT NOW(), dollars NUMERIC(8, 2) NOT NULL, invalidated BOOLEAN NOT NULL DEFAULT FALSE, PRIMARY KEY (email, created) ); CREATE TABLE login_tokens ( email TEXT REFERENCES accounts(email) ON DELETE RESTRICT, created TIMESTAMP NOT NULL DEFAULT NOW(), token TEXT NOT NULL, PRIMARY KEY (email, created) ); CREATE TABLE payment_sessions ( id TEXT PRIMARY KEY, email TEXT REFERENCES accounts(email) ON DELETE RESTRICT, type TEXT NOT NULL, created TIMESTAMP NOT NULL DEFAULT NOW(), dollars NUMERIC(8, 2) NOT NULL ); CREATE TABLE unconfirmed_btcpay_invoices ( id TEXT PRIMARY KEY, email TEXT REFERENCES accounts(email) ON DELETE RESTRICT, created TIMESTAMP NOT NULL, FOREIGN KEY (email, created) REFERENCES payments(email, created) ON DELETE CASCADE ); INSERT INTO os_images (id, template_image_file_name, description) VALUES ('alpine311', 'alpine-cloud-2020-04-18.qcow2', 'Alpine Linux 3.11'), ('ubuntu18', 'ubuntu-18.04-minimal-cloudimg-amd64.img', 'Ubuntu 18.04 LTS (Bionic)'), ('debian10', 'debian-10-genericcloud-amd64-20191117-80.qcow2', 'Debian 10 (Buster)'), ('centos7', 'CentOS-7-x86_64-GenericCloud.qcow2', 'CentOS 7'), ('centos8', 'CentOS-8-GenericCloud-8.1.1911-20200113.3.x86_64.qcow2', 'CentOS 8'), ('openbsd66', 'openbsd-cloud-2020-05.qcow2', 'OpenBSD 6.6'), ('guix110', 'guixsystem-cloud-2020-05.qcow2', 'Guix System 1.1.0'); INSERT INTO vm_sizes (id, dollars_per_month, memory_mb, vcpus, bandwidth_gb_per_month) VALUES ('f1-s', 5.33, 512, 1, 500), ('f1-m', 7.16, 1024, 1, 1000), ('f1-l', 8.92, 2048, 1, 2000), ('f1-x', 16.16, 4096, 2, 4000), ('f1-xx', 29.66, 8192, 4, 8000), ('f1-xxx', 57.58, 16384, 8, 16000); -- this is test data to be removed later INSERT INTO accounts (email) VALUES ('forest.n.johnson@gmail.com'); INSERT INTO payments (email, dollars, created) VALUES ('forest.n.johnson@gmail.com', 20.00, TO_TIMESTAMP('2020-05-05','YYYY-MM-DD')); INSERT INTO vms (id, email, os, size) VALUES ('capsul-yi9ffqbjly', 'forest.n.johnson@gmail.com', 'alpine311', 'f1-xx'); UPDATE schemaversion SET version = 2;