|
@@ -0,0 +1,577 @@
|
|
|
+do $$
|
|
|
+begin
|
|
|
+/*
|
|
|
+Скрипт создания информационной базы данных
|
|
|
+Согласно технического задания https://git.hostfl.ru/VolovikovAlex/Study2025
|
|
|
+Редакция 2025-02-12
|
|
|
+Edit by valex
|
|
|
+*/
|
|
|
+
|
|
|
+
|
|
|
+/*
|
|
|
+ 1. Удаляем старые элементы
|
|
|
+ ======================================
|
|
|
+ */
|
|
|
+
|
|
|
+raise notice 'Запускаем создание новой структуры базы данных meteo';
|
|
|
+begin
|
|
|
+
|
|
|
+ -- Связи
|
|
|
+ alter table if exists public.measurment_input_params
|
|
|
+ drop constraint if exists measurment_type_id_fk;
|
|
|
+
|
|
|
+ alter table if exists public.employees
|
|
|
+ drop constraint if exists military_rank_id_fk;
|
|
|
+
|
|
|
+ alter table if exists public.measurment_baths
|
|
|
+ drop constraint if exists measurment_input_param_id_fk;
|
|
|
+
|
|
|
+ alter table if exists public.measurment_baths
|
|
|
+ drop constraint if exists emploee_id_fk;
|
|
|
+
|
|
|
+
|
|
|
+ -- Таблицы
|
|
|
+ drop table if exists public.measurment_input_params;
|
|
|
+ drop table if exists public.measurment_baths;
|
|
|
+ drop table if exists public.employees;
|
|
|
+ drop table if exists public.measurment_types;
|
|
|
+ drop table if exists public.military_ranks;
|
|
|
+ drop table if exists public.measurment_settings;
|
|
|
+
|
|
|
+ -- Нумераторы
|
|
|
+ drop sequence if exists public.measurment_input_params_seq;
|
|
|
+ drop sequence if exists public.measurment_baths_seq;
|
|
|
+ drop sequence if exists public.employees_seq;
|
|
|
+ drop sequence if exists public.military_ranks_seq;
|
|
|
+ drop sequence if exists public.measurment_types_seq;
|
|
|
+end;
|
|
|
+
|
|
|
+raise notice 'Удаление старых данных выполнено успешно';
|
|
|
+
|
|
|
+/*
|
|
|
+ 2. Добавляем структуры данных
|
|
|
+ ================================================
|
|
|
+ */
|
|
|
+
|
|
|
+-- Справочник должностей
|
|
|
+create table military_ranks
|
|
|
+(
|
|
|
+ id integer primary key not null,
|
|
|
+ description character varying(255)
|
|
|
+);
|
|
|
+
|
|
|
+insert into military_ranks(id, description)
|
|
|
+values(1,'Рядовой'),(2,'Лейтенант');
|
|
|
+
|
|
|
+create sequence military_ranks_seq start 3;
|
|
|
+
|
|
|
+alter table military_ranks alter column id set default nextval('public.military_ranks_seq');
|
|
|
+
|
|
|
+-- Пользователя
|
|
|
+create table employees
|
|
|
+(
|
|
|
+ id integer primary key not null,
|
|
|
+ name text,
|
|
|
+ birthday timestamp ,
|
|
|
+ military_rank_id integer
|
|
|
+);
|
|
|
+
|
|
|
+insert into employees(id, name, birthday,military_rank_id )
|
|
|
+values(1, 'Воловиков Александр Сергеевич','1978-06-24', 2);
|
|
|
+
|
|
|
+create sequence employees_seq start 2;
|
|
|
+
|
|
|
+alter table employees alter column id set default nextval('public.employees_seq');
|
|
|
+
|
|
|
+
|
|
|
+-- Устройства для измерения
|
|
|
+create table measurment_types
|
|
|
+(
|
|
|
+ id integer primary key not null,
|
|
|
+ short_name character varying(50),
|
|
|
+ description text
|
|
|
+);
|
|
|
+
|
|
|
+insert into measurment_types(id, short_name, description)
|
|
|
+values(1, 'ДМК', 'Десантный метео комплекс'),
|
|
|
+(2,'ВР','Ветровое ружье');
|
|
|
+
|
|
|
+create sequence measurment_types_seq start 3;
|
|
|
+
|
|
|
+alter table measurment_types alter column id set default nextval('public.measurment_types_seq');
|
|
|
+
|
|
|
+-- Таблица с параметрами
|
|
|
+create table measurment_input_params
|
|
|
+(
|
|
|
+ id integer primary key not null,
|
|
|
+ measurment_type_id integer not null,
|
|
|
+ height numeric(8,2) default 0,
|
|
|
+ temperature numeric(8,2) default 0,
|
|
|
+ pressure numeric(8,2) default 0,
|
|
|
+ wind_direction numeric(8,2) default 0,
|
|
|
+ wind_speed numeric(8,2) default 0
|
|
|
+);
|
|
|
+
|
|
|
+insert into measurment_input_params(id, measurment_type_id, height, temperature, pressure, wind_direction,wind_speed )
|
|
|
+values(1, 1, 100,12,34,0.2,45);
|
|
|
+
|
|
|
+create sequence measurment_input_params_seq start 2;
|
|
|
+
|
|
|
+alter table measurment_input_params alter column id set default nextval('public.measurment_input_params_seq');
|
|
|
+
|
|
|
+-- Таблица с историей
|
|
|
+create table measurment_baths
|
|
|
+(
|
|
|
+ id integer primary key not null,
|
|
|
+ emploee_id integer not null,
|
|
|
+ measurment_input_param_id integer not null,
|
|
|
+ started timestamp default now()
|
|
|
+);
|
|
|
+
|
|
|
+
|
|
|
+insert into measurment_baths(id, emploee_id, measurment_input_param_id)
|
|
|
+values(1, 1, 1);
|
|
|
+
|
|
|
+create sequence measurment_baths_seq start 2;
|
|
|
+
|
|
|
+alter table measurment_baths alter column id set default nextval('public.measurment_baths_seq');
|
|
|
+
|
|
|
+-- Таблица с настройками
|
|
|
+create table measurment_settings
|
|
|
+(
|
|
|
+ key character varying(100) primary key not null,
|
|
|
+ value character varying(255) ,
|
|
|
+ description text
|
|
|
+);
|
|
|
+
|
|
|
+
|
|
|
+insert into measurment_settings(key, value, description)
|
|
|
+values('min_temperature', '-10', 'Минимальное значение температуры'),
|
|
|
+('max_temperature', '50', 'Максимальное значение температуры'),
|
|
|
+('min_pressure','500','Минимальное значение давления'),
|
|
|
+('max_pressure','900','Максимальное значение давления'),
|
|
|
+('min_wind_direction','0','Минимальное значение направления ветра'),
|
|
|
+('max_wind_direction','59','Максимальное значение направления ветра'),
|
|
|
+('calc_table_temperature','15.9','Табличное значение температуры'),
|
|
|
+('calc_table_pressure','750','Табличное значение наземного давления');
|
|
|
+
|
|
|
+
|
|
|
+raise notice 'Создание общих справочников и наполнение выполнено успешно';
|
|
|
+
|
|
|
+/*
|
|
|
+ 3. Подготовка расчетных структур
|
|
|
+ ==========================================
|
|
|
+ */
|
|
|
+
|
|
|
+drop table if exists calc_temperatures_correction;
|
|
|
+create table calc_temperatures_correction
|
|
|
+(
|
|
|
+ temperature numeric(8,2) primary key,
|
|
|
+ correction numeric(8,2)
|
|
|
+);
|
|
|
+
|
|
|
+insert into public.calc_temperatures_correction(temperature, correction)
|
|
|
+Values(0, 0.5),(5, 0.5),(10, 1), (20,1), (25, 2), (30, 3.5), (40, 4.5);
|
|
|
+
|
|
|
+drop type if exists interpolation_type;
|
|
|
+create type interpolation_type as
|
|
|
+(
|
|
|
+ x0 numeric(8,2),
|
|
|
+ x1 numeric(8,2),
|
|
|
+ y0 numeric(8,2),
|
|
|
+ y1 numeric(8,2)
|
|
|
+);
|
|
|
+
|
|
|
+drop type if exists input_params;
|
|
|
+create type input_params as
|
|
|
+(
|
|
|
+ height numeric(8,2),
|
|
|
+ temperature numeric(8,2),
|
|
|
+ pressure numeric(8,2),
|
|
|
+ wind_direction numeric(8,2),
|
|
|
+ wind_speed numeric(8,2)
|
|
|
+);
|
|
|
+
|
|
|
+raise notice 'Расчетные структуры сформированы';
|
|
|
+
|
|
|
+/*
|
|
|
+ 4. Создание связей
|
|
|
+ ==========================================
|
|
|
+ */
|
|
|
+
|
|
|
+begin
|
|
|
+
|
|
|
+ alter table public.measurment_baths
|
|
|
+ add constraint emploee_id_fk
|
|
|
+ foreign key (emploee_id)
|
|
|
+ references public.employees (id);
|
|
|
+
|
|
|
+ alter table public.measurment_baths
|
|
|
+ add constraint measurment_input_param_id_fk
|
|
|
+ foreign key(measurment_input_param_id)
|
|
|
+ references public.measurment_input_params(id);
|
|
|
+
|
|
|
+ alter table public.measurment_input_params
|
|
|
+ add constraint measurment_type_id_fk
|
|
|
+ foreign key(measurment_type_id)
|
|
|
+ references public.measurment_types (id);
|
|
|
+
|
|
|
+ alter table public.employees
|
|
|
+ add constraint military_rank_id_fk
|
|
|
+ foreign key(military_rank_id)
|
|
|
+ references public.military_ranks (id);
|
|
|
+
|
|
|
+end;
|
|
|
+
|
|
|
+raise notice 'Связи сформированы';
|
|
|
+
|
|
|
+/*
|
|
|
+ 4. Создает расчетные и вспомогательные функции
|
|
|
+ ==========================================
|
|
|
+ */
|
|
|
+
|
|
|
+drop function if exists public.fn_calc_header_temperature;
|
|
|
+create function public.fn_calc_header_temperature(
|
|
|
+ par_temperature numeric(8,2))
|
|
|
+ returns numeric(8,2)
|
|
|
+ language 'plpgsql'
|
|
|
+as $BODY$
|
|
|
+declare
|
|
|
+ default_temperature numeric(8,2) default 15.9;
|
|
|
+ default_temperature_key character varying default 'calc_table_temperature' ;
|
|
|
+ virtual_temperature numeric(8,2) default 0;
|
|
|
+ deltaTv numeric(8,2) default 0;
|
|
|
+ var_result numeric(8,2) default 0;
|
|
|
+begin
|
|
|
+
|
|
|
+ raise notice 'Расчет отклонения приземной виртуальной температуры по температуре %', par_temperature;
|
|
|
+
|
|
|
+ -- Определим табличное значение температуры
|
|
|
+ Select coalesce(value::numeric(8,2), default_temperature)
|
|
|
+ from public.measurment_settings
|
|
|
+ into virtual_temperature
|
|
|
+ where
|
|
|
+ key = default_temperature_key;
|
|
|
+
|
|
|
+ -- Вирутальная поправка
|
|
|
+ deltaTv := par_temperature +
|
|
|
+ public.fn_calc_temperature_interpolation(par_temperature => par_temperature);
|
|
|
+
|
|
|
+ -- Отклонение приземной виртуальной температуры
|
|
|
+ var_result := deltaTv - virtual_temperature;
|
|
|
+
|
|
|
+ return var_result;
|
|
|
+end;
|
|
|
+$BODY$;
|
|
|
+
|
|
|
+
|
|
|
+
|
|
|
+drop function if exists public.fn_calc_header_period;
|
|
|
+create function public.fn_calc_header_period(
|
|
|
+ par_period timestamp with time zone)
|
|
|
+ RETURNS text
|
|
|
+ LANGUAGE 'sql'
|
|
|
+ COST 100
|
|
|
+ VOLATILE PARALLEL UNSAFE
|
|
|
+
|
|
|
+RETURN ((((CASE WHEN (EXTRACT(day FROM par_period) < (10)::numeric) THEN '0'::text ELSE ''::text END || (EXTRACT(day FROM par_period))::text) || CASE WHEN (EXTRACT(hour FROM par_period) < (10)::numeric) THEN '0'::text ELSE ''::text END) || (EXTRACT(hour FROM par_period))::text) || "left"(CASE WHEN (EXTRACT(minute FROM par_period) < (10)::numeric) THEN '0'::text ELSE (EXTRACT(minute FROM par_period))::text END, 1));
|
|
|
+
|
|
|
+
|
|
|
+
|
|
|
+drop function if exists public.fn_calc_header_pressure;
|
|
|
+create function public.fn_calc_header_pressure
|
|
|
+(
|
|
|
+ par_pressure numeric(8,2))
|
|
|
+ returns numeric(8,2)
|
|
|
+ language 'plpgsql'
|
|
|
+as $body$
|
|
|
+declare
|
|
|
+ default_pressure numeric(8,2) default 750;
|
|
|
+ table_pressure numeric(8,2) default null;
|
|
|
+ default_pressure_key character varying default 'calc_table_pressure' ;
|
|
|
+begin
|
|
|
+
|
|
|
+ raise notice 'Расчет отклонения наземного давления для %', par_pressure;
|
|
|
+
|
|
|
+ -- Определяем граничное табличное значение
|
|
|
+ if not exists (select 1 from public.measurment_settings where key = default_pressure_key ) then
|
|
|
+ Begin
|
|
|
+ table_pressure := default_pressure;
|
|
|
+ end;
|
|
|
+ else
|
|
|
+ begin
|
|
|
+ select value::numeric(18,2)
|
|
|
+ into table_pressure
|
|
|
+ from public.measurment_settings where key = default_pressure_key;
|
|
|
+ end;
|
|
|
+ end if;
|
|
|
+
|
|
|
+
|
|
|
+ -- Результат
|
|
|
+ return par_pressure - coalesce(table_pressure,table_pressure) ;
|
|
|
+
|
|
|
+end;
|
|
|
+$body$;
|
|
|
+
|
|
|
+
|
|
|
+
|
|
|
+drop function if exists public.fn_calc_temperature_interpolation;
|
|
|
+create function public.fn_calc_temperature_interpolation(
|
|
|
+ par_temperature numeric(8,2))
|
|
|
+ returns numeric
|
|
|
+ language 'plpgsql'
|
|
|
+ as $body$
|
|
|
+ -- Расчет интерполяции
|
|
|
+ declare
|
|
|
+ var_interpolation interpolation_type;
|
|
|
+ var_result numeric(8,2) default 0;
|
|
|
+ var_min_temparure numeric(8,2) default 0;
|
|
|
+ var_max_temperature numeric(8,2) default 0;
|
|
|
+ var_denominator numeric(8,2) default 0;
|
|
|
+ begin
|
|
|
+
|
|
|
+ raise notice 'Расчет интерполяции для температуры %', par_temperature;
|
|
|
+
|
|
|
+ -- Проверим, возможно температура совпадает со значением в справочнике
|
|
|
+ if exists (select 1 from public.calc_temperatures_correction where temperature = par_temperature ) then
|
|
|
+ begin
|
|
|
+ select correction
|
|
|
+ into var_result
|
|
|
+ from public.calc_temperatures_correction
|
|
|
+ where
|
|
|
+ temperature = par_temperature;
|
|
|
+ end;
|
|
|
+ else
|
|
|
+ begin
|
|
|
+ -- Получим диапазон в котором работают поправки
|
|
|
+ select min(temperature), max(temperature)
|
|
|
+ into var_min_temparure, var_max_temperature
|
|
|
+ from public.calc_temperatures_correction;
|
|
|
+
|
|
|
+ if par_temperature < var_min_temparure or
|
|
|
+ par_temperature > var_max_temperature then
|
|
|
+
|
|
|
+ raise exception 'Некорректно передан параметр! Невозможно рассчитать поправку. Значение должно укладываться в диаппазон: %, %',
|
|
|
+ var_min_temparure, var_max_temperature;
|
|
|
+ end if;
|
|
|
+
|
|
|
+ -- Получим граничные параметры
|
|
|
+
|
|
|
+ select x0, y0, x1, y1
|
|
|
+ into var_interpolation.x0, var_interpolation.y0, var_interpolation.x1, var_interpolation.y1
|
|
|
+ from
|
|
|
+ (
|
|
|
+ select t1.temperature as x0, t1.correction as y0
|
|
|
+ from public.calc_temperatures_correction as t1
|
|
|
+ where t1.temperature <= par_temperature
|
|
|
+ order by t1.temperature desc
|
|
|
+ limit 1
|
|
|
+ ) as leftPart
|
|
|
+ cross join
|
|
|
+ (
|
|
|
+ select t1.temperature as x1, t1.correction as y1
|
|
|
+ from public.calc_temperatures_correction as t1
|
|
|
+ where t1.temperature >= par_temperature
|
|
|
+ order by t1.temperature
|
|
|
+ limit 1
|
|
|
+ ) as rightPart;
|
|
|
+
|
|
|
+ raise notice 'Граничные значения %', var_interpolation;
|
|
|
+
|
|
|
+ -- Расчет поправки
|
|
|
+ var_denominator := var_interpolation.x1 - var_interpolation.x0;
|
|
|
+ if var_denominator = 0.0 then
|
|
|
+
|
|
|
+ raise exception 'Деление на нуль. Возможно, некорректные данные в таблице с поправками!';
|
|
|
+
|
|
|
+ end if;
|
|
|
+
|
|
|
+ var_result := (par_temperature - var_interpolation.x0) * (var_interpolation.y1 - var_interpolation.y0) / var_denominator + var_interpolation.y0;
|
|
|
+
|
|
|
+ end;
|
|
|
+ end if;
|
|
|
+
|
|
|
+ return var_result;
|
|
|
+
|
|
|
+end;
|
|
|
+$body$;
|
|
|
+
|
|
|
+-- Функция для генерации случайной даты
|
|
|
+drop function if exists fn_get_random_timestamp;
|
|
|
+create function fn_get_random_timestamp(
|
|
|
+ par_min_value timestamp,
|
|
|
+ par_max_value timestamp)
|
|
|
+returns timestamp
|
|
|
+language 'plpgsql'
|
|
|
+as $body$
|
|
|
+begin
|
|
|
+ return random() * (par_max_value - par_min_value) + par_min_value;
|
|
|
+end;
|
|
|
+$body$;
|
|
|
+
|
|
|
+-- Функция для генерации случайного целого числа из диаппазона
|
|
|
+drop function if exists fn_get_randon_integer;
|
|
|
+create function fn_get_randon_integer(
|
|
|
+ par_min_value integer,
|
|
|
+ par_max_value integer
|
|
|
+ )
|
|
|
+returns integer
|
|
|
+language 'plpgsql'
|
|
|
+as $body$
|
|
|
+begin
|
|
|
+ return floor((par_max_value + 1 - par_min_value)*random())::integer + par_min_value;
|
|
|
+end;
|
|
|
+$body$;
|
|
|
+
|
|
|
+-- Функция для гнерации случайного текста
|
|
|
+drop function if exists fn_get_random_text;
|
|
|
+create function fn_get_random_text(
|
|
|
+ par_length int,
|
|
|
+ par_list_of_chars text DEFAULT 'АБВГДЕЁЖЗИЙКЛМНОПРСТУФХЦЧШЩЪЫЬЭЮЯабвгдеёжзийклмнопрстуфхцчшщъыьэюяABCDEFGHIJKLMNOPQRSTUVWXYZabcdefghijklmnopqrstuvwxyz_0123456789'
|
|
|
+)
|
|
|
+returns text
|
|
|
+language 'plpgsql'
|
|
|
+as $body$
|
|
|
+declare
|
|
|
+ var_len_of_list integer default length(par_list_of_chars);
|
|
|
+ var_position integer;
|
|
|
+ var_result text = '';
|
|
|
+ var_random_number integer;
|
|
|
+ var_max_value integer;
|
|
|
+ var_min_value integer;
|
|
|
+begin
|
|
|
+
|
|
|
+ var_min_value := 10;
|
|
|
+ var_max_value := 50;
|
|
|
+
|
|
|
+ for var_position in 1 .. par_length loop
|
|
|
+ -- добавляем к строке случайный символ
|
|
|
+ var_random_number := fn_get_randon_integer(var_min_value, var_max_value );
|
|
|
+ var_result := var_result || substr(par_list_of_chars, var_random_number ,1);
|
|
|
+ end loop;
|
|
|
+
|
|
|
+ return var_result;
|
|
|
+
|
|
|
+end;
|
|
|
+$body$;
|
|
|
+
|
|
|
+
|
|
|
+raise notice 'Структура сформирована успешно';
|
|
|
+end $$;
|
|
|
+
|
|
|
+-- Проверка расчета
|
|
|
+do $$
|
|
|
+declare
|
|
|
+ var_pressure_value numeric(8,2) default 0;
|
|
|
+ var_temperature_value numeric(8,2) default 0;
|
|
|
+
|
|
|
+ var_period text;
|
|
|
+ var_pressure text;
|
|
|
+ var_height text;
|
|
|
+ var_temperature text;
|
|
|
+begin
|
|
|
+
|
|
|
+ var_pressure_value := public.fn_calc_header_pressure(743);
|
|
|
+ var_temperature_value := public.fn_calc_header_temperature(23);
|
|
|
+
|
|
|
+ select
|
|
|
+ -- Дата
|
|
|
+ public.fn_calc_header_period(now()) as "ДДЧЧМ",
|
|
|
+ --Высота расположения метеопоста над уровнем моря.
|
|
|
+ lpad( 340::text, 4, '0' ) as "ВВВВ",
|
|
|
+ -- Отклонение наземного давления атмосферы
|
|
|
+ lpad(
|
|
|
+ case when var_pressure_value < 0 then
|
|
|
+ '5'
|
|
|
+ else ''
|
|
|
+ end ||
|
|
|
+ lpad ( abs((var_pressure_value)::int)::text,2,'0')
|
|
|
+ , 3, '0') as "БББ",
|
|
|
+ -- Отклонение приземной виртуальной температуры
|
|
|
+ lpad(
|
|
|
+ case when var_temperature_value < 0 then
|
|
|
+ '5'
|
|
|
+ else
|
|
|
+ ''
|
|
|
+ end ||
|
|
|
+ (var_temperature_value::int)::text
|
|
|
+ , 2,'0') as "TT"
|
|
|
+ into
|
|
|
+ var_period, var_height, var_pressure, var_temperature;
|
|
|
+
|
|
|
+ raise notice '==============================';
|
|
|
+ raise notice 'Пример расчета метео приближенный';
|
|
|
+ raise notice ' ДДЧЧМ %, ВВВВ %, БББ % , TT %', var_period, var_height, var_pressure, var_temperature;
|
|
|
+
|
|
|
+end $$;
|
|
|
+
|
|
|
+-- Генерация тестовых данных
|
|
|
+
|
|
|
+
|
|
|
+do $$
|
|
|
+declare
|
|
|
+ var_position integer;
|
|
|
+ var_emploee_ids integer[];
|
|
|
+ var_emploee_quantity integer default 5;
|
|
|
+ var_min_rank integer;
|
|
|
+ var_max_rank integer;
|
|
|
+ var_emploee_id integer;
|
|
|
+ var_current_emploee_id integer;
|
|
|
+ var_index integer;
|
|
|
+ var_measure_type_id integer;
|
|
|
+ var_measure_input_data_id integer;
|
|
|
+begin
|
|
|
+
|
|
|
+ -- Определяем макс дипазон по должностям
|
|
|
+ select min(id), max(id)
|
|
|
+ into var_min_rank,var_max_rank
|
|
|
+ from public.military_ranks;
|
|
|
+
|
|
|
+
|
|
|
+ -- Формируем список пользователей
|
|
|
+ for var_position in 1 .. var_emploee_quantity loop
|
|
|
+ insert into public.employees(name, birthday, military_rank_id )
|
|
|
+ select
|
|
|
+ fn_get_random_text(25), -- name
|
|
|
+ fn_get_random_timestamp('1978-01-01','2000-01-01'), -- birthday
|
|
|
+ fn_get_randon_integer(var_min_rank, var_max_rank) -- military_rank_id
|
|
|
+ ;
|
|
|
+ select id into var_emploee_id from public.employees order by id desc limit 1;
|
|
|
+ var_emploee_ids := var_emploee_ids || var_emploee_id;
|
|
|
+ end loop;
|
|
|
+
|
|
|
+ raise notice 'Сформированы тестовые пользователи %', var_emploee_ids;
|
|
|
+
|
|
|
+ -- Формируем для каждого по 100 измерений
|
|
|
+ foreach var_current_emploee_id in ARRAY var_emploee_ids LOOP
|
|
|
+ for var_index in 1 .. 100 loop
|
|
|
+ var_measure_type_id := fn_get_randon_integer(1,2);
|
|
|
+
|
|
|
+ insert into public.measurment_input_params(measurment_type_id, height, temperature, pressure, wind_direction, wind_speed)
|
|
|
+ select
|
|
|
+ var_measure_type_id,
|
|
|
+ fn_get_randon_integer(0,600)::numeric(8,2), -- height
|
|
|
+ fn_get_randon_integer(0, 50)::numeric(8,2), -- temperature
|
|
|
+ fn_get_randon_integer(500, 850)::numeric(8,2), -- pressure
|
|
|
+ fn_get_randon_integer(0,59)::numeric(8,2), -- ind_direction
|
|
|
+ fn_get_randon_integer(0,59)::numeric(8,2) -- wind_speed
|
|
|
+ ;
|
|
|
+
|
|
|
+ select id into var_measure_input_data_id from measurment_input_params order by id desc limit 1;
|
|
|
+
|
|
|
+ insert into public.measurment_baths( emploee_id, measurment_input_param_id, started)
|
|
|
+ select
|
|
|
+ var_current_emploee_id,
|
|
|
+ var_measure_input_data_id,
|
|
|
+ fn_get_random_timestamp('2025-02-01 00:00', '2025-02-05 00:00')
|
|
|
+ ;
|
|
|
+ end loop;
|
|
|
+
|
|
|
+ end loop;
|
|
|
+
|
|
|
+ raise notice 'Набор тестовых данных сформирован успешно';
|
|
|
+
|
|
|
+end $$;
|
|
|
+
|
|
|
+-- Проверки
|
|
|
+select * from public.measurment_input_params;
|