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

CREATE TABLE address (
	id	INT AUTO_INCREMENT,
	full_address	VARCHAR(200) NOT NULL,
	street	VARCHAR(40) NOT NULL,
	city	VARCHAR(40) NOT NULL,
	region	VARCHAR(40) NOT NULL,
	country	VARCHAR(40) NOT NULL,
	zip	VARCHAR(10) NOT NULL,
	PRIMARY KEY (`id`)
);

CREATE TABLE branch (
	id	INT AUTO_INCREMENT,
	name	VARCHAR(40) NOT NULL,
	type	ENUM('NMLS', 'FSRA') NOT NULL,
	letterhead	BLOB(102400) NOT NULL DEFAULT 0,
	num	VARCHAR(40) NOT NULL,
	phone	VARCHAR(20) NOT NULL,
	address	INT NOT NULL,
	PRIMARY KEY (id),
	FOREIGN KEY (address) REFERENCES address(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,
	customer_id 		VARCHAR(255) NOT NULL DEFAULT '',
	phone	VARCHAR(20) NOT NULL DEFAULT '',
	address	INT NOT NULL,
	password 		CHAR(64) NOT NULL,
	verified 		BOOLEAN,
	newsletter 		BOOLEAN DEFAULT 0,
	branch_id 		INT DEFAULT NULL,
	avatar	BLOB(102400) NOT NULL DEFAULT 0,
	letterhead	BLOB(102400) NOT NULL DEFAULT 0,
	/* The password should be a SHA256 hash in hex format. It's length doesn't
	 * vary */
	country 		ENUM('Canada', 'USA') NOT NULL,
	title 			ENUM('Loan Officer',
					'Branch Manager',
					'Mortgage Broker',
					'Executive',
					'Other') NOT NULL,
	status 			ENUM('Unsubscribed',
					'Trial',
					'Free',
					'Subscriber',
					'Branch',
					'Admin') DEFAULT 'Trial',
	role	ENUM('User', 'Manager', 'Admin') NOT NULL,
	created	DATETIME,
	last_login	DATETIME,
	PRIMARY KEY (`id`),
	FOREIGN KEY (branch_id) REFERENCES branch(id),
	FOREIGN KEY (address) REFERENCES address(id)
);

CREATE TABLE subscription (
	id 				INT AUTO_INCREMENT,
	stripe_id 		VARCHAR(255) DEFAULT '',
	user_id 		INT,
	customer_id 	VARCHAR(255) NOT NULL,
	price_id 	VARCHAR(255) NOT NULL,
	/* Key used by stripejs */
	client_secret 	VARCHAR(255) NOT NULL,
	status 			ENUM('incomplete',
					'incomplete_expired',
					'trialing',
					'active',
					'past_due',
					'canceled',
					'unpaid'),
	payment_status	VARCHAR(50) NOT NULL,
	current_period_end 		INT DEFAULT 0,
	current_period_start 		INT DEFAULT 0,
	PRIMARY KEY (`id`),
	FOREIGN KEY (user_id) REFERENCES user(id)
);

CREATE TABLE license (
	id 				INT AUTO_INCREMENT,
	user_id 		INT NOT NULL,
	type 			ENUM('NMLS', 'FSRA', 'Other'),
	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,
	user_id 		INT,
	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 estimate (
	id 			INT AUTO_INCREMENT,
	user_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`)
);

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. */
	estimate_id 		INT UNIQUE NOT NULL,
	PRIMARY KEY (`id`),
	FOREIGN KEY (estimate_id) REFERENCES estimate(id)
	ON DELETE CASCADE
);

CREATE TABLE estimate_template (
	id 			INT AUTO_INCREMENT,
	estimate_id 		INT UNIQUE NOT NULL,
	user_id 		INT NOT NULL, /* User who created the template */
	branch_id 		INT NOT NULL DEFAULT 0,
/* Specific branch allowed to use it. 0 is only user. */
	PRIMARY KEY (`id`),
	FOREIGN KEY (estimate_id) REFERENCES estimate(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 		FLOAT(5, 2) DEFAULT 0, /* Percentage to 2 decimal places */
	ltv 		FLOAT(5, 2) DEFAULT 0,
	dti 		FLOAT(5, 2) DEFAULT 1,
	hoi 			INT DEFAULT 0, /* Home owner's insurance annual payments */
	hazard 			INT DEFAULT 0, /* Hazard insurance annual payments */
	tax 			INT DEFAULT 0, /* Real estate taxes */
	name 			VARCHAR(30) DEFAULT '',
	PRIMARY KEY (`id`),
	FOREIGN KEY (estimate_id) REFERENCES estimate(id) ON DELETE CASCADE,
	FOREIGN KEY (type_id) REFERENCES loan_type(id)
	ON DELETE CASCADE
	ON UPDATE RESTRICT
);

CREATE TABLE mi (
	id 	INT AUTO_INCREMENT,
	loan_id 	INT,
	type 	VARCHAR(10) NOT NULL DEFAULT "",
	label 	VARCHAR(30) NOT NULL DEFAULT "",
	lender 	VARCHAR(20) NOT NULL DEFAULT "",
	rate 	INT DEFAULT 0,
	premium 	INT DEFAULT 0,
	upfront 	INT DEFAULT 0,
	five_year_total 	INT DEFAULT 0,
	initial_premium 	INT DEFAULT 0,
	initial_rate 	INT DEFAULT 0,
	initial_amount 	INT DEFAULT 0,
	PRIMARY KEY (`id`),
	FOREIGN KEY (loan_id) REFERENCES loan(id)
	ON DELETE CASCADE
);

/* 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('Government', '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)
	ON DELETE CASCADE
);

/* 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,
	amount 			INT NOT NULL,
	perc 			SMALLINT NOT NULL,
	/* Percentage of sale price instead of amount */
	type 			ENUM('Government', 'Title', 'Required', 'Lender', 'Other'),
	notes 			VARCHAR(255) NOT NULL,
	name 			VARCHAR(30) NOT NULL,
	/* Group heading shown in report */
	category 		VARCHAR(60) NOT NULL DEFAULT "",
	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)
);

CREATE TABLE estimate_result (
	id 				INT AUTO_INCREMENT,
	loan_id 		INT UNIQUE NOT NULL,
	loan_payment	INT NOT NULL,
	total_monthly	INT NOT NULL,
	total_fees	INT NOT NULL,
	total_credits	INT NOT NULL,
	cash_to_close	INT NOT NULL,
	PRIMARY KEY (`id`),
	FOREIGN KEY (loan_id) REFERENCES loan(id) ON DELETE CASCADE
);