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.
mes-heli/sql/v1.2.0/1.structure.sql

174 lines
18 KiB

This file contains ambiguous Unicode characters!

This file contains ambiguous Unicode characters that may be confused with others in your current locale. If your use case is intentional and legitimate, you can safely ignore this warning. Use the Escape button to highlight these characters.

ALTER TABLE project_order RENAME project_sale_order;
ALTER TABLE project_sale_order COMMENT '项目销售订单表';
ALTER TABLE project_order_sub RENAME project_sale_order_sub;
ALTER TABLE project_sale_order_sub COMMENT '项目销售订单子项表';
ALTER TABLE base_serial_number DROP INDEX uk_business_segment;
ALTER TABLE base_serial_number ADD UNIQUE INDEX `uk_business_segment` ( `business_type`, `segment`, `tenant_id` ) USING BTREE;
ALTER TABLE project_sale_order DROP INDEX `uk_code`;
ALTER TABLE project_sale_order ADD UNIQUE INDEX `uk_code` ( `code`, `tenant_id` );
DROP TABLE IF EXISTS `project_deliver_order`;
CREATE TABLE `project_deliver_order` (
`id` bigint(20) NOT NULL AUTO_INCREMENT COMMENT '自增字段,唯一',
`code` varchar(64) NOT NULL COMMENT '编号,唯一',
`sale_order_ids` varchar(255) not null comment '销售订单id列表 多个用英文逗号分割',
`customer_id` BIGINT(20) not null comment '客户id',
`deliver_date` DATETIME not null comment '发货日期',
`deliver_status` int(11) not null COMMENT '发货单状态 已保存/已发货',
`deliver_person` BIGINT(20) not null comment '发货人',
`deliver_person_mobile` varchar(32) not null comment '发货人电话',
`deliver_mode` char(1) not null comment '发货方式',
`receive_person_name` varchar(16) comment '收货人姓名',
`receive_person_mobile` varchar(32) comment '收货人电话',
`receive_address` varchar(255) comment '收货详细地址',
`transport_driver_name` varchar(16) comment '司机姓名',
`transport_driver_mobile` varchar(32) comment '司机电话',
`transport_bus_number` varchar(32) comment '车牌号',
`transport_weight` varchar(16) comment '重量(T)',
`transport_size` varchar(16) comment '位置(米)',
`remark` varchar(255) DEFAULT NULL COMMENT '备注',
`status` tinyint(1) NOT NULL DEFAULT '1' COMMENT '状态,1表示正常2表示禁用',
`creator` varchar(64) DEFAULT '' COMMENT '创建者',
`create_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`updater` varchar(64) DEFAULT '' COMMENT '更新者',
`update_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
`deleted` bit(1) NOT NULL DEFAULT b'0' COMMENT '是否删除',
`tenant_id` bigint(20) NOT NULL DEFAULT '0' COMMENT '租户编号',
PRIMARY KEY (`id`) USING BTREE,
UNIQUE KEY `uk_code` (`code`,`tenant_id`) USING BTREE
) ENGINE=InnoDB COMMENT='发货订单表';
DROP TABLE IF EXISTS `project_deliver_order_sub`;
CREATE TABLE `project_deliver_order_sub` (
`id` bigint(20) NOT NULL AUTO_INCREMENT COMMENT '自增字段,唯一',
`delivery_order_id` bigint(20) NOT NULL COMMENT '订单id',
`category` varchar(16) not null comment '业务类 发货清单|其他清单 DELIVER_LIST|OTHER_LIST',
`sale_order_sub_id` BIGINT(20) COMMENT '销售订单子项id',
`sale_order_code` varchar(64) COMMENT '销售订单编号',
`name` varchar(128) NOT NULL COMMENT '名称,唯一',
`blueprint_no` varchar(64) DEFAULT NULL COMMENT '图号',
`amount` int(11) NOT NULL COMMENT '数量',
`unit` char(1) NOT NULL COMMENT '单位',
`weight` varchar(16) comment '重量(T)',
`size` varchar(16) comment '尺寸(米)',
`sub_type` char(1) comment '子项类型',
`remark` varchar(255) DEFAULT NULL COMMENT '备注',
`status` tinyint(1) NOT NULL DEFAULT '1' COMMENT '状态,1表示正常2表示禁用',
`creator` varchar(64) DEFAULT '' COMMENT '创建者',
`create_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`updater` varchar(64) DEFAULT '' COMMENT '更新者',
`update_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
`deleted` bit(1) NOT NULL DEFAULT b'0' COMMENT '是否删除',
`tenant_id` bigint(20) NOT NULL DEFAULT '0' COMMENT '租户编号',
PRIMARY KEY (`id`) USING BTREE
) ENGINE=InnoDB COMMENT='发货订单子项表';
DROP TABLE IF EXISTS `wms_storage_check`;
CREATE TABLE `wms_storage_check` (
`id` bigint(20) NOT NULL AUTO_INCREMENT COMMENT '主键id',
`stock_no` varchar(100) COLLATE utf8mb4_unicode_ci NOT NULL COMMENT '盘点单号',
`check_type` tinyint(1) DEFAULT NULL COMMENT '盘点类型1部分盘点2整体盘点',
`check_time` datetime DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '盘点开始时间',
`no_zero` tinyint(1) DEFAULT NULL COMMENT '排除库存为0的物料1是2否',
`description` varchar(255) COLLATE utf8mb4_unicode_ci DEFAULT NULL COMMENT '备注',
`status` tinyint(1) DEFAULT NULL COMMENT '状态1已保存2已提交3已删除',
`wh_id` bigint(19) NOT NULL COMMENT '仓库Id对应 wms_wh 表中的Id',
`deleted` bit(1) NOT NULL DEFAULT b'0' COMMENT '逻辑删除 1.是,0.否',
`creator` varchar(64) COLLATE utf8mb4_unicode_ci NOT NULL COMMENT '记录的创建人,对应员工表中的 Id',
`create_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`updater` varchar(64) COLLATE utf8mb4_unicode_ci DEFAULT NULL COMMENT '记录的修改人,对应员工表中的 Id',
`update_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
`tenant_id` bigint(20) NOT NULL COMMENT '租户编号',
`keeper` bigint(20) DEFAULT NULL COMMENT '入库人',
`keeper_time` datetime DEFAULT NULL COMMENT '入库时间',
`outbound` bigint(20) DEFAULT NULL COMMENT '出库人',
`outbound_time` datetime DEFAULT NULL COMMENT '出库时间',
`cancel` bigint(20) DEFAULT NULL COMMENT '作废人',
`cancel_time` datetime DEFAULT NULL COMMENT '作废时间',
PRIMARY KEY (`id`) USING BTREE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci ROW_FORMAT=DYNAMIC COMMENT='入/出库盘点表';
DROP TABLE IF EXISTS `wms_storage_check_mat`;
CREATE TABLE `wms_storage_check_mat` (
`id` bigint(20) NOT NULL AUTO_INCREMENT COMMENT '主键id',
`check_id` bigint(20) NOT NULL COMMENT '盘点Id',
`mat_id` bigint(19) NOT NULL COMMENT '物料 Id,对应 base_material表中的 Id 列',
`wh_id` bigint(19) NOT NULL COMMENT '仓库 Id对应 wms_wh 表中的Id',
`rg_id` bigint(19) NOT NULL COMMENT '库区 Id对应 wms_rg 表中的Id',
`pn_id` bigint(19) NOT NULL COMMENT '库区 Id对应 wms_rg 表中的Id',
`storage_ok_qty` decimal(11,2) DEFAULT NULL COMMENT '盘点数量',
`mat_rest` decimal(10,2) DEFAULT NULL COMMENT '物料当前库存数量',
`lot_no` varchar(50) COLLATE utf8mb4_unicode_ci DEFAULT NULL COMMENT '批次号',
`deleted` bit(1) NOT NULL DEFAULT b'0' COMMENT '逻辑删除 1.是,0.否',
`creator` varchar(64) COLLATE utf8mb4_unicode_ci NOT NULL COMMENT '记录的创建人,对应员工表中的 Id',
`create_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`updater` varchar(64) COLLATE utf8mb4_unicode_ci DEFAULT NULL COMMENT '记录的修改人,对应员工表中的 Id',
`update_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
`tenant_id` bigint(20) NOT NULL COMMENT '租户编号',
PRIMARY KEY (`id`) USING BTREE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci ROW_FORMAT=DYNAMIC COMMENT='盘点物料表';
CREATE OR REPLACE VIEW v_storage_material_log AS
select 0 AS `deleted`,`lg`.`id` AS `id`,`lg`.`creator` AS `creator`,`lg`.`create_time` AS `create_time`,`lg`.`updater` AS `updater`,`lg`.`update_time` AS `update_time`,
`lg`.`tenant_id` AS `tenant_id`,`lg`.`status` AS `status`,`mat`.`code` AS `mat_code`,`mat`.`name` AS `mat_name`,
(select `system_dict_data`.`label` from `system_dict_data` where ((`system_dict_data`.`dict_type` = 'heli_material_type') and (`system_dict_data`.`value` = `mat`.`material_type`))) AS `mat_type`,
(case when (isnull(`mat`.`short_name`) = TRUE) then '' else `mat`.`short_name` end) AS `short_name`,
(case when (isnull(`mat`.`spec`) = TRUE) then '' else `mat`.`spec` end) AS `mat_spec`,
(case when (isnull(`mat`.`brand`) = TRUE) then '' else `mat`.`brand` end) AS `mat_brand`,
(select `system_dict_data`.`label` from `system_dict_data` where ((`system_dict_data`.`dict_type` = 'heli_material_unit') and (`system_dict_data`.`value` = `mat`.`unit`))) AS `mat_unit`,
`st`.`stock_no` AS `stock_no`,`st`.`stock_type` AS `stock_type`,
(case when (`st`.`stock_type` = 1) then (select `system_dict_data`.`label` from `system_dict_data` where ((`system_dict_data`.`dict_type` = 'heli_storage_in_type') and (`system_dict_data`.`value` = `st`.`stock_in_type`))) else (select `system_dict_data`.`label` from `system_dict_data` where ((`system_dict_data`.`dict_type` = 'heli_storage_out_type') and (`system_dict_data`.`value` = `st`.`stock_in_type`))) end) AS `stock_type_name`,(case when (isnull(`st`.`header_no`) = TRUE) then '' else `st`.`header_no` end) AS `header_no`,
`wh`.`wh_name` AS `wh_name`,`rg`.`rg_name` AS `rg_name`,`pn`.`pn_name` AS `pn_name`,
(case when (isnull(`lg`.`lot_no`) = 1) then '' else `lg`.`lot_no` end) AS `lot_no`,(case when ((`st`.`stock_type` = 1) and (`lg`.`status` = 2)) then `lg`.`storage_ok_qty` when ((`st`.`stock_type` = 1) and (`lg`.`status` = 3)) then (-(1) * `lg`.`storage_ok_qty`) when ((`st`.`stock_type` = 2) and (`lg`.`status` = 2)) then (-(1) * `lg`.`storage_ok_qty`) when ((`st`.`stock_type` = 2) and (`lg`.`status` = 3)) then `lg`.`storage_ok_qty` else `lg`.`storage_ok_qty` end) AS `storage_ok_qty`
from (((((`wms_storage_log` `lg`
left join `wms_storage` `st` on((`lg`.`stock_id` = `st`.`id`)))
left join `base_material` `mat` on((`lg`.`mat_id` = `mat`.`id`)))
left join `wms_wh` `wh` on((`lg`.`wh_id` = `wh`.`id`)))
left join `wms_rg` `rg` on((`lg`.`rg_id` = `rg`.`id`)))
left join `wms_pn` `pn` on((`lg`.`pn_id` = `pn`.`id`)))
where ((`st`.`deleted` = 0) and (`mat`.`deleted` = 0) and (`wh`.`deleted` = 0) and (`rg`.`deleted` = 0) and (`pn`.`deleted` = 0));
CREATE OR REPLACE VIEW v_storage_material_now AS
select `t`.`deleted` AS `deleted`,`t`.`id` AS `id`,`t`.`creator` AS `creator`,`t`.`updater` AS `updater`,cast('2000-01-01 00:00' as date) AS `create_time`,cast('2000-01-01 00:00' as date) AS `update_time`,
`t`.`tenant_id` AS `tenant_id`,`t`.`mat_code` AS `mat_code`,`t`.`mat_name` AS `mat_name`,
`t`.`mat_type` AS `mat_type`,`t`.`mat_spec` AS `mat_spec`,`t`.`mat_unit` AS `mat_unit`,`t`.`mat_brand` AS `mat_brand`,`t`.`wh_id` AS `wh_id`,`t`.`wh_name` AS `wh_name`,`t`.`rg_id` AS `rg_id`,
`t`.`rg_name` AS `rg_name`,`t`.`pn_id` AS `pn_id`,`t`.`pn_name` AS `pn_name`,'' AS `lot_no`,`t`.`short_name` AS `short_name`,sum(`t`.`storage_ok_qty`) AS `storage_ok_qty`
from (
select 0 AS `deleted`,`mat`.`id` AS `id`,`mat`.`creator` AS `creator`,`mat`.`updater` AS `updater`,`mat`.`tenant_id` AS `tenant_id`,`mat`.`code` AS `mat_code`,`mat`.`name` AS `mat_name`,
(select `mes-heli`.`system_dict_data`.`label` from `mes-heli`.`system_dict_data` where ((`mes-heli`.`system_dict_data`.`dict_type` = 'heli_material_type') and (`mes-heli`.`system_dict_data`.`value` = `mat`.`material_type`))) AS `mat_type`,
(case when (isnull(`mat`.`short_name`) = TRUE) then '' else `mat`.`short_name` end) AS `short_name`,
(case when (isnull(`mat`.`spec`) = TRUE) then '' else `mat`.`spec` end) AS `mat_spec`,
(case when (isnull(`mat`.`brand`) = TRUE) then '' else `mat`.`brand` end) AS `mat_brand`,
(select `mes-heli`.`system_dict_data`.`label` from `mes-heli`.`system_dict_data` where ((`mes-heli`.`system_dict_data`.`dict_type` = 'heli_material_unit') and (`mes-heli`.`system_dict_data`.`value` = `mat`.`unit`))) AS `mat_unit`,
`wh`.`id` AS `wh_id`,`wh`.`wh_name` AS `wh_name`,`rg`.`id` AS `rg_id`,`rg`.`rg_name` AS `rg_name`,`pn`.`id` AS `pn_id`,`pn`.`pn_name` AS `pn_name`,
(case when (isnull(`lg`.`lot_no`) = 1) then '' else `lg`.`lot_no` end) AS `lot_no`,
(case when ((`st`.`stock_type` = 1) and (`lg`.`status` = 2)) then `lg`.`storage_ok_qty` when ((`st`.`stock_type` = 1) and (`lg`.`status` = 3)) then (-(1) * `lg`.`storage_ok_qty`) when ((`st`.`stock_type` = 2) and (`lg`.`status` = 2)) then (-(1) * `lg`.`storage_ok_qty`) when ((`st`.`stock_type` = 2) and (`lg`.`status` = 3)) then `lg`.`storage_ok_qty` else `lg`.`storage_ok_qty` end) AS `storage_ok_qty`
from (((((`mes-heli`.`wms_storage_log` `lg`
left join `mes-heli`.`wms_storage` `st` on((`lg`.`stock_id` = `st`.`id`)))
left join `mes-heli`.`base_material` `mat` on((`lg`.`mat_id` = `mat`.`id`)))
left join `mes-heli`.`wms_wh` `wh` on((`lg`.`wh_id` = `wh`.`id`)))
left join `mes-heli`.`wms_rg` `rg` on((`lg`.`rg_id` = `rg`.`id`)))
left join `mes-heli`.`wms_pn` `pn` on((`lg`.`pn_id` = `pn`.`id`)))
where ((`st`.`deleted` = 0) and (`mat`.`deleted` = 0) and (`wh`.`deleted` = 0) and (`rg`.`deleted` = 0) and (`pn`.`deleted` = 0))) `t`
group by `t`.`deleted`,`t`.`id`,`t`.`creator`,`t`.`updater`,`t`.`tenant_id`,`t`.`mat_code`,`t`.`mat_name`,`t`.`mat_type`,`t`.`mat_spec`,`t`.`mat_unit`,`t`.`mat_brand`,`t`.`wh_id`,`t`.`wh_name`,`t`.`rg_id`,`t`.`rg_name`,`t`.`pn_id`,`t`.`pn_name`,`t`.`short_name`
CREATE OR REPLACE VIEW v_storage_material_amount AS
select `t`.`deleted` AS `deleted`,`t`.`id` AS `mat_id`,`t`.`creator` AS `creator`,`t`.`updater` AS `updater`,`t`.`tenant_id` AS `tenant_id`,`t`.`mat_code` AS `mat_code`,`t`.`mat_name` AS `mat_name`,
`t`.`material_type` AS `material_type`,`t`.`spec` AS `spec`,`t`.`unit` AS `unit`,`t`.`wh_id` AS `wh_id`,`t`.`rg_id` AS `rg_id`,`t`.`pn_id` AS `pn_id`,`t`.`short_name` AS `short_name`,
0 AS `storage_ok_qty`,sum(`t`.`storage_ok_qty`) AS `mat_rest`
from (
select 0 AS `deleted`,`mat`.`id` AS `id`,`mat`.`creator` AS `creator`,`mat`.`updater` AS `updater`,`mat`.`tenant_id` AS `tenant_id`,`mat`.`code` AS `mat_code`,`mat`.`name` AS `mat_name`,
`mat`.`material_type` AS `material_type`,(case when (isnull(`mat`.`short_name`) = TRUE) then '' else `mat`.`short_name` end) AS `short_name`,
`mat`.`spec` AS `spec`,`mat`.`unit` AS `unit`,`lg`.`wh_id` AS `wh_id`,`lg`.`rg_id` AS `rg_id`,`lg`.`pn_id` AS `pn_id`,
(case when (isnull(`lg`.`lot_no`) = 1) then '' else `lg`.`lot_no` end) AS `lot_no`,
(case when ((`st`.`stock_type` = 1) and (`lg`.`status` = 2)) then `lg`.`storage_ok_qty` when ((`st`.`stock_type` = 1) and (`lg`.`status` = 3)) then (-(1) * `lg`.`storage_ok_qty`) when ((`st`.`stock_type` = 2) and (`lg`.`status` = 2)) then (-(1) * `lg`.`storage_ok_qty`) when ((`st`.`stock_type` = 2) and (`lg`.`status` = 3)) then `lg`.`storage_ok_qty` else `lg`.`storage_ok_qty` end) AS `storage_ok_qty`
from ((`mes-heli`.`wms_storage_log` `lg`
left join `mes-heli`.`wms_storage` `st` on((`lg`.`stock_id` = `st`.`id`)))
left join `mes-heli`.`base_material` `mat` on((`lg`.`mat_id` = `mat`.`id`)))
where ((`st`.`deleted` = 0) and (`mat`.`deleted` = 0) and (`lg`.`deleted` = 0))
) `t`
group by `t`.`deleted`,`t`.`id`,`t`.`creator`,`t`.`updater`,`t`.`tenant_id`,`t`.`mat_code`,`t`.`mat_name`,`t`.`material_type`,`t`.`spec`,`t`.`unit`,`t`.`wh_id`,`t`.`rg_id`,`t`.`pn_id`,`t`.`short_name`;