-- Create tables CREATE TABLE users ( id SERIAL PRIMARY KEY, name VARCHAR(30) NOT NULL, email VARCHAR(255) NOT NULL, password VARCHAR NULL, time_create BIGINT NOT NULL, reset_password_token VARCHAR(150) NULL, time_gen_reset_token BIGINT NOT NULL DEFAULT 0, delete_account_token VARCHAR(150) NULL, time_gen_delete_account_token BIGINT NOT NULL DEFAULT 0, time_activate BIGINT NOT NULL DEFAULT 0, active BOOLEAN NOT NULL DEFAULT TRUE, admin BOOLEAN NOT NULL DEFAULT FALSE ); CREATE TABLE families ( id SERIAL PRIMARY KEY, time_create BIGINT NOT NULL, name VARCHAR(30) NOT NULL, invitation_code VARCHAR(7) NOT NULL ); CREATE TABLE memberships ( user_id integer NOT NULL REFERENCES users, family_id integer NOT NULL REFERENCES families, time_create BIGINT NOT NULL, is_admin BOOLEAN NOT NULL DEFAULT FALSE, PRIMARY KEY(user_id, family_id) ); CREATE TABLE photos ( id SERIAL PRIMARY KEY, file_id VARCHAR(36) NOT NULL, time_create BIGINT NOT NULL, mime_type VARCHAR(150) NOT NULL, sha512 VARCHAR(130) NOT NULL, file_size INTEGER NOT NULL, thumb_sha512 VARCHAR(130) NOT NULL ); CREATE TABLE members ( id SERIAL PRIMARY KEY, family_id integer NOT NULL REFERENCES families, first_name VARCHAR(30) NULL, last_name VARCHAR(30) NULL, birth_last_name VARCHAR(30) NULL, photo_id INTEGER NULL REFERENCES photos ON DELETE SET NULL, email VARCHAR(255) NULL, phone VARCHAR(30) NULL, address VARCHAR (155) NULL, city VARCHAR(150) NULL, postal_code VARCHAR(12) NULL, country VARCHAR(2) NULL, sex VARCHAR(1) NULL, time_create BIGINT NOT NULL, time_update BIGINT NOT NULL, mother integer NULL REFERENCES members ON DELETE SET NULL, father integer NULL REFERENCES members ON DELETE SET NULL, birth_year smallint NULL, birth_month smallint NULL, birth_day smallint NULL, death_year smallint NULL, death_month smallint NULL, death_day smallint NULL, note text NULL ); CREATE TABLE couples ( id SERIAL PRIMARY KEY, family_id integer NOT NULL REFERENCES families, wife integer NULL REFERENCES members, husband integer NULL REFERENCES members, state varchar(1) NULL, photo_id INTEGER NULL REFERENCES photos ON DELETE SET NULL, time_create BIGINT NOT NULL, time_update BIGINT NOT NULL, wedding_year smallint NULL, wedding_month smallint NULL, wedding_day smallint NULL, divorce_year smallint NULL, divorce_month smallint NULL, divorce_day smallint NULL ); -- Create views create view families_memberships as select m.user_id , m.family_id, m.is_admin , f."name", f.time_create, f.invitation_code, cm.num as count_members, ca.num as count_admins from memberships m left join families f on f.id = m.family_id -- count members left join ( select family_id , count(*) as num from memberships m group by family_id) cm on cm.family_id = m.family_id -- count admins left join ( select family_id , count(*) as num from memberships m where m.is_admin = true group by family_id) ca on ca.family_id = m.family_id