/* Precision for all money amounts assumes cents are excluded. */

CREATE TABLE branch (
	id 				INT AUTO_INCREMENT,
	type 			ENUM('NMLS', 'FSRA') NOT NULL,
	num 			VARCHAR(40) NOT NULL,
	PRIMARY KEY (id)
);

CREATE TABLE user (
	id 				INT AUTO_INCREMENT,
	email 			VARCHAR(40) UNIQUE NOT NULL,
	first_name 		VARCHAR(30) NOT NULL,
	last_name 		VARCHAR(30) NOT NULL,
	password 		CHAR(64) NOT NULL,
	verified 		BOOLEAN,
	branch_id 		INT NULL,
	/* The password should be a SHA256 hash in hex format. It's length doesn't
	 * vary */
	country 		ENUM('Canada', 'USA'),
	title 			ENUM('Loan Officer',
					'Branch Manager',
					'Mortgage Broker',
					'Other'),
	status 			ENUM('Trial',
					'Free',
					'Subscribed',
					'Branch',
					'Admin'),
	PRIMARY KEY (`id`),
	FOREIGN KEY (branch_id) REFERENCES branch(id)
);

CREATE TABLE license (
	id 				INT AUTO_INCREMENT,
	user_id 		INT NOT NULL,
	type 			ENUM('NMLS', 'FSRA'),
	num 			VARCHAR(40) NOT NULL,
	PRIMARY KEY (`id`),
	FOREIGN KEY (user_id) REFERENCES user(id)
	ON DELETE CASCADE
	ON UPDATE RESTRICT
);

/* Officers or managers may need to create new loan types with custom settings.
 * Types with branch_id and user_id values of 0 will be general cases. */
CREATE TABLE loan_type (
	id 				INT AUTO_INCREMENT,
	branch_id 		INT NOT NULL,
	user_id 		INT NOT NULL,
	name 			VARCHAR(30) UNIQUE NOT NULL,
	/* FOREIGN KEY (branch_id) REFERENCES branch(id), */
	/* FOREIGN KEY (user_id) REFERENCES user(id), */
	PRIMARY KEY (`id`)
);

CREATE TABLE borrower (
	id 				INT AUTO_INCREMENT,
	credit_score 	SMALLINT NOT NULL,
	monthly_income 	INT NOT NULL,
	num 			TINYINT NOT NULL, /* Number of people borrowing. */
	PRIMARY KEY (`id`)
);

CREATE TABLE estimate (
	id 			INT AUTO_INCREMENT,
	user_id 		INT NOT NULL,
	borrower_id 		INT NOT NULL,
	transaction 		ENUM('Purchase', 'Refinance'),
	price 			INT NOT NULL,
	property 		ENUM('Single Detached',
					'Single Attached',
					'Condo Lo-rise',
					'Condo Hi-rise'),
	occupancy 		ENUM('Primary', 'Secondary', 'Investment'),
	zip 			VARCHAR(10),
	pud 			BOOLEAN, /* Property under development */
	PRIMARY KEY (`id`),
	FOREIGN KEY (borrower_id) REFERENCES borrower(id)
);

CREATE TABLE loan (
	id  	INT AUTO_INCREMENT,
	estimate_id 		INT NOT NULL,
	type_id 		INT NOT NULL,
	amount 		INT NOT NULL,
	term 			INT, /* In years */
	interest 		INT, /* Per year, precise to 2 decimals */
	ltv 		FLOAT(5, 2) DEFAULT 0,
	dti 		FLOAT(5, 2) DEFAULT 1,
	hoi 			INT DEFAULT 0, /* Hazard insurance annual payments */
	mi_name 		VARCHAR(50) NOT NULL,
	/* Mortgage insurance title shown in menu */
	mi_amount 		INT, /* Mortgage insurance amount */
	lender 			VARCHAR(30) DEFAULT '',
	name 			VARCHAR(30) DEFAULT '',
	PRIMARY KEY (`id`),
	FOREIGN KEY (estimate_id) REFERENCES estimate(id),
	FOREIGN KEY (type_id) REFERENCES loan_type(id)
	ON UPDATE RESTRICT
);

/* template = true fees are saved for users or branches. If template or default
 * are true, estimate_id should be null.*/
CREATE TABLE fee (
	id 				INT AUTO_INCREMENT NOT NULL,
	loan_id 	INT,
	amount 			INT NOT NULL,
	perc 			SMALLINT, /* Percentage of sale price instead of amount */
	type 			ENUM('Goverment', 'Title', 'Required', 'Lender', 'Other'),
	notes 			VARCHAR(255),
	name 			VARCHAR(30),
	/* Group heading shown in report */
	category 		VARCHAR(60),
	PRIMARY KEY (`id`),
	FOREIGN KEY (loan_id) REFERENCES loan(id)
);

/* Templates to be reused by users or branches. Either user_id or branch_id must
 * be non-null.*/
CREATE TABLE fee_template (
	id 				INT AUTO_INCREMENT,
	user_id 		INT NOT NULL,
	branch_id 		INT NOT NULL,
	amount 			INT NOT NULL,
	perc 			SMALLINT NOT NULL,
	/* Percentage of sale price instead of amount */
	type 			ENUM('Goverment', 'Title', 'Required', 'Lender', 'Other'),
	notes 			VARCHAR(255) NOT NULL,
	name 			VARCHAR(30) NOT NULL,
	/* Group heading shown in report */
	category 		VARCHAR(60) NOT NULL,
	auto 			BOOLEAN NOT NULL,
	/* If fee should be automatically applied */
	PRIMARY KEY (`id`),
	FOREIGN KEY (user_id) REFERENCES user(id),
	FOREIGN KEY (branch_id) REFERENCES branch(id)
);