How do I add a user's full name into an email from a custom ticket field?
I have created a new HR queue with many custom user fields. I have a custom ticket rule to email someone when a new ticket is created. These customer user fields are just showing up at the user ID from the database instead of the user full name. I am very new to SQL and do not know how to script it to make the custom user fields show up as the users full name that is selected when opening the ticket. Below is my custom ticket rule.
SELECT
-- ticket fields
HD_TICKET.ID, -- $id
HD_TICKET.ID AS TICKNUM, -- $ticknum
HD_TICKET.TITLE, -- $title
DATE_FORMAT(HD_TICKET.CREATED,'%b %d %Y %I:%i:%s %p') AS CREATED, -- $created
DATE_FORMAT(HD_TICKET.MODIFIED,'%b %d %Y %I:%i:%s %p') AS MODIFIED, -- $modified
-- change fields
C.COMMENT, -- $comment
C.DESCRIPTION, -- $description
GROUP_CONCAT(CONCAT('----- Change by ', UPDATER.EMAIL,' at ',H.TIMESTAMP,' -----\n',
H.DESCRIPTION,'\n',H.COMMENT,'\n\nPlease see your ticket at http://k1000/userui/ticket.php?ID=',H.HD_TICKET_ID,'\n')
ORDER BY H.ID DESC SEPARATOR '\n') HISTORY, -- $history
-- about the updater
UPDATER.USER_NAME AS UPDATER_UNAME, -- $updater_uname
UPDATER.FULL_NAME AS UPDATER_FNAME, -- $updater_fname
UPDATER.EMAIL AS UPDATER_EMAIL, -- $updater_email
IF(UPDATER.FULL_NAME='',UPDATER.USER_NAME,UPDATER.FULL_NAME) AS UPDATER_CONDITIONAL, -- $updater_conditional
-- about the owner
OWNER.USER_NAME AS OWNER_UNAME, -- $owner_uname
OWNER.FULL_NAME AS OWNER_FNAME, -- $owner_fname
OWNER.EMAIL AS OWNER_EMAIL, -- $owner_email
IFNULL(OWNER.USER_NAME,'Unassigned') OWNER_USER, -- $owner_user
-- about the submitter
SUBMITTER.USER_NAME AS SUBMITTER_UNAME, -- $submitter_uname
SUBMITTER.FULL_NAME AS SUBMITTER_FNAME, -- $submitter_fname
SUBMITTER.EMAIL AS SUBMITTER_EMAIL, -- $submitter_email
-- about priority
P.NAME AS PRIORITY, -- $priority
-- about status
S.NAME AS STATUS, -- $status
-- about impact
I.NAME AS IMPACT, -- $impact
-- about category
CAT.NAME AS CATEGORY, -- $category
-- other fields
HD_TICKET.CUSTOM_FIELD_VALUE0 AS TIME_ZONE, -- $time_zone
HD_TICKET.CUSTOM_FIELD_VALUE1 AS COMPANY, -- $company
HD_TICKET.CUSTOM_FIELD_VALUE3 AS MOBILE, -- $mobile
HD_TICKET.CUSTOM_FIELD_VALUE4 AS EMPLOYEE, -- $employee
HD_TICKET.CUSTOM_FIELD_VALUE5 AS MANAGER, -- $manager
HD_TICKET.CUSTOM_FIELD_VALUE6 AS H_DRIVE, -- $H_Drive
HD_TICKET.CUSTOM_FIELD_VALUE7 AS EMAIL_END, -- $email_end
HD_TICKET.CUSTOM_FIELD_VALUE8 AS ERP, -- $erp
HD_TICKET.CUSTOM_FIELD_VALUE9 AS COMPANY9, -- $company9
HD_TICKET.CUSTOM_FIELD_VALUE10 AS TERM_DATE, -- $term_date
HD_TICKET.CUSTOM_FIELD_VALUE11 AS FORWARD_EMAIL, -- $forward_email
HD_TICKET.CUSTOM_FIELD_VALUE12 AS COMPANY12, -- $company12
HD_TICKET.CUSTOM_FIELD_VALUE13 AS COMPANY13, -- $company13
HD_TICKET.CUSTOM_FIELD_VALUE14 AS COMPANY14, -- $company14
-- -- example of static distribution list
'rtotero@handyharman.com' AS NEWTICKETEMAIL -- $newticketemail
FROM HD_TICKET
/* latest change ***/ JOIN HD_TICKET_CHANGE C ON C.HD_TICKET_ID = HD_TICKET.ID
AND C.ID=<CHANGE_ID>
/* complete history*/ JOIN HD_TICKET_CHANGE H ON H.HD_TICKET_ID = HD_TICKET.ID
/* priority ********/ JOIN HD_PRIORITY P ON P.ID=HD_PRIORITY_ID
/* status **********/ JOIN HD_STATUS S ON S.ID=HD_STATUS_ID
/* impact-severity */ JOIN HD_IMPACT I ON I.ID=HD_IMPACT_ID
/* category ********/ JOIN HD_CATEGORY CAT ON CAT.ID=HD_CATEGORY_ID
/* owner ***********/ LEFT JOIN USER OWNER ON OWNER.ID = HD_TICKET.OWNER_ID
/* submitter *******/ LEFT JOIN USER SUBMITTER ON SUBMITTER.ID = HD_TICKET.SUBMITTER_ID
/* updater *********/ LEFT JOIN USER UPDATER ON UPDATER.ID = C.USER_USER_NAME
WHERE
C.DESCRIPTION LIKE 'TICKET CREATED%'
/* this is necessary when using group by functions */
GROUP BY HD_TICKET.ID
HAVING 1=1
------------------
Email each recipient in query results
Subject:
Column containing email addresses:
$submitter_fname has submitted an Employee Termination Request.
Title: $title
Employee Name: $employee
Company: $company
Term Date: $term_date, $time_zone
Forward Email to: $forward_email
H: Drive Access to: $H_Drive
Mobile Device?: $mobile
ERP Removal: $erp
Ticket: $ticknum
For complete details, see:
http://k1000/adminui/ticket?ID=$ticknum
Comments:
$comment
--------------
0 Comments
[ + ] Show comments
Answers (1)
Answer Summary:
Please log in to answer
Posted by:
chucksteel
8 years ago
Top Answer
It looks like employee is being stored in HD_TICKET.CUSTOM_FIELD_VALUE4, so you need to create a join to the USER table based on that. In your statement look for the other lines that join to the USER table:
/* owner ***********/ LEFT JOIN USER OWNER ON OWNER.ID = HD_TICKET.OWNER_ID
/* submitter *******/ LEFT JOIN USER SUBMITTER ON SUBMITTER.ID = HD_TICKET.SUBMITTER_ID
Add a line for the employee:
LEFT JOIN USER EMPLOYEE ON EMPLOYEE.ID = HD_TICKET.CUSTOM_FIELD_VALUE4
Now, instead of this select line:
HD_TICKET.CUSTOM_FIELD_VALUE4 AS EMPLOYEE, -- $employee
You can select fields from the user table like this:
EMPLOYEE.FULL_NAME as EMPLOYEE_FNAME --$employee_fname
EMPLOYEE.EMAIL AS EMPLOYEE_EMAIL -- $employee_email
Comments:
-
Thank you so much for your help. This worked perfectly! - totero21 8 years ago