321 lines
13 KiB
SQL
321 lines
13 KiB
SQL
-- ============================================================================
|
|
-- Dubai Land Department (DLD) Database Schema with CSV Data Loading
|
|
-- MySQL Database Creation and Data Import Script
|
|
-- ============================================================================
|
|
--
|
|
-- IMPORTANT NOTES:
|
|
-- 1. Update the file paths in the LOAD DATA INFILE statements to match your CSV file locations
|
|
-- 2. Ensure MySQL has permission to read from the file location
|
|
-- 3. Enable local_infile: SET GLOBAL local_infile = 1;
|
|
-- 4. Connect with: mysql --local-infile=1 -u username -p
|
|
-- 5. Loading order is CRITICAL due to foreign key constraints
|
|
--
|
|
-- ============================================================================
|
|
|
|
-- Create database
|
|
DROP DATABASE IF EXISTS dubai_dld;
|
|
CREATE DATABASE dubai_dld CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
|
|
USE dubai_dld;
|
|
|
|
-- Enable local data loading
|
|
SET GLOBAL local_infile = 1;
|
|
|
|
-- ============================================================================
|
|
-- TABLE CREATION
|
|
-- ============================================================================
|
|
|
|
-- ----------------------------------------------------------------------------
|
|
-- TABLE: developers (MUST BE CREATED AND LOADED FIRST)
|
|
-- ----------------------------------------------------------------------------
|
|
CREATE TABLE developers (
|
|
developer_id INT AUTO_INCREMENT PRIMARY KEY,
|
|
developer_number INT NOT NULL UNIQUE,
|
|
developer_en VARCHAR(65) NOT NULL,
|
|
registration_date DATETIME NOT NULL,
|
|
license_source_en VARCHAR(35),
|
|
license_type_en VARCHAR(20),
|
|
legal_status_en VARCHAR(25),
|
|
webpage VARCHAR(255),
|
|
phone VARCHAR(20),
|
|
fax VARCHAR(30),
|
|
license_number VARCHAR(10) NOT NULL,
|
|
license_issue_date DATETIME NOT NULL,
|
|
license_expiry_date DATETIME NOT NULL,
|
|
chamber_of_commerce_no VARCHAR(20),
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
|
|
|
INDEX idx_developer_en (developer_en),
|
|
INDEX idx_license_number (license_number),
|
|
INDEX idx_license_expiry_date (license_expiry_date)
|
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci
|
|
COMMENT='Registered real estate developers with DLD licenses';
|
|
|
|
-- ----------------------------------------------------------------------------
|
|
-- TABLE: brokers
|
|
-- ----------------------------------------------------------------------------
|
|
CREATE TABLE brokers (
|
|
broker_id INT AUTO_INCREMENT PRIMARY KEY,
|
|
broker_number INT NOT NULL UNIQUE,
|
|
broker_en VARCHAR(85),
|
|
gender_en VARCHAR(10) NOT NULL,
|
|
license_start_date DATETIME,
|
|
license_end_date DATETIME,
|
|
webpage VARCHAR(255),
|
|
phone VARCHAR(20),
|
|
fax VARCHAR(30),
|
|
real_estate_number INT NOT NULL,
|
|
real_estate_en VARCHAR(115) NOT NULL,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
|
|
|
INDEX idx_broker_en (broker_en),
|
|
INDEX idx_real_estate_number (real_estate_number),
|
|
INDEX idx_real_estate_en (real_estate_en),
|
|
INDEX idx_license_end_date (license_end_date),
|
|
INDEX idx_gender_en (gender_en)
|
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci
|
|
COMMENT='Registered real estate brokers with DLD licenses';
|
|
|
|
-- ----------------------------------------------------------------------------
|
|
-- TABLE: valuations
|
|
-- ----------------------------------------------------------------------------
|
|
CREATE TABLE valuations (
|
|
valuation_id INT AUTO_INCREMENT PRIMARY KEY,
|
|
property_total_value BIGINT NOT NULL,
|
|
area_en VARCHAR(50) NOT NULL,
|
|
actual_area DECIMAL(12,2) NOT NULL,
|
|
procedure_year INT NOT NULL,
|
|
procedure_number INT NOT NULL UNIQUE,
|
|
instance_date DATETIME NOT NULL,
|
|
actual_worth DECIMAL(18,2) NOT NULL,
|
|
procedure_area DECIMAL(12,2) NOT NULL,
|
|
property_type_en VARCHAR(10) NOT NULL,
|
|
prop_sub_type_en VARCHAR(40),
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
|
|
|
INDEX idx_procedure_year (procedure_year),
|
|
INDEX idx_area_en (area_en),
|
|
INDEX idx_property_type_en (property_type_en),
|
|
INDEX idx_instance_date (instance_date),
|
|
INDEX idx_property_total_value (property_total_value)
|
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci
|
|
COMMENT='Official property valuation records from DLD';
|
|
|
|
-- ----------------------------------------------------------------------------
|
|
-- TABLE: lands
|
|
-- ----------------------------------------------------------------------------
|
|
CREATE TABLE lands (
|
|
land_id INT AUTO_INCREMENT PRIMARY KEY,
|
|
land_type_en VARCHAR(25),
|
|
prop_sub_type_en VARCHAR(40),
|
|
actual_area DECIMAL(15,2),
|
|
is_offplan_en VARCHAR(10) NOT NULL,
|
|
pre_registration_number VARCHAR(50),
|
|
is_free_hold_en VARCHAR(15) NOT NULL,
|
|
dm_zip_code INT NOT NULL,
|
|
master_project_en VARCHAR(70),
|
|
project_number DECIMAL(10,2),
|
|
project_en VARCHAR(80),
|
|
area_en VARCHAR(50) NOT NULL,
|
|
zone_en VARCHAR(10) NOT NULL,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
|
|
|
INDEX idx_land_type_en (land_type_en),
|
|
INDEX idx_area_en (area_en),
|
|
INDEX idx_zone_en (zone_en),
|
|
INDEX idx_dm_zip_code (dm_zip_code),
|
|
INDEX idx_project_number (project_number),
|
|
INDEX idx_is_free_hold_en (is_free_hold_en)
|
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci
|
|
COMMENT='Land registry information including plots and parcels';
|
|
|
|
-- ----------------------------------------------------------------------------
|
|
-- TABLE: buildings
|
|
-- ----------------------------------------------------------------------------
|
|
CREATE TABLE buildings (
|
|
building_id INT AUTO_INCREMENT PRIMARY KEY,
|
|
prop_sub_type_en VARCHAR(15) NOT NULL,
|
|
actual_area DECIMAL(12,2),
|
|
common_area DECIMAL(8,2),
|
|
actual_common_area DECIMAL(10,2),
|
|
built_up_area DECIMAL(12,2),
|
|
bld_levels DECIMAL(5,1),
|
|
shops DECIMAL(6,1),
|
|
flats DECIMAL(6,1),
|
|
offices DECIMAL(6,1),
|
|
swimming_pools DECIMAL(4,1),
|
|
elevators DECIMAL(4,1),
|
|
creation_date DATETIME NOT NULL,
|
|
is_offplan_en VARCHAR(10) NOT NULL,
|
|
pre_registration_number VARCHAR(50),
|
|
is_free_hold_en VARCHAR(15) NOT NULL,
|
|
is_lease_hold_en VARCHAR(15) NOT NULL,
|
|
floors DECIMAL(5,1),
|
|
rooms_en VARCHAR(10),
|
|
car_parks DECIMAL(8,2),
|
|
land_number INT NOT NULL,
|
|
land_sub_number DECIMAL(10,2),
|
|
land_type_en VARCHAR(25),
|
|
master_project_en VARCHAR(50),
|
|
project_number DECIMAL(10,2),
|
|
project_en VARCHAR(60),
|
|
area_en VARCHAR(50) NOT NULL,
|
|
zone_en VARCHAR(10) NOT NULL,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
|
|
|
INDEX idx_prop_sub_type_en (prop_sub_type_en),
|
|
INDEX idx_land_number (land_number),
|
|
INDEX idx_project_number (project_number),
|
|
INDEX idx_area_en (area_en),
|
|
INDEX idx_zone_en (zone_en),
|
|
INDEX idx_creation_date (creation_date)
|
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci
|
|
COMMENT='Building registry information including villas and buildings';
|
|
|
|
-- ----------------------------------------------------------------------------
|
|
-- TABLE: transactions
|
|
-- ----------------------------------------------------------------------------
|
|
CREATE TABLE transactions (
|
|
transaction_id BIGINT AUTO_INCREMENT PRIMARY KEY,
|
|
transaction_number VARCHAR(20) NOT NULL,
|
|
instance_date DATETIME NOT NULL,
|
|
group_en VARCHAR(20) NOT NULL,
|
|
procedure_en VARCHAR(50) NOT NULL,
|
|
is_offplan_en VARCHAR(10) NOT NULL,
|
|
is_free_hold_en VARCHAR(15) NOT NULL,
|
|
usage_en VARCHAR(15) NOT NULL,
|
|
area_en VARCHAR(50) NOT NULL,
|
|
prop_type_en VARCHAR(10) NOT NULL,
|
|
prop_sb_type_en VARCHAR(50),
|
|
trans_value DECIMAL(18,2) NOT NULL,
|
|
procedure_area DECIMAL(12,2),
|
|
actual_area DECIMAL(12,2) NOT NULL,
|
|
rooms_en VARCHAR(15),
|
|
parking DECIMAL(10,2),
|
|
nearest_metro_en VARCHAR(50),
|
|
nearest_mall_en VARCHAR(30),
|
|
nearest_landmark_en VARCHAR(50),
|
|
total_buyer INT NOT NULL DEFAULT 0,
|
|
total_seller INT NOT NULL DEFAULT 0,
|
|
master_project_en VARCHAR(80),
|
|
project_en VARCHAR(80),
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
|
|
|
INDEX idx_transaction_number (transaction_number),
|
|
INDEX idx_instance_date (instance_date),
|
|
INDEX idx_group_en (group_en),
|
|
INDEX idx_area_en (area_en),
|
|
INDEX idx_prop_type_en (prop_type_en),
|
|
INDEX idx_project_en (project_en),
|
|
INDEX idx_trans_value (trans_value)
|
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci
|
|
COMMENT='Real estate transaction records from Dubai Land Department';
|
|
|
|
-- ----------------------------------------------------------------------------
|
|
-- TABLE: rents
|
|
-- ----------------------------------------------------------------------------
|
|
CREATE TABLE rents (
|
|
rent_id INT AUTO_INCREMENT PRIMARY KEY,
|
|
registration_date DATETIME NOT NULL,
|
|
start_date DATETIME NOT NULL,
|
|
end_date DATETIME NOT NULL,
|
|
version_en VARCHAR(10) NOT NULL,
|
|
area_en VARCHAR(50) NOT NULL,
|
|
contract_amount DECIMAL(15,2) NOT NULL,
|
|
annual_amount DECIMAL(15,2) NOT NULL,
|
|
is_free_hold_en VARCHAR(15) NOT NULL,
|
|
actual_area DECIMAL(12,2) NOT NULL,
|
|
prop_type_en VARCHAR(15) NOT NULL,
|
|
prop_sub_type_en VARCHAR(20),
|
|
rooms DECIMAL(3,1),
|
|
usage_en VARCHAR(25),
|
|
nearest_metro_en VARCHAR(50),
|
|
nearest_mall_en VARCHAR(25),
|
|
nearest_landmark_en VARCHAR(40),
|
|
parking DECIMAL(4,1),
|
|
total_properties INT NOT NULL,
|
|
master_project_en VARCHAR(50),
|
|
project_en VARCHAR(80),
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
|
|
|
INDEX idx_registration_date (registration_date),
|
|
INDEX idx_start_date (start_date),
|
|
INDEX idx_end_date (end_date),
|
|
INDEX idx_area_en (area_en),
|
|
INDEX idx_prop_type_en (prop_type_en),
|
|
INDEX idx_contract_amount (contract_amount),
|
|
INDEX idx_project_en (project_en)
|
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci
|
|
COMMENT='Property rental contract records from Ejari system';
|
|
|
|
-- ----------------------------------------------------------------------------
|
|
-- TABLE: projects (MUST BE CREATED AND LOADED LAST - HAS FK DEPENDENCY)
|
|
-- ----------------------------------------------------------------------------
|
|
CREATE TABLE projects (
|
|
project_id INT AUTO_INCREMENT PRIMARY KEY,
|
|
project_number VARCHAR(130),
|
|
project_en VARCHAR(70),
|
|
developer_number INT,
|
|
developer_en VARCHAR(85),
|
|
start_date DATETIME,
|
|
end_date DATETIME,
|
|
adoption_date DATETIME,
|
|
prj_type_en VARCHAR(10),
|
|
project_value DECIMAL(18,2),
|
|
escrow_account_number VARCHAR(30),
|
|
project_status VARCHAR(20),
|
|
percent_completed DECIMAL(5,2),
|
|
inspection_date DATETIME,
|
|
completion_date DATETIME,
|
|
description_en TEXT,
|
|
area_en VARCHAR(140),
|
|
zone_en VARCHAR(70),
|
|
cnt_land DECIMAL(8,2),
|
|
cnt_building DECIMAL(8,2),
|
|
cnt_villa DECIMAL(8,2),
|
|
cnt_unit DECIMAL(10,2),
|
|
master_project_en VARCHAR(70),
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
|
|
|
INDEX idx_project_number (project_number),
|
|
INDEX idx_developer_number (developer_number),
|
|
INDEX idx_project_en (project_en),
|
|
INDEX idx_area_en (area_en),
|
|
INDEX idx_project_status (project_status),
|
|
INDEX idx_start_date (start_date)
|
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci
|
|
COMMENT='Real estate development projects registered with DLD';
|
|
|
|
-- ============================================================================
|
|
-- FOREIGN KEY CONSTRAINTS
|
|
-- ============================================================================
|
|
|
|
-- Link projects to developers
|
|
ALTER TABLE projects
|
|
ADD CONSTRAINT fk_project_developer
|
|
FOREIGN KEY (developer_number) REFERENCES developers(developer_number)
|
|
ON DELETE SET NULL ON UPDATE CASCADE;
|
|
|
|
-- ============================================================================
|
|
-- DATA LOADING SECTION
|
|
-- ============================================================================
|
|
--
|
|
-- CRITICAL: Loading order must be followed due to foreign key constraints
|
|
--
|
|
-- ORDER:
|
|
-- 1. developers (FIRST - parent table)
|
|
-- 2. brokers, valuations, lands, buildings, transactions, rents (independent)
|
|
-- 3. projects (LAST - references developers)
|
|
--
|
|
-- BEFORE RUNNING: Update all file paths below to match your CSV file locations
|
|
-- Example: '/path/to/your/csv/files/developers_cleaned.csv'
|
|
-- ============================================================================
|
|
|