metadata.yaml 18 KB
Newer Older
1
2
3
4
5
6
7
8
9
10
11
title: Datasette Data³ Demo
about: Data³
about_url: https://www.mediawiki.org/wiki/Data%C2%B3
description_html: |-
  Try it out at <a href="/-/dashboards">/-/dashboards</a>
plugins:
  datasette-dashboards:
    project-metrics:
      title: Data³ - workflow metrics
      description: Metrics about projects, tasks and workflows
      layout:
20after4's avatar
20after4 committed
12
13
14
15
16
17
18
19
      - [ project-navigation]
      - [ project-columns ]
      - [ all_events ]
      - [ column-metrics ]
      - [ waterfall ]
      - [ project-tasks-state ]
      - [ task-states ]

20
21
22
23
      filters:
        project:
          name: Project
          type: select
20after4's avatar
20after4 committed
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
          query:
              WITH project_events as (
              SELECT * FROM (
                SELECT
                  DISTINCT project,
                  count(*) AS cnt
                FROM
                  events e
                WHERE
                  e.project LIKE "PHID%"
                GROUP BY
                  project
                ORDER BY cnt desc
                LIMIT 150
              )
            )
            SELECT
              p.phid AS key,
              p.name AS label,
              p.slug AS slug,
              p.uri as uri
            FROM Project p
            JOIN project_events e
              ON e.project=p.phid
            WHERE p.depth<2 and not p.name like 'acl*%'
            ORDER BY label
50
51
52
53
54
55
56
57
58
59
60
        task:
          name: Task ID
          type: text
        date_start:
          name: Date Start
          type: date
          default: '2021-01-01'
        date_end:
          name: Date End
          type: date
      charts:
20after4's avatar
20after4 committed
61
62
        project-navigation:
          title: Projects
63
          db: metrics
20after4's avatar
20after4 committed
64
65
66
67
68
          query: project_tree
          library: jinja
          template: subprojects.html
          visible-when: :project
        project-columns:
69
          db: metrics
20after4's avatar
20after4 committed
70
71
72
73
74
75
76
77
78
79
          query: |-
            select
             c.*,
             p.status as projectStatus,
             p.uri as projectURI
            FROM ProjectColumn c
            LEFT JOIN Project p on c.proxyPHID=p.phid where c.project=:project and c.status=0 and p.status != 'closed'
          library: jinja
          template: project_columns.html
          visible-when: :project
80
81
82
83
84
85
86
87
88
89
        column-metrics:
          title: Tasks per column
          db: metrics
          query:
            select
              *
            from
              (
                SELECT
                  printf('T%u', c.task) AS task,
20after4's avatar
20after4 committed
90
                  datetime(c.ts, 'unixepoch') as ts,
91
92
93
94
                  date(c.ts, 'unixepoch', 'start of month') as month,
                  date(
                    c.ts,
                    'unixepoch',
20after4's avatar
20after4 committed
95
                    'weekday 1'
96
97
98
99
100
101
102
103
104
                  ) as week,
                  p.column_phid as column_phid,
                  p.column_name AS column_name,
                  p.project_phid as project_phid,
                  p.project_name as project_name,
                  p.project_name||':'||p.column_name AS qualified_name,
                  p.status as column_hidden,
                  c.value as value,
                  sum(c.value) over (partition by column_phid order by ts RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW) as total_tasks
20after4's avatar
20after4 committed
105

106
107
108
                FROM
                  column_metrics c
                  join columns p on c.column = p.column_phid
20after4's avatar
20after4 committed
109
110
                WHERE  project_phid=:project
                order by ts
111
112
113
              )
            where
              column_hidden = 0
20after4's avatar
20after4 committed
114
              AND total_tasks > 0
115
              [[ AND project_phid=:project ]]
20after4's avatar
20after4 committed
116
117
              [[ AND ts >= date(:date_start) ]]
              [[ AND ts <= date(:date_end) ]]
118
119
          library: vega
          display:
20after4's avatar
20after4 committed
120
121
122
123
124
            mark:
              type: area
              tooltip: true
              baseline: bottom
              line: true
125
            encoding:
20after4's avatar
20after4 committed
126
127
128
129
130
131
132
133
134
135
136
137
138
              y:
                field: total_tasks
                type: quantitative
                aggregate: median
              x:
                field: week
                type: temporal
                timeunit: month
              color:
                field: column_name
                type: nominal
                scale:
                  scheme: "category20b"
139
        task-states:
20after4's avatar
20after4 committed
140
          title: Task States
141
142
143
          db: metrics
          query:
            SELECT
20after4's avatar
20after4 committed
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
              task,
              '/metrics/Task?_sort=phid&id__exact='||task as url,
              t.name,
              state,
              metric,
              duration,
              datetime(ts, 'unixepoch') as start,
              datetime(ts2, 'unixepoch') as end
            FROM
              task_metrics m
              left join task t on m.task = t.id
            where TRUE
               [[ AND metric=:project ]]
               AND (
                  [[ end > :date_start ]]
                  [[ AND end < :date_end ]]
                  ) OR (
                  [[ start > :date_start ]]
                  [[ AND start < :date_end ]]
                  )
164
            ORDER BY
20after4's avatar
20after4 committed
165
              task, start, end
166
167
          library: vega
          display:
20after4's avatar
20after4 committed
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
            height: { step: 30 }
            encoding: {
              x: {
                    field: start,
                    type: temporal,
                    timeUnit: day
              },
              x2: { field: end },
            }
            layer: [
              {
                mark: {
                  type: bar,
                  tooltip: true,
                  clip: true,
                  stroke: { value: 'black' },
                  opacity: 1
                },
                encoding:
                {
                  y: { field: task, type: nominal },
                  description: { field: name, type: nominal },
                  color: { field: state, type: ordinal },
                }
              },
              {
                mark: {
                  type: text,
                  align: left,
                  dx: 10,
                  limit: 200
                },
                encoding: {
                  y: {field: task, type: nominal },
                  text: { field: state},
                  color: { value: white},
                  href: {field: url, type: nominal}
                }

              }
            ]
209
210
211
212
213
        project-tasks-state:
          title: Number of tasks in the project weekly
          db: metrics
          query:
                SELECT
20after4's avatar
20after4 committed
214
215
216
217
218
219
220
221
222
223
224
                  task,
                  state,
                  (select name from phobjects where phid=m.state) as name,
                  metric,
                  p.name as project,
                  sum(duration)/(60*60*24) as days,
                  count(*) as transactions,
                  count(distinct task) as task_count,
                  min(datetime(ts,'unixepoch')) as start,
                  max(datetime(ts2, 'unixepoch')) as end,
                  date(w.date) as week
225
                FROM
20after4's avatar
20after4 committed
226
227
228
229
230
231
232
233
234
                  task_metrics m
                  JOIN Project p ON (
                    m.metric = p.phid
                    AND m.metric = [[ :project ]]
                  )
                  join weeks w on date(w.date) >= date(m.ts, 'unixepoch') and date(w.date) <= date(m.ts2, 'unixepoch')
                group by task,week
                ORDER BY
                  start desc
235
236
          library: vega
          display:
20after4's avatar
20after4 committed
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
            layer:
              - mark:
                  type: area
                  tooltip: true
                encoding:
                  x:
                    field: week
                    type: temporal
                    timeUnit: week
                  #x2:
                    #field: w
                    #timeUnit: week
                  y:
                    field: task_count
                    type: quantitative
                    aggregate: sum
                  color:
                    field: name
                    type: nominal
              # -
              #   mark: {
              #     type: point,
              #     tooltip: true
              #   }
              #   encoding: {
              #     color: { field: state, type: ordinal, scale: { scheme: 'category20' }},
              #     y: { field: task_count, type: quantitative, aggregate: sum},
              #     x: { field: week, type: temporal },
              #     #x2: { field: end, type: temporal }
              #   }
        waterfall:
          title: Burnup
          db: metrics
          query:
              select * from (SELECT
                 task,
                 case state when 'untagged' then -count(distinct task) else count(distinct task) end AS value,
                 state,
                 metric, p.name as project,
                 w.date as week,
                 duration
            FROM
                task_metrics m
            JOIN
                weeks w on w.date >= date(m.ts, 'unixepoch') and w.date <= date(m.ts2, 'unixepoch')
                [[ AND w.date >= date(:date_start) ]]
                [[ AND w.date <= date(:date_end) ]]
            JOIN
                Project p
            ON (m.metric=p.phid )
            where [[ m.metric=:project ]]
            group by week, state, metric
            ORDER BY week)
          library: vega
          display:
            #width: 100
            mark: { type: area,tooltip: true}
            encoding:
              x: { field: week, type: temporal, timeUnit: week}
              y: { field: value, type: quantitative }
              #column: { field: state, type: ordinal,}
              color: { field: state, scale: { scheme: 'category20' }}
        all_events:
          title: 'All events'
          db: metrics
          library: vega
          query: all_events
          display:
            # transform:
            #   - pivot: "event"
            #     groupby: ['phid']
            #     value: value
309
            encoding:
20after4's avatar
20after4 committed
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
              color:
                field: name
                type: nominal
              tooltip: [
                {field: start, type: temporal, title: 'Week' },
                {field: value, type: "quantitative", title: "Tasks"},
                #{field: tasks, type: "quantitative", title: 'Task Cumulative'},
                {field: name, type: "nominal", title: "Column / Milestone"},
                {field: task, type: "nominal", title: "Task"},
                {field: event, type: "nominal", title: "Event"},
              ]
            layer:
            - mark:
                type: area
                tooltip: true
                interpolate: linear
                point: true
              encoding:
                x:
                  field: start
                  type: temporal
                  timeUnit: week
                  #bin: true
                y:
                  field: value
                  type: quantitative
                  stack: normalize
                  aggregate: sum
            - mark:
                type: rect
                tooltip: true
              encoding:
                x:
                  field: start
                  type: temporal
                  timeUnit: week
                #  bin: true
                x2:
                     field: end
                     type: temporal
                     timeUnit: week
                y:
                  field: value
                  type: quantitative
              # y2:
              #   field: value
              #   type: quantitative
                #impute: {method: 'median'}
Mhurd's avatar
Mhurd committed
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
    task-metrics:
      title: Data³ - task metrics
      description: Metrics about a task
      layout:
        - [task-details, task-projects]
        - [task-users, task-days-in-project]
        - [task-days-in-columns, task-days-in-columns]
      filters:
        project:
          name: Project
          type: select
          query:
              WITH project_events as (
              SELECT * FROM (
                SELECT
                  DISTINCT project,
                  count(*) AS cnt
                FROM
                  events e
                WHERE
                  e.project LIKE "PHID%"
                GROUP BY
                  project
                ORDER BY cnt desc
                LIMIT 150
              )
            )
            SELECT
              p.phid AS key,
              p.name AS label,
              p.slug AS slug,
              p.uri as uri
            FROM Project p
            JOIN project_events e
              ON e.project=p.phid
            WHERE p.depth<2 and not p.name like 'acl*%'
            ORDER BY label
        task_id:
          name: Task ID
          type: quantitative
      charts:
        task-days-in-project:
          title: Task days in project
          db: metrics
          query: task_days_in_project
          library: jinja
          template: task_days_in_project.html
          visible-when: :task_id
        task-days-in-columns:
          title: Days in project columns
          db: metrics
          query: select *, next_ts - ts as duration, printf('%.0f', ((next_ts - ts) / 86400.0)) AS duration_days from (select events.*, columns.column_name, columns.project_name, columns.is_default, ifnull(LEAD(ts) OVER(ORDER BY ts), strftime('%s','now', 'localtime')) next_ts from events join columns on new = column_phid where new like '%PHID-PCOL-%' and task = :task_id and event = 'columns' and project_phid = :project order by ts);
          library: vega
          display:
            mark: { type: bar, tooltip: true }
            encoding:
              x: { field: duration_days, type: quantitative, title: 'Days in column' }
              y: { field: column_name, type: nominal, title: 'Column'  }
        task-details:
          title: Task details
          db: metrics
          query: task_details
          library: jinja
          template: task_details.html
          visible-when: :task_id
        task-projects:
          title: Task projects
          db: metrics
          query: task_projects
          library: jinja
          template: task_projects.html
          visible-when: :task_id
        task-users:
          title: Task users
          db: metrics
          query: task_users
          library: jinja
          template: task_users.html
          visible-when: :task_id
20after4's avatar
20after4 committed
437
438
439



440
441
442
443


databases:
  metrics:
20after4's avatar
20after4 committed
444
445
446
    tables:
      phobjects:
        label_column: "name"
447
448
449
450
    queries:
      column_events:
        title: Column movement events.
        sql: |-
20after4's avatar
20after4 committed
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
          "select c.project_name, c.column_name as new_column, d.column_name as old_column, count(distinct task) as count, date(ts, 'unixepoch', 'start of month') as month, datetime(ts, 'unixepoch') as timestamp, task, project, user, event, old, new from events e join columns c on e.new = c.column_phid join columns d on e.old=d.column_phid where event = 'columns' group by old, new, month order by count desc limit 50"
      project_tree:
        SELECT
         phid,
         parent,
         name,
         slug,
         uri
        FROM
         Project
        WHERE
         status='open'
         AND depth=0
         AND subtype='default'
         [[ AND :project in (phid, parent) ]]
      proxy_phids:
        SELECT proxy_phid from ProjectColumn where project=:project
468
469
470
471
472
473
474
      project_events:
        title: project events
        sql: |-
            SELECT
            date(ts, 'unixepoch', 'start of month') as month,
            count(distinct task) as tasks,
            count(distinct user) as people,
20after4's avatar
20after4 committed
475
476
            count(old) as sources,
            old as source,
477
478
479
            new as column
            FROM events
            WHERE event in ('columns', 'projects') and project=:project
20after4's avatar
20after4 committed
480
            GROUP BY month,column,source ORDER BY month
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
      columns_rollup:
        title: aggregations by column and month
        sql: |-
          SELECT
          date(ts, 'unixepoch', 'start of month') as month,
          count(distinct user) as people,
          count(distinct old) as source_count,
          count(*) as rows,
          group_concat(task, ', ') as tasks,
          group_concat(user, ', ') as users,
          group_concat(old, ', ') as sources,
          group_concat(new, ', ') as destinations,
          group_concat(datetime(ts, 'unixepoch'), ', ') as times
          FROM events
          WHERE event in ('columns', 'projects') and :project in (project, old, new)
          GROUP BY month
          order by ts
Mhurd's avatar
Mhurd committed
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
      task_details:
        title: basic task details
        sql: |-
          SELECT
          UPPER(SUBSTR(task.name, 1, 1)) || SUBSTR(task.name, 2) as name,
          json_extract(data, '$.uri') AS uri,
          json_extract(task.status, '$.name') AS status
          FROM task 
          JOIN phobjects ON phobjects.phid = task.phid 
          WHERE id = :task_id
      task_projects:
        title: projects task has been tagged on
        sql: |-
          SELECT DISTINCT
          json_extract(data, '$.uri') AS uri,
          phid,
          name
          FROM task_metrics
          JOIN phobjects ON phobjects.phid = metric
          WHERE metric LIKE '%PHID-PROJ-%' AND task = CAST(:task_id AS decimal)
      task_users:
        title: users of a task
        sql: |-
          SELECT
          authorPhobjects.name AS author_name,
          json_extract(authorPhobjects.data, '$.uri') AS author_uri,
          ownerPhobjects.name AS owner_name,
          json_extract(ownerPhobjects.data, '$.uri') AS owner_uri,
          closerPhobjects.name AS closer_name,
          json_extract(closerPhobjects.data, '$.uri') AS closer_uri
          FROM Task
          LEFT OUTER JOIN phobjects authorPhobjects ON authorPHID = authorPhobjects.phid
          LEFT OUTER JOIN phobjects ownerPhobjects ON ownerPHID = ownerPhobjects.phid
          LEFT OUTER JOIN phobjects closerPhobjects ON closerPHID = closerPhobjects.phid
          WHERE id = :task_id 
      task_days_in_project:
        title: days in project
        sql: |-
          SELECT
          *,
          task,
          uri as project_uri,
          json_extract(data, '$.uri') AS task_uri,
          printf('%.0f', (sum(duration) / 86400.0)) as days,
          Project.name as project_name
          FROM task_metrics 
          JOIN Project ON metric = project.phid
          JOIN phobjects ON phobjects.name = 'T' || task_metrics.task
          WHERE state = 'tagged' AND project.phid = :project AND task = CAST(:task_id AS decimal)

548
549
extra_css_urls:
  - /static/styles.css