[Bps-public-commit] RT-Extension-rt_cpan_org branch, master, updated. 1314b323bc7386abc2ce9745d9c766508292f761

Thomas Sibley trs at bestpractical.com
Fri Jul 19 16:47:16 EDT 2013


The branch, master has been updated
       via  1314b323bc7386abc2ce9745d9c766508292f761 (commit)
      from  3891db001883246771f4e669ab0ba641894a18f6 (commit)

Summary of changes:
 bin/rt-cpan-user-activity-stats                    | 114 +++++++++++++++++++++
 etc/user-activity-queries/01-opened-a-ticket.sql   |  20 ++++
 etc/user-activity-queries/02-closed-a-ticket.sql   |  26 +++++
 .../03-replied-to-ticket-recently.sql              |  25 +++++
 .../04-status-change-recently.sql                  |  25 +++++
 .../05-watched-ticket-recently.sql                 |  26 +++++
 6 files changed, 236 insertions(+)
 create mode 100755 bin/rt-cpan-user-activity-stats
 create mode 100644 etc/user-activity-queries/01-opened-a-ticket.sql
 create mode 100644 etc/user-activity-queries/02-closed-a-ticket.sql
 create mode 100644 etc/user-activity-queries/03-replied-to-ticket-recently.sql
 create mode 100644 etc/user-activity-queries/04-status-change-recently.sql
 create mode 100644 etc/user-activity-queries/05-watched-ticket-recently.sql

- Log -----------------------------------------------------------------
commit 1314b323bc7386abc2ce9745d9c766508292f761
Author: Thomas Sibley <trs at bestpractical.com>
Date:   Fri Jul 19 13:46:39 2013 -0700

    SQLite export of user activity stats
    
    Requested by Neil Bowers.

diff --git a/bin/rt-cpan-user-activity-stats b/bin/rt-cpan-user-activity-stats
new file mode 100755
index 0000000..7217acd
--- /dev/null
+++ b/bin/rt-cpan-user-activity-stats
@@ -0,0 +1,114 @@
+#!/usr/bin/env perl
+use strict;
+use warnings;
+
+eval {
+    use RT -init;
+    1;
+} or exit usage();
+
+use IO::Compress::Gzip ();
+use DBI                ();
+use DBD::SQLite        ();
+
+sub usage {
+    print STDERR "\nUsage: perl -I /opt/rt4/local/lib -I/opt/rt4/lib $0 /export/directory\n\n";
+    return 1;
+}
+
+# Takes a parameter of the directory to export the database to
+my $dir = shift @ARGV;
+exit usage() unless $dir;
+die "Export directory '$dir' does not exist" unless -d $dir;
+die "Export directory '$dir' is not writable" unless -w $dir;
+
+# Checks our query files
+my $query_dir = RT::Plugin->new( name => "RT::Extension::rt_cpan_org" )
+                          ->Path("etc/user-activity-queries");
+die "Can't find query directory"
+    unless $query_dir and -d $query_dir;
+
+my $rt = RT->DatabaseHandle->dbh;
+
+# Clear the existing sqlite file
+my $sqlite = "$dir/user-activity-stats.sqlite";
+unlink($sqlite) or die "Failed to remove existing export '$sqlite': $!"
+    if -f $sqlite;
+
+# Connect and create the table
+my $dbh = DBI->connect("DBI:SQLite:$sqlite")
+    or die "Failed to create new export '$sqlite'";
+
+my (%data, @all_fields);
+
+# Run each query file to fill our data structure
+for my $file (sort { lc $a cmp lc $b } <$query_dir/*.sql>) {
+    my $query = do {
+        open my $fh, "<", $file or die "can't open $file: $!";
+        local $/;
+        <$fh>;
+    };
+    $query =~ s/--.*$//mg; # strip sql comments
+    $query =~ s/^\s*$//mg; # strip newlines
+
+    RT->Logger->debug("Running query: \n\n$query\n\n");
+
+    my $sth = $rt->prepare($query);
+    $sth->execute;
+
+    my @fields = grep { $_ ne "username" } @{$sth->{NAME_lc} || []};
+
+    # Add our data
+    while (my $row = $sth->fetchrow_arrayref) {
+        my $user = $data{$row->[0]} ||= [];
+        push @$user, (0) x (@all_fields - @$user); # Fill in any gaps before our fields
+        push @$user, @$row[1..@$row - 1];
+    }
+
+    push @all_fields, @fields;
+
+    # Fill in any gaps after our fields
+    push @$_, (0) x (@all_fields - @$_) for values %data;
+}
+
+# Create the schema
+my @schema = (
+    "username TEXT NOT NULL PRIMARY KEY",
+    map { "$_ INTEGER NOT NULL DEFAULT 0" } @all_fields
+);
+unshift @all_fields, "username";
+
+$dbh->do(<<"END_SQL");
+CREATE TABLE users (
+    @{[join ",\n    ", @schema]}
+);
+END_SQL
+
+# Fill the database
+my $insert = $dbh->prepare("INSERT INTO users VALUES (" . join(",", ("?") x @all_fields) . ")");
+
+$dbh->begin_work;
+my $i = 1;
+while (my ($u, $row) = each %data) {
+    $insert->execute($u, @$row);
+} continue {
+    if ($i++ % 100 == 0) {
+        $dbh->commit;
+        $dbh->begin_work;
+    }
+}
+$dbh->commit;
+
+# Create indexes
+$dbh->do("CREATE INDEX users__$_ on users ($_)")
+    for @all_fields;
+$dbh->disconnect;
+
+# Compress to the final form
+my $gz = "$sqlite.gz";
+unlink $gz or die "Failed to remove existing '$gz' export: $!"
+    if -f $gz;
+IO::Compress::Gzip::gzip( $sqlite => $gz )
+    or die "Failed to create gzip archive '$gz'";
+
+exit;
diff --git a/etc/user-activity-queries/01-opened-a-ticket.sql b/etc/user-activity-queries/01-opened-a-ticket.sql
new file mode 100644
index 0000000..ce69f7f
--- /dev/null
+++ b/etc/user-activity-queries/01-opened-a-ticket.sql
@@ -0,0 +1,20 @@
+-- Users who have opened a ticket
+-- XXX TODO: Merged users aren't treated as such
+SELECT
+    u.Name as Username,
+    count(t.id) as Tickets_created,
+    count(CASE WHEN t.Created > (NOW() - interval 30 day) THEN t.id END) as Tickets_created_in_last_30_days
+    FROM Tickets t
+    JOIN Principals p
+        ON p.id = t.Creator
+    JOIN Users u
+        ON u.id = p.id
+    JOIN CachedGroupMembers cgm
+        ON cgm.MemberId = p.id
+    WHERE
+           t.Status != 'deleted'
+       AND t.Type = 'ticket'
+       AND p.Disabled = 0
+       AND cgm.GroupId = 4
+    GROUP BY u.Name
+    ORDER BY u.Name;
diff --git a/etc/user-activity-queries/02-closed-a-ticket.sql b/etc/user-activity-queries/02-closed-a-ticket.sql
new file mode 100644
index 0000000..3441e2f
--- /dev/null
+++ b/etc/user-activity-queries/02-closed-a-ticket.sql
@@ -0,0 +1,26 @@
+-- Users who have closed a ticket
+-- XXX TODO: Merged users aren't treated as such
+SELECT
+    u.Name as Username,
+    count(distinct t.id) as Tickets_resolved,
+    count(distinct CASE WHEN txn.Created > (NOW() - interval 30 day) THEN t.id END) as Tickets_resolved_in_last_30_days
+    FROM Users u
+    JOIN Transactions txn
+        ON txn.Creator = u.id
+    JOIN Tickets t
+        ON t.id = txn.ObjectId
+       AND txn.ObjectType = 'RT::Ticket'
+    JOIN Principals p
+        ON p.id = u.id
+    JOIN CachedGroupMembers cgm
+        ON cgm.MemberId = p.id
+    WHERE
+           txn.Field = 'Status'
+       AND txn.NewValue = 'resolved'
+       AND t.Status != 'deleted'
+       AND t.Type = 'ticket'
+       AND t.EffectiveId = t.id
+       AND p.Disabled = 0
+       AND cgm.GroupId = 4
+    GROUP BY u.Name
+    ORDER BY u.Name;
diff --git a/etc/user-activity-queries/03-replied-to-ticket-recently.sql b/etc/user-activity-queries/03-replied-to-ticket-recently.sql
new file mode 100644
index 0000000..4019475
--- /dev/null
+++ b/etc/user-activity-queries/03-replied-to-ticket-recently.sql
@@ -0,0 +1,25 @@
+-- Users who have replied to a ticket recently
+-- XXX TODO: Merged users aren't treated as such
+SELECT
+    u.Name as Username,
+    count(distinct t.id) as Tickets_replied_to_in_last_30_days
+    FROM Users u
+    JOIN Transactions txn
+        ON txn.Creator = u.id
+    JOIN Tickets t
+        ON t.id = txn.ObjectId
+       AND txn.ObjectType = 'RT::Ticket'
+    JOIN Principals p
+        ON p.id = u.id
+    JOIN CachedGroupMembers cgm
+        ON cgm.MemberId = p.id
+    WHERE
+           txn.Type = 'Correspond'
+       AND t.Status != 'deleted'
+       AND t.Type = 'ticket'
+       AND t.EffectiveId = t.id
+       AND p.Disabled = 0
+       AND cgm.GroupId = 4
+       AND txn.Created > (NOW() - interval 30 day)
+    GROUP BY u.Name
+    ORDER BY u.Name;
diff --git a/etc/user-activity-queries/04-status-change-recently.sql b/etc/user-activity-queries/04-status-change-recently.sql
new file mode 100644
index 0000000..5d5e7ab
--- /dev/null
+++ b/etc/user-activity-queries/04-status-change-recently.sql
@@ -0,0 +1,25 @@
+-- Users who have changed a ticket status recently (not resolved)
+-- XXX TODO: Merged users aren't treated as such
+SELECT
+    u.Name as Username,
+    count(distinct t.id) as Tickets_with_non_new_or_resolved_status_changes_in_last_30_days
+    FROM Users u
+    JOIN Transactions txn
+        ON txn.Creator = u.id
+    JOIN Tickets t
+        ON t.id = txn.ObjectId
+       AND txn.ObjectType = 'RT::Ticket'
+    JOIN Principals p
+        ON p.id = u.id
+    JOIN CachedGroupMembers cgm
+        ON cgm.MemberId = p.id
+    WHERE
+           txn.Field = 'Status'
+       AND txn.NewValue NOT IN ('new', 'resolved')
+       AND t.Type = 'ticket'
+       AND t.EffectiveId = t.id
+       AND p.Disabled = 0
+       AND cgm.GroupId = 4
+       AND txn.Created > (NOW() - interval 30 day)
+    GROUP BY u.Name
+    ORDER BY u.Name;
diff --git a/etc/user-activity-queries/05-watched-ticket-recently.sql b/etc/user-activity-queries/05-watched-ticket-recently.sql
new file mode 100644
index 0000000..af45484
--- /dev/null
+++ b/etc/user-activity-queries/05-watched-ticket-recently.sql
@@ -0,0 +1,26 @@
+-- Users who have added themselves as a watcher to a ticket recently
+-- XXX TODO: Merged users aren't treated as such
+SELECT
+    u.Name as Username,
+    count(distinct t.id) as Tickets_watched_in_last_30_days
+    FROM Users u
+    JOIN Transactions txn
+        ON txn.Creator = u.id
+    JOIN Tickets t
+        ON t.id = txn.ObjectId
+       AND txn.ObjectType = 'RT::Ticket'
+    JOIN Principals p
+        ON p.id = u.id
+    JOIN CachedGroupMembers cgm
+        ON cgm.MemberId = p.id
+    WHERE
+           txn.Type = 'AddWatcher'
+       AND txn.NewValue = txn.Creator
+       AND t.Status != 'deleted'
+       AND t.Type = 'ticket'
+       AND t.EffectiveId = t.id
+       AND p.Disabled = 0
+       AND cgm.GroupId = 4
+       AND txn.Created > (NOW() - interval 30 day)
+    GROUP BY u.Name
+    ORDER BY u.Name;

-----------------------------------------------------------------------



More information about the Bps-public-commit mailing list