高效能源监控管理系统
You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
 
 
 
 
 
 

162 lines
11 KiB

-- 区域表
create table area_info (
id varchar(36) not null primary key,
area_name varchar(200) not null,
order_num int4,
parent_id varchar(36) default 0,
remark varchar(500),
create_by varchar(200),
update_by varchar(200),
created_time timestamp default current_timestamp,
updated_time timestamp default current_timestamp
);
comment on table area_info is '区域信息表,用于存储系统中的所有区域数据';
comment on column area_info.id is '区域唯一标识符,使用uuid格式确保全局唯一性[ty-reference](2)';
comment on column area_info.area_name is '区域名称,最长支持200个字符';
comment on column area_info.order_num is '排序号,用于定义区域显示顺序';
comment on column area_info.parent_id is '父级区域id,默认值为0表示顶级区域';
comment on column area_info.remark is '备注信息,允许存储长达500个字符的额外说明';
comment on column area_info.create_by is '创建者,记录创建该区域的用户信息';
comment on column area_info.update_by is '最后更新者,记录最近一次修改该区域的用户信息';
comment on column area_info.created_time is '创建时间,默认值为当前时间戳';
comment on column area_info.updated_time is '最后更新时间,默认值为当前时间戳';
create index idx_area_name on area_info (area_name);
create index idx_area_parent_id on area_info (parent_id);
create index idx_area_parent_order on area_info (parent_id, order_num);
create index idx_area_remark_fulltext on area_info using gin(to_tsvector('english', remark));
create index idx_area_created_time on area_info (created_time);
create index idx_area_updated_time on area_info (updated_time);
-- 楼栋表
create table building_info (
id varchar(36) not null,
building_name varchar(100) null,
parent_id varchar(36) default 0,
levels_count int null,
begin_level int null,
house_count int null,
bed_count int null,
check_in_count int null,
area_id varchar(36) null,
remark varchar(128) null,
order_num int4,
tank_height numeric(24,2) null,
pump_count int null,
low_tank_height numeric(24,2) null,
create_by varchar(200),
update_by varchar(200),
created_time timestamp default current_timestamp,
updated_time timestamp default current_timestamp,
constraint pk_building primary key (id)
);
-- 表的注释
comment on table building_info is '楼栋信息表,记录了每个楼栋的基本信息及关联数据。';
-- 列的注释
comment on column building_info.id is '楼栋唯一标识符,作为主键使用。';
comment on column building_info.building_name is '楼栋名称,用于标识具体的楼栋。';
comment on column building_info.parent_id is '父级楼栋id,默认值为"0",表示顶级楼栋。';
comment on column building_info.levels_count is '楼层数量,表示该楼栋有多少层。';
comment on column building_info.begin_level is '起始楼层号,表示楼栋的第一层编号。';
comment on column building_info.house_count is '每层房间数,记录每层楼有多少个房间。';
comment on column building_info.bed_count is '床位总数,记录楼栋内的总床位数量。';
comment on column building_info.check_in_count is '实际入住数,记录当前已入住的人数或床位数。';
comment on column building_info.area_id is '区域id,标识楼栋所属的地理或管理区域。';
comment on column building_info.remark is '备注信息,用于存储额外的说明或注释。';
comment on column building_info.order_num is '排序号,用于定义楼栋显示顺序。';
comment on column building_info.tank_height is '水箱高度,记录楼栋内水箱的高度信息。';
comment on column building_info.pump_count is '水泵数量,记录楼栋内安装的水泵数量。';
comment on column building_info.low_tank_height is '低区水箱高度,记录低区水箱的具体高度。';
comment on column building_info.create_by is '创建者,记录谁创建了这条记录。';
comment on column building_info.update_by is '更新者,记录最近一次修改该记录的用户。';
comment on column building_info.created_time is '创建时间,自动设置为记录创建时的时间戳。';
comment on column building_info.updated_time is '更新时间,自动设置为记录最后一次修改的时间戳。';
create index idx_building_name on building_info (building_name);
create index idx_area_id on building_info (area_id);
create index idx_order_num on building_info (order_num);
create index idx_area_building on building_info (area_id, building_name);
-- 楼层表
create table floor_info (
id varchar(36) not null primary key,
area_id varchar(36) not null,
building_id varchar(36) not null,
floor_name varchar(200) null,
floor_num int4 null,
floor_purpose varchar(100) null,
floor_area numeric(24, 2) null,
order_num int4,
parent_id varchar(36) default '0',
remark varchar(500),
create_by varchar(200),
update_by varchar(200),
created_time timestamp default current_timestamp,
updated_time timestamp default current_timestamp
);
-- 添加表注释
comment on table floor_info is '楼层信息表,用于记录建筑物内各楼层的基本信息和属性';
-- 为每个字段添加注释
comment on column floor_info.id is '楼层唯一标识符,作为主键使用';
comment on column floor_info.area_id is '所属区域id,关联到区域表';
comment on column floor_info.building_id is '所属建筑物id,关联到建筑物表';
comment on column floor_info.floor_name is '楼层名称,如“ground floor”或“basement”';
comment on column floor_info.floor_num is '楼层编号,在同一建筑物内必须唯一';
comment on column floor_info.floor_purpose is '楼层用途,例如办公、住宅、停车场等';
comment on column floor_info.floor_area is '楼层总面积,单位为平方米';
comment on column floor_info.order_num is '楼层排序号,用于定义楼层显示顺序';
comment on column floor_info.parent_id is '父级楼层id,默认值为“0”,表示无父级楼层';
comment on column floor_info.remark is '备注信息,用于记录额外说明';
comment on column floor_info.create_by is '创建者,记录谁创建了这条记录';
comment on column floor_info.update_by is '更新者,记录最近一次修改该记录的用户';
comment on column floor_info.created_time is '创建时间,自动设置为记录创建时的时间戳';
comment on column floor_info.updated_time is '更新时间,自动设置为记录最后一次修改的时间戳';
create index idx_floor_info_area_id on floor_info (area_id);
create index idx_floor_info_building_id on floor_info (building_id);
create index idx_floor_info_floor_purpose on floor_info (floor_purpose);
create index idx_floor_info_building_floor on floor_info (building_id, floor_num);
create index idx_floor_info_area_purpose on floor_info (area_id, floor_purpose);
create table house_info (
id varchar(36) primary key not null, -- 房屋唯一标识符,自增主键
area_id varchar(36) not null, -- 所属区域id,外键关联到area表
building_id varchar(36) not null, -- 所属建筑物id,外键关联到building表
floor_id varchar(36) not null, -- 所属楼层id,外键关联到floor_info表
house_name varchar(100) null, -- 房间名称
address varchar(200) null, -- 房屋详细地址
price decimal(10, 2), -- 房屋价格,保留两位小数
total_area numeric(24, 2), -- 房屋总面积
usable_area numeric(24, 2), -- 房屋使用面积(可居住部分)
built_year varchar(20), -- 建造年份
status int default 0, -- 0:正常,1:禁用
remark varchar(500) null, -- 备注信息
create_by varchar(200) null, -- 创建者
update_by varchar(200) null, -- 更新者
created_time timestamp default current_timestamp, -- 创建时间
updated_time timestamp default current_timestamp -- 更新时间
);
comment on table house_info is '房屋信息表,用于存储房屋的基本信息及属性';
comment on column house_info.id is '房屋唯一标识符';
comment on column house_info.area_id is '所属区域id,外键关联到area表';
comment on column house_info.building_id is '所属建筑物id,外键关联到building表';
comment on column house_info.floor_id is '所属楼层id,外键关联到floor_info表';
comment on column house_info.house_name is '房间名称';
comment on column house_info.address is '房屋详细地址';
comment on column house_info.price is '房屋价格,保留两位小数';
comment on column house_info.total_area is '房屋总面积';
comment on column house_info.usable_area is '房屋使用面积(可居住部分)';
comment on column house_info.built_year is '建造年份';
comment on column house_info.status is '状态:0:正常,1:禁用';
comment on column house_info.remark is '备注信息';
comment on column house_info.create_by is '创建者';
comment on column house_info.update_by is '更新者';
comment on column house_info.created_time is '创建时间';
comment on column house_info.updated_time is '更新时间';
create index idx_house_info_area_id on house_info (area_id);
create index idx_house_info_building_id on house_info (building_id);
create index idx_house_info_floor_id on house_info (floor_id);
create index idx_house_info_area_building on house_info (area_id, building_id);
create index idx_house_info_building_floor on house_info (building_id, floor_id);