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.
 
 
 
 
 
 

131 lines
3.5 KiB

  1. /* Precision for all money amounts assumes cents are excluded. */
  2. CREATE TABLE comparison (
  3. id INT AUTO_INCREMENT,
  4. PRIMARY KEY (id)
  5. );
  6. CREATE TABLE branch (
  7. id INT AUTO_INCREMENT,
  8. type ENUM('NMLS', 'FSRA'),
  9. num VARCHAR(40) NOT NULL,
  10. PRIMARY KEY (id)
  11. );
  12. CREATE TABLE user (
  13. id INT AUTO_INCREMENT,
  14. email VARCHAR(40) NOT NULL,
  15. first_name VARCHAR(30) NOT NULL,
  16. last_name VARCHAR(30) NOT NULL,
  17. password CHAR(64) NOT NULL,
  18. branch_id INT,
  19. /* The password should be a SHA256 hash in hex format. It's length doesn't
  20. * vary */
  21. country ENUM('Canada', 'USA'),
  22. title ENUM('Loan Officer',
  23. 'Branch Manager',
  24. 'Mortgage Broker',
  25. 'Other'),
  26. status ENUM('Trial',
  27. 'Free',
  28. 'Subscribed',
  29. 'Branch Subscribed'),
  30. PRIMARY KEY (`id`),
  31. FOREIGN KEY (branch_id) REFERENCES branch(id)
  32. ON DELETE SET NULL
  33. );
  34. CREATE TABLE license (
  35. id INT AUTO_INCREMENT,
  36. user_id INT NOT NULL,
  37. type ENUM('NMLS', 'FSRA'),
  38. num VARCHAR(40) NOT NULL,
  39. PRIMARY KEY (`id`),
  40. FOREIGN KEY (user_id) REFERENCES user(id)
  41. ON DELETE CASCADE
  42. ON UPDATE RESTRICT
  43. );
  44. /* Officers or managers may need to create new loan types with custom settings.
  45. * Types with branch_id and user_id values of null will be general cases. */
  46. CREATE TABLE loan_type (
  47. id INT AUTO_INCREMENT,
  48. branch_id INT,
  49. user_id INT,
  50. name VARCHAR(30),
  51. FOREIGN KEY (branch_id) REFERENCES branch(id),
  52. FOREIGN KEY (user_id) REFERENCES user(id),
  53. PRIMARY KEY (`id`)
  54. );
  55. CREATE TABLE borrower (
  56. id INT AUTO_INCREMENT,
  57. credit_score SMALLINT,
  58. monthly_income INT,
  59. num TINYINT, /* Number of people borrowing. */
  60. PRIMARY KEY (`id`)
  61. );
  62. CREATE TABLE estimate (
  63. id INT AUTO_INCREMENT,
  64. user_id INT NOT NULL,
  65. borrower_id INT NOT NULL,
  66. comparison_id INT,
  67. transaction ENUM('Purchase', 'Refinance'),
  68. loan_type_id INT NOT NULL,
  69. loan_amount INT NOT NULL,
  70. price INT NOT NULL,
  71. property ENUM('Single Family Detached',
  72. 'Single Family Attached',
  73. 'Condominium Lo-rise',
  74. 'Condominium Hi-rise'),
  75. pud BOOLEAN, /* Property under development */
  76. term INT, /* In months */
  77. interest INT, /* Per year, precise to 2 decimals */
  78. hoi INT, /* Hazard insurance annual payments */
  79. mi_name VARCHAR(50), /* Mortgage insurance title shown in menu */
  80. mi_amount INT, /* Mortgage insurance amount */
  81. lender VARCHAR(30),
  82. PRIMARY KEY (`id`),
  83. FOREIGN KEY (loan_type_id) REFERENCES loan_type(id)
  84. ON UPDATE RESTRICT,
  85. FOREIGN KEY (comparison_id) REFERENCES comparison(id)
  86. ON DELETE CASCADE
  87. ON UPDATE RESTRICT,
  88. FOREIGN KEY (borrower_id) REFERENCES borrower(id)
  89. );
  90. /* template = true fees are saved for users or branches. If template or default
  91. * are true, estimate_id should be null. */
  92. CREATE TABLE fee (
  93. id INT AUTO_INCREMENT NOT NULL,
  94. estimate_id INT,
  95. amount INT NOT NULL,
  96. type ENUM('Goverment', 'Title', 'Other'),
  97. notes VARCHAR(255),
  98. name VARCHAR(30),
  99. /* Group heading shown in report */
  100. category VARCHAR(60),
  101. PRIMARY KEY (`id`),
  102. FOREIGN KEY (estimate_id) REFERENCES estimate(id)
  103. );
  104. /* Templates to be reused by users or branches. Either user_id or branch_id must
  105. * be non-null. */
  106. CREATE TABLE fee_template (
  107. id INT AUTO_INCREMENT,
  108. user_id INT,
  109. branch_id INT,
  110. amount INT NOT NULL,
  111. type ENUM('Goverment', 'Title', 'Other'),
  112. notes VARCHAR(255),
  113. name VARCHAR(30),
  114. /* Group heading shown in report */
  115. category VARCHAR(60),
  116. auto BOOLEAN,
  117. /* If fee should be automatically applied */
  118. PRIMARY KEY (`id`),
  119. FOREIGN KEY (user_id) REFERENCES user(id),
  120. FOREIGN KEY (branch_id) REFERENCES branch(id)
  121. );