切换导航条
此项目
正在载入...
登录
allied-creation
/
performance
·
提交
转到一个项目
GitLab
转到群组
项目
活动
文件
提交
管道
0
构建
0
图表
里程碑
问题
0
合并请求
0
成员
标记
维基
派生
网络
创建新的问题
下载为
邮件补丁
差异文件
浏览文件
作者
Your Name
2 years ago
提交
561e9253b70a76ebb93b3d05ab01a95297c40fd0
1 个父辈
63bb712b
数据修复脚本
隐藏空白字符变更
内嵌
并排对比
正在显示
3 个修改的文件
包含
171 行增加
和
0 行删除
pkg/application/staff_assess/service/service_v2.go
pkg/infrastructure/repository/pg_evaluation_item_used_repository.go
sql/2023-04-01.sql
pkg/application/staff_assess/service/service_v2.go
查看文件 @
561e925
...
...
@@ -922,3 +922,65 @@ func (srv StaffAssessServeice) SelectAssessInviteUserV2(param *query.SelectAsses
}
return
tool_funs
.
SimpleWrapGridMap
(
int64
(
cnt
),
listData
),
nil
}
// 获取未完成的员工评估内容
// func (srv StaffAssessServeice) getAssessInfoUncompletedV2(transactionContext application.TransactionContext,
// assess *domain.StaffAssess) ([]*domain.StaffAssessContent, error) {
// evaluationItemRepo := factory.CreateEvaluationItemUsedRepository(map[string]interface{}{
// "transactionContext": transactionContext,
// })
// var evaluationItemList []*domain.EvaluationItemUsed
// var err error
// _, evaluationItemList, err = evaluationItemRepo.Find(map[string]interface{}{
// "evaluationProjectId": assess.EvaluationProjectId,
// "nodeId": assess.LinkNodeId,
// })
// if err != nil {
// return nil, application.ThrowError(application.INTERNAL_SERVER_ERROR, "获取项目填写内容"+err.Error())
// }
// if len(evaluationItemList) == 0 {
// //如果当前节点没有评估内容,就去 使用自评节点的评估内容
// _, evaluationItemList, err = evaluationItemRepo.Find(map[string]interface{}{
// "evaluationProjectId": assess.EvaluationProjectId,
// "nodeType": domain.LinkNodeSelfAssessment,
// })
// if err != nil {
// return nil, application.ThrowError(application.INTERNAL_SERVER_ERROR, "获取自评项目填写内容"+err.Error())
// }
// }
// var contentList []*domain.StaffAssessContent
// nowTime := time.Now()
// for i, v := range evaluationItemList {
// item := &domain.StaffAssessContent{
// Id: 0,
// StaffAssessId: assess.Id,
// SortBy: i + 1,
// Category: v.Category,
// Name: v.Name,
// PromptTitle: v.PromptTitle,
// PromptText: v.PromptText,
// Remark: nil,
// Value: "",
// ReteResult: "",
// CreatedAt: nowTime,
// Weight: v.Weight,
// Required: v.Required,
// UpdatedAt: nowTime,
// DeletedAt: nil,
// Rule: v.Rule,
// }
// var remarks []domain.AssessContemtRemark
// for _, vv := range v.EntryItems {
// ritem := domain.AssessContemtRemark{
// Title: vv.Title,
// HintText: vv.HintText,
// Definition: vv.Definition,
// RemarkText: "",
// }
// remarks = append(remarks, ritem)
// }
// item.Remark = remarks
// contentList = append(contentList, item)
// }
// return contentList, nil
// }
...
...
pkg/infrastructure/repository/pg_evaluation_item_used_repository.go
查看文件 @
561e925
...
...
@@ -93,6 +93,10 @@ func (repo *EvaluationItemUsedRepository) Find(queryOptions map[string]interface
query
.
Where
(
"node_type=?"
,
v
)
}
if
v
,
ok
:=
queryOptions
[
"nodeId"
];
ok
{
query
.
Where
(
"node_id=?"
,
v
)
}
if
v
,
ok
:=
queryOptions
[
"evaluatorId"
];
ok
{
query
.
Where
(
"evaluator_id=?"
,
v
)
}
...
...
sql/2023-04-01.sql
0 → 100644
查看文件 @
561e925
-- 数据修复
-- 需备份 evaluation_item_used 表数据
WITH
t1
AS
(
SELECT
evaluation_project
.
company_id
,
evaluation_project
.
id
AS
project_id
,
jsonb_array_elements
(
evaluation_project
.
"template"
#>
'{linkNodes}'
)
AS
nodes
FROM
evaluation_project
WHERE
evaluation_project
.
"template"
#>
'{linkNodes}'
<>
'null'
ORDER
BY
id
),
t2
AS
(
SELECT
t1
.
company_id
,
t1
.
project_id
,
t1
.
nodes
->>
'id'
AS
node_id
,
t1
.
nodes
->>
'type'
AS
node_type
,
jsonb_array_elements
(
t1
.
nodes
#>
'{nodeContents}'
)
AS
node_contents
FROM
t1
WHERE
t1
.
nodes
#>
'{nodeContents}'
<>
'null'
),
t3
AS
(
SELECT
t2
.
company_id
,
t2
.
project_id
,
cast
(
t2
.
node_id
AS
int8
)
AS
node_id
,
cast
(
t2
.
node_type
AS
int8
)
AS
node_type
,
t2
.
node_contents
->>
'category'
AS
"category"
,
t2
.
node_contents
->>
'name'
AS
"name"
,
cast
(
t2
.
node_contents
->>
'ruleId'
AS
int8
)
AS
"rule_id"
FROM
t2
),
t4
as
(
SELECT
t3
.
project_id
,
t3
.
node_type
,
t3
.
"category"
,
t3
.
"name"
,
row_to_json
(
"evaluation_rule"
.
*
)
as
"rule"
,
"evaluation_rule"
.
"type"
as
rule_type
FROM
t3
join
"evaluation_rule"
on
t3
.
rule_id
=
"evaluation_rule"
.
id
),
t5
as
(
SELECT
evaluation_item_used
.
"id"
,
evaluation_item_used
.
evaluation_project_id
,
evaluation_item_used
.
node_type
,
evaluation_item_used
.
category
,
evaluation_item_used
.
"name"
FROM
evaluation_item_used
WHERE
"rule"
=
'{}'
or
"rule"
ISNULL
),
t6
as
(
SELECT
t5
.
"id"
,
t4
.
"rule"
,
t4
.
rule_type
FROM
t5
,
t4
WHERE
t5
.
evaluation_project_id
=
t4
.
project_id
and
t5
.
node_type
=
t4
.
node_type
and
t5
.
category
=
t4
.
category
and
t5
.
"name"
=
t4
.
"name"
)
update
evaluation_item_used
set
"rule"
=
t6
.
"rule"
,
rule_type
=
t6
.
"rule_type"
FROM
t6
WHERE
evaluation_item_used
.
"id"
=
t6
.
"id"
;
-- 修复数据
with
t1
as
(
SELECT
evaluation_rule
.
id
::
TEXT
,
evaluation_rule
.
"name"
,
evaluation_rule
.
remark
,
evaluation_rule
.
company_id
::
TEXT
as
"companyId"
,
evaluation_rule
.
creator_id
::
TEXT
as
"creatorId"
,
evaluation_rule
.
"type"
,
evaluation_rule
.
rating
,
evaluation_rule
.
score
,
evaluation_rule
.
sys_type
as
"sysType"
FROM
evaluation_rule
),
t2
as
(
SELECT
t1
.
id
,
row_to_json
(
t1
.
*
)
as
row_j
FROM
t1
),
t3
as
(
SELECT
evaluation_item_used
.
id
,
t2
.
row_j
FROM
evaluation_item_used
join
t2
on
t2
.
id
=
evaluation_item_used
.
"rule"
->>
'id'
WHERE
evaluation_item_used
.
"rule"
->
'companyId'
ISNULL
and
evaluation_item_used
.
"rule"
->
'id'
is
not
null
)
update
evaluation_item_used
SET
"rule"
=
t3
.
row_j
FROM
t3
WHERE
evaluation_item_used
.
id
=
t3
.
id
;
...
...
请
注册
或
登录
后发表评论