Query di assegnazioni obsolete

Una volta che inizi ad assegnare argomenti, inevitabilmente finisci con assegnazioni obsolete.

Abbiamo deciso di trovarle.

Ecco la query nel caso sia utile ad altri.
Ci sono 2 sotto-query da personalizzare:

  • SonarSourcers (non chiedermi perché non abbiamo semplicemente usato ‘staff’)
  • teams
-- obiettivo: mostrare assegnazioni obsolete,
--    dove obsoleto significa 7 giorni dall'assegnazione senza attività pubblica / post 'regolari' da SonarSourcers
--    e un post di un SonarSourcer non è l'ultimo post


WITH

-- trova tutti gli argomenti assegnati
assigned_topics AS (
    SELECT a.topic_id
        , assigned_to_type
        , assigned_to_id
    FROM assignments a
    JOIN topics t ON a.topic_id = t.id
    JOIN posts p on p.topic_id = t.id
    LEFT JOIN post_custom_fields pcf ON pcf.post_id=p.id AND pcf.name='is_accepted_answer'
    WHERE active = true
        AND a.updated_at < current_date - INTEGER '7'
        AND t.closed = false
        AND pcf.id IS NULL
--        AND a.updated_at > '2022-01-01'
    ORDER BY t.updated_at desc
),

-- per ogni argomento assegnato, trova l'ULTIMA assegnazione (potrebbero essercene più di una)
last_assignment AS (
    SELECT max(p.post_number) AS assignment_post, p.topic_id, max(p.created_at) as d
    FROM posts p
    JOIN assigned_topics ON p.topic_id=assigned_topics.topic_id
    WHERE p.action_code in ('assigned', 'assigned_group', 'assigned_group_to_post', 'assigned_to_post')
    GROUP BY p.topic_id, p.created_at
),

-- trova gli utenti che lavorano per l'azienda
SonarSourcers AS (
    SELECT u.id AS user_id
    FROM groups g
    INNER JOIN group_users gu ON g.id=gu.group_id
    INNER JOIN users u ON u.id = gu.user_id
    WHERE g.name='sonarsourcers'
),

-- trova il team principale di ogni persona
teams AS (
    SELECT distinct on (user_id) -- alcuni utenti hanno 2 gruppi. restringi (arbitrariamente) a 1
        ss.user_id, g.id as group_id
    FROM SonarSourcers ss
    JOIN group_users gu on gu.user_id=ss.user_id
    JOIN groups g on g.id = gu.group_id
    WHERE -- elimina alcuni gruppi duplicati
                 g.id not in (10, 11, 12, 13, 14 -- gruppi di livello di fiducia
                    , 1, 2, 3 -- gruppi predefiniti
                    , 41 -- SonarSourcers
                    , 47 -- SonarCloud - vogliamo invece gli squad
                    , 53 -- .NET Scanner Guild
                    )
),

-- trova l'ultimo post in un argomento assegnato da un SonarSourcer
last_staff_post AS (
    SELECT p.id AS post
        , p.topic_id
        , max(p.created_at) AS last_staff_post
        , la.d AS last_assignment_date
    FROM posts p
    JOIN last_assignment la ON p.topic_id=la.topic_id
    JOIN SonarSourcers ss ON ss.user_id=p.user_id
    WHERE post_type = 1 -- regolare
    GROUP BY p.topic_id, p.id,la.d
),

-- trova l'ultimo post pubblico in assoluto nell'argomento
last_post AS (
    SELECT p.topic_id as topic_id, max(p.id) as post_id
    FROM posts p
    JOIN assigned_topics at ON at.topic_id = p.topic_id
    JOIN users u ON p.user_id=u.id
    WHERE post_type = 1 -- regolare
    GROUP BY p.topic_id
),

-- elimina i post dei SonarSourcers dall'elenco degli ultimi post per eliminare gli argomenti
-- dove stiamo chiaramente aspettando l'utente
last_post_trust_level_limit AS (
    SELECT lp.topic_id
    FROM users u
    JOIN posts p ON u.id=p.user_id
    JOIN last_post lp ON p.id = lp.post_id
    WHERE u.trust_level < 4
),

-- metti tutto insieme
stale_topics AS (
    SELECT lsp.topic_id
        , max(lsp.last_assignment_date) as "Assignment date"
        , max(lsp.last_staff_post) as "Last Staff Post"
        , CASE WHEN at.assigned_to_type = 'User'  THEN u.id END AS user_id
        , CASE WHEN at.assigned_to_type = 'Group' THEN g.id ELSE teams.group_id END AS group_id
    FROM last_staff_post lsp
    JOIN assigned_topics at ON lsp.topic_id=at.topic_id
    JOIN last_post_trust_level_limit lptll ON lsp.topic_id = lptll.topic_id
    FULL OUTER JOIN users u ON assigned_to_id=u.id
    FULL OUTER JOIN teams on teams.user_id=u.id
    FULL OUTER JOIN groups g ON assigned_to_id=g.id
    WHERE lsp.last_staff_post <= lsp.last_assignment_date + interval '7 days'
    GROUP BY at.assigned_to_id, lsp.topic_id, at.assigned_to_type, u.id, g.id, teams.group_id
)

SELECT count(topic_id), user_id, group_id
FROM stale_topics
GROUP BY user_id, group_id
ORDER BY group_id
3 Mi Piace

Nel nostro modello, assegniamo ai team e i team assegnano ai membri (o ai sotto-team).

Vediamo come stanno andando i team in termini di triage iniziale e riassegnazione:

-- obiettivo: trovare il tempo dall'assegnazione al gruppo
--    alla riassegnazione al sotto-team / SonarSourcer

-- [parametri]
-- data :start_date = 2022-10-01

WITH

-- trova l'ultima assegnazione di gruppo nel thread
group_assignment AS (
    SELECT max(p.post_number) AS assignment_post, p.topic_id --, max(p.created_at) as d
    FROM posts p
    WHERE p.action_code in ('assigned_group', 'assigned_group_to_post')
        AND p.created_at >= :start_date
    GROUP BY p.topic_id
),

-- ottieni i dettagli del post di assegnazione
group_assignment_deets AS (
    SELECT p.id as post_id, p.created_at as d, p.topic_id, pcf.value as who
    FROM posts p
    JOIN group_assignment ga on ga.topic_id=p.topic_id
        AND p.post_number = ga.assignment_post
    JOIN post_custom_fields pcf ON pcf.post_id = p.id
    WHERE pcf.name = 'action_code_who'

),

-- trova la riassegnazione avvenuta dopo l'assegnazione al gruppo
next_assignment AS (
    SELECT min(p.post_number) AS assignment_post, p.topic_id --, min(p.created_at) as d
    FROM posts p
    JOIN group_assignment ga on ga.topic_id=p.topic_id
    WHERE p.action_code in ('assigned', 'assigned_to_post', 'reassigned_group', 'reassigned')
        AND p.post_number > ga.assignment_post
    GROUP BY p.topic_id
),

-- ottieni i dettagli del post di assegnazione
next_assignment_deets AS (
    SELECT p.id as post_id, p.created_at as d, p.topic_id, pcf.value as who
    FROM posts p
    JOIN next_assignment na ON na.topic_id=p.topic_id
        AND p.post_number = na.assignment_post
    JOIN post_custom_fields pcf ON pcf.post_id = p.id
    WHERE pcf.name = 'action_code_who'
),

-- calcola i giorni per la riassegnazione per ogni thread
days_per_team AS (
    SELECT gad.who as team
        , extract(epoch from (nad.d - gad.d)/86400) as days
    FROM group_assignment_deets gad
    JOIN next_assignment_deets nad using(topic_id)
)

SELECT
    team as "Team"
    , count(*) as "Thread count"
    , round(avg(days)::numeric,2) as "Avg days to reassignment"
    , round(max(days)::numeric,2) as "Max"
    , round(min(days)::numeric,6) as "Min"
FROM days_per_team
GROUP BY team
ORDER BY "Thread count" desc

Nota che non c’è nulla da personalizzare in questo; dovrebbe “funzionare” per tutti.

2 Mi Piace