diff --git a/assets/javascripts/discourse/controllers/admin-plugins-explorer.js.es6 b/assets/javascripts/discourse/controllers/admin-plugins-explorer.js.es6 index d96904c..b363566 100644 --- a/assets/javascripts/discourse/controllers/admin-plugins-explorer.js.es6 +++ b/assets/javascripts/discourse/controllers/admin-plugins-explorer.js.es6 @@ -8,6 +8,7 @@ const NoQuery = Query.create({name: "No queries", fake: true}); export default Ember.Controller.extend({ queryParams: { selectedQueryId: "id" }, selectedQueryId: null, + editDisabled: false, showResults: false, hideSchema: false, loading: false, @@ -33,6 +34,7 @@ export default Ember.Controller.extend({ const id = parseInt(this.get('selectedQueryId')); const item = this.get('content').find(q => q.get('id') === id); !isNaN(id) ? this.set('showRecentQueries', false) : this.set('showRecentQueries', true); + if (id < 0) this.set('editDisabled', true); return item || NoQuery; }.property('selectedQueryId'), @@ -103,6 +105,7 @@ export default Ember.Controller.extend({ asc: null, order: null, showResults: false, + editDisabled: false, selectedQueryId: null, sortBy: ['last_run_at:desc'] }); diff --git a/assets/javascripts/discourse/templates/admin/plugins-explorer.hbs b/assets/javascripts/discourse/templates/admin/plugins-explorer.hbs index c753d86..f6fdcc9 100644 --- a/assets/javascripts/discourse/templates/admin/plugins-explorer.hbs +++ b/assets/javascripts/discourse/templates/admin/plugins-explorer.hbs @@ -43,7 +43,9 @@
{{d-button action="goHome" icon="chevron-left" class="previous"}}

{{selectedItem.name}} - {{d-icon "pencil"}} + {{#unless editDisabled}} + {{d-icon "pencil"}} + {{/unless}}

@@ -77,7 +79,9 @@ {{#if everEditing}} {{d-button action="save" label="explorer.save" disabled=saveDisabled class="btn-primary"}} {{else}} - {{d-button action="editName" label="explorer.edit" icon="pencil" class="btn-primary"}} + {{#unless editDisabled}} + {{d-button action="editName" label="explorer.edit" icon="pencil" class="btn-primary"}} + {{/unless}} {{/if}} {{d-button action="download" label="explorer.export" disabled=runDisabled icon="download"}}
@@ -88,7 +92,9 @@ {{#if everEditing}} {{d-button action="discard" class="btn-danger" icon="undo" label="explorer.undo" disabled=saveDisabled}} {{/if}} - {{d-button action="destroy" class="btn-danger" icon="trash" label="explorer.delete"}} + {{#unless editDisabled}} + {{d-button action="destroy" class="btn-danger" icon="trash" label="explorer.delete"}} + {{/unless}} {{/if}}
diff --git a/lib/queries.rb b/lib/queries.rb new file mode 100644 index 0000000..1c73b04 --- /dev/null +++ b/lib/queries.rb @@ -0,0 +1,289 @@ +class Queries + def self.default + # For each query, add id, name and description here and add sql below + queries = { + "most-common-likers": { + "id": -1, + "name": "Most Common Likers", + "description": "Which users like particular other users the most?" + }, + "most-messages": { + "id": -2, + "name": "Who has been sending the most messages in the last week?", + "description": "tracking down suspicious PM activity" + }, + "edited-post-spam": { + "id": -3, + "name": "Last 500 posts that were edited by TL0/TL1 users", + "description": "fighting human-driven copy-paste spam" + }, + "new-topics": { + "id": -4, + "name": "New Topics by Category", + "description": "Lists all new topics ordered by category and creation_date. The query accepts a ‘months_ago’ parameter. It defaults to 0 to give you the stats for the current month." + }, + "active-topics": { + "id": -5, + "name": "Top 100 Active Topics", + "description": "based on the number of replies, it accepts a ‘months_ago’ parameter, defaults to 1 to give results for the last calendar month." + }, + "top-likers": { + "id": -6, + "name": "Top 100 Likers", + "description": "returns the top 100 likers for a given monthly period ordered by like_count. It accepts a ‘months_ago’ parameter, defaults to 1 to give results for the last calendar month." + }, + "quality-users": { + "id": -7, + "name": "Top 50 Quality Users", + "description": "based on post score calculated using reply count, likes, incoming links, bookmarks, time spent and read count." + }, + "user-participation": { + "id": -8, + "name": "User Participation Statistics", + "description": "Detailed statistics for the most active users" + } + }.with_indifferent_access + + queries["most-common-likers"]["sql"] = <<~SQL + WITH pairs AS ( + SELECT p.user_id liked, pa.user_id liker + FROM post_actions pa + LEFT JOIN posts p ON p.id = pa.post_id + WHERE post_action_type_id = 2 + ) + SELECT liker liker_user_id, liked liked_user_id, count(*) + FROM pairs + GROUP BY liked, liker + ORDER BY count DESC + SQL + + queries["most-messages"]["sql"] = <<~SQL + SELECT user_id, count(*) AS message_count + FROM topics + WHERE archetype = 'private_message' AND subtype = 'user_to_user' + AND age(created_at) < interval '7 days' + GROUP BY user_id + ORDER BY message_count DESC + SQL + + queries["edited-post-spam"]["sql"] = <<~SQL + SELECT + p.id AS post_id, + topic_id + FROM posts p + JOIN users u + ON u.id = p.user_id + JOIN topics t + ON t.id = p.topic_id + WHERE p.last_editor_id = p.user_id + AND p.self_edits > 0 + AND (u.trust_level = 0 OR u.trust_level = 1) + AND p.deleted_at IS NULL + AND t.deleted_at IS NULL + AND t.archetype = 'regular' + ORDER BY p.updated_at DESC + LIMIT 500 + SQL + + queries["new-topics"]["sql"] = <<~SQL + -- [params] + -- int :months_ago = 1 + + WITH query_period as ( + SELECT + date_trunc('month', CURRENT_DATE) - INTERVAL ':months_ago months' as period_start, + date_trunc('month', CURRENT_DATE) - INTERVAL ':months_ago months' + INTERVAL '1 month' - INTERVAL '1 second' as period_end + ) + + SELECT + t.id as topic_id, + t.category_id + FROM topics t + RIGHT JOIN query_period qp + ON t.created_at >= qp.period_start + AND t.created_at <= qp.period_end + WHERE t.user_id > 0 + AND t.category_id IS NOT NULL + ORDER BY t.category_id, t.created_at DESC + SQL + + queries["active-topics"]["sql"] = <<~SQL + -- [params] + -- int :months_ago = 1 + + WITH query_period AS + (SELECT date_trunc('month', CURRENT_DATE) - INTERVAL ':months_ago months' AS period_start, + date_trunc('month', CURRENT_DATE) - INTERVAL ':months_ago months' + INTERVAL '1 month' - INTERVAL '1 second' AS period_end) + SELECT t.id AS topic_id, + t.category_id, + COUNT(p.id) AS reply_count + FROM topics t + JOIN posts p ON t.id = p.topic_id + JOIN query_period qp ON p.created_at >= qp.period_start + AND p.created_at <= qp.period_end + WHERE t.archetype = 'regular' + AND t.user_id > 0 + GROUP BY t.id + ORDER BY COUNT(p.id) DESC, t.score DESC + LIMIT 100 + SQL + + queries["top-likers"]["sql"] = <<~SQL + -- [params] + -- int :months_ago = 1 + + WITH query_period AS ( + SELECT + date_trunc('month', CURRENT_DATE) - INTERVAL ':months_ago months' as period_start, + date_trunc('month', CURRENT_DATE) - INTERVAL ':months_ago months' + INTERVAL '1 month' - INTERVAL '1 second' as period_end + ) + + SELECT + ua.user_id, + count(1) AS like_count + FROM user_actions ua + INNER JOIN query_period qp + ON ua.created_at >= qp.period_start + AND ua.created_at <= qp.period_end + WHERE ua.action_type = 1 + GROUP BY ua.user_id + ORDER BY like_count DESC + LIMIT 100 + SQL + + queries["quality-users"]["sql"] = <<~SQL + SELECT sum(p.score) / count(p) AS "average score per post", + count(p.id) AS post_count, + p.user_id + FROM posts p + JOIN users u ON u.id = p.user_id + WHERE p.created_at >= CURRENT_DATE - INTERVAL '6 month' + AND NOT u.admin + AND u.active + GROUP BY user_id, + u.views + HAVING count(p.id) > 50 + ORDER BY sum(p.score) / count(p) DESC + LIMIT 20 + SQL + + queries["user-participation"]["sql"] = <<~SQL + -- [params] + -- int :from_days_ago = 0 + -- int :duration_days = 30 + WITH t AS ( + SELECT CURRENT_TIMESTAMP - ((:from_days_ago + :duration_days) * (INTERVAL '1 days')) AS START, + CURRENT_TIMESTAMP - (:from_days_ago * (INTERVAL '1 days')) AS END + ), + pr AS ( + SELECT user_id, COUNT(1) AS visits, + SUM(posts_read) AS posts_read + FROM user_visits, t + WHERE posts_read > 0 + AND visited_at > t.START + AND visited_at < t. + END + GROUP BY + user_id + ), + pc AS ( + SELECT user_id, COUNT(1) AS posts_created + FROM posts, t + WHERE + created_at > t.START + AND created_at < t. + END + GROUP BY + user_id + ), + ttopics AS ( + SELECT user_id, posts_count + FROM topics, t + WHERE created_at > t.START + AND created_at < t. + END + ), + tc AS ( + SELECT user_id, COUNT(1) AS topics_created + FROM ttopics + GROUP BY user_id + ), + twr AS ( + SELECT user_id, COUNT(1) AS topics_with_replies + FROM ttopics + WHERE posts_count > 1 + GROUP BY user_id + ), + tv AS ( + SELECT user_id, + COUNT(DISTINCT(topic_id)) AS topics_viewed + FROM topic_views, t + WHERE viewed_at > t.START + AND viewed_at < t. + END + GROUP BY user_id + ), + likes AS ( + SELECT post_actions.user_id AS given_by_user_id, + posts.user_id AS received_by_user_id + FROM t, + post_actions + LEFT JOIN + posts + ON post_actions.post_id = posts.id + WHERE + post_actions.created_at > t.START + AND post_actions.created_at < t. + END + AND post_action_type_id = 2 + ), + lg AS ( + SELECT given_by_user_id AS user_id, + COUNT(1) AS likes_given + FROM likes + GROUP BY user_id + ), + lr AS ( + SELECT received_by_user_id AS user_id, + COUNT(1) AS likes_received + FROM likes + GROUP BY user_id + ), + e AS ( + SELECT email, user_id + FROM user_emails u + WHERE u.PRIMARY = TRUE + ) + SELECT + pr.user_id, + username, + name, + email, + visits, + COALESCE(topics_viewed, 0) AS topics_viewed, + COALESCE(posts_read, 0) AS posts_read, + COALESCE(posts_created, 0) AS posts_created, + COALESCE(topics_created, 0) AS topics_created, + COALESCE(topics_with_replies, 0) AS topics_with_replies, + COALESCE(likes_given, 0) AS likes_given, + COALESCE(likes_received, 0) AS likes_received + FROM pr + LEFT JOIN tv USING (user_id) + LEFT JOIN pc USING (user_id) + LEFT JOIN tc USING (user_id) + LEFT JOIN twr USING (user_id) + LEFT JOIN lg USING (user_id) + LEFT JOIN lr USING (user_id) + LEFT JOIN e USING (user_id) + LEFT JOIN users ON pr.user_id = users.id + ORDER BY + visits DESC, + posts_read DESC, + posts_created DESC + SQL + + # convert query ids from "mostcommonlikers" to "-1", "mostmessages" to "-2" etc. + queries.transform_keys!.with_index { |key, idx| "-#{idx + 1}" } + queries + end +end diff --git a/plugin.rb b/plugin.rb index 4993d23..8c60c31 100644 --- a/plugin.rb +++ b/plugin.rb @@ -566,6 +566,7 @@ SQL end # Reimplement a couple ActiveRecord methods, but use PluginStore for storage instead + require_dependency File.expand_path('../lib/queries.rb', __FILE__) class DataExplorer::Query attr_accessor :id, :name, :description, :sql, :created_by, :created_at, :last_run_at @@ -629,11 +630,17 @@ SQL end def self.find(id, opts = {}) - unless hash = DataExplorer.pstore_get("q:#{id}") - return DataExplorer::Query.new if opts[:ignore_deleted] - raise Discourse::NotFound + if DataExplorer.pstore_get("q:#{id}").nil? && id < 0 + hash = Queries.default[id.to_s] + hash[:id] = id + from_hash hash + else + unless hash = DataExplorer.pstore_get("q:#{id}") + return DataExplorer::Query.new if opts[:ignore_deleted] + raise Discourse::NotFound + end + from_hash hash end - from_hash hash end def save @@ -642,6 +649,18 @@ SQL DataExplorer.pstore_set "q:#{id}", to_hash end + def save_default_query + check_params! + # Read from queries.rb again to pick up any changes and save them + query = Queries.default[id.to_s] + @id = query["id"] + @sql = query["sql"] + @name = query["name"] + @description = query["description"] + + DataExplorer.pstore_set "q:#{id}", to_hash + end + def destroy DataExplorer.pstore_delete "q:#{id}" end @@ -907,6 +926,7 @@ SQL end require_dependency 'application_controller' + require_dependency File.expand_path('../lib/queries.rb', __FILE__) class DataExplorer::QueryController < ::ApplicationController requires_plugin DataExplorer.plugin_name @@ -919,6 +939,18 @@ SQL def index # guardian.ensure_can_use_data_explorer! queries = DataExplorer::Query.all + Queries.default.each do |params| + query = DataExplorer::Query.new + query.id = params.second["id"] + query.sql = params.second["sql"] + query.name = params.second["name"] + query.description = params.second["description"] + query.created_by = Discourse::SYSTEM_USER_ID.to_s + + # don't render this query if query with the same id already exists in pstore + queries.push(query) unless DataExplorer.pstore_get("q:#{query.id}").present? + end + render_serialized queries, DataExplorer::QuerySerializer, root: 'queries' end @@ -1000,9 +1032,16 @@ SQL # rows - array of array of strings. Results of the query. In the same order as 'columns'. def run check_xhr unless params[:download] + query = DataExplorer::Query.find(params[:id].to_i) query.last_run_at = Time.now - query.save + + if params[:id].to_i < 0 + query.created_by = Discourse::SYSTEM_USER_ID.to_s + query.save_default_query + else + query.save + end if params[:download] response.sending_file = true diff --git a/spec/controllers/queries_controller_spec.rb b/spec/controllers/queries_controller_spec.rb index 7c9d65b..95130d6 100644 --- a/spec/controllers/queries_controller_spec.rb +++ b/spec/controllers/queries_controller_spec.rb @@ -55,11 +55,15 @@ describe DataExplorer::QueryController do end describe "#index" do - it "behaves nicely with no queries" do + before do + require_dependency File.expand_path('../../../lib/queries.rb', __FILE__) + end + + it "behaves nicely with no user created queries" do DataExplorer::Query.destroy_all get :index, format: :json expect(response.status).to eq(200) - expect(response_json['queries']).to eq([]) + expect(response_json['queries'].count).to eq(Queries.default.count) end it "shows all available queries in alphabetical order" do @@ -68,7 +72,7 @@ describe DataExplorer::QueryController do make_query('SELECT 1 as value', name: 'A') get :index, format: :json expect(response.status).to eq(200) - expect(response_json['queries'].length).to eq(2) + expect(response_json['queries'].length).to eq(Queries.default.count + 2) expect(response_json['queries'][0]['name']).to eq('A') expect(response_json['queries'][1]['name']).to eq('B') end