diff --git a/main_service.py b/main_service.py index 91a38ed..4681deb 100644 --- a/main_service.py +++ b/main_service.py @@ -48,7 +48,7 @@ def create_vana(): "api_base": config('CHAT_MODEL_BASE_URL', default=''), "model": config('CHAT_MODEL_NAME', default=''), 'temperature':config('CHAT_MODEL_TEMPERATURE', default=0.7, cast=float), - 'max_tokens':config('CHAT_MODEL_MAX_TOKEN', default=20000), + 'max_tokens':config('CHAT_MODEL_MAX_TOKEN', default=5000), }, ) diff --git a/template.yaml b/template.yaml index c83f801..c5e5116 100644 --- a/template.yaml +++ b/template.yaml @@ -64,6 +64,12 @@ template: - **默认行为**:若提问未指定排序,**默认按时间字段降序排序**(即最新数据在前)。 - **格式化**:若提问要求时间/日期/年月/年,且未指定格式,则分别格式化为 'yyyy-MM-dd HH:mm:ss' / 'yyyy-MM-dd' / 'yyyy-MM' / 'yyyy',语法需适配当前数据库引擎。(达梦数据库如果时间字段是varchar类型也可以) + + 解析用户问题,识别并替换所有已知的等价短语,将前面的短语换成后面得等价短语,: + ** 数信部 -> 数字信息部 + ** 安质部 -> 安全质量部 + 例如:查询数信部有多少人->查询数字信息部有多少人 + 聚合与计算 @@ -72,6 +78,12 @@ template: 使用了函数(如 COUNT(), CAST(), SUM())的字段,必须为其指定一个英文别名。 计算占比或百分比时,结果保留两位小数,并以 '%' 符号结尾。示例:ROUND(COUNT(*) * 100.0 / (SELECT COUNT(*) FROM table), 2) || '%' (PostgreSQL语法) 若查询结果包含枚举字段(如 gender=1,2),必须使用 CASE WHEN 语句将其转换为可读的标签。示例: SELECT CASE WHEN "gender" = '1' THEN '男' WHEN "gender" = '2' THEN '女' END AS "gender" + 重点!重点!重点!涉及查询orgs表时,部门存在多层级,必须递归查询。使用 start .. with 语法。递归语法示例: + SELECT "id" + FROM "IUAP_APDOC_BASEDOC"."org_orgs" START + WITH "name"||"shortname" LIKE '%xx中心%' AND "dr"=0 AND "enable"=1 AND "code" LIKE '%CYJ%' + CONNECT BY PRIOR "id" = "parentid" + 关联与限制 diff --git a/util/load_ddl_doc.py b/util/load_ddl_doc.py index 60cd969..0e4f79c 100644 --- a/util/load_ddl_doc.py +++ b/util/load_ddl_doc.py @@ -1,6 +1,8 @@ from service.cus_vanna_srevice import CustomVanna from util import train_ddl -from util import q_and_a_dict,q_and_a_test1 +from util import q_and_a_dict,q_and_a_test1,q_a_next + +import random table_ddls = [ train_ddl.person_database_ddl,train_ddl.person_status_ddl, train_ddl.person_attendance_ddl,train_ddl.person_ac_area, @@ -20,6 +22,12 @@ def add_ddl(vn: CustomVanna): def add_documentation(vn: CustomVanna): for doc in list_documentions: vn.add_documentation(doc) + dd=[] + dd.extend(q_and_a_dict.question_and_answer) + ##dd.extend(q_a_next.org_and_attend_q_a) + random.shuffle(dd) + for d in dd: + vn.add_question_sql(question=d['question'], sql=d['answer']) for d in q_and_a_test1.question_and_answer: vn.add_question_sql( diff --git a/util/q_a_next.py b/util/q_a_next.py new file mode 100644 index 0000000..bf43888 --- /dev/null +++ b/util/q_a_next.py @@ -0,0 +1,204 @@ +org_and_attend_q_a = [ + { + "question": "XX中心员工在林芝工作的天数", + "answer": ''' + SELECT DISTINCT p."code" AS "工号", + p."name" AS "姓名", + + COUNT(DISTINCT TO_CHAR(a."attendance_time", 'yyyy-MM-dd')) AS "在林芝工作天数" + FROM "YJOA_APPSERVICE_DB"."t_pr3rl2oj_yj_person_database" p + LEFT JOIN "YJOA_APPSERVICE_DB"."t_yj_person_attendance" a ON p."code" = a."person_id" + LEFT JOIN "YJOA_APPSERVICE_DB"."t_yj_person_ac_area" ac + ON a."access_control_point" = ac."ac_point" + WHERE p."dr" = 0 + AND a."dr" = 0 + AND ac."region" = 5 + AND p."internal_dept" in + (SELECT "id" + FROM "IUAP_APDOC_BASEDOC"."org_orgs" START + WITH "name"||"shortname" LIKE '%xx中心%' AND "dr"=0 AND "enable"=1 AND "code" LIKE '%CYJ%' + CONNECT BY PRIOR "id" = "parentid") + GROUP BY p."code", p."name" + ORDER BY "在林芝工作天数" DESC LIMIT 1000 + ''' + }, { + "question": "xx中心10月有哪些人迟到/早退", + "answer": ''' + SELECT p."id" AS "id", + p."code" AS "code", + p."name" AS "name", + CASE WHEN ps."status" = '1006' THEN '迟到/早退' ELSE ps."status" END AS "status" + FROM "YJOA_APPSERVICE_DB"."t_yj_person_status" ps + INNER JOIN "YJOA_APPSERVICE_DB"."t_pr3rl2oj_yj_person_database" p + ON p."code" = ps."person_id" + WHERE ps."status" = '1006' + AND ps."date_value" LIKE '2025-10%' + AND ps."dr" = 0 + AND p."dr" = 0 + AND p."internal_dept" IN (SELECT "id" FROM "IUAP_APDOC_BASEDOC"."org_orgs" START + WITH "name" || "shortname" LIKE '%xx中心%' AND "dr"=0 AND "enable"=1 AND "code" LIKE '%CYJ%' + CONNECT BY PRIOR "id" = "parentid") + ORDER BY ps."date_value" DESC LIMIT 1000 + ''' + }, + { + "question": "xx中心10月有哪些人出差", + "answer": ''' + SELECT p."id" AS "id", + p."code" AS "code", + p."name" AS "name", + CASE WHEN ps."status" = '1002' THEN '出差' ELSE ps."status" END AS "status" + FROM "YJOA_APPSERVICE_DB"."t_yj_person_status" ps + INNER JOIN "YJOA_APPSERVICE_DB"."t_pr3rl2oj_yj_person_database" p + ON p."code" = ps."person_id" + WHERE ps."status" = '1002' + AND ps."date_value" LIKE '2025-10%' + AND ps."dr" = 0 + AND p."dr" = 0 + AND p."internal_dept" IN (SELECT "id" FROM "IUAP_APDOC_BASEDOC"."org_orgs" START + WITH "name" || "shortname" LIKE '%xx中心%' AND "dr"=0 AND "enable"=1 AND "code" LIKE '%CYJ%' + CONNECT BY PRIOR "id" = "parentid") + ORDER BY ps."date_value" DESC LIMIT 1000 + ''' + }, + { + "question": "xx中心10月有哪些人旷工", + "answer": ''' + SELECT p."id" AS "id", + p."code" AS "code", + p."name" AS "name", + CASE WHEN ps."status" = '1002' THEN '旷工' ELSE ps."status" END AS "status" + FROM "YJOA_APPSERVICE_DB"."t_yj_person_status" ps + INNER JOIN "YJOA_APPSERVICE_DB"."t_pr3rl2oj_yj_person_database" p + ON p."code" = ps."person_id" + WHERE ps."status" = '1005' + AND ps."date_value" LIKE '2025-10%' + AND ps."dr" = 0 + AND p."dr" = 0 + AND p."internal_dept" IN (SELECT "id" FROM "IUAP_APDOC_BASEDOC"."org_orgs" START + WITH "name" || "shortname" LIKE '%xx中心%' AND "dr"=0 AND "enable"=1 AND "code" LIKE '%CYJ%' + CONNECT BY PRIOR "id" = "parentid") + ORDER BY ps."date_value" DESC LIMIT 1000 + ''' + }, + { + "question": "xx中心10月有哪些人请假", + "answer": ''' + SELECT p."id" AS "id", + p."code" AS "code", + p."name" AS "name", + CASE WHEN ps."status" = '1003' THEN '请假' ELSE ps."status" END AS "status" + FROM "YJOA_APPSERVICE_DB"."t_yj_person_status" ps + INNER JOIN "YJOA_APPSERVICE_DB"."t_pr3rl2oj_yj_person_database" p + ON p."code" = ps."person_id" + WHERE ps."status" = '1005' + AND ps."date_value" LIKE '2025-10%' + AND ps."dr" = 0 + AND p."dr" = 0 + AND p."internal_dept" IN (SELECT "id" FROM "IUAP_APDOC_BASEDOC"."org_orgs" START + WITH "name" || "shortname" LIKE '%xx中心%' AND "dr"=0 AND "enable"=1 AND "code" LIKE '%CYJ%' + CONNECT BY PRIOR "id" = "parentid") + ORDER BY ps."date_value" DESC LIMIT 1000 + ''' + }, + { + "question": "xx中心,9月迟到次数多前三是哪几个员工", + "answer": ''' + SELECT p.name AS "employee_name", + p.code AS "employee_code", + o.name AS "department_name", + COUNT(ps.id) AS "late_count" + FROM "YJOA_APPSERVICE_DB"."t_pr3rl2oj_yj_person_database" p + JOIN "IUAP_APDOC_BASEDOC"."org_orgs" o ON p.internal_dept = o.id + JOIN "YJOA_APPSERVICE_DB"."t_yj_person_status" ps ON p.id = ps.person_id + WHERE p.dr = 0 + AND ps.dr = 0 + AND ps.status = '1006' + AND ps.date_value LIKE '2025-09%' + AND o.id IN (SELECT id FROM "IUAP_APDOC_BASEDOC"."org_orgs" START + WITH (name LIKE '%xx中心%' OR shortname LIKE '%xx中心%') AND dr=0 AND enable=1 + CONNECT BY PRIOR id = parentid) + GROUP BY p.name, p.code, o.name + ORDER BY "late_count" DESC LIMIT 3 + ''' + }, { + "question": "xx中心员工10月打卡记录查询", + "answer": ''' + SELECT a."person_name" AS "person_name", + p."code" AS "employee_code", + a."attendance_time" AS "attendance_time", + a."attendance_address" AS "attendance_address", + CASE + WHEN a."status" = 1 THEN '在岗' + WHEN a."status" = 2 THEN '出差' + WHEN a."status" = 3 + THEN '休假' END AS "status_desc", + CASE + WHEN a."enter_or_exit" = 1 THEN '进' + WHEN a."enter_or_exit" = 2 + THEN '出' END AS "entry_exit", + o."name" AS "department_name" + FROM "YJOA_APPSERVICE_DB"."t_yj_person_attendance" a + JOIN "YJOA_APPSERVICE_DB"."t_pr3rl2oj_yj_person_database" p ON a."person_id" = p."code" + JOIN "IUAP_APDOC_BASEDOC"."org_orgs" o ON p."internal_dept" = o."id" + WHERE a."dr" = 0 + AND p."dr" = 0 + AND a."attendance_time" >= '2025-10-01' + AND a."attendance_time" < '2025-11-01' + AND o."id" IN (SELECT o2."id" FROM "IUAP_APDOC_BASEDOC"."org_orgs" o2 + START WITH (o2."name" LIKE '%xx中心%' + OR o2."shortname" LIKE '%xx中心%') + AND o2."dr" = 0 + AND o2."enable" = 1 + CONNECT BY PRIOR o2."id" = o2."parentid") + ORDER BY a."attendance_time" DESC LIMIT 1000 + ''' + }, { + "question": "xx中心员工10月考勤查询", + "answer": ''' + SELECT p."code" AS "工号", + p."name" AS "姓名", + o."name" AS "部门名称", + ps."date_value" AS "日期", + CASE + WHEN ps."status" = '1001' THEN '在岗' + WHEN ps."status" = '1002' THEN '出差' + WHEN ps."status" = '1003' THEN '休假,请假' + WHEN ps."status" = '1005' THEN '旷工' + WHEN ps."status" = '1006' THEN '迟到,早退' + WHEN ps."status" = '1007' THEN '休息日' + WHEN ps."status" = '4001' THEN 'am在岗pm缺勤' + WHEN ps."status" = '4002' THEN 'am缺勤pm在岗' + WHEN ps."status" = '6001' THEN 'am在岗pm早退' + WHEN ps."status" = '6002' THEN 'am迟到pm在岗' + WHEN ps."status" = '6004' THEN 'am迟到pm缺勤' + WHEN ps."status" = '4006' THEN 'am缺勤pm早退' + ELSE ps."status" END AS "人员状态" + FROM "YJOA_APPSERVICE_DB"."t_yj_person_status" ps + JOIN "YJOA_APPSERVICE_DB"."t_pr3rl2oj_yj_person_database" p ON ps."person_id" = p."code" + JOIN "IUAP_APDOC_BASEDOC"."org_orgs" o ON p."internal_dept" = o."id" + WHERE o."id" IN (SELECT id FROM "IUAP_APDOC_BASEDOC"."org_orgs" START + WITH ("name" LIKE '%xx中心%' OR "shortname" LIKE '%xx中心%') AND "enable" = 1 AND "dr" = 0 AND "code" LIKE '%CYJ%' + CONNECT BY PRIOR "id" = "parentid") AND ps."date_value" LIKE '2025-10%' AND ps."dr" = 0 AND p."dr" = 0 + ORDER BY ps."date_value" DESC LIMIT 1000 + ''' + },{ + "question": "10月迟到人数最多的部门", + "answer": ''' + SELECT o."name" AS "部门名称", COUNT(DISTINCT ps."person_id") AS "迟到人数" + FROM "YJOA_APPSERVICE_DB"."t_yj_person_status" ps + JOIN "YJOA_APPSERVICE_DB"."t_pr3rl2oj_yj_person_database" p + ON ps."person_id" = p."code" + JOIN "IUAP_APDOC_BASEDOC"."org_orgs" o ON p."internal_dept" = o."id" + WHERE ps."status" = '1006' + AND ps."date_value" LIKE '2025-10%' + AND ps."dr" = 0 + AND o."dr" = 0 + AND o."enable" = 1 + AND o."code" LIKE '%CYJ%' + GROUP BY o."name" + ORDER BY COUNT(DISTINCT ps."person_id") DESC LIMIT 1 + ''' + } + +] diff --git a/util/q_and_a_dict.py b/util/q_and_a_dict.py index 25f940d..c622909 100644 --- a/util/q_and_a_dict.py +++ b/util/q_and_a_dict.py @@ -1,32 +1,7 @@ question_and_answer = [ - {"question": "XX部有多少员工,男女员工分别有多少", - "answer": ''' - SELECT COUNT(*) AS "总人数", - SUM(CASE WHEN gender = '1' THEN 1 ELSE 0 END) AS "男员工数", - SUM(CASE WHEN gender = '2' THEN 1 ELSE 0 END) AS "女员工数" - FROM YJOA_APPSERVICE_DB.t_pr3rl2oj_yj_person_database p - WHERE p.internal_dept IN (SELECT "id" - FROM "IUAP_APDOC_BASEDOC"."org_orgs" START - WITH "name"||"shortname" LIKE '%XX部%' - CONNECT BY PRIOR "id" = "parentid" - ) - AND p.dr = 0 - LIMIT 1000; - ''' - }, - { - "question": "外部单位是联通下面有哪些员工", - "answer": ''' - SELECT "id" AS "id", - "code" AS "工号", - "name" AS "姓名", - "external_unit" AS "外部单位" - FROM "YJOA_APPSERVICE_DB"."t_pr3rl2oj_yj_person_database" - WHERE "external_unit" LIKE '%联通%' LIMIT 1000 - ''' - }, + { "question": "9月有多少哪些员工在休假", "answer": ''' @@ -351,21 +326,7 @@ question_and_answer = [ LIMIT 1000; ''' }, - { - "question": "XX综合部女员工有多少", - "answer": ''' - SELECT (SELECT COUNT(*) - FROM "YJOA_APPSERVICE_DB"."t_pr3rl2oj_yj_person_database" p - WHERE p."internal_dept" IN (SELECT "id" - FROM "IUAP_APDOC_BASEDOC"."org_orgs" START - WITH "name"||"shortname" LIKE '%XX综合部%' AND "dr"=0 AND "enable"=1 AND "code" LIKE '%CYJ%' - CONNECT BY PRIOR "id" = "parentid" - ) - AND p."gender" = '2' - AND p."dr" = 0 - ) AS "女员工数" - ''' - }, + { "question": "XX中心今天各个处室在岗人员数量", "answer": ''' @@ -440,29 +401,7 @@ question_and_answer = [ LIMIT 1 ''' }, - { - "question": "张三今天早上9点半之前,今天早上0点之后,有打卡记录吗", - "answer": ''' - SELECT a."person_name" AS "姓名", - a."attendance_time" AS "考勤时间", - a."attendance_address" AS "考勤地址", - CASE - WHEN a."status" = 1 THEN '在岗' - WHEN a."status" = 2 THEN '出差' - WHEN a."status" = 3 THEN '休假' - END AS "状态", - CASE - WHEN a."enter_or_exit" = 1 THEN '进' - WHEN a."enter_or_exit" = 2 THEN '出' - END AS "进出类型" - FROM "YJOA_APPSERVICE_DB"."t_yj_person_attendance" a - WHERE a."person_name" = '张三' - AND a."attendance_time" >= '2025-10-16 00:00:00' - AND a."attendance_time" < '2025-10-16 09:30:00' - AND a."dr" = 0 - ORDER BY a."attendance_time" DESC LIMIT 1000 - ''' - }, + { "question": "XX中心正式人员有多少,各个处室有多少?", "answer": ''' diff --git a/util/train_ddl.py b/util/train_ddl.py index 105b4eb..cbb1814 100644 --- a/util/train_ddl.py +++ b/util/train_ddl.py @@ -7,11 +7,7 @@ train_document=''' 查询单位时,通过orgs表查询,且需要基于parentID查询递归查询单位下的子单位; 查询内部单位时,则可以直接查询人员信息表,通过like模糊查询; 没有明确说明查询外部单位,都默认查询通过orgs查询单位; - 数信中心和数信部并非同一个部门,注意区分,不要混淆 - 数信中心下还有多个部门,这些部门里的人员也隶属于数信中心 根据部门名称查询部门时除了全称name,简称shortname也重要信息 - 数信部是简称 - 部门表org_orgs中的level字段 {1:公司,2:一级部门,3:二级部门.....} internal_dept和internal_unit是部门编号不是名称,注意区分 查询部门信息时尽量使用internal_dept而非internal_unit '''