CREATE TABLE IF NOT EXISTS users ( mx_id VARCHAR(64), room_id VARCHAR(64) UNIQUE, name VARCHAR(32) DEFAULT NULL, age SMALLINT DEFAULT NULL, sex CHAR, -- 'm' of 'f' interest CHAR, -- male, female or both ('m', 'f' and 'b') description VARCHAR(512) DEFAULT NULL, language VARCHAR(8) DEFAULT 'en', location INTEGER DEFAULT NULL, -- link to ID, cities range DOUBLE PRECISION DEFAULT 20.0, current_action VARCHAR(16) DEFAULT NULL, currently_viewing VARCHAR(64) --link to "room_id" ); CREATE TABLE IF NOT EXISTS likes ( sender VARCHAR(64), -- link to room_id recipient VARCHAR(64), -- link to room_id read BOOLEAN DEFAULT FALSE ); CREATE UNIQUE INDEX IF NOT EXISTS unique_likes ON likes(sender, recipient) ; CREATE TABLE IF NOT EXISTS media ( owner VARCHAR(64), -- link to room_id, type CHAR, -- 'i' for image, 'v' for video purpose CHAR, -- 'p' for media in profile, 'm' for media in message url VARCHAR(64) -- mxc://...... ); CREATE TABLE IF NOT EXISTS messages ( sender VARCHAR(64), -- link to room_id recipient VARCHAR(64), -- link to room_id type CHAR, -- 't' for text, 'p' for picture and 'v' for video content VARCHAR(128), -- will contain a url if media and text if the message is just a text read BOOLEAN DEFAULT FALSE ); CREATE UNIQUE INDEX IF NOT EXISTS unique_messages ON messages(sender, recipient); CREATE TABLE IF NOT EXISTS cities ( ID SERIAL, name VARCHAR(64), lat REAL, lng REAL, country VARCHAR(64) ); CREATE EXTENSION IF NOT EXISTS fuzzystrmatch SCHEMA public; CREATE OR REPLACE FUNCTION deg2rad(double precision) RETURNS double precision AS 'SELECT $1 * 0.01745329' LANGUAGE SQL IMMUTABLE RETURNS NULL ON NULL INPUT; -- lat1, lng1, lat2, lng2, range CREATE OR REPLACE FUNCTION check_distance(double precision, double precision, double precision, double precision, double precision) RETURNS BOOLEAN AS ' SELECT 2 * ASIN(SQRT( POWER(SIN( (deg2rad($3 - $1)) / 2 ), 2) + COS(deg2rad($1)) * COS(deg2rad($3)) * POWER(SIN(deg2rad($4 - $2)/2), 2) )) * 6371 <= $5 ' LANGUAGE SQL RETURNS NULL ON NULL INPUT;