Files
pmgr/db/schema.sql

1382 lines
54 KiB
SQL

--
-- Database 'property_manager'
-- 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 :-/
-- REVISIT <AP>: 20090511
-- By not specifying the database, the script can
-- make the determination of which one to use.
-- DROP DATABASE IF EXISTS `property_manager`;
-- CREATE DATABASE `property_manager`;
-- USE `property_manager`;
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ##
-- ## SOFTWARE CONFIGURATION
-- ##
-- ----------------------------------------------------------------------
-- ----------------------------------------------------------------------
-- TABLE pmgr_config_system
DROP TABLE IF EXISTS `pmgr_config_system`;
CREATE TABLE `pmgr_config_system` (
`config_version_id` INT(10) UNSIGNED NOT NULL
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
LOCK TABLES `pmgr_config_system` WRITE;
INSERT INTO `pmgr_config_system` (`config_version_id`)
VALUES
(1);
UNLOCK TABLES;
-- ----------------------------------------------------------------------
-- ----------------------------------------------------------------------
-- TABLE pmgr_config_versions
DROP TABLE IF EXISTS `pmgr_config_versions`;
CREATE TABLE `pmgr_config_versions` (
`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 `pmgr_config_versions` WRITE;
INSERT INTO `pmgr_config_versions` (`id`, `schema`, `major`, `minor`, `bugfix`, `stamp`, `comment`)
VALUES
(1, 1, 0, 1, 0, '2009-05-11 06:00', 'First revision');
UNLOCK TABLES;
-- ----------------------------------------------------------------------
-- ----------------------------------------------------------------------
-- TABLE pmgr_config_options
DROP TABLE IF EXISTS `pmgr_config_options`;
CREATE TABLE `pmgr_config_options` (
`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 pmgr_contacts
DROP TABLE IF EXISTS `pmgr_contacts`;
CREATE TABLE `pmgr_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) DEFAULT NULL,
-- FEDERAL ID, e.g. SSN or EIN
`id_federal` VARCHAR(16) DEFAULT NULL,
-- LOCAL ID, e.g. drivers license
`id_local` VARCHAR(16) DEFAULT NULL,
`id_local_state` CHAR(2) DEFAULT NULL,
`id_local_exp` DATE DEFAULT NULL,
`comment` VARCHAR(255) DEFAULT NULL,
PRIMARY KEY (`id`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
-- ----------------------------------------------------------------------
-- ----------------------------------------------------------------------
-- TABLE pmgr_contact_addresses
DROP TABLE IF EXISTS `pmgr_contact_addresses`;
CREATE TABLE `pmgr_contact_addresses` (
`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 pmgr_contact_phones
DROP TABLE IF EXISTS `pmgr_contact_phones`;
CREATE TABLE `pmgr_contact_phones` (
`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,
UNIQUE KEY `number_key` (`phone`, `ext`),
PRIMARY KEY (`id`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
-- ----------------------------------------------------------------------
-- ----------------------------------------------------------------------
-- TABLE pmgr_contact_emails
DROP TABLE IF EXISTS `pmgr_contact_emails`;
CREATE TABLE `pmgr_contact_emails` (
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
`email` VARCHAR(128) NOT NULL,
`comment` VARCHAR(255) DEFAULT NULL,
UNIQUE KEY `email_key` (`email`),
PRIMARY KEY (`id`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
-- ----------------------------------------------------------------------
-- ----------------------------------------------------------------------
-- TABLE pmgr_contacts_methods
DROP TABLE IF EXISTS `pmgr_contacts_methods`;
CREATE TABLE `pmgr_contacts_methods` (
`contact_id` INT(10) UNSIGNED NOT NULL,
`method` ENUM('ADDRESS',
'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 pmgr_groups
DROP TABLE IF EXISTS `pmgr_groups`;
CREATE TABLE `pmgr_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 pmgr_group_options
DROP TABLE IF EXISTS `pmgr_group_options`;
CREATE TABLE `pmgr_group_options` (
`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 pmgr_group_permissions
DROP TABLE IF EXISTS `pmgr_group_permissions`;
CREATE TABLE `pmgr_group_permissions` (
`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 pmgr_users
DROP TABLE IF EXISTS `pmgr_users`;
CREATE TABLE `pmgr_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 pmgr_user_options
DROP TABLE IF EXISTS `pmgr_user_options`;
CREATE TABLE `pmgr_user_options` (
`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 pmgr_sites
DROP TABLE IF EXISTS `pmgr_sites`;
CREATE TABLE `pmgr_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 pmgr_site_options
DROP TABLE IF EXISTS `pmgr_site_options`;
CREATE TABLE `pmgr_site_options` (
`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 pmgr_site_memberships
--
-- 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 pmgr_users U
-- LEFT JOIN pmgr_site_membership M ON M.user_id = U.id
-- LEFT JOIN pmgr_groups G ON G.id = M.group_id
-- LEFT JOIN pmgr_group_permissions P ON P.group_id = G.id
-- GROUP BY U.id, P.name
DROP TABLE IF EXISTS `pmgr_site_memberships`;
CREATE TABLE `pmgr_site_memberships` (
`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 pmgr_site_areas
DROP TABLE IF EXISTS `pmgr_site_areas`;
CREATE TABLE `pmgr_site_areas` (
`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 pmgr_units
DROP TABLE IF EXISTS `pmgr_units`;
CREATE TABLE `pmgr_units` (
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
`unit_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',
'LOCKED',
'LIENED')
NOT NULL DEFAULT 'VACANT',
`current_lease_id` INT(10) UNSIGNED DEFAULT NULL,
`sort_order` MEDIUMINT UNSIGNED NOT NULL,
`walk_order` MEDIUMINT UNSIGNED NOT NULL,
`deposit` FLOAT(12,2) DEFAULT NULL,
`rent` FLOAT(12,2) DEFAULT NULL,
`comment` VARCHAR(255) DEFAULT NULL,
PRIMARY KEY (`id`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
-- ----------------------------------------------------------------------
-- ----------------------------------------------------------------------
-- TABLE pmgr_unit_types
DROP TABLE IF EXISTS `pmgr_unit_types`;
CREATE TABLE `pmgr_unit_types` (
`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 pmgr_unit_sizes
DROP TABLE IF EXISTS `pmgr_unit_sizes`;
CREATE TABLE `pmgr_unit_sizes` (
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
`unit_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,
`rent` FLOAT(12,2) DEFAULT NULL,
PRIMARY KEY (`id`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ##
-- ## ACTIONS
-- ##
-- ----------------------------------------------------------------------
-- ----------------------------------------------------------------------
-- TABLE pmgr_actions
DROP TABLE IF EXISTS `pmgr_actions`;
CREATE TABLE `pmgr_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 pmgr_late_schedules
DROP TABLE IF EXISTS `pmgr_late_schedules`;
CREATE TABLE `pmgr_late_schedules` (
`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 pmgr_actions_late_schedules
DROP TABLE IF EXISTS `pmgr_actions_late_schedules`;
CREATE TABLE `pmgr_actions_late_schedules` (
`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;
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ##
-- ## CUSTOMERS
-- ##
-- ----------------------------------------------------------------------
-- ----------------------------------------------------------------------
-- TABLE pmgr_customers
DROP TABLE IF EXISTS `pmgr_customers`;
CREATE TABLE `pmgr_customers` (
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
-- Customer name may be the same as the primary contact
-- or it may entirely independent of that person.
`name` VARCHAR(80) NOT NULL,
-- Primary Contact... every customer must have one
-- (and presumably, most customers will _be_ one).
-- REVISIT <AP> 20090612:
-- Does this contact also get added to the
-- contacts_customers table?
`primary_contact_id` INT(10) UNSIGNED NOT NULL,
-- Number of different leases for this customer.
-- It's not good to have redundant information,
-- but these fields change infrequently, and make
-- certain queries much easier, most notably for
-- the grid query, in which linking customer to
-- lease results in repeated statement entries
-- when a customer has more than one lease.
`lease_count` SMALLINT UNSIGNED NOT NULL DEFAULT 0,
`current_lease_count` SMALLINT UNSIGNED NOT NULL DEFAULT 0,
`past_lease_count` SMALLINT UNSIGNED NOT NULL DEFAULT 0,
`comment` VARCHAR(255) DEFAULT NULL,
PRIMARY KEY (`id`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
-- ----------------------------------------------------------------------
-- ----------------------------------------------------------------------
-- TABLE pmgr_contacts_customers
DROP TABLE IF EXISTS `pmgr_contacts_customers`;
CREATE TABLE `pmgr_contacts_customers` (
`contact_id` INT(10) UNSIGNED NOT NULL,
`customer_id` INT(10) UNSIGNED NOT NULL,
-- What type of contact is this for the lease?
`type` ENUM('TENANT', -- TENANT
'ALTERNATE') -- ALTERNATE CONTACT ONLY
NOT NULL DEFAULT 'TENANT',
-- If the tenant is active as part of the lease
`active` TINYINT DEFAULT 1,
`comment` VARCHAR(255) DEFAULT NULL,
PRIMARY KEY (`customer_id`, `contact_id`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ##
-- ## LEASES
-- ##
-- ----------------------------------------------------------------------
-- ----------------------------------------------------------------------
-- TABLE pmgr_leases
DROP TABLE IF EXISTS `pmgr_leases`;
CREATE TABLE `pmgr_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,
`customer_id` INT(10) UNSIGNED NOT NULL,
`late_schedule_id` INT(10) UNSIGNED DEFAULT NULL,
`lease_date` DATE NOT NULL,
`movein_planned_date` DATE DEFAULT NULL,
`movein_date` DATE DEFAULT NULL,
`moveout_date` DATE DEFAULT NULL,
`moveout_planned_date` DATE DEFAULT NULL,
`notice_given_date` DATE DEFAULT NULL,
`notice_received_date` DATE DEFAULT NULL,
`close_date` DATE DEFAULT NULL,
`charge_through_date` DATE DEFAULT NULL,
`paid_through_date` DATE DEFAULT NULL,
`deposit` FLOAT(12,2) DEFAULT NULL,
`rent` FLOAT(12,2) DEFAULT NULL,
`next_rent` FLOAT(12,2) DEFAULT NULL,
`next_rent_date` DATE DEFAULT NULL,
`comment` VARCHAR(255) DEFAULT NULL,
PRIMARY KEY (`id`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
-- ----------------------------------------------------------------------
-- ----------------------------------------------------------------------
-- TABLE pmgr_lease_types
DROP TABLE IF EXISTS `pmgr_lease_types`;
CREATE TABLE `pmgr_lease_types` (
`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;
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ##
-- ## RESERVATIONS
-- ##
-- ----------------------------------------------------------------------
-- ----------------------------------------------------------------------
-- TABLE pmgr_reservations
DROP TABLE IF EXISTS `pmgr_reservations`;
CREATE TABLE `pmgr_reservations` (
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
-- Allow user to specify their own reservation numbers
-- If NULL, `id` will be used
`number` VARCHAR(20) DEFAULT NULL,
`customer_id` INT(10) UNSIGNED NOT NULL,
`deposit` FLOAT(12,2) DEFAULT NULL,
`reservation_date` DATE NOT NULL,
`expiration_date` DATE DEFAULT NULL,
`fulfilled_date` DATE DEFAULT NULL,
`lease_id` INT(10) UNSIGNED NOT NULL,
`comment` VARCHAR(255) DEFAULT NULL,
PRIMARY KEY (`id`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
-- ----------------------------------------------------------------------
-- ----------------------------------------------------------------------
-- TABLE pmgr_reservations_units
DROP TABLE IF EXISTS `pmgr_reservations_units`;
CREATE TABLE `pmgr_reservations_units` (
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
`reservation_id` INT(10) UNSIGNED NOT NULL,
`requested_id` INT(10) UNSIGNED DEFAULT NULL,
`type` ENUM('UNIT',
'UNIT_SIZE',
'UNIT_TYPE')
NOT NULL DEFAULT 'UNIT',
PRIMARY KEY (`id`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ##
-- ## FINANCIAL ACCOUNTS
-- ##
-- ----------------------------------------------------------------------
-- ----------------------------------------------------------------------
-- TABLE pmgr_accounts
DROP TABLE IF EXISTS `pmgr_accounts`;
CREATE TABLE `pmgr_accounts` (
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
`type` ENUM('ASSET',
'LIABILITY',
'EQUITY',
'INCOME',
'EXPENSE')
NOT NULL DEFAULT 'ASSET',
-- Accounts Receivable / Accounts Payable
-- If this is a trackable account, any credit posted
-- to an ASSET OR EXPENSE account should have an
-- entry posted to the reconciliations table (unless
-- it is a "pre-payment" of sorts, in which case the
-- reconciliation will have to wait for the debit).
-- For LIABILITY, EQUITY, and INCOME, the opposite
-- is true, with reconciliations posted, under
-- normal circumstances, when a debit occurs.
-- `trackable` TINYINT(1) UNSIGNED NOT NULL DEFAULT 1,
`deposits` TINYINT(1) UNSIGNED NOT NULL DEFAULT 0, -- Can be used for deposits?
`invoices` TINYINT(1) UNSIGNED NOT NULL DEFAULT 0, -- Can be used for invoices?
`receipts` TINYINT(1) UNSIGNED NOT NULL DEFAULT 0, -- Can be used for receipts?
`refunds` TINYINT(1) UNSIGNED NOT NULL DEFAULT 0, -- Can be used for refunds?
-- Security Level
`level` INT UNSIGNED DEFAULT 10,
`name` VARCHAR(80) NOT NULL,
`external_account` INT(10) UNSIGNED DEFAULT NULL,
`external_name` VARCHAR(80) DEFAULT NULL,
`comment` VARCHAR(255) DEFAULT NULL,
PRIMARY KEY (`id`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
LOCK TABLES `pmgr_accounts` WRITE;
INSERT INTO `pmgr_accounts` (`type`, `name`)
VALUES
('ASSET', 'A/R' ),
('LIABILITY', 'A/P' ),
('LIABILITY', 'Credit' );
INSERT INTO `pmgr_accounts` (`type`, `name`, `receipts`)
VALUES
('ASSET', 'Cash', 1),
('ASSET', 'Check', 1),
('ASSET', 'Money Order', 1),
('ASSET', 'ACH', 1),
('EXPENSE', 'Concession', 1);
INSERT INTO `pmgr_accounts` (`type`, `name`)
VALUES
('ASSET', 'NSF' ),
('EXPENSE', 'Waiver' ),
('EXPENSE', 'Bad Debt' );
INSERT INTO `pmgr_accounts` (`type`, `name`, `invoices`)
VALUES
('LIABILITY', 'Tax', 0),
('LIABILITY', 'Security Deposit', 1),
('INCOME', 'Rent', 1),
('INCOME', 'Late Charge', 1),
('INCOME', 'NSF Charge', 1),
('INCOME', 'Cleaning', 1),
('INCOME', 'Damage', 1);
INSERT INTO `pmgr_accounts` (`type`, `name`)
VALUES
('EXPENSE', 'Maintenance' );
INSERT INTO `pmgr_accounts` (`type`, `name`, `refunds`)
VALUES
('ASSET', 'Petty Cash', 1);
INSERT INTO `pmgr_accounts` (`type`, `name`, `level`, `deposits`, `refunds`)
VALUES
('ASSET', 'Bank', 6, 1, 1);
INSERT INTO `pmgr_accounts` (`type`, `name`, `level`)
VALUES
('ASSET', 'Closing', 6),
('LIABILITY', 'Loan', 1),
('EQUITY', 'Equity', 1);
UNLOCK TABLES;
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ##
-- ## LEDGERS
-- ##
-- ----------------------------------------------------------------------
-- ----------------------------------------------------------------------
-- TABLE pmgr_ledgers
DROP TABLE IF EXISTS `pmgr_ledgers`;
CREATE TABLE `pmgr_ledgers` (
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
`name` VARCHAR(90) NOT NULL,
`account_id` INT(10) UNSIGNED NOT NULL,
`sequence` INT(10) UNSIGNED DEFAULT 1,
`prior_ledger_id` INT(10) UNSIGNED DEFAULT NULL,
`close_transaction_id` INT(10) UNSIGNED DEFAULT NULL,
`comment` VARCHAR(255) DEFAULT NULL,
PRIMARY KEY (`id`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
-- ----------------------------------------------------------------------
-- ----------------------------------------------------------------------
-- TABLE pmgr_transactions
DROP TABLE IF EXISTS `pmgr_transactions`;
CREATE TABLE `pmgr_transactions` (
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
-- REVISIT <AP>: 20090804
-- I'm not sure about most of these terms.
-- Just as long as they're distinct though... I can rename them later
`type` ENUM('INVOICE', -- Sales Invoice
'RECEIPT', -- Actual receipt of monies
'PURCHASE_INVOICE', -- Committment to pay
'CREDIT_NOTE', -- Inverse of Sales Invoice
'PAYMENT', -- Actual payment
'DEPOSIT',
'AUTO_DEPOSIT', -- Fundamentally same as DEPOSIT
'WITHDRAWAL',
'CLOSE', -- Essentially an internal (not accounting) transaction
-- 'CREDIT',
-- 'REFUND',
'TRANSFER') -- Unsure of TRANSFERs use
NOT NULL,
`stamp` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
-- All entries of a transaction should be for the same
-- customer. By keeping track of customer here, it ensures
-- that we can always track what's happening with the user
-- even if there are only ledger entries, and no statement
-- entries for some reason (the primary concern being the
-- receipt of money, with nothing to pay for).
-- customer_id can be NULL, for internal transfers and such.
-- In that case, there should be no statement entries for
-- this transaction, only ledger entries.
-- REVISIT <AP>: 20090723
-- It sounds like a transaction that has customer_id as NULL
-- is really a fundamentally different type of "transaction".
-- Do we need to have a new table for those type of
-- entries / activities?
`customer_id` INT(10) UNSIGNED DEFAULT NULL,
-- The account/ledger of the transaction set
-- (e.g. A/R, Bank, etc)
`account_id` INT(10) UNSIGNED DEFAULT NULL,
`ledger_id` INT(10) UNSIGNED DEFAULT NULL,
`crdr` ENUM('DEBIT',
'CREDIT')
DEFAULT NULL,
-- amount is for convenience. It can always be calculated from
-- the associated double entries (and therefore will need to be
-- updated if they should change in any way).
`amount` FLOAT(12,2) DEFAULT NULL,
`comment` VARCHAR(255) DEFAULT NULL,
PRIMARY KEY (`id`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
-- -- ----------------------------------------------------------------------
-- -- ----------------------------------------------------------------------
-- -- TABLE pmgr_ledger_entries
DROP TABLE IF EXISTS `pmgr_ledger_entries`;
CREATE TABLE `pmgr_ledger_entries` (
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
`transaction_id` INT(10) UNSIGNED NOT NULL,
-- The account/ledger of the entry
`account_id` INT(10) UNSIGNED NOT NULL,
`ledger_id` INT(10) UNSIGNED NOT NULL,
`crdr` ENUM('DEBIT',
'CREDIT')
NOT NULL,
`amount` FLOAT(12,2) NOT NULL,
`comment` VARCHAR(255) DEFAULT NULL,
PRIMARY KEY (`id`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
-- -- ----------------------------------------------------------------------
-- -- ----------------------------------------------------------------------
-- -- TABLE pmgr_double_entries
DROP TABLE IF EXISTS `pmgr_double_entries`;
CREATE TABLE `pmgr_double_entries` (
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
-- The two entries that make up a "double entry"
`debit_entry_id` INT(10) UNSIGNED NOT NULL,
`credit_entry_id` INT(10) UNSIGNED NOT NULL,
-- REVISIT <AP>: 20090720
-- The amount from ledger_entries should be moved here to
-- eliminate duplication, and crdr should just be deleted.
-- However, it can always be changed later, and I thinks
-- those fields will come in handy when generating a
-- a ledger report. So, duplication for now.
`comment` VARCHAR(255) DEFAULT NULL,
PRIMARY KEY (`id`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
-- -- ----------------------------------------------------------------------
-- -- ----------------------------------------------------------------------
-- -- TABLE pmgr_statement_entries
DROP TABLE IF EXISTS `pmgr_statement_entries`;
CREATE TABLE `pmgr_statement_entries` (
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
-- REVISIT <AP>: 20090804
-- I'm not sure about most of these terms.
-- Just as long as they're distinct though... I can rename them later
`type` ENUM('CHARGE', -- Invoiced Charge to Customer
'DISBURSEMENT', -- Disbursement of Receipt Funds
'REVERSAL', -- Reversal of a charge
'WRITEOFF', -- Write-off bad debt
'VOUCHER', -- Agreement to pay
'PAYMENT', -- Payment of a Voucher
'REFUND', -- Payment due to refund
'SURPLUS', -- Surplus Receipt Funds
'WAIVER', -- Waived Charge
-- REVISIT <AP>: 20090730
-- VOID is used for handling NSF and perhaps charge reversals.
-- It's not clear this is the best way to handle these things.
'VOID')
NOT NULL,
`transaction_id` INT(10) UNSIGNED NOT NULL,
-- Effective date is when the charge/disbursement/transfer actually
-- takes effect (since it may not be at the time of the transaction).
-- Through date is used if/when a charge covers a certain time period,
-- like rent. A security deposit, for example, would not use the
-- through date.
`effective_date` DATE DEFAULT NULL, -- first day
`through_date` DATE DEFAULT NULL, -- last day
`due_date` DATE DEFAULT NULL,
-- Customer ID is redundant, since it is saved as part of the
-- transaction. Keeping it here anyway, for simplicity. If it's
-- truly redundant, and unnecessary, we can always re
`customer_id` INT(10) UNSIGNED NOT NULL,
`lease_id` INT(10) UNSIGNED DEFAULT NULL,
`amount` FLOAT(12,2) NOT NULL,
-- The account of the entry
-- REVISIT <AP>: 20090720
-- We don't want to confuse statement entries with ledger entries,
-- yet we're including account here. It doesn't feel right, but at
-- the same time, it will allow us to show _what_ was charged for
-- in the statement. Keeping it for now...
`account_id` INT(10) UNSIGNED DEFAULT NULL,
-- Allow the disbursement to reconcile against the charge
`charge_entry_id` INT(10) UNSIGNED DEFAULT NULL,
-- The transaction that reversed this charge, if any
`reverse_transaction_id` INT(10) UNSIGNED DEFAULT NULL,
`comment` VARCHAR(255) DEFAULT NULL,
PRIMARY KEY (`id`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
-- ----------------------------------------------------------------------
-- ----------------------------------------------------------------------
-- TABLE pmgr_tender_types
DROP TABLE IF EXISTS `pmgr_tender_types`;
CREATE TABLE `pmgr_tender_types` (
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
-- name may (or may not) be used to clarify in reports
-- for example, 'Check #1234' as the legal tender name.
`name` VARCHAR(80) NOT NULL,
-- Does this form of legal tender actually change hands?
-- If so, then it's tillable. Examples include cash,
-- checks, and money orders. Things that are not tillable
-- include credit cards, debit cards, and ACH transfers.
`tillable` TINYINT(1) UNSIGNED NOT NULL DEFAULT 1,
-- Should these items be deposited automatically?
`auto_deposit` TINYINT(1) UNSIGNED NOT NULL DEFAULT 0,
-- Names of the 4 data fields (or NULL if not used)
-- Not the most robust of solutions, especially since
-- it requires (or strongly implicates) that all fields
-- be of the same type (ugh). A more complete solution
-- would be for each type to have its own table of data
-- and to have that table specified here. However, this
-- is MUCH simpler, and works for now.
`data1_name` VARCHAR(80) DEFAULT NULL,
`data2_name` VARCHAR(80) DEFAULT NULL,
`data3_name` VARCHAR(80) DEFAULT NULL,
`data4_name` VARCHAR(80) DEFAULT NULL,
-- The field from pmgr_tenders that is used for helping
-- to name the tender. For example, a Check tender type
-- might specify data1 as the field, so that tenders
-- would be named "Check #0000"
`naming_field` VARCHAR(80) DEFAULT 'id',
-- When we accept legal tender of this form, where does
-- it go? Each type of legal tender can specify an
-- account, either distinct or non-distinct from others
`account_id` INT(10) UNSIGNED NOT NULL,
-- Which account should these items be deposited in?
-- This may or may not actually be used for all types
-- but will likely get used for auto deposit items.
`deposit_account_id` INT(10) UNSIGNED DEFAULT NULL,
`comment` VARCHAR(255) DEFAULT NULL,
PRIMARY KEY (`id`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
-- ----------------------------------------------------------------------
-- ----------------------------------------------------------------------
-- TABLE pmgr_tenders
DROP TABLE IF EXISTS `pmgr_tenders`;
CREATE TABLE `pmgr_tenders` (
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
-- name may (or may not) be used to clarify in reports
-- for example, 'Check #1234' as the legal tender name.
`name` VARCHAR(80) DEFAULT NULL,
-- The type of this legal tender
`tender_type_id` INT(10) UNSIGNED DEFAULT NULL,
-- The customer that provided this tender
-- REVISIT <AP>: 20090728 Do we allow anonymous payments?
`customer_id` INT(10) UNSIGNED NOT NULL,
-- REVISIT <AP>: 20090605
-- Check Number;
-- Routing Number, Account Number;
-- Card Number, Expiration Date; CVV2 Code
-- etc.
-- REVISIT <AP> 20090630
-- I _think_ that CVV2 is NEVER supposed to
-- be stored ANYWHERE. Merchants agree to
-- use it only to verify the transaction and
-- then leave no record of it, so that even
-- if their security is compromised, no one
-- will know the CVV2 code unless they are
-- in physical possession of the card.
`data1` VARCHAR(80) DEFAULT NULL,
`data2` VARCHAR(80) DEFAULT NULL,
`data3` VARCHAR(80) DEFAULT NULL,
`data4` VARCHAR(80) DEFAULT NULL,
-- The ledger entry this legal tender applies to
`ledger_entry_id` INT(10) UNSIGNED NOT NULL,
-- The ledger entry if this tender is marked NSF
`nsf_ledger_entry_id` INT(10) UNSIGNED DEFAULT NULL,
-- The ledger entry if this actual deposit transaction
`deposit_ledger_entry_id` INT(10) UNSIGNED DEFAULT NULL,
-- The deposit transaction that included these monies
`deposit_transaction_id` INT(10) UNSIGNED DEFAULT NULL,
-- The NSF transaction coming back from the bank.
`nsf_transaction_id` INT(10) UNSIGNED DEFAULT NULL,
`comment` VARCHAR(255) DEFAULT NULL,
PRIMARY KEY (`id`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
-- ----------------------------------------------------------------------
-- ----------------------------------------------------------------------
-- TABLE pmgr_deposits
DROP TABLE IF EXISTS `pmgr_deposits`;
CREATE TABLE `pmgr_deposits` (
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
`transaction_id` INT(10) UNSIGNED NOT NULL,
-- The account/ledger of the entry
`account_id` INT(10) UNSIGNED NOT NULL,
`ledger_id` INT(10) UNSIGNED NOT NULL,
-- For convenience. Should always be DEBIT (unless we
-- decide to credit NSF instead of a negative debit).
`crdr` ENUM('DEBIT')
NOT NULL DEFAULT 'DEBIT',
`amount` FLOAT(12,2) NOT NULL,
`comment` VARCHAR(255) DEFAULT NULL,
PRIMARY KEY (`id`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ######################################################################
-- ##
-- ## SITE MAPS
-- ##
-- ----------------------------------------------------------------------
-- ----------------------------------------------------------------------
-- TABLE pmgr_maps
DROP TABLE IF EXISTS `pmgr_maps`;
CREATE TABLE `pmgr_maps` (
`id` INT(10) UNSIGNED NOT NULL AUTO_INCREMENT,
`site_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
PRIMARY KEY (`id`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
-- ----------------------------------------------------------------------
-- ----------------------------------------------------------------------
-- TABLE pmgr_maps_units
DROP TABLE IF EXISTS `pmgr_maps_units`;
CREATE TABLE `pmgr_maps_units` (
`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 pmgr_notes
DROP TABLE IF EXISTS `pmgr_notes`;
CREATE TABLE `pmgr_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;