Skouter mortgage estimates. Web application with view written in PHP and Vue, but controller and models in Go.
You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
 
 
 
 
 
 

167 lines
4.7 KiB

  1. /* Precision for all money amounts assumes cents are excluded. */
  2. CREATE TABLE branch (
  3. id INT AUTO_INCREMENT,
  4. type ENUM('NMLS', 'FSRA') NOT NULL,
  5. num VARCHAR(40) NOT NULL,
  6. PRIMARY KEY (id)
  7. );
  8. CREATE TABLE user (
  9. id INT AUTO_INCREMENT,
  10. email VARCHAR(40) UNIQUE NOT NULL,
  11. first_name VARCHAR(30) NOT NULL,
  12. last_name VARCHAR(30) NOT NULL,
  13. password CHAR(64) NOT NULL,
  14. verified BOOLEAN,
  15. branch_id INT NULL,
  16. /* The password should be a SHA256 hash in hex format. It's length doesn't
  17. * vary */
  18. country ENUM('Canada', 'USA'),
  19. title ENUM('Loan Officer',
  20. 'Branch Manager',
  21. 'Mortgage Broker',
  22. 'Other'),
  23. status ENUM('Trial',
  24. 'Free',
  25. 'Subscribed',
  26. 'Branch',
  27. 'Admin'),
  28. role ENUM('User', 'Manager', 'Admin') NOT NULL,
  29. PRIMARY KEY (`id`),
  30. FOREIGN KEY (branch_id) REFERENCES branch(id)
  31. );
  32. CREATE TABLE license (
  33. id INT AUTO_INCREMENT,
  34. user_id INT NOT NULL,
  35. type ENUM('NMLS', 'FSRA'),
  36. num VARCHAR(40) NOT NULL,
  37. PRIMARY KEY (`id`),
  38. FOREIGN KEY (user_id) REFERENCES user(id)
  39. ON DELETE CASCADE
  40. ON UPDATE RESTRICT
  41. );
  42. /* Officers or managers may need to create new loan types with custom settings.
  43. * Types with branch_id and user_id values of 0 will be general cases. */
  44. CREATE TABLE loan_type (
  45. id INT AUTO_INCREMENT,
  46. branch_id INT NOT NULL,
  47. user_id INT NOT NULL,
  48. name VARCHAR(30) UNIQUE NOT NULL,
  49. /* FOREIGN KEY (branch_id) REFERENCES branch(id), */
  50. /* FOREIGN KEY (user_id) REFERENCES user(id), */
  51. PRIMARY KEY (`id`)
  52. );
  53. CREATE TABLE borrower (
  54. id INT AUTO_INCREMENT,
  55. credit_score SMALLINT NOT NULL,
  56. monthly_income INT NOT NULL,
  57. num TINYINT NOT NULL, /* Number of people borrowing. */
  58. PRIMARY KEY (`id`)
  59. );
  60. CREATE TABLE estimate (
  61. id INT AUTO_INCREMENT,
  62. user_id INT NOT NULL,
  63. borrower_id INT NOT NULL,
  64. transaction ENUM('Purchase', 'Refinance'),
  65. price INT NOT NULL,
  66. property ENUM('Single Detached',
  67. 'Single Attached',
  68. 'Condo Lo-rise',
  69. 'Condo Hi-rise'),
  70. occupancy ENUM('Primary', 'Secondary', 'Investment'),
  71. zip VARCHAR(10),
  72. pud BOOLEAN, /* Property under development */
  73. PRIMARY KEY (`id`),
  74. FOREIGN KEY (borrower_id) REFERENCES borrower(id)
  75. );
  76. CREATE TABLE loan (
  77. id INT AUTO_INCREMENT,
  78. estimate_id INT NOT NULL,
  79. type_id INT NOT NULL,
  80. amount INT NOT NULL,
  81. term INT, /* In years */
  82. interest FLOAT(5, 2) DEFAULT 0,
  83. ltv FLOAT(5, 2) DEFAULT 0,
  84. dti FLOAT(5, 2) DEFAULT 1,
  85. hoi INT DEFAULT 0, /* Home owner's insurance annual payments */
  86. hazard INT DEFAULT 0, /* Hazard insurance annual payments */
  87. tax INT DEFAULT 0, /* Real estate taxes */
  88. name VARCHAR(30) DEFAULT '',
  89. PRIMARY KEY (`id`),
  90. FOREIGN KEY (estimate_id) REFERENCES estimate(id),
  91. FOREIGN KEY (type_id) REFERENCES loan_type(id)
  92. ON UPDATE RESTRICT
  93. );
  94. CREATE TABLE mi (
  95. id INT AUTO_INCREMENT,
  96. loan_id INT,
  97. type VARCHAR(10) NOT NULL DEFAULT "",
  98. label VARCHAR(30) NOT NULL DEFAULT "",
  99. lender VARCHAR(20) NOT NULL DEFAULT "",
  100. rate INT DEFAULT 0,
  101. premium INT DEFAULT 0,
  102. upfront INT DEFAULT 0,
  103. five_year_total INT DEFAULT 0,
  104. initial_premium INT DEFAULT 0,
  105. initial_rate INT DEFAULT 0,
  106. initial_amount INT DEFAULT 0,
  107. PRIMARY KEY (`id`),
  108. FOREIGN KEY (loan_id) REFERENCES loan(id)
  109. );
  110. /* template = true fees are saved for users or branches. If template or default
  111. * are true, estimate_id should be null. */
  112. CREATE TABLE fee (
  113. id INT AUTO_INCREMENT NOT NULL,
  114. loan_id INT,
  115. amount INT NOT NULL,
  116. perc SMALLINT, /* Percentage of sale price instead of amount */
  117. type ENUM('Goverment', 'Title', 'Required', 'Lender', 'Other'),
  118. notes VARCHAR(255),
  119. name VARCHAR(30),
  120. /* Group heading shown in report */
  121. category VARCHAR(60),
  122. PRIMARY KEY (`id`),
  123. FOREIGN KEY (loan_id) REFERENCES loan(id)
  124. );
  125. /* Templates to be reused by users or branches. Either user_id or branch_id must
  126. * be non-null.*/
  127. CREATE TABLE fee_template (
  128. id INT AUTO_INCREMENT,
  129. user_id INT NOT NULL,
  130. branch_id INT NOT NULL,
  131. amount INT NOT NULL,
  132. perc SMALLINT NOT NULL,
  133. /* Percentage of sale price instead of amount */
  134. type ENUM('Goverment', 'Title', 'Required', 'Lender', 'Other'),
  135. notes VARCHAR(255) NOT NULL,
  136. name VARCHAR(30) NOT NULL,
  137. /* Group heading shown in report */
  138. category VARCHAR(60) NOT NULL,
  139. auto BOOLEAN NOT NULL,
  140. /* If fee should be automatically applied */
  141. PRIMARY KEY (`id`),
  142. FOREIGN KEY (user_id) REFERENCES user(id),
  143. FOREIGN KEY (branch_id) REFERENCES branch(id)
  144. );
  145. CREATE TABLE estimate_result (
  146. id INT AUTO_INCREMENT,
  147. loan_id INT UNIQUE NOT NULL,
  148. loan_payment INT NOT NULL,
  149. total_monthly INT NOT NULL,
  150. total_fees INT NOT NULL,
  151. total_credits INT NOT NULL,
  152. cash_to_close INT NOT NULL,
  153. PRIMARY KEY (`id`),
  154. FOREIGN KEY (loan_id) REFERENCES loan(id)
  155. );