The default badge queries

This is a reference guide for the SQL queries of the default badges, and their trigger information (where available).

Core Badges

:2nd_place_medal: Anniversary

(This one has some extra backend magic in to choose the dates, but I’ll include it anyway)

 start_date = start_date.iso8601(6)
    end_date = end_date.iso8601(6)

      SELECT u.id
        FROM users AS u
        JOIN posts AS p ON p.user_id = u.id
        JOIN topics AS t ON p.topic_id = t.id
       WHERE u.id > 0
         AND u.active
         AND NOT u.staged
         AND (u.silenced_till IS NULL OR u.silenced_till < '#{start_date}')
         AND (u.suspended_till IS NULL OR u.suspended_till < '#{start_date}')
         AND u.created_at <= '#{start_date}'
         AND NOT p.hidden
         AND p.deleted_at IS NULL
         AND p.created_at BETWEEN '#{start_date}' AND '#{end_date}'
         AND t.visible
         AND t.archetype <> 'private_message'
         AND t.deleted_at IS NULL
         AND NOT EXISTS (SELECT 1 FROM user_badges AS ub WHERE ub.user_id = u.id AND ub.badge_id = #{Badge::Anniversary} AND ub.granted_at BETWEEN '#{start_date}' AND '#{end_date}')
         AND NOT EXISTS (SELECT 1 FROM anonymous_users AS au WHERE au.user_id = u.id)
       GROUP BY u.id
      HAVING COUNT(p.id) > 0
Run revocation query daily
Query targets posts
Trigger Update daily

:3rd_place_medal: Appreciated (number of Likes on multiple posts)

The :3rd_place_medal: Appreciated, :2nd_place_medal: Respected and :1st_place_medal: Admired badges follow the same pattern but with different values for p.like_count and HAVING COUNT(*).

SELECT p.user_id, CURRENT_TIMESTAMP AS granted_at
      FROM posts AS p
      WHERE p.like_count >= #{like_count}
        AND (:backfill OR p.user_id IN (:user_ids))
      GROUP BY p.user_id
      HAVING COUNT(*) > #{post_count}
Run revocation query daily
Query targets posts
Trigger Update daily

:3rd_place_medal: Autobiographer

SELECT u.id user_id, CURRENT_TIMESTAMP granted_at
    FROM users u
    JOIN user_profiles up on u.id = up.user_id
    WHERE bio_raw IS NOT NULL AND LENGTH(TRIM(bio_raw)) > 10 AND
          uploaded_avatar_id IS NOT NULL AND
          (:backfill OR u.id IN (:user_ids) )
Run revocation query daily :white_check_mark:
Query targets posts
Trigger When a user is edited or created

:3rd_place_medal: Basic (Trust Levels)

The :3rd_place_medal: Basic, :3rd_place_medal: Member, :2nd_place_medal: Regular, :1st_place_medal: Leader badges all follow the same pattern but with a different trust_level value.

SELECT u.id user_id, current_timestamp granted_at FROM users u
      WHERE trust_level >= #{level.to_i} AND (
        :backfill OR u.id IN (:user_ids)
      )
Run revocation query daily :white_check_mark:
Query targets posts
Trigger When a user changes trust level

:3rd_place_medal: Certified and :2nd_place_medal: Licensed


(Tracking it down)


:3rd_place_medal: Editor

 SELECT p.user_id, min(p.id) post_id, min(p.created_at) granted_at
    FROM badge_posts p
    WHERE p.self_edits > 0 AND
        (:backfill OR p.id IN (:post_ids) )
    GROUP BY p.user_id
Run revocation query daily :white_check_mark:
Query targets posts
Trigger When a user edits or creates a post

:3rd_place_medal: Enthusiast

The :3rd_place_medal: Enthusiast, :2nd_place_medal: Aficionado, and :1st_place_medal: Devotee badges follow the same pattern but with a different HAVING COUNT(*) threshold.

WITH consecutive_visits AS (
        SELECT user_id
             , visited_at
             , visited_at - (DENSE_RANK() OVER (PARTITION BY user_id ORDER BY visited_at))::int s
          FROM user_visits
      ), visits AS (
        SELECT user_id
             , MIN(visited_at) "start"
             , DENSE_RANK() OVER (PARTITION BY user_id ORDER BY s) "rank"
          FROM consecutive_visits
      GROUP BY user_id, s
        HAVING COUNT(*) >= #{days}
      )
      SELECT user_id
           , "start" + interval '#{days} days' "granted_at"
        FROM visits
       WHERE "rank" = 1
Run revocation query daily
Query targets posts
Trigger Update daily

:3rd_place_medal: First Emoji


(Tracking it down)


:3rd_place_medal: First Flag

SELECT pa1.user_id, pa1.created_at granted_at, pa1.post_id
    FROM (
      SELECT pa.user_id, MIN(pa.id) id
      FROM post_actions pa
      JOIN badge_posts p on p.id = pa.post_id
      WHERE post_action_type_id IN (3,4,8) AND
        (:backfill OR pa.post_id IN (:post_ids) )
      GROUP BY pa.user_id
    ) x
    JOIN post_actions pa1 on pa1.id = x.id
Run revocation query daily
Query targets posts :white_check_mark:
Trigger When a user acts on a post

:3rd_place_medal: First Like

SELECT pa1.user_id, pa1.created_at granted_at, pa1.post_id
    FROM (
      SELECT pa.user_id, MIN(pa.id) id
      FROM post_actions pa
      JOIN badge_posts p on p.id = pa.post_id
      WHERE post_action_type_id = 2 AND
        (:backfill OR pa.post_id IN (:post_ids) )
      GROUP BY pa.user_id
    ) x
    JOIN post_actions pa1 on pa1.id = x.id
Run revocation query daily :white_check_mark:
Query targets posts :white_check_mark:
Trigger When a user acts on a post

:3rd_place_medal: First Link

SELECT l.user_id, l.post_id, l.created_at granted_at
    FROM
    (
      SELECT MIN(l1.id) id
      FROM topic_links l1
      JOIN badge_posts p1 ON p1.id = l1.post_id
      JOIN badge_posts p2 ON p2.id = l1.link_post_id
      WHERE NOT reflection AND p1.topic_id <> p2.topic_id AND not quote AND
        (:backfill OR ( p1.id in (:post_ids) ))
      GROUP BY l1.user_id
    ) ids
    JOIN topic_links l ON l.id = ids.id
Run revocation query daily :white_check_mark:
Query targets posts :white_check_mark:
Trigger When a user edits or creates a post

:3rd_place_medal: First Mention

SELECT acting_user_id AS user_id, MIN(target_post_id) AS post_id, MIN(p.created_at) AS granted_at
    FROM user_actions
    JOIN posts p ON p.id = target_post_id
    JOIN topics t ON t.id = topic_id
    JOIN categories c on c.id = category_id
    WHERE action_type = 7
      AND NOT read_restricted
      AND p.deleted_at IS  NULL
      AND t.deleted_at IS  NULL
      AND t.visible
      AND t.archetype <> 'private_message'
      AND (:backfill OR p.id IN (:post_ids))
    GROUP BY acting_user_id
Run revocation query daily :white_check_mark:
Query targets posts :white_check_mark:
Trigger When a user edits or creates a post

:3rd_place_medal: First Onebox


(Tracking it down)


:3rd_place_medal: First Quote

SELECT ids.user_id, q.post_id, p3.created_at granted_at
    FROM
    (
      SELECT p1.user_id, MIN(q1.id) id
      FROM quoted_posts q1
      JOIN badge_posts p1 ON p1.id = q1.post_id
      JOIN badge_posts p2 ON p2.id = q1.quoted_post_id
      WHERE (:backfill OR ( p1.id IN (:post_ids) ))
      GROUP BY p1.user_id
    ) ids
    JOIN quoted_posts q ON q.id = ids.id
    JOIN badge_posts p3 ON q.post_id = p3.id
Run revocation query daily :white_check_mark:
Query targets posts :white_check_mark:
Trigger When a user edits or creates a post

:3rd_place_medal: First Reply-by-Email


(Tracking it down)


Original community suggestion 'Reply by email' badge - #3 by lrossouw

:3rd_place_medal: First Share

SELECT views.user_id, i2.post_id, i2.created_at granted_at
    FROM
    (
      SELECT i.user_id, MIN(i.id) i_id
      FROM incoming_links i
      JOIN badge_posts p on p.id = i.post_id
      JOIN users u on u.id = i.user_id
      GROUP BY i.user_id
    ) as views
    JOIN incoming_links i2 ON i2.id = views.i_id
Run revocation query daily :white_check_mark:
Query targets posts :white_check_mark:
Trigger Update daily

:3rd_place_medal: New User of the Month


(Tracking it down)


:3rd_place_medal: Nice Reply (Likes on a Post)

The :3rd_place_medal: Nice Reply, :2nd_place_medal: Good Reply, and :1st_place_medal: Great Reply badges all follow the same pattern but with a different threshold for p.like_count.

SELECT p.user_id, p.id post_id, CURRENT_TIMESTAMP granted_at
      FROM badge_posts p
      WHERE p.post_number > 1 AND p.like_count >= #{count.to_i} AND
        (:backfill OR p.id IN (:post_ids) )
Run revocation query daily :white_check_mark:
Query targets posts :white_check_mark:
Trigger When a user acts on a post

:3rd_place_medal: Nice Share (Link Sharing)

The :3rd_place_medal: Nice Share, :2nd_place_medal: Good Share, and :1st_place_medal: Great Share badges al follow the same pattern but with a different HAVING COUNT(*) threshold.

SELECT views.user_id, i2.post_id, CURRENT_TIMESTAMP granted_at
      FROM
      (
        SELECT i.user_id, MIN(i.id) i_id
        FROM incoming_links i
        JOIN badge_posts p on p.id = i.post_id
        JOIN users u on u.id = i.user_id
        GROUP BY i.user_id,i.post_id
        HAVING COUNT(*) >= #{count}
      ) as views
      JOIN incoming_links i2 ON i2.id = views.i_id
Run revocation query daily :white_check_mark:
Query targets posts :white_check_mark:
Trigger Update daily

:3rd_place_medal: Nice Topic (Likes on a Topic)

The :3rd_place_medal: Nice Topic, :2nd_place_medal: Good Topic, and :1st_place_medal: Great Topic badges all follow the same pattern but with a different threshold for p.like_count.

SELECT p.user_id, p.id post_id, CURRENT_TIMESTAMP granted_at
      FROM badge_posts p
      WHERE p.post_number = 1 AND p.like_count >= #{count.to_i} AND
        (:backfill OR p.id IN (:post_ids) )
Run revocation query daily :white_check_mark:
Query targets posts :white_check_mark:
Trigger When a user acts on a post

:3rd_place_medal: Out of Love (Max Likes in a day)

The :3rd_place_medal: Out of Love, :2nd_place_medal: Higher Love, and :1st_place_medal: Crazy in Love badges all follow the same pattern but with a different value HAVING COUNT(*) threshold.

SELECT gdl.user_id, CURRENT_TIMESTAMP AS granted_at
      FROM given_daily_likes AS gdl
      WHERE gdl.limit_reached
        AND (:backfill OR gdl.user_id IN (:user_ids))
      GROUP BY gdl.user_id
      HAVING COUNT(*) >= #{count}
Run revocation query daily
Query targets posts
Trigger Update daily

:3rd_place_medal: Popular Link (Link Clicks)

The :3rd_place_medal: Popular Link, :2nd_place_medal: Hot Link, and :1st_place_medal: Famous Link all follow the same pattern but with a different tl.clicks threshold.

SELECT tl.user_id, post_id, CURRENT_TIMESTAMP granted_at
        FROM topic_links tl
        JOIN badge_posts p ON p.id = post_id
       WHERE NOT tl.internal
         AND tl.clicks >= #{count}
      GROUP BY tl.user_id, tl.post_id
Run revocation query daily :white_check_mark:
Query targets posts :white_check_mark:
Trigger Update daily

:3rd_place_medal: Promoter (Invites)

The :3rd_place_medal: Promoter, :2nd_place_medal: Campaigner, and :1st_place_medal: Champion badges all follow the same pattern but with a different Trust Level value needed for the invitees, and a different HAVING COUNT(*) threshold.

SELECT u.id user_id, CURRENT_TIMESTAMP granted_at
      FROM users u
      WHERE u.id IN (
        SELECT invited_by_id
        FROM invites i
        JOIN invited_users iu ON iu.invite_id = i.id
        JOIN users u2 ON u2.id = iu.user_id
        WHERE i.deleted_at IS NULL
        AND i.invited_by_id <> u2.id
        AND u2.active
        AND u2.trust_level >= #{trust_level.to_i}
        AND u2.silenced_till IS NULL
        GROUP BY invited_by_id
        HAVING COUNT(*) >= #{count.to_i}
      ) AND u.active AND u.silenced_till IS NULL AND u.id > 0 AND
      (:backfill OR u.id IN (:user_ids) )
Run revocation query daily :white_check_mark:
Query targets posts
Trigger Update daily

:3rd_place_medal: Read Guidelines

 SELECT user_id, read_faq granted_at
    FROM user_stats
    WHERE read_faq IS NOT NULL AND (user_id IN (:user_ids) OR :backfill)
Run revocation query daily :white_check_mark:
Query targets posts
Trigger When a user is edited or created

:3rd_place_medal: Reader

SELECT id user_id, CURRENT_TIMESTAMP granted_at
    FROM users
    WHERE id IN
    (
      SELECT pt.user_id
      FROM post_timings pt
      JOIN badge_posts b ON b.post_number = pt.post_number AND
                            b.topic_id = pt.topic_id
      JOIN topics t ON t.id = pt.topic_id
      LEFT JOIN user_badges ub ON ub.badge_id = 17 AND ub.user_id = pt.user_id
      WHERE ub.id IS NULL AND t.posts_count > 100
      GROUP BY pt.user_id, pt.topic_id, t.posts_count
      HAVING COUNT(*) >= t.posts_count
Run revocation query daily
Query targets posts
Trigger

:3rd_place_medal: Thank You (Likes given + Likes received)

The :3rd_place_medal: Thank You and :2nd_place_medal: Gives Back, and :1st_place_medal: Empathetic badges follow the same pattern but with different values for us.likes_given and HAVING COUNT(*).

SELECT us.user_id, CURRENT_TIMESTAMP granted_at
      FROM user_stats AS us
      INNER JOIN posts AS p ON p.user_id = us.user_id
      WHERE p.like_count > 0
        AND us.likes_given >= #{likes_given}
        AND (:backfill OR us.user_id IN (:user_ids))
      GROUP BY us.user_id, us.likes_given
      HAVING COUNT(*) > #{likes_received}
Run revocation query daily
Query targets posts
Trigger Update daily

:3rd_place_medal: Welcome

SELECT p.user_id, MIN(post_id) post_id, MIN(pa.created_at) granted_at
    FROM post_actions pa
    JOIN badge_posts p on p.id = pa.post_id
    WHERE post_action_type_id = 2 AND
        (:backfill OR pa.post_id IN (:post_ids) )
    GROUP BY p.user_id
Run revocation query daily :white_check_mark:
Query targets posts :white_check_mark:
Trigger When a user acts on a post

:3rd_place_medal: Wiki Editor

SELECT pr2.user_id, pr2.post_id, pr2.created_at granted_at
    FROM
    (
      SELECT MIN(pr.id) id
      FROM post_revisions pr
      JOIN badge_posts p on p.id = pr.post_id
      WHERE p.wiki
          AND NOT pr.hidden
          AND (:backfill OR p.id IN (:post_ids))
      GROUP BY pr.user_id
    ) as X
    JOIN post_revisions pr2 ON pr2.id = X.id
Run revocation query daily :white_check_mark:
Query targets posts :white_check_mark:
Trigger When a user edits or creates a post

Discourse Reactions

:3rd_place_medal: First Reaction

SELECT user_id, created_at AS granted_at, post_id
  FROM (
           SELECT ru.post_id, ru.user_id, ru.created_at,
                  ROW_NUMBER() OVER (PARTITION BY ru.user_id ORDER BY ru.created_at) AS row_number
           FROM discourse_reactions_reaction_users ru
                JOIN badge_posts p ON ru.post_id = p.id
           WHERE :backfill
              OR ru.post_id IN (:post_ids)
       ) x
  WHERE row_number = 1
Run revocation query daily :white_check_mark:
Query targets posts :white_check_mark:
Trigger When a user edits or creates a post

Discourse Solved

:3rd_place_medal: Solved!

SELECT post_id, user_id, created_at AS granted_at
  FROM (
           SELECT p.id AS post_id, p.user_id, pcf.created_at,
                  ROW_NUMBER() OVER (PARTITION BY p.user_id ORDER BY pcf.created_at) AS row_number
           FROM post_custom_fields pcf
                JOIN badge_posts p ON pcf.post_id = p.id
                JOIN topics t ON p.topic_id = t.id
           WHERE pcf.name = 'is_accepted_answer'
             AND p.user_id <> t.user_id -- ignore topics solved by OP
             AND (:backfill OR p.id IN (:post_ids))
       ) x
  WHERE row_number = 1
Run revocation query daily :white_check_mark:
Query targets posts
Trigger When a user edits or creates a post

:2nd_place_medal: Guidance Counsellor

The badges for :2nd_place_medal: Guidance Counsellor, :1st_place_medal: Know-it-All, and :1st_place_medal: Solution Institution all follow the same pattern but with a different HAVING COUNT (*) >= threshold:

SELECT p.user_id, MAX(pcf.created_at) AS granted_at
   FROM post_custom_fields pcf
        JOIN badge_posts p ON pcf.post_id = p.id
        JOIN topics t ON p.topic_id = t.id
   WHERE pcf.name = 'is_accepted_answer'
     AND p.user_id <> t.user_id -- ignore topics solved by OP
     AND (:backfill OR p.id IN (:post_ids))
   GROUP BY p.user_id
   HAVING COUNT(*) >= #{min_count}
Run revocation query daily :white_check_mark:
Query targets posts
Trigger When a user edits or creates a post

Discourse Github

I can’t read these ones. :upside_down:

Sources:
https://github.com/discourse/discourse/blob/main/lib/badge_queries.rb
https://github.com/discourse/discourse-reactions/blob/main/db/fixtures/001_badges.rb
https://github.com/discourse/discourse-solved/blob/main/db/fixtures/001_badges.rb
https://github.com/discourse/discourse-github/blob/main/app/lib/github_badges.rb

6 Likes

This is awesome @JammyDodger thank for doing this helpful topic! :slight_smile:

5 Likes