Skip to content

Add initial statistics for WAF installations

What does this MR do?

Related to #32358 (closed)

This MR adds statistics for WAF installations, we are fetching number of environments where WAF was successfully deployed and is enabled (in logging/blocking) or disabled.

Optimization

exec CREATE INDEX index_clusters_applications_ingress_on_modsecurity ON public.clusters_applications_ingress USING btree (modsecurity_enabled, modsecurity_mode, cluster_id);
# The query has been executed. Duration: 137.000 ms

exec CREATE INDEX index_enabled_clusters_on_id ON public.clusters USING btree (id) WHERE (enabled = true);
# The query has been executed. Duration: 63.000 ms

exec CREATE INDEX index_successful_deployments_on_cluster_id_and_environment_id ON public.deployments USING btree (cluster_id, environment_id) WHERE (status = 2);
# The query has been executed. Duration: 11.308 min

Query

SELECT
  COUNT(DISTINCT "deployments"."environment_id")
FROM "clusters_applications_ingress"
INNER JOIN "clusters" ON "clusters"."id" = "clusters_applications_ingress"."cluster_id"
INNER JOIN "deployments" ON "deployments"."cluster_id" = "clusters"."id"
WHERE
  "clusters_applications_ingress"."modsecurity_enabled" = FALSE
  AND "clusters"."enabled" = TRUE
  AND "deployments"."status" = 2;

Before: https://explain.depesz.com/s/N1r5 (~9.3 min) After: https://explain.depesz.com/s/yqQu (~622 ms)

MIN

SELECT
  MIN("deployments"."environment_id")
FROM "clusters_applications_ingress"
INNER JOIN "clusters" ON "clusters"."id" = "clusters_applications_ingress"."cluster_id"
INNER JOIN "deployments" ON "deployments"."cluster_id" = "clusters"."id"
WHERE
  "clusters_applications_ingress"."modsecurity_enabled" = FALSE
  AND "clusters"."enabled" = TRUE
  AND "deployments"."status" = 2;

https://explain.depesz.com/s/PbyS (~508 ms)

MAX

SELECT
  MAX("deployments"."environment_id")
FROM "clusters_applications_ingress"
INNER JOIN "clusters" ON "clusters"."id" = "clusters_applications_ingress"."cluster_id"
INNER JOIN "deployments" ON "deployments"."cluster_id" = "clusters"."id"
WHERE
  "clusters_applications_ingress"."modsecurity_enabled" = FALSE
  AND "clusters"."enabled" = TRUE
  AND "deployments"."status" = 2;

https://explain.depesz.com/s/wgBx (~520 ms)

BETWEEN

0-1250

SELECT
  COUNT(DISTINCT "deployments"."environment_id")
FROM "clusters_applications_ingress"
INNER JOIN "clusters" ON "clusters"."id" = "clusters_applications_ingress"."cluster_id"
INNER JOIN "deployments" ON "deployments"."cluster_id" = "clusters"."id"
WHERE
  "clusters_applications_ingress"."modsecurity_enabled" = FALSE
  AND "clusters"."enabled" = TRUE
  AND "deployments"."status" = 2
  AND "deployments"."environment_id" BETWEEN 0 AND 1250;

https://explain.depesz.com/s/d7NS (~32 ms)

1250-2500

SELECT
  COUNT(DISTINCT "deployments"."environment_id")
FROM "clusters_applications_ingress"
INNER JOIN "clusters" ON "clusters"."id" = "clusters_applications_ingress"."cluster_id"
INNER JOIN "deployments" ON "deployments"."cluster_id" = "clusters"."id"
WHERE
  "clusters_applications_ingress"."modsecurity_enabled" = FALSE
  AND "clusters"."enabled" = TRUE
  AND "deployments"."status" = 2
  AND "deployments"."environment_id" BETWEEN 1250 AND 2500;

https://explain.depesz.com/s/vs5pn (~13 ms)

Migration output

⋊> env VERBOSE=true bundle exec rake db:migrate:down VERSION=20200402115013
== 20200402115013 AddIndexOnModsecurityToIngress: reverting ===================
-- transaction_open?()
   -> 0.0000s
-- index_exists?(:clusters_applications_ingress, [:modsecurity_enabled, :modsecurity_mode, :cluster_id], {:name=>"index_clusters_applications_ingress_on_modsecurity", :algorithm=>:concurrently})
   -> 0.0035s
-- execute("SET statement_timeout TO 0")
   -> 0.0002s
-- remove_index(:clusters_applications_ingress, {:name=>"index_clusters_applications_ingress_on_modsecurity", :algorithm=>:concurrently, :column=>[:modsecurity_enabled, :modsecurity_mode, :cluster_id]})
   -> 0.0085s
-- execute("RESET ALL")
   -> 0.0002s
== 20200402115013 AddIndexOnModsecurityToIngress: reverted (0.0125s) ==========

⋊> env VERBOSE=true bundle exec rake db:migrate:up VERSION=20200402115013
== 20200402115013 AddIndexOnModsecurityToIngress: migrating ===================
-- transaction_open?()
   -> 0.0000s
-- index_exists?(:clusters_applications_ingress, [:modsecurity_enabled, :modsecurity_mode, :cluster_id], {:name=>"index_clusters_applications_ingress_on_modsecurity", :algorithm=>:concurrently})
   -> 0.0019s
-- execute("SET statement_timeout TO 0")
   -> 0.0001s
-- add_index(:clusters_applications_ingress, [:modsecurity_enabled, :modsecurity_mode, :cluster_id], {:name=>"index_clusters_applications_ingress_on_modsecurity", :algorithm=>:concurrently})
   -> 0.0085s
-- execute("RESET ALL")
   -> 0.0002s
== 20200402115013 AddIndexOnModsecurityToIngress: migrated (0.0109s) ==========

⋊> env VERBOSE=true bundle exec rake db:migrate:down VERSION=20200402115623
^[[A== 20200402115623 AddIndexOnSuccessfulDeploymentAndEnvironmentIdToDeployments: reverting
-- transaction_open?()
   -> 0.0000s
-- index_exists?(:deployments, [:cluster_id, :environment_id], {:where=>"status = 2", :name=>"index_successful_deployments_on_cluster_id_and_environment_id", :algorithm=>:concurrently})
   -> 0.0070s
-- execute("SET statement_timeout TO 0")
   -> 0.0001s
-- remove_index(:deployments, {:where=>"status = 2", :name=>"index_successful_deployments_on_cluster_id_and_environment_id", :algorithm=>:concurrently, :column=>[:cluster_id, :environment_id]})
   -> 0.0054s
-- execute("RESET ALL")
   -> 0.0001s
== 20200402115623 AddIndexOnSuccessfulDeploymentAndEnvironmentIdToDeployments: reverted (0.0129s)

⋊> env VERBOSE=true bundle exec rake db:migrate:up VERSION=20200402115623
== 20200402115623 AddIndexOnSuccessfulDeploymentAndEnvironmentIdToDeployments: migrating
-- transaction_open?()
   -> 0.0000s
-- index_exists?(:deployments, [:cluster_id, :environment_id], {:where=>"status = 2", :name=>"index_successful_deployments_on_cluster_id_and_environment_id", :algorithm=>:concurrently})
   -> 0.0071s
-- execute("SET statement_timeout TO 0")
   -> 0.0002s
-- add_index(:deployments, [:cluster_id, :environment_id], {:where=>"status = 2", :name=>"index_successful_deployments_on_cluster_id_and_environment_id", :algorithm=>:concurrently})
   -> 0.0050s
-- execute("RESET ALL")
   -> 0.0002s
== 20200402115623 AddIndexOnSuccessfulDeploymentAndEnvironmentIdToDeployments: migrated (0.0126s)

Does this MR meet the acceptance criteria?

Conformity

Availability and Testing

Security

If this MR contains changes to processing or storing of credentials or tokens, authorization and authentication methods and other items described in the security review guidelines:

  • [-] Label as security and @ mention @gitlab-com/gl-security/appsec
  • [-] The MR includes necessary changes to maintain consistency between UI, API, email, or other methods
  • [-] Security reports checked/validated by a reviewer from the AppSec team
Edited by Yorick Peterse

Merge request reports