You cannot select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.

455 lines
32 KiB
Transact-SQL

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.

-- =============================================
-- WMS报表数据库表设计
-- 基于WmsReportMapper中的查询SQL设计包含完整中文注释
-- =============================================
-- 1. 退库原因分析报表表
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[wms_report_return_reason_analysis]') AND type in (N'U'))
DROP TABLE [dbo].[wms_report_return_reason_analysis]
GO
CREATE TABLE wms_report_return_reason_analysis (
id BIGINT IDENTITY(1,1) PRIMARY KEY,
tenant_id NVARCHAR(50) NOT NULL,
return_reason_category NVARCHAR(100) NOT NULL,
return_order_count INT NOT NULL DEFAULT 0,
total_return_amount DECIMAL(18,2) NOT NULL DEFAULT 0,
order_count_ratio DECIMAL(10,2) NOT NULL DEFAULT 0,
amount_ratio DECIMAL(10,2) NOT NULL DEFAULT 0,
material_name NVARCHAR(200),
material_category_name NVARCHAR(100),
material_code NVARCHAR(100),
statistics_date DATE NOT NULL DEFAULT GETDATE(),
create_time DATETIME2 NOT NULL DEFAULT GETDATE(),
update_time DATETIME2 NOT NULL DEFAULT GETDATE(),
INDEX IX_tenant_date (tenant_id, statistics_date),
INDEX IX_category (return_reason_category),
INDEX IX_material (material_code)
);
-- 添加表注释
EXEC sp_addextendedproperty 'MS_Description', N'退库原因分析报表', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_return_reason_analysis'
GO
-- 添加字段注释
EXEC sp_addextendedproperty 'MS_Description', N'主键ID', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_return_reason_analysis', 'COLUMN', N'id'
GO
EXEC sp_addextendedproperty 'MS_Description', N'租户编号', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_return_reason_analysis', 'COLUMN', N'tenant_id'
GO
EXEC sp_addextendedproperty 'MS_Description', N'退库原因分类(质量问题/订单变更/物料损坏/过期物料等)', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_return_reason_analysis', 'COLUMN', N'return_reason_category'
GO
EXEC sp_addextendedproperty 'MS_Description', N'退库单数量', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_return_reason_analysis', 'COLUMN', N'return_order_count'
GO
EXEC sp_addextendedproperty 'MS_Description', N'退库总数量', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_return_reason_analysis', 'COLUMN', N'total_return_amount'
GO
EXEC sp_addextendedproperty 'MS_Description', N'单据数量占比(%', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_return_reason_analysis', 'COLUMN', N'order_count_ratio'
GO
EXEC sp_addextendedproperty 'MS_Description', N'数量占比(%', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_return_reason_analysis', 'COLUMN', N'amount_ratio'
GO
EXEC sp_addextendedproperty 'MS_Description', N'物料名称', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_return_reason_analysis', 'COLUMN', N'material_name'
GO
EXEC sp_addextendedproperty 'MS_Description', N'物料分类名称', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_return_reason_analysis', 'COLUMN', N'material_category_name'
GO
EXEC sp_addextendedproperty 'MS_Description', N'物料编码', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_return_reason_analysis', 'COLUMN', N'material_code'
GO
EXEC sp_addextendedproperty 'MS_Description', N'统计日期', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_return_reason_analysis', 'COLUMN', N'statistics_date'
GO
EXEC sp_addextendedproperty 'MS_Description', N'创建时间', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_return_reason_analysis', 'COLUMN', N'create_time'
GO
EXEC sp_addextendedproperty 'MS_Description', N'更新时间', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_return_reason_analysis', 'COLUMN', N'update_time'
GO
-- 2. 库存变动趋势分析报表表
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[wms_report_inventory_trend_analysis]') AND type in (N'U'))
DROP TABLE [dbo].[wms_report_inventory_trend_analysis]
GO
CREATE TABLE wms_report_inventory_trend_analysis (
id BIGINT IDENTITY(1,1) PRIMARY KEY,
tenant_id NVARCHAR(50) NOT NULL,
material_id BIGINT NOT NULL,
material_code NVARCHAR(100) NOT NULL,
material_name NVARCHAR(200) NOT NULL,
material_category_name NVARCHAR(100),
statistics_month NVARCHAR(7) NOT NULL, -- YYYY-MM格式
statistics_week INT NOT NULL,
current_inventory_qty DECIMAL(18,2) NOT NULL DEFAULT 0,
week_instock_qty DECIMAL(18,2) NOT NULL DEFAULT 0,
week_outstock_qty DECIMAL(18,2) NOT NULL DEFAULT 0,
last_week_inventory_qty DECIMAL(18,2) NOT NULL DEFAULT 0,
key_node_mark NVARCHAR(50),
statistics_date DATE NOT NULL DEFAULT GETDATE(),
create_time DATETIME2 NOT NULL DEFAULT GETDATE(),
update_time DATETIME2 NOT NULL DEFAULT GETDATE(),
INDEX IX_tenant_material (tenant_id, material_id),
INDEX IX_month_week (statistics_month, statistics_week),
INDEX IX_material_code (material_code)
);
-- 添加表注释
EXEC sp_addextendedproperty 'MS_Description', N'库存变动趋势分析报表', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_trend_analysis'
GO
-- 添加字段注释
EXEC sp_addextendedproperty 'MS_Description', N'主键ID', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_trend_analysis', 'COLUMN', N'id'
GO
EXEC sp_addextendedproperty 'MS_Description', N'租户编号', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_trend_analysis', 'COLUMN', N'tenant_id'
GO
EXEC sp_addextendedproperty 'MS_Description', N'物料ID', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_trend_analysis', 'COLUMN', N'material_id'
GO
EXEC sp_addextendedproperty 'MS_Description', N'物料编码', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_trend_analysis', 'COLUMN', N'material_code'
GO
EXEC sp_addextendedproperty 'MS_Description', N'物料名称', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_trend_analysis', 'COLUMN', N'material_name'
GO
EXEC sp_addextendedproperty 'MS_Description', N'物料分类名称', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_trend_analysis', 'COLUMN', N'material_category_name'
GO
EXEC sp_addextendedproperty 'MS_Description', N'统计月份YYYY-MM格式', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_trend_analysis', 'COLUMN', N'statistics_month'
GO
EXEC sp_addextendedproperty 'MS_Description', N'统计周次', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_trend_analysis', 'COLUMN', N'statistics_week'
GO
EXEC sp_addextendedproperty 'MS_Description', N'当前库存数量', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_trend_analysis', 'COLUMN', N'current_inventory_qty'
GO
EXEC sp_addextendedproperty 'MS_Description', N'本周入库数量', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_trend_analysis', 'COLUMN', N'week_instock_qty'
GO
EXEC sp_addextendedproperty 'MS_Description', N'本周出库数量', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_trend_analysis', 'COLUMN', N'week_outstock_qty'
GO
EXEC sp_addextendedproperty 'MS_Description', N'上周库存数量', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_trend_analysis', 'COLUMN', N'last_week_inventory_qty'
GO
EXEC sp_addextendedproperty 'MS_Description', N'关键节点标记(大额入库/大额出库/正常变动)', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_trend_analysis', 'COLUMN', N'key_node_mark'
GO
EXEC sp_addextendedproperty 'MS_Description', N'统计日期', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_trend_analysis', 'COLUMN', N'statistics_date'
GO
EXEC sp_addextendedproperty 'MS_Description', N'创建时间', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_trend_analysis', 'COLUMN', N'create_time'
GO
EXEC sp_addextendedproperty 'MS_Description', N'更新时间', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_trend_analysis', 'COLUMN', N'update_time'
GO
-- 3. 安全库存预警报表表
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[wms_report_safety_stock_alert]') AND type in (N'U'))
DROP TABLE [dbo].[wms_report_safety_stock_alert]
GO
CREATE TABLE wms_report_safety_stock_alert (
id BIGINT IDENTITY(1,1) PRIMARY KEY,
tenant_id NVARCHAR(50) NOT NULL,
material_id BIGINT NOT NULL,
material_code NVARCHAR(100) NOT NULL,
material_name NVARCHAR(200) NOT NULL,
material_category_name NVARCHAR(100),
current_inventory_qty DECIMAL(18,2) NOT NULL DEFAULT 0,
safe_stock_amount DECIMAL(18,2),
min_stock_amount DECIMAL(18,2),
max_stock_amount DECIMAL(18,2),
alert_status NVARCHAR(50) NOT NULL, -- 短缺预警/积压预警/正常
difference_amount DECIMAL(18,2) NOT NULL DEFAULT 0,
last_update_time DATETIME2,
statistics_date DATE NOT NULL DEFAULT GETDATE(),
create_time DATETIME2 NOT NULL DEFAULT GETDATE(),
update_time DATETIME2 NOT NULL DEFAULT GETDATE(),
INDEX IX_tenant_material (tenant_id, material_id),
INDEX IX_alert_status (alert_status),
INDEX IX_material_code (material_code)
);
-- 添加表注释
EXEC sp_addextendedproperty 'MS_Description', N'安全库存预警报表', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_safety_stock_alert'
GO
-- 添加字段注释
EXEC sp_addextendedproperty 'MS_Description', N'主键ID', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_safety_stock_alert', 'COLUMN', N'id'
GO
EXEC sp_addextendedproperty 'MS_Description', N'租户编号', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_safety_stock_alert', 'COLUMN', N'tenant_id'
GO
EXEC sp_addextendedproperty 'MS_Description', N'物料ID', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_safety_stock_alert', 'COLUMN', N'material_id'
GO
EXEC sp_addextendedproperty 'MS_Description', N'物料编码', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_safety_stock_alert', 'COLUMN', N'material_code'
GO
EXEC sp_addextendedproperty 'MS_Description', N'物料名称', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_safety_stock_alert', 'COLUMN', N'material_name'
GO
EXEC sp_addextendedproperty 'MS_Description', N'物料分类名称', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_safety_stock_alert', 'COLUMN', N'material_category_name'
GO
EXEC sp_addextendedproperty 'MS_Description', N'当前库存数量', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_safety_stock_alert', 'COLUMN', N'current_inventory_qty'
GO
EXEC sp_addextendedproperty 'MS_Description', N'安全库存数量', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_safety_stock_alert', 'COLUMN', N'safe_stock_amount'
GO
EXEC sp_addextendedproperty 'MS_Description', N'最小库存数量', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_safety_stock_alert', 'COLUMN', N'min_stock_amount'
GO
EXEC sp_addextendedproperty 'MS_Description', N'最大库存数量', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_safety_stock_alert', 'COLUMN', N'max_stock_amount'
GO
EXEC sp_addextendedproperty 'MS_Description', N'预警状态(短缺预警/积压预警/正常)', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_safety_stock_alert', 'COLUMN', N'alert_status'
GO
EXEC sp_addextendedproperty 'MS_Description', N'差异数量(超出或不足的数量)', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_safety_stock_alert', 'COLUMN', N'difference_amount'
GO
EXEC sp_addextendedproperty 'MS_Description', N'最后更新时间', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_safety_stock_alert', 'COLUMN', N'last_update_time'
GO
EXEC sp_addextendedproperty 'MS_Description', N'统计日期', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_safety_stock_alert', 'COLUMN', N'statistics_date'
GO
EXEC sp_addextendedproperty 'MS_Description', N'创建时间', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_safety_stock_alert', 'COLUMN', N'create_time'
GO
EXEC sp_addextendedproperty 'MS_Description', N'更新时间', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_safety_stock_alert', 'COLUMN', N'update_time'
GO
-- 4. 呆滞料库存报表表
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[wms_report_stagnant_inventory]') AND type in (N'U'))
DROP TABLE [dbo].[wms_report_stagnant_inventory]
GO
CREATE TABLE wms_report_stagnant_inventory (
id BIGINT IDENTITY(1,1) PRIMARY KEY,
tenant_id NVARCHAR(50) NOT NULL,
material_id BIGINT NOT NULL,
material_code NVARCHAR(100) NOT NULL,
material_name NVARCHAR(200) NOT NULL,
material_category_name NVARCHAR(100),
stagnant_inventory_qty DECIMAL(18,2) NOT NULL DEFAULT 0,
material_unit NVARCHAR(20),
last_outstock_time NVARCHAR(50), -- 可能是"从未出库"或日期时间
stagnant_days INT NOT NULL DEFAULT 0,
stagnant_reason NVARCHAR(100),
material_spec NVARCHAR(200),
warehouse_name NVARCHAR(100),
last_activity_time NVARCHAR(50),
statistics_date DATE NOT NULL DEFAULT GETDATE(),
create_time DATETIME2 NOT NULL DEFAULT GETDATE(),
update_time DATETIME2 NOT NULL DEFAULT GETDATE(),
INDEX IX_tenant_material (tenant_id, material_id),
INDEX IX_stagnant_days (stagnant_days),
INDEX IX_material_code (material_code)
);
-- 添加表注释
EXEC sp_addextendedproperty 'MS_Description', N'呆滞料库存报表', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_stagnant_inventory'
GO
-- 添加字段注释
EXEC sp_addextendedproperty 'MS_Description', N'主键ID', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_stagnant_inventory', 'COLUMN', N'id'
GO
EXEC sp_addextendedproperty 'MS_Description', N'租户编号', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_stagnant_inventory', 'COLUMN', N'tenant_id'
GO
EXEC sp_addextendedproperty 'MS_Description', N'物料ID', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_stagnant_inventory', 'COLUMN', N'material_id'
GO
EXEC sp_addextendedproperty 'MS_Description', N'物料编码', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_stagnant_inventory', 'COLUMN', N'material_code'
GO
EXEC sp_addextendedproperty 'MS_Description', N'物料名称', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_stagnant_inventory', 'COLUMN', N'material_name'
GO
EXEC sp_addextendedproperty 'MS_Description', N'物料分类名称', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_stagnant_inventory', 'COLUMN', N'material_category_name'
GO
EXEC sp_addextendedproperty 'MS_Description', N'呆滞库存数量', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_stagnant_inventory', 'COLUMN', N'stagnant_inventory_qty'
GO
EXEC sp_addextendedproperty 'MS_Description', N'物料单位', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_stagnant_inventory', 'COLUMN', N'material_unit'
GO
EXEC sp_addextendedproperty 'MS_Description', N'最后出库时间(可能是"从未出库"或具体日期时间)', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_stagnant_inventory', 'COLUMN', N'last_outstock_time'
GO
EXEC sp_addextendedproperty 'MS_Description', N'呆滞天数', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_stagnant_inventory', 'COLUMN', N'stagnant_days'
GO
EXEC sp_addextendedproperty 'MS_Description', N'呆滞原因(从未出库/超过6个月未出库/正常)', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_stagnant_inventory', 'COLUMN', N'stagnant_reason'
GO
EXEC sp_addextendedproperty 'MS_Description', N'物料规格', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_stagnant_inventory', 'COLUMN', N'material_spec'
GO
EXEC sp_addextendedproperty 'MS_Description', N'仓库名称', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_stagnant_inventory', 'COLUMN', N'warehouse_name'
GO
EXEC sp_addextendedproperty 'MS_Description', N'最后活动时间', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_stagnant_inventory', 'COLUMN', N'last_activity_time'
GO
EXEC sp_addextendedproperty 'MS_Description', N'统计日期', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_stagnant_inventory', 'COLUMN', N'statistics_date'
GO
EXEC sp_addextendedproperty 'MS_Description', N'创建时间', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_stagnant_inventory', 'COLUMN', N'create_time'
GO
EXEC sp_addextendedproperty 'MS_Description', N'更新时间', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_stagnant_inventory', 'COLUMN', N'update_time'
GO-- 5. 库存差异报表表
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[wms_report_inventory_difference]') AND type in (N'U'))
DROP TABLE [dbo].[wms_report_inventory_difference]
GO
CREATE TABLE wms_report_inventory_difference (
id BIGINT IDENTITY(1,1) PRIMARY KEY,
tenant_id NVARCHAR(50) NOT NULL,
check_code NVARCHAR(100) NOT NULL,
check_type NVARCHAR(50) NOT NULL, -- 抽检/盘点/库位/货架盘点
warehouse_id BIGINT,
warehouse_name NVARCHAR(100),
material_id BIGINT NOT NULL,
material_code NVARCHAR(100) NOT NULL,
material_name NVARCHAR(200) NOT NULL,
material_category_name NVARCHAR(100),
book_inventory_qty DECIMAL(18,2) NOT NULL DEFAULT 0,
actual_inventory_qty DECIMAL(18,2) NOT NULL DEFAULT 0,
difference_qty DECIMAL(18,2) NOT NULL DEFAULT 0,
difference_type NVARCHAR(20) NOT NULL, -- 无差异/盘盈/盘亏
difference_rate DECIMAL(10,2) NOT NULL DEFAULT 0,
difference_level NVARCHAR(20) NOT NULL, -- 重大差异/一般差异/轻微差异/无差异
check_time DATETIME2,
check_by NVARCHAR(100),
statistics_date DATE NOT NULL DEFAULT GETDATE(),
create_time DATETIME2 NOT NULL DEFAULT GETDATE(),
update_time DATETIME2 NOT NULL DEFAULT GETDATE(),
INDEX IX_tenant_check (tenant_id, check_code),
INDEX IX_difference_type (difference_type),
INDEX IX_material_code (material_code)
);
-- 添加表注释
EXEC sp_addextendedproperty 'MS_Description', N'库存差异报表', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_difference'
GO
-- 添加字段注释
EXEC sp_addextendedproperty 'MS_Description', N'主键ID', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_difference', 'COLUMN', N'id'
GO
EXEC sp_addextendedproperty 'MS_Description', N'租户编号', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_difference', 'COLUMN', N'tenant_id'
GO
EXEC sp_addextendedproperty 'MS_Description', N'盘点单号', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_difference', 'COLUMN', N'check_code'
GO
EXEC sp_addextendedproperty 'MS_Description', N'盘点类型(抽检/盘点/库位/货架盘点)', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_difference', 'COLUMN', N'check_type'
GO
EXEC sp_addextendedproperty 'MS_Description', N'仓库ID', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_difference', 'COLUMN', N'warehouse_id'
GO
EXEC sp_addextendedproperty 'MS_Description', N'仓库名称', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_difference', 'COLUMN', N'warehouse_name'
GO
EXEC sp_addextendedproperty 'MS_Description', N'物料ID', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_difference', 'COLUMN', N'material_id'
GO
EXEC sp_addextendedproperty 'MS_Description', N'物料编码', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_difference', 'COLUMN', N'material_code'
GO
EXEC sp_addextendedproperty 'MS_Description', N'物料名称', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_difference', 'COLUMN', N'material_name'
GO
EXEC sp_addextendedproperty 'MS_Description', N'物料分类名称', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_difference', 'COLUMN', N'material_category_name'
GO
EXEC sp_addextendedproperty 'MS_Description', N'账面库存数量', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_difference', 'COLUMN', N'book_inventory_qty'
GO
EXEC sp_addextendedproperty 'MS_Description', N'实际库存数量', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_difference', 'COLUMN', N'actual_inventory_qty'
GO
EXEC sp_addextendedproperty 'MS_Description', N'差异数量', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_difference', 'COLUMN', N'difference_qty'
GO
EXEC sp_addextendedproperty 'MS_Description', N'差异类型(无差异/盘盈/盘亏)', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_difference', 'COLUMN', N'difference_type'
GO
EXEC sp_addextendedproperty 'MS_Description', N'差异率(%', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_difference', 'COLUMN', N'difference_rate'
GO
EXEC sp_addextendedproperty 'MS_Description', N'差异等级(重大差异/一般差异/轻微差异/无差异)', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_difference', 'COLUMN', N'difference_level'
GO
EXEC sp_addextendedproperty 'MS_Description', N'盘点时间', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_difference', 'COLUMN', N'check_time'
GO
EXEC sp_addextendedproperty 'MS_Description', N'盘点人', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_difference', 'COLUMN', N'check_by'
GO
EXEC sp_addextendedproperty 'MS_Description', N'统计日期', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_difference', 'COLUMN', N'statistics_date'
GO
EXEC sp_addextendedproperty 'MS_Description', N'创建时间', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_difference', 'COLUMN', N'create_time'
GO
EXEC sp_addextendedproperty 'MS_Description', N'更新时间', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_difference', 'COLUMN', N'update_time'
GO
-- 6. 库存周转报表表
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[wms_report_inventory_turnover]') AND type in (N'U'))
DROP TABLE [dbo].[wms_report_inventory_turnover]
GO
CREATE TABLE wms_report_inventory_turnover (
id BIGINT IDENTITY(1,1) PRIMARY KEY,
tenant_id NVARCHAR(50) NOT NULL,
material_id BIGINT NOT NULL,
material_code NVARCHAR(100) NOT NULL,
material_name NVARCHAR(200) NOT NULL,
material_category_name NVARCHAR(100),
statistics_month NVARCHAR(7) NOT NULL, -- YYYY-MM格式
begin_inventory_qty DECIMAL(18,2) NOT NULL DEFAULT 0,
end_inventory_qty DECIMAL(18,2) NOT NULL DEFAULT 0,
month_outstock_qty DECIMAL(18,2) NOT NULL DEFAULT 0,
inventory_turnover_rate DECIMAL(10,2) NOT NULL DEFAULT 0,
simple_turnover_rate DECIMAL(10,2) NOT NULL DEFAULT 0,
turnover_evaluation NVARCHAR(50), -- 无流动/快速周转/正常周转/缓慢周转
statistics_date DATE NOT NULL DEFAULT GETDATE(),
create_time DATETIME2 NOT NULL DEFAULT GETDATE(),
update_time DATETIME2 NOT NULL DEFAULT GETDATE(),
INDEX IX_tenant_material (tenant_id, material_id),
INDEX IX_month (statistics_month),
INDEX IX_turnover_rate (inventory_turnover_rate),
INDEX IX_material_code (material_code)
);
-- 添加表注释
EXEC sp_addextendedproperty 'MS_Description', N'库存周转报表', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_turnover'
GO
-- 添加字段注释
EXEC sp_addextendedproperty 'MS_Description', N'主键ID', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_turnover', 'COLUMN', N'id'
GO
EXEC sp_addextendedproperty 'MS_Description', N'租户编号', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_turnover', 'COLUMN', N'tenant_id'
GO
EXEC sp_addextendedproperty 'MS_Description', N'物料ID', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_turnover', 'COLUMN', N'material_id'
GO
EXEC sp_addextendedproperty 'MS_Description', N'物料编码', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_turnover', 'COLUMN', N'material_code'
GO
EXEC sp_addextendedproperty 'MS_Description', N'物料名称', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_turnover', 'COLUMN', N'material_name'
GO
EXEC sp_addextendedproperty 'MS_Description', N'物料分类名称', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_turnover', 'COLUMN', N'material_category_name'
GO
EXEC sp_addextendedproperty 'MS_Description', N'统计月份YYYY-MM格式', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_turnover', 'COLUMN', N'statistics_month'
GO
EXEC sp_addextendedproperty 'MS_Description', N'期初库存数量', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_turnover', 'COLUMN', N'begin_inventory_qty'
GO
EXEC sp_addextendedproperty 'MS_Description', N'期末库存数量', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_turnover', 'COLUMN', N'end_inventory_qty'
GO
EXEC sp_addextendedproperty 'MS_Description', N'月出库数量', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_turnover', 'COLUMN', N'month_outstock_qty'
GO
EXEC sp_addextendedproperty 'MS_Description', N'库存周转率(%', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_turnover', 'COLUMN', N'inventory_turnover_rate'
GO
EXEC sp_addextendedproperty 'MS_Description', N'简单周转率(%', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_turnover', 'COLUMN', N'simple_turnover_rate'
GO
EXEC sp_addextendedproperty 'MS_Description', N'周转评价(无流动/快速周转/正常周转/缓慢周转)', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_turnover', 'COLUMN', N'turnover_evaluation'
GO
EXEC sp_addextendedproperty 'MS_Description', N'统计日期', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_turnover', 'COLUMN', N'statistics_date'
GO
EXEC sp_addextendedproperty 'MS_Description', N'创建时间', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_turnover', 'COLUMN', N'create_time'
GO
EXEC sp_addextendedproperty 'MS_Description', N'更新时间', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_inventory_turnover', 'COLUMN', N'update_time'
GO
-- =============================================
-- 7. 报表数据汇总表(可选,用于快速查询)
-- =============================================
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[wms_report_summary]') AND type in (N'U'))
DROP TABLE [dbo].[wms_report_summary]
GO
CREATE TABLE wms_report_summary (
id BIGINT IDENTITY(1,1) PRIMARY KEY,
tenant_id NVARCHAR(50) NOT NULL,
report_type NVARCHAR(50) NOT NULL, -- 报表类型
report_date DATE NOT NULL,
total_records INT NOT NULL DEFAULT 0,
last_update_time DATETIME2 NOT NULL DEFAULT GETDATE(),
create_time DATETIME2 NOT NULL DEFAULT GETDATE(),
INDEX IX_tenant_type_date (tenant_id, report_type, report_date)
);
-- 添加表注释
EXEC sp_addextendedproperty 'MS_Description', N'WMS报表数据汇总表', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_summary'
GO
-- 添加字段注释
EXEC sp_addextendedproperty 'MS_Description', N'主键ID', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_summary', 'COLUMN', N'id'
GO
EXEC sp_addextendedproperty 'MS_Description', N'租户编号', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_summary', 'COLUMN', N'tenant_id'
GO
EXEC sp_addextendedproperty 'MS_Description', N'报表类型(退库原因分析/库存变动趋势分析/安全库存预警/呆滞料库存/库存差异/库存周转)', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_summary', 'COLUMN', N'report_type'
GO
EXEC sp_addextendedproperty 'MS_Description', N'报表日期', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_summary', 'COLUMN', N'report_date'
GO
EXEC sp_addextendedproperty 'MS_Description', N'记录总数', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_summary', 'COLUMN', N'total_records'
GO
EXEC sp_addextendedproperty 'MS_Description', N'最后更新时间', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_summary', 'COLUMN', N'last_update_time'
GO
EXEC sp_addextendedproperty 'MS_Description', N'创建时间', 'SCHEMA', N'dbo', 'TABLE', N'wms_report_summary', 'COLUMN', N'create_time'
GO
-- =============================================
-- 表创建完成提示
-- =============================================
PRINT '=== WMS报表表结构创建完成 ==='
PRINT '已创建以下报表表:'
PRINT '1. wms_report_return_reason_analysis - 退库原因分析报表'
PRINT '2. wms_report_inventory_trend_analysis - 库存变动趋势分析报表'
PRINT '3. wms_report_safety_stock_alert - 安全库存预警报表'
PRINT '4. wms_report_stagnant_inventory - 呆滞料库存报表'
PRINT '5. wms_report_inventory_difference - 库存差异报表'
PRINT '6. wms_report_inventory_turnover - 库存周转报表'
PRINT '7. wms_report_summary - 报表数据汇总表'
PRINT '=== 所有表均包含完整的中文注释可在Navicat中查看 ==='