Examples of Dr.Web Server Database Queries

Below are examples of the SQL queries to the PostgreSQL database. Queries to other databases may contain some differences due to the features of the database itself and the subtleties of its use.

info

SQL syntax ignores the hierarchy of groups and stations.

To query the database directly

1.Open the Control Center of your Dr.Web Server.

2.Go to the Administration → SQL console section.

3.Write an SQL query. Examples of queries are given below.

4.Click Execute.

Examples of SQL Queries

1.Find stations where Windows Server OS is installed and whose virus databases are earlier than 2019.07.04-00:00:00 UTC (12.0).

SELECT
 stations.name Station,
 groups_list.name OS,
 station_products.crev Bases
FROM
 stations
INNER JOIN groups_list ON groups_list.platform =(
  CAST(stations.lastos AS INTEGER) & ~15728640
 )
AND (
   (
    CAST(stations.lastos AS INTEGER) & 2130706560
   ) = 33554560
 )
INNER JOIN station_products ON station_products.id = stations.id
AND station_products.product = '10-drwbases'
AND station_products.crev < 12020190704000000;

2.Find stations with High and Maximum severity records in the Anti-virus network → Statistics → Status section.

SELECT
 stations.name Station
FROM
 stations
WHERE
 id IN (
  SELECT
    DISTINCT id
  FROM
     station_status
  WHERE
     severity >= 1342177280
 );

3.Get the correspondence between statuses and the number of stations with these statuses.

SELECT
 code Code,
COUNT(code) Num
FROM
 (
  SELECT
    DISTINCT id,
     code
  FROM
     station_status
 ) AS t
GROUP BY
 Code
ORDER BY
 Code;

4.Get the top 10 threats detected from 2019.06.01 through 2019.07.01 on stations included in the group with the identifier '373a9afb-9c9a-4d4d-b9b1-de817b96bcc5' or into any nested groups.

SELECT
 cat_virus.str Threat,
COUNT(cat_virus.str) Num
FROM
 station_infection
INNER JOIN cat_virus ON cat_virus.id = station_infection.virus
WHERE
 station_infection.infectiontime BETWEEN 20190601000000000
AND 20190701000000000
AND station_infection.id IN (
  SELECT
     sid
  FROM
     station_groups
  WHERE
     gid = '373a9afb-9c9a-4d4d-b9b1-de817b96bcc5'
    OR gid IN (
      SELECT
         child
      FROM
         group_children
      WHERE
         id = '373a9afb-9c9a-4d4d-b9b1-de817b96bcc5'
     )
 )
GROUP BY
 cat_virus.str
ORDER BY
 Num DESC
LIMIT
10;

5.Get the top 10 infected stations.

SELECT
 Station,
 Grp,
 Num
FROM
 (
  SELECT
     stations.id,
     groups_list.id,
     stations.name Station,
     groups_list.name Grp,
    COUNT(stations.id) Num
  FROM
     station_infection
    INNER JOIN stations ON station_infection.id = stations.id
    INNER JOIN groups_list ON groups_list.id = stations.gid
  GROUP BY
     stations.id,
     groups_list.id,
     stations.name,
     groups_list.name
  ORDER BY
     Num DESC
  LIMIT
    10
 ) AS t;

6.Remove all stations from user groups that are not primary for those stations.

DELETE FROM
 station_groups;
INSERT INTO station_groups(sid, gid)
SELECT
 stations.id,
 groups_list.id
FROM
 stations
INNER JOIN groups_list ON stations.gid = groups_list.id
AND groups_list.type NOT IN(1, 4);

7.Find objects on the anti-virus network that contain the domain whitelisted in the personal settings of the SpIDer Gate component.

SELECT
 stations.name Station
FROM
 station_cfg
INNER JOIN stations ON stations.id = station_cfg.id
WHERE
 station_cfg.component = 38
AND station_cfg.name = 'WhiteVirUrlList'
AND station_cfg.value = 'domain.tld';
SELECT
 groups_list.name Grp
FROM
 group_cfg
INNER JOIN groups_list ON groups_list.id = group_cfg.id
WHERE
 group_cfg.component = 38
AND group_cfg.name = 'WhiteVirUrlList'
AND group_cfg.value = 'domain.tld';
SELECT
 policy_list.name Policy
FROM
 policy_cfg
INNER JOIN policy_list ON policy_list.id = policy_cfg.id
WHERE
 policy_cfg.component = 38
AND policy_cfg.name = 'WhiteVirUrlList'
AND policy_cfg.value = 'domain.tld';

8.Get the events of unsuccessful administrator logins to the Control Center with the corresponding authorization error codes.

SELECT
 admin_activity.login Login,
 admin_activity.address Address,
 activity_data.value ErrorCode,
 admin_activity.createtime EventTimestamp
FROM
 admin_activity
INNER JOIN activity_data ON admin_activity.record = activity_data.record
WHERE
 admin_activity.oper = 10100
AND admin_activity.status != 1
AND activity_data.item = 'Error';

9.Find stations running Windows OS that do not have required security fixes installed.

SELECT
 stations.name Station
FROM
 stations
WHERE
 id NOT IN (
  SELECT
     station_env_kb.id
  FROM
     station_env_kb
    INNER JOIN stations ON stations.id = station_env_kb.id
  WHERE
     (
      CAST(stations.lastos AS INTEGER) & 2130706432
     )= 33554432
    AND station_env_kb.name IN (
      SELECT
         id
      FROM
         env_strings
      WHERE
         str IN(
          'KB4012212', 'KB4012213', 'KB4012214',
          'KB4012215', 'KB4012216', 'KB4012217',
          'KB4012598'
         )
     )
 );