Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

StatsHandlerのN+1解消 #10

Merged
merged 8 commits into from Nov 25, 2023
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
1 change: 1 addition & 0 deletions perl/cpanfile
Expand Up @@ -18,3 +18,4 @@ requires 'Crypt::OpenSSL::Random', '0.15';
requires 'Data::Lock', '1.03';
requires 'JSON::Types', '0.05';
requires 'Digest::SHA', '6.04';
requires 'Regexp::Assemble';
79 changes: 54 additions & 25 deletions perl/lib/Isupipe/Handler/LivecommentHandler.pm
Expand Up @@ -4,6 +4,8 @@ use utf8;

use HTTP::Status qw(:constants);
use Types::Standard -types;
use Regexp::Assemble;
use List::Util qw/sum0/;

use Isupipe::Log;
use Isupipe::Entity::Livecomment;
Expand Down Expand Up @@ -76,6 +78,11 @@ sub post_livecomment_handler($app, $c) {
$c->halt(HTTP_BAD_REQUEST, "failed to decode the request body as json");
}

my $livestream_owner_user_id = $params->{tip} ? $app->dbh->select_one(
'SELECT u.id FROM livestreams l INNER JOIN users u ON u.id = l.user_id WHERE l.id = ?',
$livestream_id,
) : undef;

my $txn = $app->dbh->txn_scope;

my $livestream = $app->dbh->select_row_as(
Expand All @@ -88,6 +95,7 @@ sub post_livecomment_handler($app, $c) {
}

# スパム判定
# NOTE(karupa): 各件の数は大したことない
my $ng_words = $app->dbh->select_all_as(
'Isupipe::Entity::NGWord',
'SELECT id, user_id, livestream_id, word FROM ng_words WHERE user_id = ? AND livestream_id = ?',
Expand Down Expand Up @@ -127,10 +135,26 @@ sub post_livecomment_handler($app, $c) {
'INSERT INTO livecomments (user_id, livestream_id, comment, tip, created_at) VALUES (:user_id, :livestream_id, :comment, :tip, :created_at)',
$livecomment->as_hashref,
);

my $livecomment_id = $app->dbh->last_insert_id;
$livecomment->id($livecomment_id);

if ($params->{tip}) {
$app->dbh->query(
'UPDATE livestream_scores SET score = score + :tip WHERE livestream_id = :livestream_id',
{
livestream_id => $livestream_id,
tip => $params->{tip},
},
);
$app->dbh->query(
'UPDATE user_scores SET score = score + :tip WHERE user_id = :user_id',
{
user_id => $livestream_owner_user_id,
tip => $params->{tip},
},
);
}

$livecomment = fill_livecomment_response($app, $livecomment);

$txn->commit;
Expand Down Expand Up @@ -246,35 +270,40 @@ sub moderate_handler($app, $c) {

my $word_id = $app->dbh->last_insert_id;

my $ng_words = $app->dbh->select_all_as(
'Isupipe::Entity::NGWord',
'SELECT * FROM ng_words WHERE livestream_id = ?',
my $ng_words_regex = do {
my $ng_words = $app->dbh->selectcol_arrayref('SELECT word FROM ng_words WHERE livestream_id = ?', undef, $livestream_id);
my $ra = Regexp::Assemble->new;
$ra->add(quotemeta $_) for @$ng_words;
my $re = $ra->re;
qr/$re/m;
};

# NGワードにヒットする過去の投稿も全削除する
my $livecomments = $app->dbh->select_all_as(
'Isupipe::Entity::Livecomment',
'SELECT * FROM livecomments WHERE livestream_id = ?',
$livestream_id,
);

# NGワードにヒットする過去の投稿も全削除する
for my $ng_word ($ng_words->@*) {
# ライブコメント一覧取得
my $livecomments = $app->dbh->select_all_as(
'Isupipe::Entity::Livecomment',
'SELECT * FROM livecomments',
my @targets = grep $_->comment =~ $ng_words_regex, $livecomments->@*;

my @ids;
if (@targets) {
$app->dbh->query(
'DELETE FROM livecomments WHERE id IN (?)',
[map { $_->id } @targets],
);

for my $livecomment ($livecomments->@*) {
my $query = <<~ 'SQL';
DELETE FROM livecomments
WHERE
id = ? AND
livestream_id = ? AND
(SELECT COUNT(*)
FROM
(SELECT ? AS text) AS texts
INNER JOIN
(SELECT CONCAT('%', ?, '%') AS pattern) AS patterns
ON texts.text LIKE patterns.pattern) >= 1;
SQL

$app->dbh->query($query, $livecomment->id, $livestream_id, $livecomment->comment, $ng_word->word);
my $tips = sum0 map { $_->tip } @targets;
if ($tips) {
$app->dbh->query(
'UPDATE user_scores SET score = score - ? WHERE user_id = ?',
$tips, $user_id,
);
$app->dbh->query(
'UPDATE user_scores SET score = score - ? WHERE livestream_id = ?',
$tips, $livestream_id,
);
}
}

Expand Down
4 changes: 3 additions & 1 deletion perl/lib/Isupipe/Handler/LivestreamHandler.pm
Expand Up @@ -99,8 +99,10 @@ sub reserve_livestream_handler($app, $c) {
'INSERT INTO livestreams (user_id, title, description, playlist_url, thumbnail_url, start_at, end_at) VALUES(:user_id, :title, :description, :playlist_url, :thumbnail_url, :start_at, :end_at)',
$livestream->as_hashref,
);

my $livestream_id = $app->dbh->last_insert_id;

$app->dbh->query('INSERT INTO livestream_scores (livestream_id, score) VALUES (?, 0)', $livestream_id);

$livestream->id($livestream_id);

# タグ追加
Expand Down
9 changes: 8 additions & 1 deletion perl/lib/Isupipe/Handler/ReactionHandler.pm
Expand Up @@ -63,6 +63,11 @@ sub post_reaction_handler($app, $c) {
$c->halt(HTTP_BAD_REQUEST, 'invalid request');
}

my $livestream_owner_user_id = $app->dbh->select_one(
'SELECT u.id FROM livestreams l INNER JOIN users u ON u.id = l.user_id WHERE l.id = ?',
$livestream_id,
);

my $txn = $app->dbh->txn_scope;

my $reaction = Isupipe::Entity::Reaction->new(
Expand All @@ -76,10 +81,12 @@ sub post_reaction_handler($app, $c) {
'INSERT INTO reactions (user_id, livestream_id, emoji_name, created_at) VALUES (:user_id, :livestream_id, :emoji_name,:created_at)',
$reaction->as_hashref,
);

my $reaction_id = $app->dbh->last_insert_id;
$reaction->id($reaction_id);

$app->dbh->query('UPDATE livestream_scores SET score = score + 1 WHERE livestream_id = ?', $livestream_id);
$app->dbh->query('UPDATE user_scores SET score = score + 1 WHERE user_id = ?', $livestream_owner_user_id);

$txn->commit;

$reaction = fill_reaction_response($app, $reaction);
Expand Down
109 changes: 4 additions & 105 deletions perl/lib/Isupipe/Handler/StatsHandler.pm
Expand Up @@ -35,60 +35,8 @@ sub get_user_statistics_handler($app, $c) {
}

# ランク算出
my $users = $app->dbh->select_all_as(
'Isupipe::Entity::User',
'SELECT * FROM users'
);

my $ranking = [];
for my $user ($users->@*) {

my $reactions = $app->dbh->select_one(
q[
SELECT COUNT(*) FROM users u
INNER JOIN livestreams l ON l.user_id = u.id
INNER JOIN reactions r ON r.livestream_id = l.id
WHERE u.id = ?
],
$user->id
);

my $tips = $app->dbh->select_one(
q[
SELECT IFNULL(SUM(l2.tip), 0) FROM users u
INNER JOIN livestreams l ON l.user_id = u.id
INNER JOIN livecomments l2 ON l2.livestream_id = l.id
WHERE u.id = ?
],
$user->id
);

my $score = $reactions + $tips;
push $ranking->@* => Isupipe::Entity::UserRankingEntry->new(
user_name => $user->name,
score => $score,
);
}

my @sorted_ranking = sort {
if ($a->score == $b->score) {
$a->user_name cmp $b->user_name;
}
else {
$a->score <=> $b->score;
}
} $ranking->@*;

$ranking = \@sorted_ranking;

my $rank = 1;
for (my $i = scalar $ranking->@* - 1; $i >= 0; $i--) {
my $entry = $ranking->[$i];
if ($entry->user_name eq $username) {
last;
}
$rank++;
}
$app->dbh->query('SET @r = 0');
my $rank = $app->dbh->select_one('SELECT `rank` FROM (SELECT user_id, score, @r := @r+1 AS `rank` FROM user_scores ORDER BY score DESC, user_name DESC) a WHERE a.user_id = ?', $user->id);

# リアクション数
my $total_reactions = $app->dbh->select_one(
Expand Down Expand Up @@ -179,58 +127,9 @@ sub get_livestream_statistics_handler($app, $c) {
$c->halt(HTTP_NOT_FOUND, 'cannot get stats of not found livestream');
}

my $livestreams = $app->dbh->select_all_as(
'Isupipe::Entity::Livestream',
'SELECT * FROM livestreams'
);

# ランク算出
my $ranking = [];
for my $livestream ($livestreams->@*) {
my $reactions = $app->dbh->select_one(
q[
SELECT COUNT(*) FROM livestreams l
INNER JOIN reactions r ON r.livestream_id = l.id
WHERE l.id = ?
],
$livestream->id
);

my $total_tips = $app->dbh->select_one(
q[
SELECT IFNULL(SUM(l2.tip), 0) FROM livestreams l
INNER JOIN livecomments l2 ON l2.livestream_id = l.id
WHERE l.id = ?
],
$livestream->id
);

my $score = $reactions + $total_tips;
push $ranking->@* => Isupipe::Entity::LivestreamRankingEntry->new(
livestream_id => $livestream->id,
score => $score,
);
}

my @sorted_ranking = sort {
if ($a->score == $b->score) {
$a->livestream_id <=> $b->livestream_id;
}
else {
$a->score <=> $b->score;
}
} $ranking->@*;

$ranking = \@sorted_ranking;

my $rank = 1;
for (my $i = scalar $ranking->@* - 1; $i >= 0; $i--) {
my $entry = $ranking->[$i];
if ($entry->livestream_id == $livestream_id) {
last;
}
$rank++;
}
$app->dbh->query('SET @r = 0');
my $rank = $app->dbh->select_one(q!SELECT `rank` FROM (SELECT livestream_id, score, @r := @r+1 AS `rank` FROM livestream_scores ORDER BY score DESC, livestream_id DESC) a WHERE a.livestream_id = ?!, $livestream_id);

# 視聴者数算出
my $viewers_count = $app->dbh->select_one(
Expand Down
3 changes: 2 additions & 1 deletion perl/lib/Isupipe/Handler/UserHandler.pm
Expand Up @@ -80,8 +80,9 @@ sub register_handler($app, $c) {
'INSERT INTO users (name, display_name, description, password) VALUES(:name, :display_name, :description, :password)',
$user->as_hashref
);

my $user_id = $app->dbh->last_insert_id;
$app->dbh->query('INSERT INTO user_scores (user_id, score, user_name) VALUES (?, 0, ?)', $user_id, $params->{name});

$user->id($user_id);

my $theme = Isupipe::Entity::Theme->new(
Expand Down
6 changes: 6 additions & 0 deletions sql/init.sh
Expand Up @@ -68,6 +68,12 @@ mysql -u"$ISUCON_DB_USER" \
--port "$ISUCON_DB_PORT" \
"$ISUCON_DB_NAME" < initial_livecomments.sql

mysql -u"$ISUCON_DB_USER" \
-p"$ISUCON_DB_PASSWORD" \
--host "$ISUCON_DB_HOST" \
--port "$ISUCON_DB_PORT" \
"$ISUCON_DB_NAME" < initial_scores.sql

bash ../pdns/init_zone.sh


2 changes: 2 additions & 0 deletions sql/init.sql
Expand Up @@ -10,6 +10,8 @@ TRUNCATE TABLE livestream_tags;
TRUNCATE TABLE livecomments;
TRUNCATE TABLE livestreams;
TRUNCATE TABLE users;
TRUNCATE TABLE user_scores;
TRUNCATE TABLE livestream_scores;

ALTER TABLE `themes` auto_increment = 1;
ALTER TABLE `icons` auto_increment = 1;
Expand Down
14 changes: 14 additions & 0 deletions sql/initdb.d/10_schema.sql
Expand Up @@ -110,3 +110,17 @@ CREATE TABLE `reactions` (
`created_at` BIGINT NOT NULL
) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_bin;
CREATE INDEX reactions_livestream_id ON reactions(`livestream_id`);

-- スコア
CREATE TABLE `user_scores` (
`user_id` BIGINT NOT NULL PRIMARY KEY,
`score` BIGINT NOT NULL,
`user_name` VARCHAR(255) NOT NULL,
INDEX ranking_idx (`score` DESC, `user_name` DESC)
) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_bin;

CREATE TABLE `livestream_scores` (
`livestream_id` BIGINT NOT NULL PRIMARY KEY,
`score` BIGINT NOT NULL,
INDEX ranking_idx (`score` DESC, `livestream_id` DESC)
) ENGINE=InnoDB CHARACTER SET utf8mb4 COLLATE utf8mb4_bin;
7 changes: 7 additions & 0 deletions sql/initial_scores.sql
@@ -0,0 +1,7 @@
INSERT INTO livestream_scores SELECT * FROM (SELECT l.id, IFNULL(SUM(lc.tip), 0) AS tips FROM livecomments lc INNER JOIN livestreams l ON l.id = lc.livestream_id GROUP BY l.id) AS q ON DUPLICATE KEY UPDATE score = score + q.tips;
INSERT INTO livestream_scores SELECT * FROM (SELECT livestream_id, COUNT(*) AS reactions FROM reactions GROUP BY livestream_id) AS q ON DUPLICATE KEY UPDATE score = score + q.reactions;
INSERT INTO livestream_scores SELECT id, 0 FROM livestreams l WHERE NOT EXISTS (SELECT 1 FROM livestream_scores WHERE livestream_id = l.id);

INSERT INTO user_scores SELECT * FROM (SELECT u.id, IFNULL(SUM(lc.tip), 0) AS tips, u.name FROM livecomments lc INNER JOIN livestreams l ON l.id = lc.livestream_id INNER JOIN users u ON u.id = l.user_id GROUP BY u.id) AS q ON DUPLICATE KEY UPDATE score = score + q.tips;
INSERT INTO user_scores SELECT * FROM (SELECT u.id, COUNT(*) AS reactions, u.name FROM reactions r INNER JOIN livestreams l ON l.id = r.livestream_id INNER JOIN users u ON u.id = l.user_id GROUP BY u.id) AS q ON DUPLICATE KEY UPDATE score = score + q.reactions;
INSERT INTO user_scores SELECT id, 0, name FROM users u WHERE NOT EXISTS (SELECT 1 FROM user_scores WHERE user_id = u.id);