New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Feature/solutions #2881

Merged
merged 1 commit into from Dec 4, 2017

Conversation

4 participants
@trasher
Member

trasher commented Oct 2, 2017

Q A
Bug fix? yes
New feature? yes
BC breaks? no
Deprecations? no
Tests pass? yes
Fixed tickets #2089
  • Fix rights
  • Fix massive actions
  • Change rejected image
  • Fix data migration

@trasher trasher added the wip label Oct 2, 2017

@orthagh orthagh added this to Next major version in Project Roadmap Oct 6, 2017

@tomolimo

This comment has been minimized.

Show comment
Hide comment
@tomolimo

tomolimo Oct 12, 2017

Contributor

Hello @trasher,

  1. Question: why not use a similar DB schema than for tasks? I mean glpi_tickettasks, glpi_problemtasks, ..., this schema is also used for followups (glpi_ticketfollowups). My opinion on this schema: this way of grouping all solutions into one unique table leads to low performances, and more complex queries than splitting into three tables, also it leads to bigger tables: more fields :), and more records in one table.
  2. I saw that during migration, date_creation and date_mod are set to current datetime instead of real datetime of the solution. and that users_id, users_id_editor and is_rejected is always set to 0:
    image
  3. If you don't want to re-build solution history, then why not use glpi_tickets which contains the latest info instead of logs
  4. of course it would be good to rebuild solution history 😃, this is complex but feasible.

regards,
Tomolimo

Contributor

tomolimo commented Oct 12, 2017

Hello @trasher,

  1. Question: why not use a similar DB schema than for tasks? I mean glpi_tickettasks, glpi_problemtasks, ..., this schema is also used for followups (glpi_ticketfollowups). My opinion on this schema: this way of grouping all solutions into one unique table leads to low performances, and more complex queries than splitting into three tables, also it leads to bigger tables: more fields :), and more records in one table.
  2. I saw that during migration, date_creation and date_mod are set to current datetime instead of real datetime of the solution. and that users_id, users_id_editor and is_rejected is always set to 0:
    image
  3. If you don't want to re-build solution history, then why not use glpi_tickets which contains the latest info instead of logs
  4. of course it would be good to rebuild solution history 😃, this is complex but feasible.

regards,
Tomolimo

@trasher

This comment has been minimized.

Show comment
Hide comment
@trasher

trasher Oct 12, 2017

Member

Hi @tomolimo ,

  1. mainly because this is more complex to manage several objects/tables than only one...
  2. I know there are some issues on the migration; this is on the todolist ;) Anyways, thanks for the details; that will help
  3. as far as I remember, I rely on informations that are used from the ticket class
  4. I do not want to plan too much queries on the logs tables... Existing ones are (in my mind) required to get all solutions informations; adding more should be a big deal :(
Member

trasher commented Oct 12, 2017

Hi @tomolimo ,

  1. mainly because this is more complex to manage several objects/tables than only one...
  2. I know there are some issues on the migration; this is on the todolist ;) Anyways, thanks for the details; that will help
  3. as far as I remember, I rely on informations that are used from the ticket class
  4. I do not want to plan too much queries on the logs tables... Existing ones are (in my mind) required to get all solutions informations; adding more should be a big deal :(
@tomolimo

This comment has been minimized.

Show comment
Hide comment
@tomolimo

tomolimo Oct 12, 2017

Contributor
  1. as far as I remember, I rely on informations that are used from the ticket class

currently info are coming from logs, and not from ticket table :)

Contributor

tomolimo commented Oct 12, 2017

  1. as far as I remember, I rely on informations that are used from the ticket class

currently info are coming from logs, and not from ticket table :)

@tomolimo

This comment has been minimized.

Show comment
Hide comment
@tomolimo

tomolimo Oct 12, 2017

Contributor
  1. mainly because this is more complex to manage several objects/tables than only one...

But to harmonize DB schema: what will be done in future?

Contributor

tomolimo commented Oct 12, 2017

  1. mainly because this is more complex to manage several objects/tables than only one...

But to harmonize DB schema: what will be done in future?

@trasher

This comment has been minimized.

Show comment
Hide comment
@trasher

trasher Oct 12, 2017

Member

currently info are coming from logs, and not from ticket table :)
Yes, informations are retrieved from logs table from ticket class.

But to harmonize DB schema: what will be done in future?
This is a good question.... I had in mind using tables with itemtype + items_id was the way to go. BTW, I'm pretty sure there are several other existing inconsistances :(

Member

trasher commented Oct 12, 2017

currently info are coming from logs, and not from ticket table :)
Yes, informations are retrieved from logs table from ticket class.

But to harmonize DB schema: what will be done in future?
This is a good question.... I had in mind using tables with itemtype + items_id was the way to go. BTW, I'm pretty sure there are several other existing inconsistances :(

@tomolimo

This comment has been minimized.

Show comment
Hide comment
@tomolimo

tomolimo Oct 12, 2017

Contributor

In order to retrieve the solution history, you may test this sql query:

select tkt.id as tickets_id, 
			IFNULL(glsolve.date_mod, tkt.solvedate) as date_begin, 
			IF( IFNULL(glansw.date_mod, tkt.closedate) is null, 1, IF( glansw.new_value = 6 or (glansw.new_value is null and tkt.closedate is not null), 3, 2)) as approval,
			IFNULL(glansw.date_mod, tkt.closedate) as date_answer, 
			SUBSTRING_INDEX(SUBSTRING_INDEX(glsolve.user_name, '(', -1), ')', 1) as users_id,  
			fup.content as approval_comment, 
			fup.users_id as users_id_approver,
			0 as solutiontemplates_id,
			IF(glsolvetype.new_value is not null, SUBSTRING_INDEX(SUBSTRING_INDEX(glsolvetype.new_value, '(', -1), ')', 1), tkt.solutiontypes_id) as solutiontypes_id,
			IFNULL(glsolve.new_value, tkt.solution) as solution
from glpi_tickets as tkt
left join glpi_logs as glsolve on glsolve.itemtype='Ticket' and glsolve.items_id=tkt.id and glsolve.id_search_option=24 
left join glpi_logs as glsolvetype on glsolvetype.itemtype='Ticket' and glsolvetype.items_id=tkt.id and glsolvetype.id_search_option=23 and glsolvetype.id = (select max(gl.id) from glpi_logs as gl where gl.itemtype='Ticket' and gl.items_id=tkt.id and gl.id_search_option=23 and gl.id < glsolve.id group by gl.items_id)
left join glpi_logs as glansw on glansw.itemtype='Ticket' and glansw.items_id=tkt.id and glansw.id_search_option=12 and glansw.old_value = 5 and glansw.id = (select min(gl.id) from glpi_logs as gl where gl.itemtype='Ticket' and gl.items_id=tkt.id and gl.id_search_option=12 and gl.old_value = 5 and gl.id > glsolve.id group by gl.items_id )
left join glpi_logs as glfup on glfup.itemtype='Ticket' and glfup.items_id=tkt.id and glfup.itemtype_link='TicketFollowup' and glfup.id = (select min(gl.id) from glpi_logs as gl where gl.itemtype='Ticket' and gl.items_id=tkt.id and gl.itemtype_link='TicketFollowup' and gl.id > glansw.id group by gl.items_id)
left join glpi_ticketfollowups as fup on fup.id=glfup.new_value
where tkt.solution is not null and tkt.solution <> ''

It will return the complete solution history.

to fill the table, you must use a REPLACE INTO, like following:

REPLACE INTO `glpi_ticketsolutions` (tickets_id, date_begin, approval, date_answer, users_id, approval_comment, users_id_approver, solutiontypes_id, solution)
(select tkt.id as tickets_id, 
			IFNULL(glsolve.date_mod, tkt.solvedate) as date_begin, 
			IF( IFNULL(glansw.date_mod, tkt.closedate) is null, 1, IF( glansw.new_value = 6 or (glansw.new_value is null and tkt.closedate is not null), 3, 2)) as approval,
			IFNULL(glansw.date_mod, tkt.closedate) as date_answer, 
			SUBSTRING_INDEX(SUBSTRING_INDEX(glsolve.user_name, '(', -1), ')', 1) as users_id,  
			fup.content as approval_comment, 
			fup.users_id as users_id_approver,
			IF(glsolvetype.new_value is not null, SUBSTRING_INDEX(SUBSTRING_INDEX(glsolvetype.new_value, '(', -1), ')', 1), tkt.solutiontypes_id) as solutiontypes_id,
			IFNULL(glsolve.new_value, tkt.solution) as solution
from glpi_tickets as tkt
left join glpi_logs as glsolve on glsolve.itemtype='Ticket' and glsolve.items_id=tkt.id and glsolve.id_search_option=24 
left join glpi_logs as glsolvetype on glsolvetype.id = (select max(gl.id) from glpi_logs as gl where gl.itemtype='Ticket' and gl.items_id=tkt.id and gl.id_search_option=23 and gl.id < glsolve.id group by gl.items_id)
left join glpi_logs as glansw on glansw.id = (select min(gl.id) from glpi_logs as gl where gl.itemtype='Ticket' and gl.items_id=tkt.id and gl.id_search_option=12 and gl.old_value = 5 and gl.id > glsolve.id group by gl.items_id )
left join glpi_logs as glfup on glfup.id = (select min(gl.id) from glpi_logs as gl where gl.itemtype='Ticket' and gl.items_id=tkt.id and gl.itemtype_link='TicketFollowup' and gl.id > glansw.id group by gl.items_id)
left join glpi_ticketfollowups as fup on fup.id=glfup.new_value
where tkt.solution is not null and tkt.solution <> '')

as you may encounter several solutions at the same datetime (several consecutive solution saves with different texts) you must use REPLACE INTO. the request will keep the latest when datetime are identical.

This request lasts about 3.8 seconds on my server test DB: tickets: 253154, followups: 538488, logs: 28M (5.8GB), and it adds 228997 solution records.

As soon as you'll have define new fields in the glpi_itilsolutions table, I'll provide you with a new request.

regards,
Tomolimo

Contributor

tomolimo commented Oct 12, 2017

In order to retrieve the solution history, you may test this sql query:

select tkt.id as tickets_id, 
			IFNULL(glsolve.date_mod, tkt.solvedate) as date_begin, 
			IF( IFNULL(glansw.date_mod, tkt.closedate) is null, 1, IF( glansw.new_value = 6 or (glansw.new_value is null and tkt.closedate is not null), 3, 2)) as approval,
			IFNULL(glansw.date_mod, tkt.closedate) as date_answer, 
			SUBSTRING_INDEX(SUBSTRING_INDEX(glsolve.user_name, '(', -1), ')', 1) as users_id,  
			fup.content as approval_comment, 
			fup.users_id as users_id_approver,
			0 as solutiontemplates_id,
			IF(glsolvetype.new_value is not null, SUBSTRING_INDEX(SUBSTRING_INDEX(glsolvetype.new_value, '(', -1), ')', 1), tkt.solutiontypes_id) as solutiontypes_id,
			IFNULL(glsolve.new_value, tkt.solution) as solution
from glpi_tickets as tkt
left join glpi_logs as glsolve on glsolve.itemtype='Ticket' and glsolve.items_id=tkt.id and glsolve.id_search_option=24 
left join glpi_logs as glsolvetype on glsolvetype.itemtype='Ticket' and glsolvetype.items_id=tkt.id and glsolvetype.id_search_option=23 and glsolvetype.id = (select max(gl.id) from glpi_logs as gl where gl.itemtype='Ticket' and gl.items_id=tkt.id and gl.id_search_option=23 and gl.id < glsolve.id group by gl.items_id)
left join glpi_logs as glansw on glansw.itemtype='Ticket' and glansw.items_id=tkt.id and glansw.id_search_option=12 and glansw.old_value = 5 and glansw.id = (select min(gl.id) from glpi_logs as gl where gl.itemtype='Ticket' and gl.items_id=tkt.id and gl.id_search_option=12 and gl.old_value = 5 and gl.id > glsolve.id group by gl.items_id )
left join glpi_logs as glfup on glfup.itemtype='Ticket' and glfup.items_id=tkt.id and glfup.itemtype_link='TicketFollowup' and glfup.id = (select min(gl.id) from glpi_logs as gl where gl.itemtype='Ticket' and gl.items_id=tkt.id and gl.itemtype_link='TicketFollowup' and gl.id > glansw.id group by gl.items_id)
left join glpi_ticketfollowups as fup on fup.id=glfup.new_value
where tkt.solution is not null and tkt.solution <> ''

It will return the complete solution history.

to fill the table, you must use a REPLACE INTO, like following:

REPLACE INTO `glpi_ticketsolutions` (tickets_id, date_begin, approval, date_answer, users_id, approval_comment, users_id_approver, solutiontypes_id, solution)
(select tkt.id as tickets_id, 
			IFNULL(glsolve.date_mod, tkt.solvedate) as date_begin, 
			IF( IFNULL(glansw.date_mod, tkt.closedate) is null, 1, IF( glansw.new_value = 6 or (glansw.new_value is null and tkt.closedate is not null), 3, 2)) as approval,
			IFNULL(glansw.date_mod, tkt.closedate) as date_answer, 
			SUBSTRING_INDEX(SUBSTRING_INDEX(glsolve.user_name, '(', -1), ')', 1) as users_id,  
			fup.content as approval_comment, 
			fup.users_id as users_id_approver,
			IF(glsolvetype.new_value is not null, SUBSTRING_INDEX(SUBSTRING_INDEX(glsolvetype.new_value, '(', -1), ')', 1), tkt.solutiontypes_id) as solutiontypes_id,
			IFNULL(glsolve.new_value, tkt.solution) as solution
from glpi_tickets as tkt
left join glpi_logs as glsolve on glsolve.itemtype='Ticket' and glsolve.items_id=tkt.id and glsolve.id_search_option=24 
left join glpi_logs as glsolvetype on glsolvetype.id = (select max(gl.id) from glpi_logs as gl where gl.itemtype='Ticket' and gl.items_id=tkt.id and gl.id_search_option=23 and gl.id < glsolve.id group by gl.items_id)
left join glpi_logs as glansw on glansw.id = (select min(gl.id) from glpi_logs as gl where gl.itemtype='Ticket' and gl.items_id=tkt.id and gl.id_search_option=12 and gl.old_value = 5 and gl.id > glsolve.id group by gl.items_id )
left join glpi_logs as glfup on glfup.id = (select min(gl.id) from glpi_logs as gl where gl.itemtype='Ticket' and gl.items_id=tkt.id and gl.itemtype_link='TicketFollowup' and gl.id > glansw.id group by gl.items_id)
left join glpi_ticketfollowups as fup on fup.id=glfup.new_value
where tkt.solution is not null and tkt.solution <> '')

as you may encounter several solutions at the same datetime (several consecutive solution saves with different texts) you must use REPLACE INTO. the request will keep the latest when datetime are identical.

This request lasts about 3.8 seconds on my server test DB: tickets: 253154, followups: 538488, logs: 28M (5.8GB), and it adds 228997 solution records.

As soon as you'll have define new fields in the glpi_itilsolutions table, I'll provide you with a new request.

regards,
Tomolimo

@trasher

This comment has been minimized.

Show comment
Hide comment
@trasher

trasher Oct 12, 2017

Member

Great, thank you :)

Member

trasher commented Oct 12, 2017

Great, thank you :)

@tomolimo

This comment has been minimized.

Show comment
Hide comment
@tomolimo

tomolimo Oct 16, 2017

Contributor

New version for Ticket solution history migration:

SELECT 'Ticket' AS itemtype,
		                  obj.`id` AS items_id,
			               IFNULL(glsolve.`date_mod`, obj.`solvedate`) AS date_creation,
			               SUBSTRING_INDEX(SUBSTRING_INDEX(glsolve.`user_name`, '(', -1), ')', 1) AS users_id,
			               IF(glsolvetype.`new_value` IS NOT NULL, SUBSTRING_INDEX(SUBSTRING_INDEX(glsolvetype.`new_value`, '(', -1), ')', 1), obj.`solutiontypes_id`) AS solutiontypes_id,
			               IFNULL(glcontent.`new_value`, obj.`solution`) AS content,
			               IF( IFNULL(glansw.`date_mod`, obj.`closedate`) IS NULL, 1, IF( glansw.`new_value` = 6 OR (glansw.`new_value` IS NULL AND obj.`closedate` IS NOT NULL), 3, 2)) AS approval,
			               IFNULL(glansw.`date_mod`, obj.`closedate`) AS date_mod,
			               fup.`id` AS 'ticketfollowups_id', fup.`users_id` AS users_id_editor
                     FROM glpi_tickets AS obj
                     LEFT JOIN `glpi_logs` AS glsolve ON glsolve.`itemtype` = 'Ticket' AND glsolve.`items_id` = obj.`id` AND glsolve.`id_search_option` = 12 AND glsolve.`new_value` = 5
                     LEFT JOIN `glpi_logs` AS glsolvetype ON glsolvetype.`itemtype` = 'Ticket' AND glsolvetype.`items_id` = obj.`id` AND glsolvetype.`id_search_option` = 23 AND glsolvetype.`date_mod` = glsolve.`date_mod`
                     LEFT JOIN `glpi_logs` AS glcontent ON  glcontent.`id` = (SELECT MAX(gl.`id`) FROM `glpi_logs` AS gl WHERE gl.`itemtype`='Ticket' AND gl.`items_id` = obj.`id` AND gl.`id_search_option` = 24 AND gl.`id` < glsolve.`id` GROUP BY gl.`items_id`)
                     LEFT JOIN `glpi_logs` AS glansw ON glansw.`id` = (SELECT MIN(gl.`id`) FROM `glpi_logs` AS gl WHERE gl.`itemtype`='Ticket' AND gl.`items_id` = obj.`id` AND gl.`id_search_option` = 12 AND gl.`old_value` = 5 AND gl.`id` > glsolve.`id` GROUP BY gl.`items_id`)
                     LEFT JOIN `glpi_logs` AS glfup ON glfup.`itemtype` = 'Ticket' AND glfup.`items_id` = obj.`id` AND glfup.`itemtype_link`='TicketFollowup' AND glfup.`date_mod` = glansw.`date_mod`
                                 LEFT JOIN `glpi_ticketfollowups` AS fup ON fup.`id`=glfup.`new_value`
                     WHERE obj.`solution` IS NOT NULL AND obj.`solution` <> ''

regards,
Tomolimo

Contributor

tomolimo commented Oct 16, 2017

New version for Ticket solution history migration:

SELECT 'Ticket' AS itemtype,
		                  obj.`id` AS items_id,
			               IFNULL(glsolve.`date_mod`, obj.`solvedate`) AS date_creation,
			               SUBSTRING_INDEX(SUBSTRING_INDEX(glsolve.`user_name`, '(', -1), ')', 1) AS users_id,
			               IF(glsolvetype.`new_value` IS NOT NULL, SUBSTRING_INDEX(SUBSTRING_INDEX(glsolvetype.`new_value`, '(', -1), ')', 1), obj.`solutiontypes_id`) AS solutiontypes_id,
			               IFNULL(glcontent.`new_value`, obj.`solution`) AS content,
			               IF( IFNULL(glansw.`date_mod`, obj.`closedate`) IS NULL, 1, IF( glansw.`new_value` = 6 OR (glansw.`new_value` IS NULL AND obj.`closedate` IS NOT NULL), 3, 2)) AS approval,
			               IFNULL(glansw.`date_mod`, obj.`closedate`) AS date_mod,
			               fup.`id` AS 'ticketfollowups_id', fup.`users_id` AS users_id_editor
                     FROM glpi_tickets AS obj
                     LEFT JOIN `glpi_logs` AS glsolve ON glsolve.`itemtype` = 'Ticket' AND glsolve.`items_id` = obj.`id` AND glsolve.`id_search_option` = 12 AND glsolve.`new_value` = 5
                     LEFT JOIN `glpi_logs` AS glsolvetype ON glsolvetype.`itemtype` = 'Ticket' AND glsolvetype.`items_id` = obj.`id` AND glsolvetype.`id_search_option` = 23 AND glsolvetype.`date_mod` = glsolve.`date_mod`
                     LEFT JOIN `glpi_logs` AS glcontent ON  glcontent.`id` = (SELECT MAX(gl.`id`) FROM `glpi_logs` AS gl WHERE gl.`itemtype`='Ticket' AND gl.`items_id` = obj.`id` AND gl.`id_search_option` = 24 AND gl.`id` < glsolve.`id` GROUP BY gl.`items_id`)
                     LEFT JOIN `glpi_logs` AS glansw ON glansw.`id` = (SELECT MIN(gl.`id`) FROM `glpi_logs` AS gl WHERE gl.`itemtype`='Ticket' AND gl.`items_id` = obj.`id` AND gl.`id_search_option` = 12 AND gl.`old_value` = 5 AND gl.`id` > glsolve.`id` GROUP BY gl.`items_id`)
                     LEFT JOIN `glpi_logs` AS glfup ON glfup.`itemtype` = 'Ticket' AND glfup.`items_id` = obj.`id` AND glfup.`itemtype_link`='TicketFollowup' AND glfup.`date_mod` = glansw.`date_mod`
                                 LEFT JOIN `glpi_ticketfollowups` AS fup ON fup.`id`=glfup.`new_value`
                     WHERE obj.`solution` IS NOT NULL AND obj.`solution` <> ''

regards,
Tomolimo

@tomolimo

This comment has been minimized.

Show comment
Hide comment
@tomolimo

tomolimo Oct 16, 2017

Contributor

Basic request which uses most of solution info from tickets table and does not retrieve solution history:

REPLACE INTO `glpi_itilsolutions` (`itemtype`, `items_id`, `date_creation`, `users_id`, `solutiontypes_id`, `content`, `approval`, `date_mod`, `ticketfollowups_id`, `users_id_editor`)
                     (SELECT 'Ticket' AS itemtype,
		                 obj.`id` AS items_id,
			               obj.`solvedate` AS date_creation,
			               SUBSTRING_INDEX(SUBSTRING_INDEX(glsolve.`user_name`, '(', -1), ')', 1) AS users_id,
			               obj.`solutiontypes_id` AS solutiontypes_id,
			               obj.`solution` AS content,
			               IF( obj.`closedate` IS NULL, 1, 3) AS approval,
			               obj.`closedate` AS date_mod,
			               fup.`id` AS 'ticketfollowups_id', 
										 SUBSTRING_INDEX(SUBSTRING_INDEX(glfup.`user_name`, '(', -1), ')', 1) AS users_id_editor
                     FROM glpi_tickets AS obj
                     LEFT JOIN `glpi_logs` AS glsolve ON glsolve.`itemtype` = 'Ticket' AND glsolve.`items_id` = obj.`id` AND glsolve.`id_search_option` = 12 AND glsolve.date_mod = obj.`solvedate`
                     LEFT JOIN `glpi_logs` AS glfup ON glfup.`itemtype` = 'Ticket' AND glfup.`items_id` = obj.`id` AND glfup.`itemtype_link`='TicketFollowup' AND glfup.`date_mod` = obj.`closedate`
                     LEFT JOIN `glpi_ticketfollowups` AS fup ON fup.`id`=glfup.`new_value`
                     WHERE obj.`solvedate` IS NOT NULL 
                  )

regards
Tomolimo

Contributor

tomolimo commented Oct 16, 2017

Basic request which uses most of solution info from tickets table and does not retrieve solution history:

REPLACE INTO `glpi_itilsolutions` (`itemtype`, `items_id`, `date_creation`, `users_id`, `solutiontypes_id`, `content`, `approval`, `date_mod`, `ticketfollowups_id`, `users_id_editor`)
                     (SELECT 'Ticket' AS itemtype,
		                 obj.`id` AS items_id,
			               obj.`solvedate` AS date_creation,
			               SUBSTRING_INDEX(SUBSTRING_INDEX(glsolve.`user_name`, '(', -1), ')', 1) AS users_id,
			               obj.`solutiontypes_id` AS solutiontypes_id,
			               obj.`solution` AS content,
			               IF( obj.`closedate` IS NULL, 1, 3) AS approval,
			               obj.`closedate` AS date_mod,
			               fup.`id` AS 'ticketfollowups_id', 
										 SUBSTRING_INDEX(SUBSTRING_INDEX(glfup.`user_name`, '(', -1), ')', 1) AS users_id_editor
                     FROM glpi_tickets AS obj
                     LEFT JOIN `glpi_logs` AS glsolve ON glsolve.`itemtype` = 'Ticket' AND glsolve.`items_id` = obj.`id` AND glsolve.`id_search_option` = 12 AND glsolve.date_mod = obj.`solvedate`
                     LEFT JOIN `glpi_logs` AS glfup ON glfup.`itemtype` = 'Ticket' AND glfup.`items_id` = obj.`id` AND glfup.`itemtype_link`='TicketFollowup' AND glfup.`date_mod` = obj.`closedate`
                     LEFT JOIN `glpi_ticketfollowups` AS fup ON fup.`id`=glfup.`new_value`
                     WHERE obj.`solvedate` IS NOT NULL 
                  )

regards
Tomolimo

@tomolimo

This comment has been minimized.

Show comment
Hide comment
@tomolimo

tomolimo Oct 17, 2017

Contributor

Hello,

Here is the latest version of the basic request :

REPLACE INTO `glpi_itilsolutions` (`itemtype`, `items_id`, `date_creation`, `users_id`, `solutiontypes_id`, `content`, `approval`, `date_mod`, `ticketfollowups_id`, `users_id_editor`)
                     (SELECT DISTINCT 'Ticket' AS itemtype,
		                 obj.`id` AS items_id,
			               obj.`solvedate` AS date_creation,
			               SUBSTRING_INDEX(SUBSTRING_INDEX(glsolve.`user_name`, '(', -1), ')', 1) AS users_id,
			               obj.`solutiontypes_id` AS solutiontypes_id,
			               obj.`solution` AS content,
			               IF(obj.`closedate` IS NULL, 1, 3) AS approval,
			               obj.`closedate` AS date_mod,
			               fup.`id` AS 'ticketfollowups_id', 
										 SUBSTRING_INDEX(SUBSTRING_INDEX(glfup.`user_name`, '(', -1), ')', 1) AS users_id_editor
                     FROM glpi_tickets AS obj
                     LEFT JOIN `glpi_logs` AS glsolve ON glsolve.`itemtype` = 'Ticket' AND glsolve.`items_id` = obj.`id` AND (glsolve.`id_search_option` = 12 OR glsolve.`id_search_option` =  24) AND glsolve.`date_mod` = obj.`solvedate`
                     LEFT JOIN `glpi_logs` AS glfup ON glfup.`itemtype` = 'Ticket' AND glfup.`items_id` = obj.`id` AND glfup.`itemtype_link`='TicketFollowup' AND glfup.`date_mod` = obj.`closedate`
                     LEFT JOIN `glpi_ticketfollowups` AS fup ON fup.`id`=glfup.`new_value`
                     WHERE obj.`solvedate` IS NOT NULL 
                     )

regards
Tomolimo

Contributor

tomolimo commented Oct 17, 2017

Hello,

Here is the latest version of the basic request :

REPLACE INTO `glpi_itilsolutions` (`itemtype`, `items_id`, `date_creation`, `users_id`, `solutiontypes_id`, `content`, `approval`, `date_mod`, `ticketfollowups_id`, `users_id_editor`)
                     (SELECT DISTINCT 'Ticket' AS itemtype,
		                 obj.`id` AS items_id,
			               obj.`solvedate` AS date_creation,
			               SUBSTRING_INDEX(SUBSTRING_INDEX(glsolve.`user_name`, '(', -1), ')', 1) AS users_id,
			               obj.`solutiontypes_id` AS solutiontypes_id,
			               obj.`solution` AS content,
			               IF(obj.`closedate` IS NULL, 1, 3) AS approval,
			               obj.`closedate` AS date_mod,
			               fup.`id` AS 'ticketfollowups_id', 
										 SUBSTRING_INDEX(SUBSTRING_INDEX(glfup.`user_name`, '(', -1), ')', 1) AS users_id_editor
                     FROM glpi_tickets AS obj
                     LEFT JOIN `glpi_logs` AS glsolve ON glsolve.`itemtype` = 'Ticket' AND glsolve.`items_id` = obj.`id` AND (glsolve.`id_search_option` = 12 OR glsolve.`id_search_option` =  24) AND glsolve.`date_mod` = obj.`solvedate`
                     LEFT JOIN `glpi_logs` AS glfup ON glfup.`itemtype` = 'Ticket' AND glfup.`items_id` = obj.`id` AND glfup.`itemtype_link`='TicketFollowup' AND glfup.`date_mod` = obj.`closedate`
                     LEFT JOIN `glpi_ticketfollowups` AS fup ON fup.`id`=glfup.`new_value`
                     WHERE obj.`solvedate` IS NOT NULL 
                     )

regards
Tomolimo

@tomolimo

This comment has been minimized.

Show comment
Hide comment
@tomolimo

tomolimo Oct 17, 2017

Contributor

Hello,

Complete SQL request with solution history and names when id can't be extracted from names (logs not normalized):

REPLACE INTO `glpi_itilsolutions` (`itemtype`, `items_id`, `date_creation`, `users_id`, `user_name`, `solutiontypes_id`, `solutiontype_name`, `content`, `approval`, `date_mod`, `ticketfollowups_id`, `users_id_editor`, `user_name_editor` )
					(SELECT 'Ticket' AS itemtype,
		                obj.`id` AS items_id,
			               IFNULL(glsolve.`date_mod`, obj.`solvedate`) AS date_creation,			               
			               IF(glsolve.user_name REGEXP '\\([0-9]+\\)$', SUBSTRING_INDEX(SUBSTRING_INDEX(glsolve.`user_name`, '(', -1), ')', 1), NULL) AS users_id,
			               IF(glsolve.user_name REGEXP '\\([0-9]+\\)$', NULL, glsolve.`user_name`) AS user_name,
			               IF(glsolvetype.`new_value` REGEXP '\\([0-9]+\\)$', SUBSTRING_INDEX(SUBSTRING_INDEX(glsolvetype.`new_value`, '(', -1), ')', 1), NULL) AS solutiontypes_id,
			               IF(glsolvetype.`new_value` REGEXP '\\([0-9]+\\)$', NULL, glsolvetype.`new_value`) AS solutiontype_name,
			               IFNULL(glcontent.`new_value`, obj.`solution`) AS content,
			               IF( IFNULL(glansw.`date_mod`, obj.`closedate`) IS NULL, 1, IF( glansw.`new_value` = 6 OR (glansw.`new_value` IS NULL AND obj.`closedate` IS NOT NULL), 3, 2)) AS approval,
			               IFNULL(glansw.`date_mod`, obj.`closedate`) AS date_mod,
			               fup.`id` AS 'ticketfollowups_id', 
										 IF(glansw.`user_name` REGEXP '\\([0-9]+\\)$', SUBSTRING_INDEX(SUBSTRING_INDEX(glansw.`user_name`, '(', -1), ')', 1), NULL) AS users_id_editor,
										 IF(glansw.`user_name` REGEXP '\\([0-9]+\\)$', NULL, glansw.`user_name`) AS user_name_editor
                     FROM glpi_tickets AS obj
                     LEFT JOIN `glpi_logs` AS glsolve ON glsolve.`itemtype` = 'Ticket' AND glsolve.`items_id` = obj.`id` AND glsolve.`id_search_option` = 12 AND glsolve.`new_value` = 5
                     LEFT JOIN `glpi_logs` AS glsolvetype ON glsolvetype.id = (select max(gl.id) from glpi_logs as gl where gl.itemtype='Ticket' and gl.items_id=obj.id and gl.id_search_option=23 and gl.id < glsolve.id group by gl.items_id)
                     LEFT JOIN `glpi_logs` AS glcontent ON  glcontent.`id` = (SELECT MAX(gl.`id`) FROM `glpi_logs` AS gl WHERE gl.`itemtype`='Ticket' AND gl.`items_id` = obj.`id` AND gl.`id_search_option` = 24 AND gl.`id` < glsolve.`id` GROUP BY gl.`items_id`)
                     LEFT JOIN `glpi_logs` AS glansw ON glansw.`id` = (SELECT MIN(gl.`id`) FROM `glpi_logs` AS gl WHERE gl.`itemtype`='Ticket' AND gl.`items_id` = obj.`id` AND gl.`id_search_option` = 12 AND gl.`old_value` = 5 AND gl.`id` > glsolve.`id` GROUP BY gl.`items_id`)
                     LEFT JOIN `glpi_logs` AS glfup ON glfup.id = (select min(gl.id) from glpi_logs as gl where gl.itemtype='Ticket' and gl.items_id=obj.id and gl.itemtype_link='TicketFollowup' and gl.id > glansw.id group by gl.items_id)
                     LEFT JOIN `glpi_ticketfollowups` AS fup ON fup.`id`=glfup.`new_value`
                     WHERE obj.`solution` IS NOT NULL 
                     )

Three new columns need to be created:

`solutiontype_name` VARCHAR(255) NULL,
`user_name` VARCHAR(255) NULL,
`user_name_editor` VARCHAR(255) NULL,

regards,
Tomolimo

Contributor

tomolimo commented Oct 17, 2017

Hello,

Complete SQL request with solution history and names when id can't be extracted from names (logs not normalized):

REPLACE INTO `glpi_itilsolutions` (`itemtype`, `items_id`, `date_creation`, `users_id`, `user_name`, `solutiontypes_id`, `solutiontype_name`, `content`, `approval`, `date_mod`, `ticketfollowups_id`, `users_id_editor`, `user_name_editor` )
					(SELECT 'Ticket' AS itemtype,
		                obj.`id` AS items_id,
			               IFNULL(glsolve.`date_mod`, obj.`solvedate`) AS date_creation,			               
			               IF(glsolve.user_name REGEXP '\\([0-9]+\\)$', SUBSTRING_INDEX(SUBSTRING_INDEX(glsolve.`user_name`, '(', -1), ')', 1), NULL) AS users_id,
			               IF(glsolve.user_name REGEXP '\\([0-9]+\\)$', NULL, glsolve.`user_name`) AS user_name,
			               IF(glsolvetype.`new_value` REGEXP '\\([0-9]+\\)$', SUBSTRING_INDEX(SUBSTRING_INDEX(glsolvetype.`new_value`, '(', -1), ')', 1), NULL) AS solutiontypes_id,
			               IF(glsolvetype.`new_value` REGEXP '\\([0-9]+\\)$', NULL, glsolvetype.`new_value`) AS solutiontype_name,
			               IFNULL(glcontent.`new_value`, obj.`solution`) AS content,
			               IF( IFNULL(glansw.`date_mod`, obj.`closedate`) IS NULL, 1, IF( glansw.`new_value` = 6 OR (glansw.`new_value` IS NULL AND obj.`closedate` IS NOT NULL), 3, 2)) AS approval,
			               IFNULL(glansw.`date_mod`, obj.`closedate`) AS date_mod,
			               fup.`id` AS 'ticketfollowups_id', 
										 IF(glansw.`user_name` REGEXP '\\([0-9]+\\)$', SUBSTRING_INDEX(SUBSTRING_INDEX(glansw.`user_name`, '(', -1), ')', 1), NULL) AS users_id_editor,
										 IF(glansw.`user_name` REGEXP '\\([0-9]+\\)$', NULL, glansw.`user_name`) AS user_name_editor
                     FROM glpi_tickets AS obj
                     LEFT JOIN `glpi_logs` AS glsolve ON glsolve.`itemtype` = 'Ticket' AND glsolve.`items_id` = obj.`id` AND glsolve.`id_search_option` = 12 AND glsolve.`new_value` = 5
                     LEFT JOIN `glpi_logs` AS glsolvetype ON glsolvetype.id = (select max(gl.id) from glpi_logs as gl where gl.itemtype='Ticket' and gl.items_id=obj.id and gl.id_search_option=23 and gl.id < glsolve.id group by gl.items_id)
                     LEFT JOIN `glpi_logs` AS glcontent ON  glcontent.`id` = (SELECT MAX(gl.`id`) FROM `glpi_logs` AS gl WHERE gl.`itemtype`='Ticket' AND gl.`items_id` = obj.`id` AND gl.`id_search_option` = 24 AND gl.`id` < glsolve.`id` GROUP BY gl.`items_id`)
                     LEFT JOIN `glpi_logs` AS glansw ON glansw.`id` = (SELECT MIN(gl.`id`) FROM `glpi_logs` AS gl WHERE gl.`itemtype`='Ticket' AND gl.`items_id` = obj.`id` AND gl.`id_search_option` = 12 AND gl.`old_value` = 5 AND gl.`id` > glsolve.`id` GROUP BY gl.`items_id`)
                     LEFT JOIN `glpi_logs` AS glfup ON glfup.id = (select min(gl.id) from glpi_logs as gl where gl.itemtype='Ticket' and gl.items_id=obj.id and gl.itemtype_link='TicketFollowup' and gl.id > glansw.id group by gl.items_id)
                     LEFT JOIN `glpi_ticketfollowups` AS fup ON fup.`id`=glfup.`new_value`
                     WHERE obj.`solution` IS NOT NULL 
                     )

Three new columns need to be created:

`solutiontype_name` VARCHAR(255) NULL,
`user_name` VARCHAR(255) NULL,
`user_name_editor` VARCHAR(255) NULL,

regards,
Tomolimo

@trasher

This comment has been minimized.

Show comment
Hide comment
@trasher

trasher Nov 7, 2017

Member

Issue spotted: when reopening a ticket; the solution is not set as rejected as it should.

Member

trasher commented Nov 7, 2017

Issue spotted: when reopening a ticket; the solution is not set as rejected as it should.

@trasher trasher removed the wip label Nov 8, 2017

@trasher trasher requested a review from orthagh Nov 8, 2017

@orthagh

orthagh approved these changes Dec 4, 2017

Rework solutions; fixes #2089
Add solution object, form, add solution from ticket timeline
Set solved adding solution, set solution rejected on status change
Add schema and migration script for solutions (thanks to @tomolimo)
Visual distinction beetween accepted and rejected solution
Add ComonITILObject::maySolve() similar to canSolve() but not checking actuel status
Add unit tests
Use unicity on table for migration only
Drop images on solutions background and use fa instead
Do not rely only on ticket
Rework display in tab (looks like timeline)
Add approval form on solutions tab; invert approval buttons

@trasher trasher merged commit 2e99b65 into glpi-project:master Dec 4, 2017

1 check passed

continuous-integration/travis-ci/pr The Travis CI build passed
Details

@trasher trasher deleted the trasher:feature/solutions branch Dec 4, 2017

@Armin83

This comment has been minimized.

Show comment
Hide comment
@Armin83

Armin83 Sep 7, 2018

Only visually, but still not removed in the project roadmap view

Armin83 commented Sep 7, 2018

Only visually, but still not removed in the project roadmap view

@orthagh orthagh moved this from Next major version to Done in Project Roadmap Sep 10, 2018

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment