diff --git a/ansible/runonce/pui.yml b/ansible/runonce/pui.yml index 0693b87cd..9a160fca8 100755 --- a/ansible/runonce/pui.yml +++ b/ansible/runonce/pui.yml @@ -351,9 +351,23 @@ - name: "Create participant/config/db.php" copy: - content: " 'yii\\db\\Connection', 'dsn' => 'mysql:host={{db_ip}};dbname=echoCTF', 'username' => 'participantUI', 'password' => 'participantUI', 'charset' => 'utf8mb4','enableSchemaCache' => true, 'schemaCacheDuration' => 60,'schemaCache' => 'cache',];\n" dest: "/home/participantUI/{{domain_name}}/frontend/config/db.php" mode: '0444' + content: | + 'yii\\db\\Connection', + 'dsn' => 'mysql:host={{db_ip}};dbname=echoCTF', + 'username' => 'participantUI', + 'password' => 'participantUI', + 'charset' => 'utf8mb4', + 'enableSchemaCache' => true, + 'schemaCacheDuration' => 0, + 'schemaCache' => 'cache', + 'enableQueryCache'=>true, + 'queryCache'=>'qcache', + 'queryCacheDuration'=>60, + ]; tags: - conf diff --git a/backend/migrations/m241110_214630_from_v0_25_0_to_v1_0_0.php b/backend/migrations/m241110_214630_from_v0_25_0_to_v1_0_0.php index 4a5c463f8..7cd632d26 100644 --- a/backend/migrations/m241110_214630_from_v0_25_0_to_v1_0_0.php +++ b/backend/migrations/m241110_214630_from_v0_25_0_to_v1_0_0.php @@ -17,6 +17,55 @@ public function safeUp() $this->upsert('init_data',['version'=>'m241108_100648_populate_default_sysconfig_keys','apply_time'=>time()]); // add missing url routes } + + // describe SELECT * FROM `treasure` WHERE `target_id`=13 ORDER BY `weight` DESC, `id` DESC; + $this->db->createCommand('CREATE INDEX IF NOT EXISTS `query-index` ON treasure (target_id,weight,id)')->execute(); + + // describe SELECT * FROM `headshot` WHERE `target_id`=13 ORDER BY `created_at`; + // SELECT `headshot`.* FROM `headshot` LEFT JOIN `player` ON `headshot`.`player_id` = `player`.`id` WHERE (`player`.`status`=10) AND (`headshot`.`target_id`=13) ORDER BY `created_at` DESC LIMIT 50 + $this->db->createCommand('CREATE INDEX IF NOT EXISTS `query-index` ON headshot (target_id,created_at)')->execute(); + + // SELECT * FROM `network_target_schedule` WHERE (`target_id`=13) ORDER BY `migration_date`, `network_id` LIMIT 1; + $this->db->createCommand('CREATE INDEX IF NOT EXISTS `query-index` ON network_target_schedule (target_id,migration_date,network_id)')->execute(); + + // SELECT * FROM `notification` WHERE (`archived`=0) AND (`player_id`=21) + // SELECT `id`, `title`, `category`, `body`, `created_at`, `archived` FROM `notification` WHERE (`player_id`=21) AND (`archived`=0) ORDER BY `created_at` DESC, `id` DESC + $this->db->createCommand('CREATE INDEX IF NOT EXISTS `query-index` ON notification (player_id,archived,created_at,id)')->execute(); + + // SELECT * FROM `writeup` WHERE (approved=1) AND (`target_id`=13) ORDER BY `created_at` + $this->db->createCommand('CREATE INDEX IF NOT EXISTS `query-index` ON writeup (target_id,approved,created_at)')->execute(); + + // describe SELECT COUNT(*) FROM `stream` LEFT JOIN `player` ON `stream`.`player_id` = `player`.`id` WHERE ((((`model_id`=24) AND (`model`='finding')) OR ((`model_id` IN (86, 85, 84, 83)) AND (`model`='treasure'))) OR ((`model_id`=13) AND (`model`='headshot'))) AND (`academic`=0); + // SELECT `stream`.*, TS_AGO(stream.ts) AS `ts_ago` FROM `stream` LEFT JOIN `player` ON `stream`.`player_id` = `player`.`id` WHERE ((((`model_id`=24) AND (`model`='finding')) OR ((`model_id` IN (86, 85, 84, 83)) AND (`model`='treasure'))) OR ((`model_id`=13) AND (`model`='headshot'))) AND (`academic`=0) ORDER BY `stream`.`ts` DESC, `stream`.`id` DESC LIMIT 10 + $this->db->createCommand('CREATE INDEX IF NOT EXISTS `query-index` ON stream (ts,id,model_id,model(20))')->execute(); + + // SELECT css,js FROM layout_override WHERE (player_id=21 or player_id IS NULL) AND ((NOW() BETWEEN valid_from AND valid_until) OR (repeating=1 AND NOW() BETWEEN DATE_FORMAT(valid_from,CONCAT(YEAR(NOW()),'-%m-%d')) AND DATE_FORMAT(valid_until,CONCAT(YEAR(NOW()),'-%m-%d')))) + $this->db->createCommand('CREATE INDEX IF NOT EXISTS `query-index` ON layout_override (player_id,valid_from,valid_until,repeating)')->execute(); + + // SELECT COUNT(*) FROM `network` WHERE `active`=1 + $this->db->createCommand('CREATE INDEX IF NOT EXISTS `count-active-network` ON network (active)')->execute(); + $this->db->createCommand('CREATE INDEX IF NOT EXISTS `idx-network-weight` ON network (weight)')->execute(); + + // SELECT * FROM `question` WHERE `challenge_id`=1 ORDER BY `weight`, `id` + $this->db->createCommand('CREATE INDEX IF NOT EXISTS `order-query-index` ON question (`challenge_id`,`weight`,`id`)')->execute(); + + // SELECT `id`, `name` FROM `vpn_template` WHERE (`active`=TRUE) AND (`visible`=TRUE) AND (`client`=TRUE) ORDER BY `name` + $this->db->createCommand('CREATE INDEX IF NOT EXISTS `query-index` ON vpn_template (active,visible,client,`name`)')->execute(); + + // SELECT COUNT(*) FROM `challenge_solver` LEFT JOIN `player` ON `challenge_solver`.`player_id` = `player`.`id` LEFT JOIN `challenge` ON `challenge_solver`.`challenge_id` = `challenge`.`id` WHERE (`player`.`status`=10) AND (`challenge`.`timer`=1) AND (`challenge_solver`.`timer` > 0) + $this->db->createCommand('CREATE INDEX IF NOT EXISTS `idx-timer` ON challenge (`timer`)')->execute(); + $this->db->createCommand('CREATE INDEX IF NOT EXISTS `idx-timer` ON challenge_solver (`timer`)')->execute(); + + + // FILESORTS // + // SELECT `team`.* FROM `team` LEFT JOIN `team_player` ON `team`.`id` = `team_player`.`team_id` WHERE `academic`=0 GROUP BY `team`.`id` ORDER BY `name`, `approved` DESC, `ts` + $this->db->createCommand('CREATE INDEX IF NOT EXISTS `idx-academic` ON team (`academic`)')->execute(); + $this->db->createCommand('CREATE INDEX IF NOT EXISTS `idx-ts` ON team (`ts`)')->execute(); + + // SELECT * FROM `team_player` WHERE `team_id` IN (61, 68, 32, 17, 58, 27, 75) ORDER BY `approved` DESC, `ts` + $this->db->createCommand('CREATE INDEX IF NOT EXISTS `idx-approved` ON team_player (`approved`)')->execute(); + $this->db->createCommand('CREATE INDEX IF NOT EXISTS `idx-ts` ON team_player (`ts`)')->execute(); + $this->upsert('sysconfig',['id'=>'platform_version','val'=>'v1.0.0']); } diff --git a/contrib/Dockerfile-frontend b/contrib/Dockerfile-frontend index 321e53c59..e1a2d258d 100644 --- a/contrib/Dockerfile-frontend +++ b/contrib/Dockerfile-frontend @@ -29,7 +29,7 @@ RUN set -ex \ && cp ${RED_APP}/config/db-local.php ${RED_APP}/config/db.php \ && chmod a+x /usr/local/bin/composer \ && sed -ie "s/127.0.0.1/${MYSQL_HOST}/g" ${RED_APP}/config/cache.php \ - && echo " 'yii\db\Connection', 'dsn' => 'mysql:host=${MYSQL_HOST};dbname=${MYSQL_DATABASE}', 'username' => '${MYSQL_USER}', 'password' => '${MYSQL_PASSWORD}', 'charset' => 'utf8mb4', ];">${RED_APP}/config/db.php \ + && echo " 'yii\db\Connection', 'dsn' => 'mysql:host=${MYSQL_HOST};dbname=${MYSQL_DATABASE}', 'username' => '${MYSQL_USER}', 'password' => '${MYSQL_PASSWORD}', 'charset' => 'utf8mb4','enableSchemaCache' => true,'schemaCacheDuration' => 0,'schemaCache' => 'cache','enableQueryCache' => true,'queryCache'=>'qcache','queryCacheDuration'=>60,];">${RED_APP}/config/db.php \ && mkdir -p ${RED_APP}/web/assets ${RED_APP}/runtime ${RED_APP}/web/images/avatars/team ${RED_APP}/web/uploads\ && chown -R www-data ${RED_APP}/web/assets ${RED_APP}/web/images/avatars \ && chown www-data ${RED_APP}/runtime ${RED_APP}/web/uploads \ diff --git a/frontend/config/db-local.php b/frontend/config/db-local.php index 9bca3150c..dc01f3ef2 100644 --- a/frontend/config/db-local.php +++ b/frontend/config/db-local.php @@ -5,11 +5,11 @@ 'username' => 'root', 'password' => '', 'charset' => 'utf8mb4', - 'enableProfiling'=>true, + //'enableProfiling'=>false, //'enableParamLogging'=>true, // Schema cache options (for production environment) 'enableSchemaCache' => true, - 'schemaCacheDuration' => 3600*24, + 'schemaCacheDuration' => 0, 'schemaCache' => 'cache', 'enableQueryCache' => true, 'queryCache'=>'qcache', diff --git a/frontend/models/NotificationQuery.php b/frontend/models/NotificationQuery.php index d3c18112b..6b778fdcd 100644 --- a/frontend/models/NotificationQuery.php +++ b/frontend/models/NotificationQuery.php @@ -9,38 +9,38 @@ */ class NotificationQuery extends \yii\db\ActiveQuery { - public function my() - { - return $this->andWhere('[[player_id]]=:player_id',[':player_id'=>\Yii::$app->user->id]); - } + public function my() + { + return $this->from([new \yii\db\Expression('{{%notification}} USE INDEX (`query-index`)')])->andWhere('[[player_id]]=:player_id', [':player_id' => \Yii::$app->user->id]); + } - public function pending() - { - return $this->andWhere('[[archived]]=0'); - } + public function pending() + { + return $this->andWhere('[[archived]]=0'); + } - public function forPlayer($player_id) - { - return $this->andWhere(['player_id'=>$player_id]); - } - public function forAjax() - { - return $this->select(['id', 'title', 'category', 'body', 'created_at', 'archived']); - } + public function forPlayer($player_id) + { + return $this->andWhere(['player_id' => $player_id]); + } + public function forAjax() + { + return $this->select(['id', 'title', 'category', 'body', 'created_at', 'archived']); + } - /** - * @return Notification[]|array - */ - public function all($db=null) - { - return parent::all($db); - } + /** + * @return Notification[]|array + */ + public function all($db = null) + { + return parent::all($db); + } - /** - * @return Notification|array|null - */ - public function one($db=null) - { - return parent::one($db); - } + /** + * @return Notification|array|null + */ + public function one($db = null) + { + return parent::one($db); + } } diff --git a/frontend/modules/network/models/NetworkTargetScheduleQuery.php b/frontend/modules/network/models/NetworkTargetScheduleQuery.php index 092f9add4..cc8ba4f9f 100644 --- a/frontend/modules/network/models/NetworkTargetScheduleQuery.php +++ b/frontend/modules/network/models/NetworkTargetScheduleQuery.php @@ -11,7 +11,7 @@ class NetworkTargetScheduleQuery extends \yii\db\ActiveQuery { public function pending() { - return $this->andWhere('migration_date >= NOW()')->orderBy(['migration_date'=>SORT_ASC,'network_id'=>SORT_ASC]); + return $this->orderBy(['migration_date'=>SORT_ASC,'network_id'=>SORT_ASC]); } /** diff --git a/frontend/modules/target/controllers/DefaultController.php b/frontend/modules/target/controllers/DefaultController.php index 3cc621067..60a5a6700 100644 --- a/frontend/modules/target/controllers/DefaultController.php +++ b/frontend/modules/target/controllers/DefaultController.php @@ -272,10 +272,13 @@ public function actionView(int $id) ->where(['model_id' => $findings, 'model' => 'finding']) ->orWhere(['model_id' => $treasures, 'model' => 'treasure']) ->orWhere(['model_id' => $id, 'model' => 'headshot']); - if (\Yii::$app->user->isGuest) { - $model->andWhere(['academic' => 0]); - } else { - $model->andWhere(['academic' => \Yii::$app->user->identity->academic]); + if(\Yii::$app->sys->academic_grouping!==false) + { + if (\Yii::$app->user->isGuest) { + $model->andWhere(['academic' => 0]); + } else { + $model->andWhere(['academic' => \Yii::$app->user->identity->academic]); + } } $dataProvider = new ActiveDataProvider([ diff --git a/schemas/echoCTF.sql b/schemas/echoCTF.sql index f16a885ea..596a844d5 100644 --- a/schemas/echoCTF.sql +++ b/schemas/echoCTF.sql @@ -152,6 +152,7 @@ CREATE TABLE `challenge` ( `public` tinyint(1) NOT NULL DEFAULT 1, PRIMARY KEY (`id`), UNIQUE KEY `name` (`name`), + KEY `idx-timer` (`timer`), KEY `idx-challenge-public` (`public`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; @@ -170,6 +171,7 @@ CREATE TABLE `challenge_solver` ( PRIMARY KEY (`challenge_id`,`player_id`), KEY `idx-challenge_solver-challenge_id` (`challenge_id`), KEY `idx-challenge_solver-player_id` (`player_id`), + KEY `idx-timer` (`timer`), CONSTRAINT `fk-challenge_solver-challenge_id` FOREIGN KEY (`challenge_id`) REFERENCES `challenge` (`id`) ON DELETE CASCADE, CONSTRAINT `fk-challenge_solver-player_id` FOREIGN KEY (`player_id`) REFERENCES `player` (`id`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; @@ -355,6 +357,7 @@ CREATE TABLE `headshot` ( `rating` smallint(6) DEFAULT -1, `first` tinyint(1) DEFAULT 0, PRIMARY KEY (`player_id`,`target_id`), + KEY `query-index` (`target_id`,`created_at`), KEY `idx-headshot-player_id` (`player_id`), KEY `idx-headshot-target_id` (`target_id`), CONSTRAINT `fk-headshot-player_id` FOREIGN KEY (`player_id`) REFERENCES `player` (`id`) ON DELETE CASCADE, @@ -493,6 +496,7 @@ CREATE TABLE `layout_override` ( `repeating` tinyint(1) NOT NULL DEFAULT 0, `valid_from` datetime NOT NULL, `valid_until` datetime NOT NULL, + KEY `query-index` (player_id,valid_from,valid_until, repeating), PRIMARY KEY (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; @@ -575,7 +579,8 @@ CREATE TABLE `network` ( `weight` int(11) NOT NULL DEFAULT 0, PRIMARY KEY (`id`), UNIQUE KEY `name` (`name`), - KEY `idx-network-weight` (`weight`) + KEY `idx-network-weight` (`weight`), + KEY `count-active-network` (`active`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- @@ -626,6 +631,7 @@ CREATE TABLE `network_target_schedule` ( `created_at` datetime NOT NULL, `updated_at` timestamp NOT NULL DEFAULT current_timestamp() ON UPDATE current_timestamp(), PRIMARY KEY (`id`), + KEY `query-index` (`target_id`,`migration_date`,`network_id`), KEY `idx-network_target_schedule-target_id` (`target_id`), KEY `idx-network_target_schedule-network_id` (`network_id`), CONSTRAINT `fk-network_target_schedule-network_id` FOREIGN KEY (`network_id`) REFERENCES `network` (`id`) ON DELETE SET NULL ON UPDATE CASCADE, @@ -662,6 +668,7 @@ CREATE TABLE `notification` ( `created_at` datetime DEFAULT NULL, `updated_at` datetime DEFAULT NULL, PRIMARY KEY (`id`), + KEY `query-index` (player_id,archived,created_at,id), KEY `idx-notification-player_id` (`player_id`), KEY `idx-notification-archived` (`archived`), KEY `idx-notification-category` (`category`), @@ -1166,6 +1173,7 @@ CREATE TABLE `question` ( `parent` int(11) DEFAULT 0, PRIMARY KEY (`id`), UNIQUE KEY `challenge_id` (`challenge_id`,`name`), + KEY `order-query-index` (`challenge_id`,`weight`,`id`), CONSTRAINT `question_ibfk_1` FOREIGN KEY (`challenge_id`) REFERENCES `challenge` (`id`) ON DELETE CASCADE ON UPDATE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; @@ -1337,6 +1345,7 @@ CREATE TABLE `stream` ( `pubmessage` mediumtext DEFAULT NULL, `ts` timestamp NOT NULL DEFAULT current_timestamp(), PRIMARY KEY (`id`), + KEY `query-index` (ts,id,model_id,model(20)), KEY `player_id` (`player_id`), CONSTRAINT `stream_ibfk_1` FOREIGN KEY (`player_id`) REFERENCES `player` (`id`) ON DELETE CASCADE ON UPDATE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='Information stream for participants and public alike'; @@ -1576,6 +1585,8 @@ CREATE TABLE `team` ( UNIQUE KEY `name` (`name`), UNIQUE KEY `token` (`token`), KEY `owner_id` (`owner_id`), + KEY `idx-academic` (`academic`), + KEY `idx-ts` (`ts`), CONSTRAINT `team_ibfk_1` FOREIGN KEY (`owner_id`) REFERENCES `player` (`id`) ON DELETE CASCADE ON UPDATE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; @@ -1627,6 +1638,8 @@ CREATE TABLE `team_player` ( `approved` tinyint(1) DEFAULT 0, `ts` timestamp NOT NULL DEFAULT current_timestamp(), PRIMARY KEY (`id`), + KEY `idx-approved` (`approved`), + KEY `idx-ts` (`ts`), UNIQUE KEY `player_id` (`player_id`), UNIQUE KEY `team_id` (`team_id`,`player_id`), CONSTRAINT `team_player_ibfk_1` FOREIGN KEY (`team_id`) REFERENCES `team` (`id`) ON DELETE CASCADE ON UPDATE CASCADE, @@ -1704,6 +1717,7 @@ CREATE TABLE `treasure` ( UNIQUE KEY `code` (`code`), KEY `target_id` (`target_id`), KEY `idx-treasure-weight` (`weight`), + KEY `query-index` (`target_id`,`weight`,`id`), CONSTRAINT `treasure_ibfk_1` FOREIGN KEY (`target_id`) REFERENCES `target` (`id`) ON DELETE CASCADE ON UPDATE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='Claimable points by the user, through hidden codes and files'; @@ -1842,7 +1856,8 @@ CREATE TABLE `vpn_template` ( `created_at` datetime DEFAULT NULL, `updated_at` datetime DEFAULT NULL, PRIMARY KEY (`id`), - UNIQUE KEY `name` (`name`) + UNIQUE KEY `name` (`name`), + KEY `query-index` (active,visible,client,`name`(60)) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- @@ -1864,6 +1879,7 @@ CREATE TABLE `writeup` ( `id` int(11) NOT NULL AUTO_INCREMENT, PRIMARY KEY (`player_id`,`target_id`), UNIQUE KEY `id` (`id`), + KEY `query-index` (target_id,approved,created_at), KEY `idx-writeup-player_id` (`player_id`), KEY `idx-writeup-target_id` (`target_id`), KEY `fk_language_id` (`language_id`),