|
@@ -0,0 +1,755 @@
|
|
1
|
+CREATE TABLE ts_consultant_kpi(
|
|
2
|
+ `serial_no` INT NOT NULL AUTO_INCREMENT COMMENT '序号' ,
|
|
3
|
+ `statis_date` VARCHAR(32) COMMENT '统计日期 格式YYYYMMDD' ,
|
|
4
|
+ `org_id` INT COMMENT '公司id' ,
|
|
5
|
+ `building_id` VARCHAR(64) COMMENT '楼盘id' ,
|
|
6
|
+ `building_name` VARCHAR(1024) COMMENT '楼盘名称' ,
|
|
7
|
+ `user_id` INT COMMENT '置业顾问ID' ,
|
|
8
|
+ `user_name` VARCHAR(128) COMMENT '置业顾问名称' ,
|
|
9
|
+ `phone` VARCHAR(32) COMMENT '置业顾问电话' ,
|
|
10
|
+ `new_persons` INT COMMENT '新增客户' ,
|
|
11
|
+ `share_num` INT COMMENT '分享次数' ,
|
|
12
|
+ `visit_persons` INT COMMENT '分享访问人数' ,
|
|
13
|
+ `visit_num` INT COMMENT '分享访问次数' ,
|
|
14
|
+ `share_persons` INT COMMENT '分享拓客' ,
|
|
15
|
+ `home_page_persons` INT COMMENT '主页访问人数' ,
|
|
16
|
+ `home_page_nums` INT COMMENT '主页访问次数' ,
|
|
17
|
+ `chat_persons` INT COMMENT '咨询数' ,
|
|
18
|
+ `favor_num` INT COMMENT '点赞数' ,
|
|
19
|
+ PRIMARY KEY (serial_no)
|
|
20
|
+) COMMENT = '置业顾问KPI ';;
|
|
21
|
+
|
|
22
|
+ALTER TABLE ts_consultant_kpi ADD INDEX idx_sts_consultant_date(statis_date);;
|
|
23
|
+ALTER TABLE ts_consultant_kpi ADD INDEX idx_sts_consultant_org(org_id,building_id,statis_date);;
|
|
24
|
+
|
|
25
|
+CREATE TABLE ts_activity_daily(
|
|
26
|
+ `serial_no` INT NOT NULL AUTO_INCREMENT COMMENT '序号' ,
|
|
27
|
+ `statis_date` VARCHAR(32) COMMENT '统计时间' ,
|
|
28
|
+ `org_id` INT COMMENT '公司id' ,
|
|
29
|
+ `building_id` VARCHAR(64) COMMENT '楼盘id' ,
|
|
30
|
+ `building_name` VARCHAR(1024) COMMENT '楼盘名称' ,
|
|
31
|
+ `target_type` VARCHAR(32) COMMENT '活动类型' ,
|
|
32
|
+ `target_id` VARCHAR(64) COMMENT '活动ID' ,
|
|
33
|
+ `target_name` VARCHAR(1024) COMMENT '活动名称' ,
|
|
34
|
+ `share_num` INT COMMENT '分享次数' ,
|
|
35
|
+ `share_persons` INT COMMENT '分享人数' ,
|
|
36
|
+ `visit_num` INT COMMENT '访问次数' ,
|
|
37
|
+ `visit_persons` INT COMMENT '访问人数' ,
|
|
38
|
+ `new_persons` INT COMMENT '新增用户' ,
|
|
39
|
+ `new_customers` INT COMMENT '新增客户' ,
|
|
40
|
+ PRIMARY KEY (serial_no)
|
|
41
|
+) COMMENT = '活动统计 ';;
|
|
42
|
+
|
|
43
|
+ALTER TABLE ts_activity_daily ADD INDEX sts_activity_org(org_id);;
|
|
44
|
+
|
|
45
|
+
|
|
46
|
+CREATE TABLE ta_customer_from(
|
|
47
|
+ `serial_no` INT NOT NULL AUTO_INCREMENT COMMENT '序号' ,
|
|
48
|
+ `person_id` VARCHAR(32) COMMENT '用户ID' ,
|
|
49
|
+ `customer_id` VARCHAR(32) COMMENT '客户ID' ,
|
|
50
|
+ `person_name` VARCHAR(128) COMMENT '用户名' ,
|
|
51
|
+ `target_type` VARCHAR(32) COMMENT '目标类型' ,
|
|
52
|
+ `target_id` VARCHAR(64) COMMENT '目标ID' ,
|
|
53
|
+ `target_name` VARCHAR(128) COMMENT '目标名称' ,
|
|
54
|
+ `org_id` INT COMMENT '公司id' ,
|
|
55
|
+ `building_id` VARCHAR(64) COMMENT '楼盘id' ,
|
|
56
|
+ `building_name` VARCHAR(128) COMMENT '楼盘名称' ,
|
|
57
|
+ `share_person_id` VARCHAR(64) COMMENT '分享人ID' ,
|
|
58
|
+ `share_person_name` VARCHAR(128) COMMENT '分享人名称' ,
|
|
59
|
+ `scene_id` VARCHAR(32) COMMENT '场景ID' ,
|
|
60
|
+ `is_org_first` TINYINT(1) COMMENT '首次进入小程序' ,
|
|
61
|
+ `is_project_first` TINYINT(1) COMMENT '首次进入项目' ,
|
|
62
|
+ `create_date` DATETIME COMMENT '创建时间' ,
|
|
63
|
+ `remark` VARCHAR(512) COMMENT '备注' ,
|
|
64
|
+ PRIMARY KEY (serial_no)
|
|
65
|
+) COMMENT = '客户来源 ';;
|
|
66
|
+
|
|
67
|
+ALTER TABLE ta_customer_from ADD INDEX idx_customer_from_org(org_id);;
|
|
68
|
+ALTER TABLE ta_customer_from ADD INDEX idx_cusromer_from_project(org_id,building_id);;
|
|
69
|
+
|
|
70
|
+
|
|
71
|
+ALTER TABLE `ta_person_building`
|
|
72
|
+ADD INDEX `idx_building_user`(`building_id`, `user_id`),
|
|
73
|
+ADD INDEX `idx_building_only_user`(`user_id`);
|
|
74
|
+
|
|
75
|
+ALTER TABLE `ta_share_count`
|
|
76
|
+ADD INDEX `idx_share_cout_person`(`person_id`);
|
|
77
|
+
|
|
78
|
+ALTER TABLE `ta_favor`
|
|
79
|
+ADD INDEX `idx_favor_target`(`be_favor`, `tagert_type`);
|
|
80
|
+
|
|
81
|
+ALTER TABLE `ta_chat`
|
|
82
|
+ADD INDEX `idx_chat_send`(`send_person`),
|
|
83
|
+ADD INDEX `idx_char_receive`(`receive_person`);
|
|
84
|
+
|
|
85
|
+ALTER TABLE `ta_person_visit_record`
|
|
86
|
+ADD INDEX `idx_event_target`(`org_id`, `event_type`, `target_id`, `visit_time`);
|
|
87
|
+
|
|
88
|
+ALTER TABLE `ta_recommend_customer`
|
|
89
|
+ADD INDEX `idx_consultant_sts`(`org_id`, `realty_consultant`, `create_date`);
|
|
90
|
+
|
|
91
|
+ALTER TABLE `ta_share_person_from`
|
|
92
|
+ADD COLUMN `target_name` varchar(1024) NULL COMMENT '目标名称' AFTER `is_first_time`;
|
|
93
|
+
|
|
94
|
+ALTER TABLE `ta_share_count`
|
|
95
|
+ADD COLUMN `target_name` varchar(1024) NULL COMMENT '对象名称' AFTER `create_date`;
|
|
96
|
+
|
|
97
|
+ALTER TABLE `ta_share_count`
|
|
98
|
+ADD COLUMN `org_id` int NULL COMMENT '组织ID' AFTER `target_name`;
|
|
99
|
+ALTER TABLE `ta_share_count`
|
|
100
|
+ADD INDEX `idx_share_cout_org`(`org_id`);
|
|
101
|
+
|
|
102
|
+--
|
|
103
|
+INSERT INTO `td_biz_event_type`(`type_id`, `type_name`, `status`, `create_date`, `parent_type_id`) VALUES ('other', '其他', 1, '2020-04-27 15:57:10', NULL);
|
|
104
|
+
|
|
105
|
+
|
|
106
|
+-- 菜单数据
|
|
107
|
+update sys_menu t
|
|
108
|
+set t.`status` = -1
|
|
109
|
+where t.`menu_id` = 85;
|
|
110
|
+
|
|
111
|
+delete from ta_role_menu where menu_id = 85;
|
|
112
|
+
|
|
113
|
+INSERT INTO `sys_menu`(`menu_id`, `code`, `name`, `parent_code`, `icon`, `app_type`, `status`, `menu_root`, `sort_num`)
|
|
114
|
+VALUES (110, '/statistical', '数据统计', '-1', NULL, 'estateagent-admin', 1, 110, 2);
|
|
115
|
+INSERT INTO `sys_menu`(`menu_id`, `code`, `name`, `parent_code`, `icon`, `app_type`, `status`, `menu_root`, `sort_num`)
|
|
116
|
+VALUES (111, '/statistical/monitor', '数据报表', '110', NULL, 'estateagent-admin', 1, 110, 1);
|
|
117
|
+INSERT INTO `sys_menu`(`menu_id`, `code`, `name`, `parent_code`, `icon`, `app_type`, `status`, `menu_root`, `sort_num`)
|
|
118
|
+VALUES (112, '/statistical/activity', '活动统计', '110', NULL, 'estateagent-admin', 1, 110, 2);
|
|
119
|
+INSERT INTO `sys_menu`(`menu_id`, `code`, `name`, `parent_code`, `icon`, `app_type`, `status`, `menu_root`, `sort_num`)
|
|
120
|
+VALUES (113, '/statistical/consultant', '置业顾问KPI', '110', NULL, 'estateagent-admin', 1, 110, 4);
|
|
121
|
+INSERT INTO `sys_menu`(`menu_id`, `code`, `name`, `parent_code`, `icon`, `app_type`, `status`, `menu_root`, `sort_num`)
|
|
122
|
+VALUES (114, '/statistical/building', '项目统计', '110', NULL, 'estateagent-admin', 1, 110, 3);
|
|
123
|
+
|
|
124
|
+INSERT ta_role_menu ( role_id, menu_id )
|
|
125
|
+SELECT s.role_id, 110
|
|
126
|
+FROM ta_user t
|
|
127
|
+ LEFT JOIN ta_user_role s ON t.user_id = s.user_id
|
|
128
|
+WHERE
|
|
129
|
+ t.is_admin = 1
|
|
130
|
+ AND s.role_id IS NOT NULL
|
|
131
|
+GROUP BY
|
|
132
|
+ s.role_id;
|
|
133
|
+
|
|
134
|
+INSERT ta_role_menu ( role_id, menu_id )
|
|
135
|
+SELECT s.role_id, 111
|
|
136
|
+FROM ta_user t
|
|
137
|
+ LEFT JOIN ta_user_role s ON t.user_id = s.user_id
|
|
138
|
+WHERE
|
|
139
|
+ t.is_admin = 1
|
|
140
|
+ AND s.role_id IS NOT NULL
|
|
141
|
+GROUP BY
|
|
142
|
+ s.role_id;
|
|
143
|
+
|
|
144
|
+INSERT ta_role_menu ( role_id, menu_id )
|
|
145
|
+SELECT s.role_id, 112
|
|
146
|
+FROM ta_user t
|
|
147
|
+ LEFT JOIN ta_user_role s ON t.user_id = s.user_id
|
|
148
|
+WHERE
|
|
149
|
+ t.is_admin = 1
|
|
150
|
+ AND s.role_id IS NOT NULL
|
|
151
|
+GROUP BY
|
|
152
|
+ s.role_id;
|
|
153
|
+
|
|
154
|
+INSERT ta_role_menu ( role_id, menu_id )
|
|
155
|
+SELECT s.role_id, 113
|
|
156
|
+FROM ta_user t
|
|
157
|
+ LEFT JOIN ta_user_role s ON t.user_id = s.user_id
|
|
158
|
+WHERE
|
|
159
|
+ t.is_admin = 1
|
|
160
|
+ AND s.role_id IS NOT NULL
|
|
161
|
+GROUP BY
|
|
162
|
+ s.role_id;
|
|
163
|
+
|
|
164
|
+INSERT ta_role_menu ( role_id, menu_id )
|
|
165
|
+SELECT s.role_id, 114
|
|
166
|
+FROM ta_user t
|
|
167
|
+ LEFT JOIN ta_user_role s ON t.user_id = s.user_id
|
|
168
|
+WHERE
|
|
169
|
+ t.is_admin = 1
|
|
170
|
+ AND s.role_id IS NOT NULL
|
|
171
|
+GROUP BY
|
|
172
|
+ s.role_id;
|
|
173
|
+
|
|
174
|
+
|
|
175
|
+-- 菜单按钮
|
|
176
|
+INSERT INTO `sys_button_in_menu`(`btn_id`, `menu_id`, `name`, `status`, `code`, `remark`)
|
|
177
|
+VALUES (212, 114, '导出', 1, 'admin.statistical.building.export', NULL);
|
|
178
|
+INSERT INTO `sys_button_in_menu`(`btn_id`, `menu_id`, `name`, `status`, `code`, `remark`)
|
|
179
|
+VALUES (213, 112, '导出', 1, 'admin.statistical.activity.export', NULL);
|
|
180
|
+INSERT INTO `sys_button_in_menu`(`btn_id`, `menu_id`, `name`, `status`, `code`, `remark`)
|
|
181
|
+VALUES (214, 113, '导出', 1, 'admin.statistical.consultant.export', NULL);
|
|
182
|
+
|
|
183
|
+
|
|
184
|
+INSERT ta_role_button ( role_id, btn_id )
|
|
185
|
+SELECT s.role_id, 212
|
|
186
|
+FROM ta_user t
|
|
187
|
+ LEFT JOIN ta_user_role s ON t.user_id = s.user_id
|
|
188
|
+WHERE
|
|
189
|
+ t.is_admin = 1
|
|
190
|
+ AND s.role_id IS NOT NULL
|
|
191
|
+GROUP BY
|
|
192
|
+ s.role_id;
|
|
193
|
+
|
|
194
|
+INSERT ta_role_button ( role_id, btn_id )
|
|
195
|
+SELECT s.role_id, 213
|
|
196
|
+FROM ta_user t
|
|
197
|
+ LEFT JOIN ta_user_role s ON t.user_id = s.user_id
|
|
198
|
+WHERE
|
|
199
|
+ t.is_admin = 1
|
|
200
|
+ AND s.role_id IS NOT NULL
|
|
201
|
+GROUP BY
|
|
202
|
+ s.role_id;
|
|
203
|
+
|
|
204
|
+INSERT ta_role_button ( role_id, btn_id )
|
|
205
|
+SELECT s.role_id, 214
|
|
206
|
+FROM ta_user t
|
|
207
|
+ LEFT JOIN ta_user_role s ON t.user_id = s.user_id
|
|
208
|
+WHERE
|
|
209
|
+ t.is_admin = 1
|
|
210
|
+ AND s.role_id IS NOT NULL
|
|
211
|
+GROUP BY
|
|
212
|
+ s.role_id;
|
|
213
|
+
|
|
214
|
+INSERT ta_role_button ( role_id, btn_id )
|
|
215
|
+SELECT s.role_id, 215
|
|
216
|
+FROM ta_user t
|
|
217
|
+ LEFT JOIN ta_user_role s ON t.user_id = s.user_id
|
|
218
|
+WHERE
|
|
219
|
+ t.is_admin = 1
|
|
220
|
+ AND s.role_id IS NOT NULL
|
|
221
|
+GROUP BY
|
|
222
|
+ s.role_id;
|
|
223
|
+
|
|
224
|
+INSERT ta_role_button ( role_id, btn_id )
|
|
225
|
+SELECT s.role_id, 216
|
|
226
|
+FROM ta_user t
|
|
227
|
+ LEFT JOIN ta_user_role s ON t.user_id = s.user_id
|
|
228
|
+WHERE
|
|
229
|
+ t.is_admin = 1
|
|
230
|
+ AND s.role_id IS NOT NULL
|
|
231
|
+GROUP BY
|
|
232
|
+ s.role_id;
|
|
233
|
+
|
|
234
|
+INSERT ta_role_button ( role_id, btn_id )
|
|
235
|
+SELECT s.role_id, 217
|
|
236
|
+FROM ta_user t
|
|
237
|
+ LEFT JOIN ta_user_role s ON t.user_id = s.user_id
|
|
238
|
+WHERE
|
|
239
|
+ t.is_admin = 1
|
|
240
|
+ AND s.role_id IS NOT NULL
|
|
241
|
+GROUP BY
|
|
242
|
+ s.role_id;
|
|
243
|
+
|
|
244
|
+
|
|
245
|
+-- 置业KPI日统计
|
|
246
|
+delimiter $$
|
|
247
|
+CREATE PROCEDURE `pro_consultant_kpi`(IN `st_date` varchar(32))
|
|
248
|
+BEGIN
|
|
249
|
+
|
|
250
|
+DECLARE day_start datetime;
|
|
251
|
+DECLARE day_end datetime;
|
|
252
|
+
|
|
253
|
+SET day_start = STR_TO_DATE(st_date, '%Y%m%d');
|
|
254
|
+SET day_end = STR_TO_DATE(concat(st_date, '235959'), '%Y%m%d%H%i%s');
|
|
255
|
+
|
|
256
|
+
|
|
257
|
+-- 先删除当天的
|
|
258
|
+delete from ts_consultant_kpi where statis_date = st_date;
|
|
259
|
+
|
|
260
|
+-- 重新插入
|
|
261
|
+insert into ts_consultant_kpi (
|
|
262
|
+ statis_date,
|
|
263
|
+ org_id,
|
|
264
|
+ building_id,
|
|
265
|
+ building_name,
|
|
266
|
+ user_id,
|
|
267
|
+ user_name,
|
|
268
|
+ phone,
|
|
269
|
+ new_persons,
|
|
270
|
+ share_num,
|
|
271
|
+ visit_persons,
|
|
272
|
+ visit_num,
|
|
273
|
+ share_persons,
|
|
274
|
+ home_page_persons,
|
|
275
|
+ home_page_nums,
|
|
276
|
+ chat_persons,
|
|
277
|
+ favor_num
|
|
278
|
+ )
|
|
279
|
+select
|
|
280
|
+ st_date as statis_date,
|
|
281
|
+ t.org_id,
|
|
282
|
+ s.building_id,
|
|
283
|
+ n.building_name,
|
|
284
|
+ t.user_id,
|
|
285
|
+ t.user_name,
|
|
286
|
+ t.phone,
|
|
287
|
+
|
|
288
|
+ -- 新增客户的时间字段不正确
|
|
289
|
+ -- 可能错误: create_date 是之前的时间, 但是最近才分配置业的情况统计不到
|
|
290
|
+ (select count(*) from ta_recommend_customer a
|
|
291
|
+ where a.org_id = t.org_id
|
|
292
|
+ and (a.realty_consultant = concat(t.user_id, '') or a.realty_consultant = m.person_id)
|
|
293
|
+ and a.create_date BETWEEN day_start and day_end
|
|
294
|
+ and a.building_id = s.building_id
|
|
295
|
+ and a.status > 0
|
|
296
|
+ ) as new_persons,
|
|
297
|
+
|
|
298
|
+ -- 分享次数
|
|
299
|
+ -- 不区分项目
|
|
300
|
+ (select count(*) as share_num from ta_share_count b
|
|
301
|
+ where b.person_id = m.person_id
|
|
302
|
+ and b.create_date BETWEEN day_start and day_end
|
|
303
|
+ and (
|
|
304
|
+ b.tagert_type IN ( 'consultant', 'project', 'activity', 'group', 'h5', 'help', 'news', 'main' )
|
|
305
|
+ OR b.tagert_type like 'house%'
|
|
306
|
+ OR b.tagert_type like 'live%'
|
|
307
|
+ )
|
|
308
|
+ ) as share_num,
|
|
309
|
+
|
|
310
|
+ -- 分享访问人数
|
|
311
|
+ (select count(DISTINCT c.person_id) from ta_share_person_from c
|
|
312
|
+ where c.org_id = t.org_id
|
|
313
|
+ and c.share_person = concat(t.user_id, '')
|
|
314
|
+ and (
|
|
315
|
+ c.target_type IN ( 'card_share', 'building_share', 'dynamic_share', 'group_share', 'h5_share', 'help_share', 'house_share', 'live_share', 'news_share', 'poster' )
|
|
316
|
+ or ( c.target_type = 'share' and c.target_id = 'index' )
|
|
317
|
+ )
|
|
318
|
+ and (c.building_id is null or c.building_id = s.building_id)
|
|
319
|
+ and c.create_date BETWEEN day_start and day_end
|
|
320
|
+ ) as visit_persons,
|
|
321
|
+
|
|
322
|
+ -- 分享访问次数
|
|
323
|
+ (select count(*) from ta_share_person_from d
|
|
324
|
+ where d.org_id = t.org_id
|
|
325
|
+ and d.share_person = concat(t.user_id, '')
|
|
326
|
+ and (
|
|
327
|
+ d.target_type IN ( 'card_share', 'building_share', 'dynamic_share', 'group_share', 'h5_share', 'help_share', 'house_share', 'live_share', 'news_share', 'poster' )
|
|
328
|
+ or ( d.target_type = 'share' and d.target_id = 'index' )
|
|
329
|
+ )
|
|
330
|
+ and (d.building_id is null or d.building_id = s.building_id)
|
|
331
|
+ and d.create_date BETWEEN day_start and day_end
|
|
332
|
+ ) as visit_num,
|
|
333
|
+
|
|
334
|
+ -- 分享拓客
|
|
335
|
+ (select count(DISTINCT e.person_id) from ta_customer_from e
|
|
336
|
+ where e.org_id = t.org_id
|
|
337
|
+ and e.building_id = s.building_id
|
|
338
|
+ and e.share_person_id = m.person_id
|
|
339
|
+ and e.target_type is not null
|
|
340
|
+ and e.is_project_first = 1
|
|
341
|
+ ) as share_persons,
|
|
342
|
+
|
|
343
|
+ -- 主页访问人数
|
|
344
|
+ (select count(DISTINCT f.person_id) from ta_person_visit_record f
|
|
345
|
+ where f.org_id = t.org_id
|
|
346
|
+ and f.building_id = s.building_id
|
|
347
|
+ and f.event_type = 'card'
|
|
348
|
+ and f.target_id = m.person_id
|
|
349
|
+ and f.visit_time BETWEEN day_start and day_end
|
|
350
|
+ ) as home_page_persons,
|
|
351
|
+
|
|
352
|
+ -- 主页访问次数
|
|
353
|
+ (select count(*) from ta_person_visit_record g
|
|
354
|
+ where g.org_id = t.org_id
|
|
355
|
+ and g.building_id = s.building_id
|
|
356
|
+ and g.event_type = 'card'
|
|
357
|
+ and g.target_id = m.person_id
|
|
358
|
+ and g.visit_time BETWEEN day_start and day_end
|
|
359
|
+ ) as home_page_nums,
|
|
360
|
+
|
|
361
|
+ -- 咨询数
|
|
362
|
+ -- 不区分项目
|
|
363
|
+ (select count(DISTINCT h.send_person) from ta_chat h
|
|
364
|
+ where h.receive_person = m.person_id
|
|
365
|
+ and h.create_date BETWEEN day_start and day_end
|
|
366
|
+ ) as chat_persons,
|
|
367
|
+
|
|
368
|
+ -- 点赞数
|
|
369
|
+ -- 不区分项目
|
|
370
|
+ (select count(*) from ta_favor i
|
|
371
|
+ where i.be_favor = m.person_id
|
|
372
|
+ and i.tagert_type = 'consultant'
|
|
373
|
+ and i.create_date BETWEEN day_start and day_end
|
|
374
|
+ ) as favor_num
|
|
375
|
+
|
|
376
|
+from ta_user t
|
|
377
|
+left join ta_person_building s on t.user_id = s.user_id
|
|
378
|
+left join ta_person m on t.org_id = m.org_id and t.user_id = m.user_id and m.status = 1
|
|
379
|
+left join ta_building n on n.building_id = s.building_id
|
|
380
|
+where t.is_consultant = 1;
|
|
381
|
+
|
|
382
|
+END$$
|
|
383
|
+
|
|
384
|
+
|
|
385
|
+delimiter $$
|
|
386
|
+CREATE PROCEDURE `pro_update_share_target_name`()
|
|
387
|
+BEGIN
|
|
388
|
+
|
|
389
|
+ -- 分享项目
|
|
390
|
+ UPDATE ta_share_person_from t
|
|
391
|
+ INNER JOIN ta_building s ON s.building_id = t.target_id
|
|
392
|
+ SET t.target_name = s.building_name
|
|
393
|
+ WHERE t.target_type = 'building_share'
|
|
394
|
+ AND t.target_name is null;
|
|
395
|
+
|
|
396
|
+ UPDATE ta_share_count t
|
|
397
|
+ INNER JOIN ta_building s ON s.building_id = t.be_share
|
|
398
|
+ SET t.target_name = s.building_name,
|
|
399
|
+ t.org_id = s.org_id
|
|
400
|
+ WHERE t.tagert_type = 'project'
|
|
401
|
+ AND t.target_name is null;
|
|
402
|
+
|
|
403
|
+ -- 普通活动
|
|
404
|
+ UPDATE ta_share_person_from t
|
|
405
|
+ INNER JOIN ta_building_dynamic s ON s.dynamic_id = t.target_id
|
|
406
|
+ SET t.target_name = s.title
|
|
407
|
+ WHERE t.target_type = 'dynamic_share'
|
|
408
|
+ AND t.target_name is null;
|
|
409
|
+
|
|
410
|
+ UPDATE ta_share_count t
|
|
411
|
+ INNER JOIN ta_building_dynamic s ON s.dynamic_id = t.be_share
|
|
412
|
+ SET t.target_name = s.title,
|
|
413
|
+ t.org_id = s.org_id
|
|
414
|
+ WHERE t.tagert_type = 'activity'
|
|
415
|
+ AND t.target_name is null;
|
|
416
|
+
|
|
417
|
+ -- 助力活动
|
|
418
|
+ UPDATE ta_share_person_from t
|
|
419
|
+ INNER JOIN ta_help_activity s ON s.help_activity_id = t.target_id
|
|
420
|
+ SET t.target_name = s.title,
|
|
421
|
+ t.org_id = s.org_id
|
|
422
|
+ WHERE t.target_type = 'help_share'
|
|
423
|
+ AND t.target_name is null;
|
|
424
|
+
|
|
425
|
+ UPDATE ta_share_count t
|
|
426
|
+ INNER JOIN ta_help_activity s ON s.help_activity_id = t.be_share
|
|
427
|
+ SET t.target_name = s.title
|
|
428
|
+ WHERE t.tagert_type = 'help'
|
|
429
|
+ AND t.target_name is null;
|
|
430
|
+
|
|
431
|
+ -- 拼团活动
|
|
432
|
+ UPDATE ta_share_person_from t
|
|
433
|
+ INNER JOIN ta_share_activity s ON s.group_activity_id = t.target_id
|
|
434
|
+ SET t.target_name = s.activity_name
|
|
435
|
+ WHERE t.target_type = 'group_share'
|
|
436
|
+ AND t.target_name is null;
|
|
437
|
+
|
|
438
|
+ UPDATE ta_share_count t
|
|
439
|
+ INNER JOIN ta_share_activity s ON s.group_activity_id = t.be_share
|
|
440
|
+ SET t.target_name = s.activity_name,
|
|
441
|
+ t.org_id = s.org_id
|
|
442
|
+ WHERE t.tagert_type = 'group'
|
|
443
|
+ AND t.target_name is null;
|
|
444
|
+
|
|
445
|
+ -- H5 活动
|
|
446
|
+ UPDATE ta_share_person_from t
|
|
447
|
+ INNER JOIN ta_drainage s ON s.drainage_id = t.target_id
|
|
448
|
+ SET t.target_name = s.`name`
|
|
449
|
+ WHERE t.target_type = 'h5_share'
|
|
450
|
+ AND t.target_name is null;
|
|
451
|
+
|
|
452
|
+ UPDATE ta_share_count t
|
|
453
|
+ INNER JOIN ta_drainage s ON s.drainage_id = t.be_share
|
|
454
|
+ SET t.target_name = s.`name`,
|
|
455
|
+ t.org_id = s.org_id
|
|
456
|
+ WHERE t.tagert_type = 'h5'
|
|
457
|
+ AND t.target_name is null;
|
|
458
|
+
|
|
459
|
+ -- 资讯
|
|
460
|
+ UPDATE ta_share_person_from t
|
|
461
|
+ INNER JOIN ta_news s ON s.news_id = t.target_id
|
|
462
|
+ SET t.target_name = s.news_name
|
|
463
|
+ WHERE t.target_type = 'news_share'
|
|
464
|
+ AND t.target_name is null;
|
|
465
|
+
|
|
466
|
+ UPDATE ta_share_count t
|
|
467
|
+ INNER JOIN ta_news s ON s.news_id = t.be_share
|
|
468
|
+ SET t.target_name = s.news_name,
|
|
469
|
+ t.org_id = s.org_id
|
|
470
|
+ WHERE t.tagert_type = 'news'
|
|
471
|
+ AND t.target_name is null;
|
|
472
|
+
|
|
473
|
+ -- 直播活动
|
|
474
|
+ UPDATE ta_share_person_from t
|
|
475
|
+ INNER JOIN ta_live_activity s ON s.live_activity_id = t.target_id
|
|
476
|
+ SET t.target_name = s.live_activity_title
|
|
477
|
+ WHERE t.target_type = 'live_share'
|
|
478
|
+ AND t.target_name is null;
|
|
479
|
+
|
|
480
|
+ UPDATE ta_share_count t
|
|
481
|
+ INNER JOIN ta_live_activity s ON s.live_activity_id = t.be_share
|
|
482
|
+ SET t.target_name = s.live_activity_title,
|
|
483
|
+ t.org_id = s.org_id
|
|
484
|
+ WHERE t.tagert_type like 'live%'
|
|
485
|
+ AND t.target_name is null;
|
|
486
|
+
|
|
487
|
+ -- 房源列表
|
|
488
|
+ UPDATE ta_share_person_from t
|
|
489
|
+ INNER JOIN ta_sales_batch s ON s.sales_batch_id = t.target_id
|
|
490
|
+ INNER JOIN ta_building m on m.building_id = s.building_id
|
|
491
|
+ SET t.target_name = m.building_name
|
|
492
|
+ WHERE t.target_type = 'house_share'
|
|
493
|
+ AND t.target_name is null;
|
|
494
|
+
|
|
495
|
+ UPDATE ta_share_count t
|
|
496
|
+ INNER JOIN ta_sales_batch s ON s.sales_batch_id = t.be_share
|
|
497
|
+ INNER JOIN ta_building m on m.building_id = s.building_id
|
|
498
|
+ SET t.target_name = m.building_name,
|
|
499
|
+ t.org_id = s.org_id
|
|
500
|
+ WHERE t.tagert_type like 'house%'
|
|
501
|
+ AND t.target_name is null;
|
|
502
|
+
|
|
503
|
+
|
|
504
|
+ -- 更新 org
|
|
505
|
+ UPDATE ta_share_count t
|
|
506
|
+ INNER JOIN ta_person s ON s.person_id = t.be_share
|
|
507
|
+ SET t.org_id = s.org_id
|
|
508
|
+ WHERE t.tagert_type = 'consultant'
|
|
509
|
+ AND t.org_id is null;
|
|
510
|
+
|
|
511
|
+END$$
|
|
512
|
+
|
|
513
|
+delimiter $$
|
|
514
|
+CREATE PROCEDURE `pro_activity_daily`(IN `st_date` varchar(32))
|
|
515
|
+BEGIN
|
|
516
|
+DECLARE day_start datetime;
|
|
517
|
+DECLARE day_end datetime;
|
|
518
|
+
|
|
519
|
+SET day_start = STR_TO_DATE(st_date, '%Y-%m-%d');
|
|
520
|
+SET day_end = STR_TO_DATE(concat(st_date, ' 235959'), '%Y-%m-%d %H%i%s');
|
|
521
|
+
|
|
522
|
+
|
|
523
|
+delete from ts_activity_daily where statis_date = st_date;
|
|
524
|
+
|
|
525
|
+insert into ts_activity_daily (
|
|
526
|
+ `statis_date`,
|
|
527
|
+ `org_id`,
|
|
528
|
+ `building_id`,
|
|
529
|
+ `building_name`,
|
|
530
|
+ `target_type`,
|
|
531
|
+ `target_id`,
|
|
532
|
+ `target_name`,
|
|
533
|
+ `share_persons`,
|
|
534
|
+ `share_num`,
|
|
535
|
+ `visit_persons`,
|
|
536
|
+ `visit_num`,
|
|
537
|
+ `new_persons`,
|
|
538
|
+ `new_customers`
|
|
539
|
+)
|
|
540
|
+
|
|
541
|
+select
|
|
542
|
+ st_date as statis_date,
|
|
543
|
+ a.org_id,
|
|
544
|
+ a.building_id,
|
|
545
|
+ a.building_name,
|
|
546
|
+ a.target_type,
|
|
547
|
+ a.target_id,
|
|
548
|
+ a.target_name,
|
|
549
|
+
|
|
550
|
+ -- 活动分享人数
|
|
551
|
+ (SELECT count(DISTINCT b.person_id) FROM ta_share_count b
|
|
552
|
+ WHERE b.org_id = a.org_id
|
|
553
|
+ AND b.tagert_type like concat(a.target_type,'%')
|
|
554
|
+ AND b.be_share = a.target_id
|
|
555
|
+ AND b.create_date BETWEEN day_start AND day_end
|
|
556
|
+ ) as share_persons,
|
|
557
|
+
|
|
558
|
+ -- 活动分享次数
|
|
559
|
+ (SELECT count(*) FROM ta_share_count c
|
|
560
|
+ WHERE c.org_id = a.org_id
|
|
561
|
+ AND c.tagert_type like concat(a.target_type,'%')
|
|
562
|
+ AND c.be_share = a.target_id
|
|
563
|
+ AND c.create_date BETWEEN day_start AND day_end
|
|
564
|
+ ) as share_num,
|
|
565
|
+
|
|
566
|
+ -- 活动访问人数
|
|
567
|
+ (select count( DISTINCT d.person_id ) from ta_person_visit_record d
|
|
568
|
+ WHERE d.org_id = a.org_id
|
|
569
|
+ AND if(d.target_type is null ,d.event_type = a.target_type, d.target_type = REPLACE(a.target_type, 'activity', 'dynamic'))
|
|
570
|
+ AND d.target_id = a.target_id
|
|
571
|
+ AND d.`event` = 'detail'
|
|
572
|
+ AND d.visit_time BETWEEN day_start AND day_end
|
|
573
|
+ ) as visit_persons,
|
|
574
|
+
|
|
575
|
+ -- 活动访问次数
|
|
576
|
+ (select count(*) from ta_person_visit_record e
|
|
577
|
+ WHERE e.org_id = a.org_id
|
|
578
|
+ AND if(e.target_type is null ,e.event_type = a.target_type, e.target_type = REPLACE(a.target_type, 'activity', 'dynamic'))
|
|
579
|
+ AND e.target_id = a.target_id
|
|
580
|
+ AND e.`event` = 'detail'
|
|
581
|
+ AND e.visit_time BETWEEN day_start AND day_end
|
|
582
|
+ ) as visit_num,
|
|
583
|
+
|
|
584
|
+ -- 分享新增用户
|
|
585
|
+ (select count(*) from ta_share_person_from f
|
|
586
|
+ where f.org_id = a.org_id
|
|
587
|
+ AND f.target_type = concat(REPLACE(a.target_type, 'activity', 'dynamic'), '_share')
|
|
588
|
+ AND f.target_id = a.target_id
|
|
589
|
+ AND f.`status` > 0
|
|
590
|
+ AND f.create_date BETWEEN day_start AND day_end
|
|
591
|
+ AND f.is_first_time = 1
|
|
592
|
+ ) as new_persons,
|
|
593
|
+
|
|
594
|
+ -- 分享新增客户
|
|
595
|
+ (select count(*) from ta_customer_from g
|
|
596
|
+ inner join ta_person h on h.person_id = g.person_id
|
|
597
|
+ where g.org_id = a.org_id
|
|
598
|
+ AND g.target_type = a.target_type
|
|
599
|
+ AND g.target_id = a.target_id
|
|
600
|
+ AND g.create_date BETWEEN day_start AND day_end
|
|
601
|
+ AND g.is_org_first = 1
|
|
602
|
+ ) as new_customers
|
|
603
|
+
|
|
604
|
+from (
|
|
605
|
+ -- 增加时间的过滤, 是为了减少统计的数据量
|
|
606
|
+ -- 如果统计的时候, 活动还没有创建, 那么活动不创建
|
|
607
|
+ -- 主要是针对初始化数据
|
|
608
|
+
|
|
609
|
+ -- 报名活动
|
|
610
|
+ select t.org_id, t.building_id, s.building_name, t.dynamic_id as target_id, t.title as target_name, 'activity' as target_type, t.create_date from ta_building_dynamic t
|
|
611
|
+ left join ta_building s on s.building_id = t.building_id
|
|
612
|
+ where t.`status` > -1
|
|
613
|
+ union all
|
|
614
|
+
|
|
615
|
+ -- h5
|
|
616
|
+ select t.org_id, t.building_id, s.building_name, t.drainage_id as target_id, t.`name` as target_name, 'h5' as target_type, t.create_date from ta_drainage t
|
|
617
|
+ left join ta_building s on s.building_id = t.building_id
|
|
618
|
+ where t.`status` > -1
|
|
619
|
+ union all
|
|
620
|
+
|
|
621
|
+ -- 助力
|
|
622
|
+ select t.org_id, t.building_id, s.building_name, t.help_activity_id as target_id, t.title as target_name, 'help' as target_type, t.create_date from ta_help_activity t
|
|
623
|
+ left join ta_building s on s.building_id = t.building_id
|
|
624
|
+ where t.`status` > -1
|
|
625
|
+ union all
|
|
626
|
+
|
|
627
|
+ -- 拼团
|
|
628
|
+ select t.org_id, t.building_id, s.building_name, t.group_activity_id as target_id, t.activity_name as target_name, 'group' as target_type, t.start_time as create_date from ta_share_activity t
|
|
629
|
+ left join ta_building s on s.building_id = t.building_id
|
|
630
|
+ where t.`status` > -1
|
|
631
|
+ union all
|
|
632
|
+
|
|
633
|
+ -- 直播
|
|
634
|
+ select t.org_id, t.building_id, s.building_name, t.live_activity_id as target_id, t.live_activity_title as target_name, 'live' as target_type, t.create_date from ta_live_activity t
|
|
635
|
+ left join ta_building s on s.building_id = t.building_id
|
|
636
|
+ where t.`status` > -1
|
|
637
|
+ ) a;
|
|
638
|
+
|
|
639
|
+END$$
|
|
640
|
+
|
|
641
|
+delimiter $$
|
|
642
|
+CREATE PROCEDURE `pro_init_activity_daily`(IN `days` int)
|
|
643
|
+BEGIN
|
|
644
|
+ DECLARE inx int DEFAULT 1;
|
|
645
|
+ DECLARE dt VARCHAR(10);
|
|
646
|
+ DECLARE nw datetime DEFAULT now();
|
|
647
|
+
|
|
648
|
+ while inx <= days do
|
|
649
|
+ set dt = DATE_FORMAT(DATE_SUB(nw, INTERVAL inx DAY),"%Y-%m-%d");
|
|
650
|
+
|
|
651
|
+ call pro_activity_daily(dt);
|
|
652
|
+
|
|
653
|
+ set inx = inx + 1;
|
|
654
|
+ end while;
|
|
655
|
+END$$
|
|
656
|
+
|
|
657
|
+
|
|
658
|
+CREATE EVENT `evt_update_share_target_name_2h`
|
|
659
|
+ON SCHEDULE
|
|
660
|
+EVERY 2 HOUR STARTS CURRENT_TIMESTAMP
|
|
661
|
+DO BEGIN
|
|
662
|
+ CALL pro_update_share_target_name();
|
|
663
|
+END;
|
|
664
|
+
|
|
665
|
+
|
|
666
|
+
|
|
667
|
+-- 数据初始化脚本
|
|
668
|
+delimiter $$
|
|
669
|
+CREATE PROCEDURE `pro_init_consultant_kpi`(IN days int)
|
|
670
|
+BEGIN
|
|
671
|
+ DECLARE inx int DEFAULT 1;
|
|
672
|
+ DECLARE dt VARCHAR(10);
|
|
673
|
+ DECLARE nw datetime DEFAULT now();
|
|
674
|
+
|
|
675
|
+ while inx <= days do
|
|
676
|
+ set dt = DATE_FORMAT(DATE_SUB(nw, INTERVAL inx DAY),"%Y%m%d");
|
|
677
|
+
|
|
678
|
+ call pro_consultant_kpi(dt);
|
|
679
|
+
|
|
680
|
+ set inx = inx + 1;
|
|
681
|
+ end while;
|
|
682
|
+END$$
|
|
683
|
+
|
|
684
|
+-- 置业KPI统计每 4 小时执行一次
|
|
685
|
+CREATE EVENT `evt_consultant_kpi_daily`
|
|
686
|
+ON SCHEDULE
|
|
687
|
+EVERY 4 HOUR STARTS CURRENT_TIMESTAMP
|
|
688
|
+DO BEGIN
|
|
689
|
+
|
|
690
|
+call pro_consultant_kpi(DATE_FORMAT(now(),"%Y%m%d"));
|
|
691
|
+
|
|
692
|
+END;
|
|
693
|
+
|
|
694
|
+-- 活动统计每 4 小时执行一次
|
|
695
|
+CREATE EVENT `evt_activity_daily`
|
|
696
|
+ON SCHEDULE
|
|
697
|
+EVERY 4 HOUR STARTS CURRENT_TIMESTAMP
|
|
698
|
+DO BEGIN
|
|
699
|
+
|
|
700
|
+call pro_activity_daily(DATE_FORMAT(now(),"%Y-%m-%d"));
|
|
701
|
+
|
|
702
|
+END;
|
|
703
|
+
|
|
704
|
+ALTER TABLE td_live_dict ADD sort INT ( 11 );
|
|
705
|
+
|
|
706
|
+UPDATE td_live_dict
|
|
707
|
+SET sort = 6
|
|
708
|
+WHERE
|
|
709
|
+ id = 1;
|
|
710
|
+UPDATE td_live_dict
|
|
711
|
+SET sort = 5
|
|
712
|
+WHERE
|
|
713
|
+ id = 2;
|
|
714
|
+UPDATE td_live_dict
|
|
715
|
+SET sort = 4
|
|
716
|
+WHERE
|
|
717
|
+ id = 3;
|
|
718
|
+UPDATE td_live_dict
|
|
719
|
+SET sort = 3
|
|
720
|
+WHERE
|
|
721
|
+ id = 4;
|
|
722
|
+UPDATE td_live_dict
|
|
723
|
+SET sort = 2
|
|
724
|
+WHERE
|
|
725
|
+ id = 5;
|
|
726
|
+UPDATE td_live_dict
|
|
727
|
+SET sort = 1
|
|
728
|
+WHERE
|
|
729
|
+ id = 6;
|
|
730
|
+
|
|
731
|
+ALTER TABLE ta_share_person_from ADD INDEX idx_share_person_personId ( person_id );
|
|
732
|
+ALTER TABLE ta_person_from_record ADD INDEX idx_from_record_personId ( share_person_id );
|
|
733
|
+ALTER TABLE ta_extend_content ADD create_user INT ( 11 );
|
|
734
|
+ALTER TABLE ta_drainage ADD create_user INT ( 11 );
|
|
735
|
+
|
|
736
|
+INSERT INTO `td_report` ( `report_code`, `report_name`, `is_project`, `remark`, `status`, `create_date` )
|
|
737
|
+VALUES
|
|
738
|
+ ( 'total_number_of_visit_users', '今日访问次数', NULL, NULL, 1, '2020-04-23 16:07:18' );
|
|
739
|
+INSERT INTO ta_building_report ( `report_code`, `create_date`, `org_id` ) SELECT
|
|
740
|
+'total_number_of_visit_users',
|
|
741
|
+NOW( ),
|
|
742
|
+org_id
|
|
743
|
+FROM
|
|
744
|
+ ta_miniapp;
|
|
745
|
+
|
|
746
|
+UPDATE ta_recommend_customer t
|
|
747
|
+LEFT JOIN ta_person p ON t.person_id = p.person_id
|
|
748
|
+SET t.sex = p.gender
|
|
749
|
+WHERE
|
|
750
|
+ t.sex IS NULL;
|
|
751
|
+
|
|
752
|
+
|
|
753
|
+
|
|
754
|
+
|
|
755
|
+
|