Added database schema file. For the complete revision history of schema.sql, see branches/rent_manager_20090510/db path of the 'domain' repository
git-svn-id: file:///svn-source/pmgr/branches/initial_20090526@9 97e9348a-65ac-dc4b-aefc-98561f571b83
This commit is contained in:
985
db/schema.sql
Normal file
985
db/schema.sql
Normal file
@@ -0,0 +1,985 @@
|
||||
--
|
||||
-- Database 'rentmgr'
|
||||
|
||||
-- REVISIT <AP>: 20090511
|
||||
-- Perhaps "Rent Master" instead of "Rent Manager" ?
|
||||
-- Perhaps "Property Master" ?
|
||||
-- Perhaps better to market under several names:
|
||||
-- "Self Storage Master", "Apartment Master", etc.
|
||||
|
||||
|
||||
-- AP:
|
||||
-- Originally authored for MySQL.
|
||||
-- However, requirements to consider / keep in mind:
|
||||
-- PostgreSQL: Don't want to be tied to ONLY MySQL.
|
||||
-- SQLite: Will likely require a standalone option.
|
||||
|
||||
-- REVISIT <AP>: 20090511
|
||||
-- I would like timestamps to note when things change, but
|
||||
-- I don't think we can rely on the magic of MySQL to update
|
||||
-- them, since we may be required to use other engines.
|
||||
-- At the moment, I'll keep the MySQL statements, but we
|
||||
-- may have to move this logic into the application :-/
|
||||
|
||||
|
||||
DROP DATABASE IF EXISTS `rentmgr`;
|
||||
CREATE DATABASE `rentmgr`;
|
||||
USE `rentmgr`;
|
||||
|
||||
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ##
|
||||
-- ## SOFTWARE CONFIGURATION
|
||||
-- ##
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_configSystem
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_configSystem`;
|
||||
CREATE TABLE `rmgr_configSystem` (
|
||||
`version_id` INT(10) UNSIGNED NOT NULL
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
LOCK TABLES `rmgr_configSystem` WRITE;
|
||||
INSERT INTO `rmgr_configSystem` (`version_id`)
|
||||
VALUES
|
||||
(1);
|
||||
UNLOCK TABLES;
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_configVersions
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_configVersions`;
|
||||
CREATE TABLE `rmgr_configVersions` (
|
||||
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
`schema` INT UNSIGNED NOT NULL DEFAULT 1, -- DB REVISION
|
||||
`major` INT UNSIGNED NOT NULL,
|
||||
`minor` INT UNSIGNED NOT NULL,
|
||||
`bugfix` INT UNSIGNED NOT NULL DEFAULT 0,
|
||||
|
||||
-- REVISIT <AP>: 20090511
|
||||
-- Should we just use the 'notes' table instead?
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
`stamp` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
|
||||
PRIMARY KEY (`id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
LOCK TABLES `rmgr_configVersions` WRITE;
|
||||
INSERT INTO `rmgr_configVersions` (`id`, `schema`, `major`, `minor`, `bugfix`, `stamp`, `comment`)
|
||||
VALUES
|
||||
(1, 1, 0, 1, 0, '2009-05-11 06:00', 'First revision');
|
||||
UNLOCK TABLES;
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_configOptions
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_configOptions`;
|
||||
CREATE TABLE `rmgr_configOptions` (
|
||||
`name` VARCHAR(50) NOT NULL,
|
||||
`value` VARCHAR(255) NOT NULL,
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
|
||||
PRIMARY KEY (`name`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
|
||||
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ##
|
||||
-- ## CONTACTS (PEOPLE and COMPANIES)
|
||||
-- ##
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_contacts
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_contacts`;
|
||||
CREATE TABLE `rmgr_contacts` (
|
||||
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
`first_name` VARCHAR(255) DEFAULT NULL,
|
||||
`middle_name` VARCHAR(255) DEFAULT NULL,
|
||||
`last_name` VARCHAR(255) DEFAULT NULL,
|
||||
`company_name` VARCHAR(255) DEFAULT NULL,
|
||||
`display_name` VARCHAR(512) NOT NULL,
|
||||
|
||||
-- FEDERAL ID, e.g. SSN or EIN
|
||||
`id_federal` VARCHAR(16) DEFAULT NULL,
|
||||
|
||||
-- STATE ID, e.g. drivers license
|
||||
`id_num` VARCHAR(16) DEFAULT NULL,
|
||||
`id_state` CHAR(2) DEFAULT NULL,
|
||||
`id_exp` DATE DEFAULT NULL,
|
||||
|
||||
PRIMARY KEY (`id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_contactAddress
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_contactAddresses`;
|
||||
CREATE TABLE `rmgr_contactAddresses` (
|
||||
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
`address` VARCHAR(255) DEFAULT NULL,
|
||||
`city` VARCHAR(255) DEFAULT NULL,
|
||||
`state` CHAR(2) DEFAULT NULL, -- REVISIT <AP>: Convert to ENUM
|
||||
`postcode` VARCHAR(12) DEFAULT NULL,
|
||||
`country` VARCHAR(128) DEFAULT NULL, -- REVISIT <AP>: Convert to ENUM
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
|
||||
PRIMARY KEY (`id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_contactPhones
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_contactPhones`;
|
||||
CREATE TABLE `rmgr_contactPhones` (
|
||||
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
`type` ENUM('LANDLINE',
|
||||
'MOBILE',
|
||||
'VIRTUAL',
|
||||
'PAGER',
|
||||
'FAX')
|
||||
NOT NULL DEFAULT 'LANDLINE',
|
||||
`phone` VARCHAR(18) NOT NULL,
|
||||
`ext` VARCHAR(6) DEFAULT NULL,
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
|
||||
KEY `number_key` (`phone`),
|
||||
PRIMARY KEY (`id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_contactEmails
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_contactEmails`;
|
||||
CREATE TABLE `rmgr_contactEmails` (
|
||||
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
`email` VARCHAR(128) NOT NULL,
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
|
||||
KEY `email_key` (`email`),
|
||||
PRIMARY KEY (`id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_contactMethods
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_contactMethods`;
|
||||
CREATE TABLE `rmgr_contactMethods` (
|
||||
`contact_id` INT(10) UNSIGNED NOT NULL,
|
||||
`method` ENUM('POST',
|
||||
'PHONE',
|
||||
'EMAIL')
|
||||
NOT NULL,
|
||||
`method_id` INT(10) UNSIGNED NOT NULL,
|
||||
`type` ENUM('MAIN',
|
||||
'HOME',
|
||||
'BUSINESS',
|
||||
'OTHER')
|
||||
NOT NULL DEFAULT 'MAIN',
|
||||
`preference` ENUM('PRIMARY',
|
||||
'WORK',
|
||||
'ALTERNATE',
|
||||
'EMERGENCY')
|
||||
NOT NULL DEFAULT 'PRIMARY',
|
||||
-- `position` TINYINT UNSIGNED NOT NULL DEFAULT 1,
|
||||
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
|
||||
PRIMARY KEY (`contact_id`, `method`, `method_id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ##
|
||||
-- ## GROUPS
|
||||
-- ##
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_groups
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_groups`;
|
||||
CREATE TABLE `rmgr_groups` (
|
||||
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
-- REVISIT <AP>: 20090511
|
||||
-- code may not be userful
|
||||
`code` VARCHAR(12) NOT NULL, -- User style "id"
|
||||
`name` VARCHAR(80) NOT NULL,
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
|
||||
PRIMARY KEY (`id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_groupOptions
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_groupOptions`;
|
||||
CREATE TABLE `rmgr_groupOptions` (
|
||||
`group_id` INT(10) UNSIGNED NOT NULL,
|
||||
`name` VARCHAR(50) NOT NULL,
|
||||
`value` VARCHAR(255) NOT NULL,
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
|
||||
PRIMARY KEY (`group_id`, `name`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_groupPermissions
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_groupPermissions`;
|
||||
CREATE TABLE `rmgr_groupPermissions` (
|
||||
`group_id` INT(10) UNSIGNED NOT NULL,
|
||||
`name` CHAR(30) NOT NULL,
|
||||
`access` ENUM('ALLOWED',
|
||||
'DENIED',
|
||||
'FORCED')
|
||||
NOT NULL DEFAULT 'ALLOWED',
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
|
||||
PRIMARY KEY (`group_id`, `name`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ##
|
||||
-- ## USERS
|
||||
-- ##
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_users
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_users`;
|
||||
CREATE TABLE `rmgr_users` (
|
||||
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
`code` VARCHAR(12) NOT NULL, -- User style "id"
|
||||
|
||||
-- Login details. Passwords are not yet used (and so NULL).
|
||||
`login` VARCHAR(30) NOT NULL,
|
||||
`salt` CHAR(12) DEFAULT NULL,
|
||||
`passhash` VARCHAR(255) DEFAULT NULL,
|
||||
|
||||
-- Contact information for this user
|
||||
`contact_id` INT(10) UNSIGNED NOT NULL,
|
||||
|
||||
-- Specific comments
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
|
||||
PRIMARY KEY (`id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_userOptions
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_userOptions`;
|
||||
CREATE TABLE `rmgr_userOptions` (
|
||||
`user_id` INT(10) UNSIGNED NOT NULL,
|
||||
`name` VARCHAR(50) NOT NULL,
|
||||
`value` VARCHAR(255) NOT NULL,
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
|
||||
PRIMARY KEY (`user_id`, `name`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ##
|
||||
-- ## SITES
|
||||
-- ##
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_sites
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_sites`;
|
||||
CREATE TABLE `rmgr_sites` (
|
||||
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
`code` VARCHAR(12) NOT NULL, -- User style "id"
|
||||
`name` VARCHAR(80) NOT NULL,
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
|
||||
UNIQUE KEY `site_code` (`code`),
|
||||
PRIMARY KEY (`id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_siteOptions
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_siteOptions`;
|
||||
CREATE TABLE `rmgr_siteOptions` (
|
||||
`site_id` INT(10) UNSIGNED NOT NULL,
|
||||
`name` VARCHAR(50) NOT NULL,
|
||||
`value` VARCHAR(255) NOT NULL,
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
|
||||
PRIMARY KEY (`site_id`, `name`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_siteMemberships
|
||||
--
|
||||
-- Which users are allowed to access which sites,
|
||||
-- and under which set of group permissions (possibly multiple)
|
||||
|
||||
-- SELECT U.id, P.name, MAX(P.access)
|
||||
-- FROM rmgr_users U
|
||||
-- LEFT JOIN rmgr_siteMembership M ON M.user_id = U.id
|
||||
-- LEFT JOIN rmgr_groups G ON G.id = M.group_id
|
||||
-- LEFT JOIN rmgr_groupPermissions P ON P.group_id = G.id
|
||||
-- GROUP BY U.id, P.name
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_siteMemberships`;
|
||||
CREATE TABLE `rmgr_siteMemberships` (
|
||||
`site_id` INT(10) UNSIGNED NOT NULL,
|
||||
`user_id` INT(10) UNSIGNED NOT NULL,
|
||||
`group_id` INT(10) UNSIGNED NOT NULL,
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
|
||||
PRIMARY KEY (`site_id`, `user_id`, `group_id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_siteAreas
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_siteAreas`;
|
||||
CREATE TABLE `rmgr_siteAreas` (
|
||||
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
`site_id` INT(10) UNSIGNED NOT NULL,
|
||||
`code` VARCHAR(12) NOT NULL, -- User style "id"
|
||||
`name` VARCHAR(80) NOT NULL,
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
|
||||
PRIMARY KEY (`id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ##
|
||||
-- ## UNITS
|
||||
-- ##
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_unitTypes
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_unitTypes`;
|
||||
CREATE TABLE `rmgr_unitTypes` (
|
||||
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
`code` VARCHAR(12) NOT NULL, -- User style "id"
|
||||
`name` VARCHAR(80) NOT NULL,
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
|
||||
PRIMARY KEY (`id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_unitSizes
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_unitSizes`;
|
||||
CREATE TABLE `rmgr_unitSizes` (
|
||||
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
`type_id` INT(10) UNSIGNED NOT NULL,
|
||||
`code` VARCHAR(12) NOT NULL, -- User style "id"
|
||||
`name` VARCHAR(80) NOT NULL,
|
||||
`width` SMALLINT UNSIGNED NOT NULL, -- inches
|
||||
`depth` SMALLINT UNSIGNED NOT NULL, -- inches
|
||||
`height` SMALLINT UNSIGNED DEFAULT NULL, -- inches
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
|
||||
`deposit` FLOAT(12,2) DEFAULT NULL,
|
||||
`amount` FLOAT(12,2) DEFAULT NULL,
|
||||
|
||||
PRIMARY KEY (`id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_units
|
||||
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_units`;
|
||||
CREATE TABLE `rmgr_units` (
|
||||
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
`size_id` INT(10) UNSIGNED NOT NULL,
|
||||
`code` VARCHAR(12) NOT NULL, -- User style "id"
|
||||
`name` VARCHAR(80) NOT NULL,
|
||||
|
||||
`status` ENUM('DELETED',
|
||||
'DAMAGED',
|
||||
'COMPANY',
|
||||
'UNAVAILABLE',
|
||||
'RESERVED',
|
||||
'DIRTY',
|
||||
'VACANT',
|
||||
'OCCUPIED',
|
||||
'LATE', -- NOT SURE
|
||||
'LOCKED',
|
||||
'LIENED')
|
||||
NOT NULL DEFAULT 'VACANT',
|
||||
|
||||
`sort_order` MEDIUMINT UNSIGNED NOT NULL,
|
||||
`walk_order` MEDIUMINT UNSIGNED NOT NULL,
|
||||
|
||||
`deposit` FLOAT(12,2) DEFAULT NULL,
|
||||
`amount` FLOAT(12,2) DEFAULT NULL,
|
||||
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
|
||||
PRIMARY KEY (`id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ##
|
||||
-- ## ACTIONS
|
||||
-- ##
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_actions
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_actions`;
|
||||
CREATE TABLE `rmgr_actions` (
|
||||
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
|
||||
`action` ENUM('LETTER',
|
||||
'GATELOCK',
|
||||
'OVERLOCK',
|
||||
'LIEN',
|
||||
'AUCTION')
|
||||
NOT NULL,
|
||||
|
||||
-- Which letter, or other specific action?
|
||||
-- REVISIT <AP>: Are there other specific actions?
|
||||
`item_id` INT(10) UNSIGNED DEFAULT NULL,
|
||||
|
||||
`name` VARCHAR(80) NOT NULL,
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
|
||||
PRIMARY KEY (`id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_lateSchedules
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_lateSchedules`;
|
||||
CREATE TABLE `rmgr_lateSchedules` (
|
||||
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
`code` VARCHAR(12) NOT NULL, -- User style "id"
|
||||
|
||||
`name` VARCHAR(80) NOT NULL,
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
|
||||
|
||||
|
||||
PRIMARY KEY (`id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_lateScheduleActions
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_lateScheduleActions`;
|
||||
CREATE TABLE `rmgr_lateScheduleActions` (
|
||||
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
|
||||
`late_schedule_id` INT(10) UNSIGNED DEFAULT NULL,
|
||||
`days_past_due` SMALLINT NOT NULL,
|
||||
`recurring` TINYINT DEFAULT 0,
|
||||
`action_id` INT(10) UNSIGNED DEFAULT NULL,
|
||||
-- REVISIT <AP>: 20090513
|
||||
-- Should we have a specific fee list, or just use account
|
||||
-- `fee_id` INT(10) UNSIGNED DEFAULT NULL,
|
||||
`account_id` INT(10) UNSIGNED DEFAULT NULL,
|
||||
`amount` FLOAT(12,2) DEFAULT NULL,
|
||||
`tax` FLOAT(12,2) DEFAULT NULL,
|
||||
`name` VARCHAR(80) NOT NULL,
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
|
||||
PRIMARY KEY (`id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ##
|
||||
-- ## LEASES
|
||||
-- ##
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_leaseTypes
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_leaseTypes`;
|
||||
CREATE TABLE `rmgr_leaseTypes` (
|
||||
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
`code` VARCHAR(12) NOT NULL, -- User style "id"
|
||||
`name` VARCHAR(80) NOT NULL,
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
|
||||
PRIMARY KEY (`id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_leases
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_leases`;
|
||||
CREATE TABLE `rmgr_leases` (
|
||||
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
|
||||
-- Allow user to specify their own lease numbers
|
||||
-- If NULL, `id` will be used
|
||||
`number` VARCHAR(20) DEFAULT NULL,
|
||||
|
||||
`lease_type_id` INT(10) UNSIGNED NOT NULL,
|
||||
`unit_id` INT(10) UNSIGNED NOT NULL,
|
||||
`late_schedule_id` INT(10) UNSIGNED DEFAULT NULL,
|
||||
|
||||
`lease_date` DATE NOT NULL,
|
||||
`movein_planed_date` DATE DEFAULT NULL,
|
||||
`movein_date` DATE DEFAULT NULL,
|
||||
`moveout_date` DATE DEFAULT NULL,
|
||||
`moveout_planed_date` DATE DEFAULT NULL,
|
||||
`notice_given_date` DATE DEFAULT NULL,
|
||||
`notice_received_date` DATE DEFAULT NULL,
|
||||
`close_date` DATE DEFAULT NULL,
|
||||
|
||||
`deposit` FLOAT(12,2) DEFAULT NULL,
|
||||
`amount` FLOAT(12,2) DEFAULT NULL,
|
||||
|
||||
`next_amount` FLOAT(12,2) DEFAULT NULL,
|
||||
`next_amount_date` DATE DEFAULT NULL,
|
||||
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
|
||||
PRIMARY KEY (`id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_leaseAltContacts
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_leaseContacts`;
|
||||
CREATE TABLE `rmgr_leaseContacts` (
|
||||
`lease_id` INT(10) UNSIGNED NOT NULL,
|
||||
`contact_id` INT(10) UNSIGNED NOT NULL,
|
||||
|
||||
-- What type of contact is this for the lease?
|
||||
`type` ENUM('TENANT', -- PRIMARY TENANT
|
||||
'COTENANT', -- ADDITIONAL TENANT
|
||||
'ALTERNATE') -- ALTERNATE CONTACT ONLY
|
||||
NOT NULL DEFAULT 'TENANT',
|
||||
|
||||
-- If the tenant is removed as part of the lease
|
||||
`active` TINYINT DEFAULT 1,
|
||||
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
|
||||
PRIMARY KEY (`lease_id`, `contact_id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ##
|
||||
-- ## TRANSACTIONS
|
||||
-- ##
|
||||
|
||||
-- # Charge
|
||||
-- # - Issued against customer lease
|
||||
-- # - associated with account (i.e. QuickBooks account / category)
|
||||
-- # Receipt
|
||||
-- # - Collections of payments paid at one time
|
||||
-- # Payment
|
||||
-- # - Credited towards customer (or lease?)
|
||||
-- # - may be more than customer owes
|
||||
-- # - cash/check/charge/ach/etc
|
||||
-- # Reconciliation
|
||||
-- # - Associates a payment with the charge
|
||||
-- # - Indicates amount of credit towards charge
|
||||
-- # - Payments may cover several charges
|
||||
-- # - Several payments may cover the same charge
|
||||
|
||||
|
||||
-- Which charges haven not been paid?
|
||||
-- SELECT C.id AS cid, C.total AS total, COALESCE(SUM(R.amount),0) AS paid
|
||||
-- FROM rmgr_transactionCharges C
|
||||
-- LEFT JOIN rmgr_transactionReconciliations R ON R.charge_id = C.id
|
||||
-- GROUP BY C.id
|
||||
-- HAVING paid < C.total
|
||||
|
||||
-- SELECT ChL.lid AS lid, U.name, C.display_name,
|
||||
-- SUM(ChL.total) AS total, SUM(ChL.paid) AS paid,
|
||||
-- SUM(ChL.total) - SUM(ChL.paid) AS owing
|
||||
-- FROM (SELECT Ch.lease_id AS lid, Ch.total AS total, COALESCE(SUM(R.amount),0) AS paid
|
||||
-- FROM rmgr_transactionCharges Ch
|
||||
-- LEFT JOIN rmgr_transactionReconciliations R ON R.charge_id = Ch.id
|
||||
-- WHERE Ch.due_date < NOW()
|
||||
-- GROUP BY Ch.id
|
||||
-- HAVING paid < Ch.total) ChL
|
||||
-- LEFT JOIN rmgr_leases L ON L.id = ChL.lid
|
||||
-- LEFT JOIN rmgr_leaseContacts Lc ON Lc.lease_id = L.id AND Lc.type = 'TENANT'
|
||||
-- LEFT JOIN rmgr_contacts C ON C.id = Lc.contact_id
|
||||
-- LEFT JOIN rmgr_units U ON U.id = L.unit_id
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_chargeTypes
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_chargeTypes`;
|
||||
CREATE TABLE `rmgr_chargeTypes` (
|
||||
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
|
||||
`name` VARCHAR(80) NOT NULL,
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
`account_id` INT(10) UNSIGNED NOT NULL, -- quickbooks tracking
|
||||
|
||||
PRIMARY KEY (`id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
LOCK TABLES `rmgr_chargeTypes` WRITE;
|
||||
INSERT INTO `rmgr_chargeTypes` (`id`, `name`, `account_id`)
|
||||
VALUES
|
||||
(1, 'Security Deposit', 0),
|
||||
(2, 'Rent', 0),
|
||||
(3, 'Late Charge', 0);
|
||||
UNLOCK TABLES;
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_paymentTypes
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_paymentTypes`;
|
||||
CREATE TABLE `rmgr_paymentTypes` (
|
||||
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
|
||||
`name` VARCHAR(80) NOT NULL,
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
`tillable` TINYINT(1) NOT NULL DEFAULT 1, -- Does manager collect by hand?
|
||||
|
||||
PRIMARY KEY (`id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
LOCK TABLES `rmgr_paymentTypes` WRITE;
|
||||
INSERT INTO `rmgr_paymentTypes` (`id`, `name`, `tillable`)
|
||||
VALUES
|
||||
(1, 'Cash', 1),
|
||||
(2, 'Check', 1),
|
||||
(3, 'Money Order', 1),
|
||||
(4, 'ACH', 0),
|
||||
(5, 'Debit Card', 0),
|
||||
(6, 'Credit Card', 0),
|
||||
(7, 'Other Tillable', 1),
|
||||
(8, 'Other Non-Tillable', 0);
|
||||
UNLOCK TABLES;
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_transactionCharges
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_transactionCharges`;
|
||||
CREATE TABLE `rmgr_transactionCharges` (
|
||||
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
|
||||
`type_id` INT(10) UNSIGNED NOT NULL,
|
||||
`lease_id` INT(10) UNSIGNED NOT NULL,
|
||||
`charge_date` DATE NOT NULL,
|
||||
`charge_to_date` DATE NOT NULL,
|
||||
`due_date` DATE DEFAULT NULL,
|
||||
`amount` FLOAT(12,2) NOT NULL,
|
||||
`tax` FLOAT(12,2) NOT NULL,
|
||||
`total` FLOAT(12,2) NOT NULL,
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
|
||||
PRIMARY KEY (`id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_transactionReceipts
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_transactionReceipts`;
|
||||
CREATE TABLE `rmgr_transactionReceipts` (
|
||||
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
|
||||
`stamp` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
|
||||
PRIMARY KEY (`id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_transactionPayments
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_transactionPayments`;
|
||||
CREATE TABLE `rmgr_transactionPayments` (
|
||||
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
|
||||
`receipt_id` INT(10) UNSIGNED NOT NULL,
|
||||
`payment_type_id` INT(10) UNSIGNED NOT NULL,
|
||||
`amount` FLOAT(12,2) NOT NULL,
|
||||
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
|
||||
PRIMARY KEY (`id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_transactionReconciliations
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_transactionReconciliations`;
|
||||
CREATE TABLE `rmgr_transactionReconciliations` (
|
||||
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
`charge_id` INT(10) UNSIGNED NOT NULL,
|
||||
-- REVISIT <AP>: 20090514
|
||||
-- THIS SHOULD BE RECEIPT_ID, NOT PAYMENT_ID, RIGHT??
|
||||
`receipt_id` INT(10) UNSIGNED NOT NULL,
|
||||
`amount` FLOAT(12,2) NOT NULL,
|
||||
PRIMARY KEY (`id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ##
|
||||
-- ## SITE MAPS
|
||||
-- ##
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_maps
|
||||
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_maps`;
|
||||
CREATE TABLE `rmgr_maps` (
|
||||
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
`site_id` INT(10) UNSIGNED NOT NULL,
|
||||
`area_id` INT(10) UNSIGNED NOT NULL,
|
||||
`name` VARCHAR(80) DEFAULT NULL,
|
||||
`comment` VARCHAR(255) DEFAULT NULL,
|
||||
|
||||
`width` SMALLINT UNSIGNED NOT NULL, -- inches
|
||||
`depth` SMALLINT UNSIGNED NOT NULL, -- inches
|
||||
|
||||
UNIQUE KEY `map_key` (`site_id`, `area_id`),
|
||||
PRIMARY KEY (`id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_mapUnits
|
||||
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_mapUnits`;
|
||||
CREATE TABLE `rmgr_mapUnits` (
|
||||
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
`map_id` INT(10) UNSIGNED NOT NULL,
|
||||
`unit_id` INT(10) UNSIGNED NOT NULL,
|
||||
`pt_top` SMALLINT UNSIGNED NOT NULL, -- inches
|
||||
`pt_left` SMALLINT UNSIGNED NOT NULL, -- inches
|
||||
-- `pt_bottom` SMALLINT UNSIGNED NOT NULL, -- inches
|
||||
-- `pt_right` SMALLINT UNSIGNED NOT NULL, -- inches
|
||||
`transpose` SMALLINT UNSIGNED NOT NULL,
|
||||
|
||||
PRIMARY KEY (`id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
|
||||
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ######################################################################
|
||||
-- ##
|
||||
-- ## NOTES
|
||||
-- ##
|
||||
|
||||
|
||||
-- ----------------------------------------------------------------------
|
||||
-- ----------------------------------------------------------------------
|
||||
-- TABLE rmgr_notes
|
||||
|
||||
DROP TABLE IF EXISTS `rmgr_notes`;
|
||||
CREATE TABLE `rmgr_notes` (
|
||||
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
|
||||
|
||||
-- HISTORY is a note created by the system, when the
|
||||
-- user changes a setting or field that has been
|
||||
-- flagged for tracking.
|
||||
-- USER is a manually entered note.
|
||||
`type` ENUM('HISTORY',
|
||||
'USER')
|
||||
NOT NULL DEFAULT 'USER',
|
||||
|
||||
-- `item` references the object type, and `item_id` denotes
|
||||
-- the specific object to which this note is attached
|
||||
`item_id` INT(10) UNSIGNED NOT NULL,
|
||||
`item` ENUM('OPTION',
|
||||
'UNIT_TYPE',
|
||||
'UNIT_SIZE',
|
||||
'UNIT',
|
||||
'CUSTOMER',
|
||||
'SITE',
|
||||
'SITE_AREA',
|
||||
'USER') -- etc, etc
|
||||
NOT NULL,
|
||||
|
||||
-- Text of the recorded note
|
||||
`note` TEXT,
|
||||
|
||||
-- User that made this note, or if HISTORY, made the change
|
||||
`user_id` INT(10) UNSIGNED NOT NULL,
|
||||
`stamp` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
|
||||
PRIMARY KEY (`id`)
|
||||
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
|
||||
|
||||
|
||||
|
||||
Reference in New Issue
Block a user