Добавил пояснительную запуску и SQL запросы
This commit is contained in:
commit
dcd467c834
1
.gitignore
vendored
Normal file
1
.gitignore
vendored
Normal file
@ -0,0 +1 @@
|
||||
/.DS_Store
|
117
SQL/AddData.sql
Normal file
117
SQL/AddData.sql
Normal file
@ -0,0 +1,117 @@
|
||||
USE Metro
|
||||
GO
|
||||
|
||||
INSERT INTO stanciya (kod, name, paspotok, kod_vpered, rast_vpered, kod_nazad, rast_nazad, stat)
|
||||
VALUES
|
||||
('1', 'Парк Культуры', '49', '2', '1000', NULL, NULL, 1),
|
||||
('2', 'Кировская', '69', '3', '750', '1', '1000', 1),
|
||||
('3', 'Комсомольская', '89', '4', '1000', '2', '750', 1),
|
||||
('4', 'Автозаводская', '98', '5', '700', '3', '1000', 1),
|
||||
('5', 'Пролетарская', '98', '6', '900', '4', '700', 1),
|
||||
('6', 'Двигатель Революции', '139', '7', '1100', '5', '900', 1),
|
||||
('7', 'Заречная', '218', '8', '1600', '6', '1100', 1),
|
||||
('8', 'Ленинская', '219', '9', '1550', '7', '1600', 1),
|
||||
('9', 'Чкаловская', '123', '10', '1000', '8', '1550', 1),
|
||||
('10', 'Московская', '84', '11', '3000', '9', '1000', 1),
|
||||
('11', 'Горьковская', '47', NULL, NULL, '10', '3000', 1),
|
||||
('12', 'Буревестник', '59', '13', '1150', NULL, NULL, 1),
|
||||
('13', 'Бурнаковская', '95', '14', '1150', '12', '1150', 1),
|
||||
('14', 'Канавинская', '149', '15', '1200', '13', '1150', 1),
|
||||
('15', 'Московская', '200', '16', '2500', '14', '1200', 1),
|
||||
('16', 'Стрелка', '117', '17', '2300', '15', '2500', 1),
|
||||
('17', 'Волга', '68', NULL, NULL, '16', '2300', 1)
|
||||
GO
|
||||
|
||||
|
||||
INSERT INTO vetka
|
||||
VALUES
|
||||
('Красная', 1, 11, 1, 3, 5),
|
||||
('Синяя', 12, 17, 2, 4, 6)
|
||||
GO
|
||||
|
||||
INSERT INTO dispetcher
|
||||
VALUES
|
||||
(123456, 'Александр Акимов', '89102348768', 'Старший Диспетчер', HASHBYTES('MD5','123456')),
|
||||
(748120, 'Евгений Кулик', '89109876543', 'Диспетчер', HASHBYTES('MD5','748120')),
|
||||
(321295, 'Анастасия Азимова', '89103219876', 'Диспетчер', HASHBYTES('MD5','321295')),
|
||||
(398123, 'Евгений Кулик', '89158374921', 'Диспетчер', HASHBYTES('MD5','398123')),
|
||||
(129348, 'Юлия Нагибина', '83927430134', 'Диспетчер', HASHBYTES('MD5','129348'))
|
||||
GO
|
||||
|
||||
|
||||
INSERT INTO typsostav
|
||||
VALUES
|
||||
('1', '81-767 «Москва»', '330', '160', '2686', '3680', 'Пасажирский', '1520', '11'),
|
||||
('2', '81-717', '330', '192', '2670', '3650', 'Пасажирский', '1520', '13'),
|
||||
('5', 'E81-717', '330', '192', '2670', '3650', 'Пасажирский Автоуправляемый', '1520', '13'),
|
||||
('3', 'CMM-2', '0', '30', '2590', '3690', 'Снегоуборочный', '1520', '7'),
|
||||
('4', 'RYT-4', '0', '30', '2700', '3700', 'Промывка Тонелей', '1520', '7')
|
||||
GO
|
||||
|
||||
INSERT INTO psostav
|
||||
VALUES
|
||||
('1', '1', '1', '20432', '20', '4'),
|
||||
('2', '1', '1', '12342', '15', '5'),
|
||||
('3', '1', '1', '20394', '18', '2'),
|
||||
('4', '1', '1', '13321', '17', '3'),
|
||||
('5', '1', '1', '12493', '18', '4'),
|
||||
('6', '1', '1', '12943', '18', '5'),
|
||||
('7', '1', '1', '18242', '20', '2'),
|
||||
('8', '1', '1', '28432', '22', '2'),
|
||||
('9', '1', '1', '21827', '15', '3'),
|
||||
('10', '1', '1', '18212', '12', '3'),
|
||||
('11', '2', '1', '9123', '5', '5'),
|
||||
('12', '2', '1', '8323', '2', '4'),
|
||||
('13', '2', '1', '10212', '3', '3'),
|
||||
('14', '2', '1', '7293', '4', '4'),
|
||||
('15', '2', '2', '3928', '5', 37),
|
||||
('16', '2', '2', '9432', '9', '4'),
|
||||
('17', '2', '2', '3023', '12', '2'),
|
||||
('18', '2', '2', '3943', '2', '4'),
|
||||
('19', '2', '2', '1293', '7', '5'),
|
||||
('20', '2', '2', '9432', '8', '6'),
|
||||
('21', '3', '2', '5034', '10', '3'),
|
||||
('22', '3', '2', '7054', '15', '4'),
|
||||
('23', '4', '2', '15033', '20', '5'),
|
||||
('24', '4', '2', '13495', '22', '2')
|
||||
GO
|
||||
|
||||
INSERT INTO mashinist
|
||||
VALUES
|
||||
(340432, '1', 'Павел Дуров', '89495571599', '7', 'Третья'),
|
||||
(385312, '2', 'Дмитрий Медведев', '', '4', 'Первая'),
|
||||
(586341, '3', 'Михаил Галустян', '86128324123', '8', 'Вторая'),
|
||||
(963453, '4', 'Макс Тарасенко', '89320432123', '1', 'Первая'),
|
||||
(3582395823, '5', 'Егор Крид', '89102938473', '2', 'Первая'),
|
||||
(4599683475, '6', 'Павел Воля', '89159432384', '8', 'Вторая'),
|
||||
(2395834523, '7', 'Максим Голополосов', '83928438899', '15', 'Третья'),
|
||||
(2387574234, '8', 'Роман Фильченков', '', '1', 'Первая'),
|
||||
(4958873644, '9', 'Андрей Рогозов', '', '3', 'Первая'),
|
||||
(4495948242, '10', 'Рамзан Кадыров', '8394838412', '3', 'Первая'),
|
||||
(3988574444, '11', 'Алексей Долматов', '83743745646', '4', 'Первая'),
|
||||
(3384754332, '12', 'Дима Билан', '', '9', 'Третья'),
|
||||
(2340542485, '13', 'Александр Шепс', '83748374212', '5', 'Первая'),
|
||||
(3843743244, '14', 'Николай Соболев', '89102837463', '8', 'Вторая'),
|
||||
(3847738495, '15', 'Вася Вакуленко', '87364521243', '3', 'Первая'),
|
||||
(4838475554, '16', 'Владимир Жириновский', '', '25', 'Первая'),
|
||||
(2283746372, '17', 'Юрий Хованский', '', '15', 'Третья'),
|
||||
(3948577483, '18', 'Макс Брандт', '', '5', 'Первая'),
|
||||
(2398327475, '19', 'Даниил Добродушный', '89057349394', '4', 'Первая'),
|
||||
(4938472384, '20', 'Николай Наумов', '89056743432', '3', 'Первая'),
|
||||
(4039857422, '21', 'Алексей Навальный', '89204930794', '9', 'Вторая'),
|
||||
(9584727343, '22', 'Костя Павлов', '89208956350', '14', 'Третья'),
|
||||
(2944723954, '23', 'Рома Жёлудь', '89027853099', '25', 'Третья'),
|
||||
(2563323954, NULL, 'Сергей Собянин', '89084105484', '34', 'Третья')
|
||||
GO
|
||||
|
||||
INSERT INTO spravka
|
||||
VALUES
|
||||
(1, 'Колодки', '35', 10, 15),
|
||||
(2, 'Пробег', '200000', 0, 23),
|
||||
(3, 'Мотор', '25', 25, 20)
|
||||
GO
|
||||
|
||||
INSERT INTO remont (typik)
|
||||
VALUES
|
||||
(1), (2), (3), (4), (5)
|
||||
GO
|
179
SQL/Create BD.sql
Normal file
179
SQL/Create BD.sql
Normal file
@ -0,0 +1,179 @@
|
||||
USE master
|
||||
GO
|
||||
CREATE DATABASE Metro
|
||||
ON
|
||||
(NAME='Metro_Data',
|
||||
FILENAME='C:\Metro\Metro.mdf',
|
||||
SIZE=5,
|
||||
MAXSIZE=100,
|
||||
FILEGROWTH=2)
|
||||
LOG ON
|
||||
(NAME='Metro_Log',
|
||||
FILENAME='C:\Metro\Metro.ldf',
|
||||
SIZE=5,
|
||||
MAXSIZE=100,
|
||||
FILEGROWTH=2)
|
||||
GO
|
||||
USE Metro
|
||||
GO
|
||||
|
||||
CREATE DEFAULT d_start_time
|
||||
AS '5:15'
|
||||
GO
|
||||
|
||||
CREATE DEFAULT d_finish_time
|
||||
AS '23:55'
|
||||
GO
|
||||
|
||||
CREATE RULE r_kvalif
|
||||
AS @x IN ('Ïåðâàÿ','Âòîðàÿ','Òðåòüÿ')
|
||||
GO
|
||||
|
||||
CREATE TYPE t_doljnost
|
||||
FROM nvarchar(20) not null
|
||||
GO
|
||||
CREATE DEFAULT d_doljnost
|
||||
AS 'Äèñïåò÷åð'
|
||||
GO
|
||||
EXEC sp_bindefault 'd_doljnost', 't_doljnost'
|
||||
GO
|
||||
CREATE RULE r_doljnost
|
||||
AS @x IN ('Äèñïåò÷åð', 'Ñòàðøèé Äèñïåò÷åð')
|
||||
GO
|
||||
EXEC sp_bindrule 'r_doljnost', 't_doljnost'
|
||||
GO
|
||||
|
||||
CREATE TYPE t_fio
|
||||
FROM nvarchar(64) not null
|
||||
GO
|
||||
CREATE RULE r_fio
|
||||
AS
|
||||
@x like '% %'
|
||||
GO
|
||||
exec sp_bindrule 'r_fio', 't_fio'
|
||||
GO
|
||||
|
||||
CREATE TABLE typsostav (
|
||||
typkod int PRIMARY KEY,
|
||||
name nvarchar(20),
|
||||
kolmest int,
|
||||
dlina float CHECK (dlina < 200) not null,
|
||||
shirina int CHECK (shirina < 3000) not null,
|
||||
visota int CHECK (visota < 5000) not null,
|
||||
naznachenie nvarchar(30),
|
||||
koleya int CHECK (koleya=1520) not null,
|
||||
speed int
|
||||
)
|
||||
|
||||
CREATE TABLE psostav (
|
||||
serial int PRIMARY KEY,
|
||||
typkod int,
|
||||
stat int,
|
||||
probeg int not null,
|
||||
iznos_motor int not null,
|
||||
iznos_tk int not null,
|
||||
constraint FK_typkod_psostav foreign key (typkod) references typsostav
|
||||
)
|
||||
GO
|
||||
|
||||
CREATE TABLE mashinist (
|
||||
serialpas float PRIMARY KEY,
|
||||
serial int,
|
||||
fio t_fio,
|
||||
tel nvarchar(16) not null,
|
||||
staj int not null,
|
||||
kvalif nvarchar(10),
|
||||
constraint FK_serial_mashinist foreign key (serial) references psostav
|
||||
)
|
||||
GO
|
||||
EXEC sp_bindrule 'r_kvalif', 'mashinist.kvalif'
|
||||
GO
|
||||
|
||||
CREATE TABLE dispetcher (
|
||||
serialpas float PRIMARY KEY,
|
||||
fio t_fio,
|
||||
tel nvarchar(16) not null,
|
||||
doljnost t_doljnost,
|
||||
pas nvarchar(1000) not null
|
||||
)
|
||||
GO
|
||||
|
||||
CREATE TABLE stanciya (
|
||||
kod int PRIMARY KEY,
|
||||
name nvarchar(20),
|
||||
paspotok int,
|
||||
kod_vpered int,
|
||||
rast_vpered int,
|
||||
kod_nazad int,
|
||||
rast_nazad int,
|
||||
stat int,
|
||||
start_time time,
|
||||
finish_time time
|
||||
)
|
||||
GO
|
||||
|
||||
EXEC sp_bindefault 'd_start_time', 'stanciya.start_time'
|
||||
EXEC sp_bindefault 'd_finish_time', 'stanciya.finish_time'
|
||||
|
||||
|
||||
CREATE TABLE vetka (
|
||||
name nvarchar(20) PRIMARY KEY,
|
||||
start_stanciya int,
|
||||
finish_stanciya int,
|
||||
depo_status int,
|
||||
start_status int,
|
||||
finish_status int,
|
||||
constraint FK_start_stanciya foreign key (start_stanciya) references stanciya(kod),
|
||||
constraint FK_finish_stanciya foreign key (finish_stanciya) references stanciya(kod),
|
||||
)
|
||||
GO
|
||||
|
||||
CREATE TABLE spravka (
|
||||
kod int PRIMARY KEY,
|
||||
name nvarchar(30),
|
||||
krit float,
|
||||
srok_dos_det int,
|
||||
vremya_remonta int
|
||||
)
|
||||
GO
|
||||
|
||||
CREATE TABLE remont (
|
||||
typik int PRIMARY KEY,
|
||||
serial int,
|
||||
start datetime,
|
||||
kod int,
|
||||
constraint FK_kod_remont foreign key (kod) references spravka,
|
||||
constraint FK_serial_remont foreign key (serial) references psostav
|
||||
)
|
||||
GO
|
||||
|
||||
CREATE TABLE raspisanie (
|
||||
start_vremya time,
|
||||
start_kod int,
|
||||
finish_vremya time,
|
||||
finish_kod int,
|
||||
naprav int,
|
||||
vetka nvarchar(20),
|
||||
serial int,
|
||||
serialpas float,
|
||||
constraint PK_jurnal_raspisanie PRIMARY KEY (start_vremya,serialpas,serial,start_kod),
|
||||
constraint FK_serial_raspisanie foreign key (serial) references psostav,
|
||||
constraint FK_serialpas_raspisanie foreign key (serialpas) references dispetcher,
|
||||
constraint FK_start_kod_raspisanie foreign key (start_kod) references stanciya(kod),
|
||||
constraint FK_finish_kod_raspisanie foreign key (finish_kod) references stanciya(kod),
|
||||
constraint FK_vetka_raspisanie foreign key (vetka) references vetka(name)
|
||||
)
|
||||
GO
|
||||
|
||||
CREATE TABLE jurnal (
|
||||
start datetime,
|
||||
serialpas float,
|
||||
serial int,
|
||||
typik int,
|
||||
zametka nvarchar(30)
|
||||
constraint PK_jurnal PRIMARY KEY (start,serialpas,serial,typik),
|
||||
constraint FK_serial_jurnal foreign key (serial) references psostav,
|
||||
constraint FK_serialpas_jurnal foreign key (serialpas) references dispetcher,
|
||||
constraint FK_typik_jurnal foreign key (typik) references remont
|
||||
)
|
||||
GO
|
166
SQL/Function.sql
Normal file
166
SQL/Function.sql
Normal file
@ -0,0 +1,166 @@
|
||||
USE
|
||||
Metro
|
||||
GO
|
||||
|
||||
/* êîëè÷åñòâî ñòàíöèé â âåòêå */
|
||||
CREATE FUNCTION kol_stanciy (@vetka nvarchar(20))
|
||||
RETURNS INT AS
|
||||
BEGIN
|
||||
DECLARE @kol int, @stanciya int
|
||||
SET @kol=1
|
||||
SELECT @stanciya = start_stanciya FROM vetka WHERE name=@vetka
|
||||
WHILE (SELECT kod_vpered FROM stanciya WHERE kod=@stanciya) IS NOT NULL
|
||||
BEGIN
|
||||
SET @kol = @kol + 1
|
||||
SET @stanciya=(SELECT kod_vpered FROM stanciya WHERE kod=@stanciya)
|
||||
END
|
||||
RETURN @kol
|
||||
END
|
||||
GO
|
||||
|
||||
CREATE FUNCTION adtime (@typ int, @stan int, @naprav int)
|
||||
RETURNS INT AS
|
||||
BEGIN
|
||||
DECLARE @s int
|
||||
IF (@naprav=0)
|
||||
SELECT @s=rast_vpered FROM stanciya WHERE kod=@stan
|
||||
ELSE
|
||||
SELECT @s=rast_nazad FROM stanciya WHERE kod=@stan
|
||||
DECLARE @u int
|
||||
SELECT @u=speed FROM typsostav WHERE typkod=@typ
|
||||
RETURN FLOOR(@s/@u)
|
||||
END
|
||||
GO
|
||||
|
||||
/* îïðåäåëÿåì äëèííó âåòêè */
|
||||
CREATE FUNCTION dlina_vetka (@vetka varchar(20))
|
||||
RETURNS INT AS
|
||||
BEGIN
|
||||
DECLARE @dlina int, @stanciya int
|
||||
SET @dlina=0
|
||||
SELECT @stanciya = start_stanciya FROM vetka WHERE name=@vetka
|
||||
WHILE (SELECT kod_vpered FROM stanciya WHERE kod=@stanciya) IS NOT NULL
|
||||
BEGIN
|
||||
SET @dlina = @dlina + (SELECT rast_vpered FROM stanciya WHERE kod=@stanciya)
|
||||
SET @stanciya=(SELECT kod_vpered FROM stanciya WHERE kod=@stanciya)
|
||||
END
|
||||
RETURN @dlina
|
||||
END
|
||||
GO
|
||||
|
||||
/* Îïðåäåëÿåì ðàññòîÿíèå ìåæäó ñòàíöèÿìè */
|
||||
CREATE FUNCTION dlina (@stanciya int, @finish int, @p int, @p2 int)
|
||||
RETURNS INT AS
|
||||
BEGIN
|
||||
DECLARE @next_stanciya int, @rastoyanie int
|
||||
SET @rastoyanie=0;
|
||||
WHILE 1=1
|
||||
BEGIN
|
||||
IF (@stanciya=@finish and @p=@p2) BREAK
|
||||
IF (@p=0)
|
||||
BEGIN
|
||||
SELECT @next_stanciya=kod_vpered FROM stanciya WHERE kod=@stanciya
|
||||
IF (@next_stanciya is NULL)
|
||||
BEGIN
|
||||
SELECT @next_stanciya=kod_nazad FROM stanciya WHERE kod=@stanciya
|
||||
SET @p=1
|
||||
IF (@stanciya=@finish and @p=@p2) BREAK
|
||||
SET @rastoyanie=@rastoyanie+(SELECT rast_nazad FROM stanciya WHERE kod=@stanciya)
|
||||
END
|
||||
ELSE SET @rastoyanie=@rastoyanie+(SELECT rast_vpered FROM stanciya WHERE kod=@stanciya)
|
||||
END
|
||||
ELSE
|
||||
BEGIN
|
||||
SELECT @next_stanciya=kod_nazad FROM stanciya WHERE kod=@stanciya
|
||||
IF (@next_stanciya is NULL)
|
||||
BEGIN
|
||||
SELECT @next_stanciya=kod_vpered FROM stanciya WHERE kod=@stanciya
|
||||
SET @p=0
|
||||
IF (@stanciya=@finish and @p=@p2) BREAK
|
||||
SET @rastoyanie=@rastoyanie+(SELECT rast_vpered FROM stanciya WHERE kod=@stanciya)
|
||||
END
|
||||
ELSE SET @rastoyanie=@rastoyanie+(SELECT rast_nazad FROM stanciya WHERE kod=@stanciya)
|
||||
END
|
||||
SET @stanciya=@next_stanciya
|
||||
END
|
||||
RETURN @rastoyanie
|
||||
END
|
||||
GO
|
||||
|
||||
/* ïàññàæèðîïîòîê íà âåòêå */
|
||||
CREATE FUNCTION paspotok_vetki (@vetka nvarchar(20))
|
||||
RETURNS INT AS
|
||||
BEGIN
|
||||
DECLARE @paspotok int
|
||||
SET @paspotok=0;
|
||||
DECLARE @stanciya int
|
||||
SELECT @stanciya=start_stanciya FROM vetka WHERE name=@vetka
|
||||
WHILE @stanciya IS NOT NULL
|
||||
BEGIN
|
||||
IF (SELECT stat FROM stanciya WHERE kod=@stanciya) = 1
|
||||
SET @paspotok=@paspotok+(SELECT paspotok FROM stanciya WHERE kod=@stanciya)
|
||||
SET @stanciya=(SELECT kod_vpered FROM stanciya WHERE kod=@stanciya)
|
||||
END
|
||||
RETURN @paspotok
|
||||
END
|
||||
GO
|
||||
|
||||
/* îïòèìàëüíûé èíòåðâàë ìåæäó ïîåçäàìè */
|
||||
CREATE FUNCTION start_interval(@vetka nvarchar(20), @typ int, @kol_sostav int)
|
||||
RETURNS INT AS
|
||||
BEGIN
|
||||
DECLARE @speed int, @interval int, @s int, @f int
|
||||
SELECT @s=start_stanciya, @f=finish_stanciya FROM vetka WHERE name=@vetka
|
||||
SELECT @speed=speed FROM typsostav WHERE typkod=@typ
|
||||
SET @interval = FLOOR((dbo.dlina_vetka(@vetka)*2)/@speed)+15*dbo.kol_stanciy(@vetka)*2
|
||||
RETURN CEILING(@interval/@kol_sostav)
|
||||
END
|
||||
GO
|
||||
|
||||
/*ìàêñèìàëüíîå êîëè÷åñòâî ñîñòàâîâ íà âåòêå */
|
||||
CREATE FUNCTION maxi_sostav(@vetka nvarchar(20), @typ int)
|
||||
RETURNS INT AS
|
||||
BEGIN
|
||||
DECLARE @speed int, @interval int, @kol_sostav int, @s int, @f int
|
||||
SELECT @s=start_stanciya, @f=finish_stanciya FROM vetka WHERE name=@vetka
|
||||
SELECT @speed=speed FROM typsostav WHERE typkod=@typ
|
||||
SET @interval = FLOOR((dbo.dlina_vetka(@vetka)*2)/@speed)+15*dbo.kol_stanciy(@vetka)*2
|
||||
RETURN CEILING(@interval/90)
|
||||
END
|
||||
GO
|
||||
|
||||
/* ïðîâåðêà òåõíè÷åñêîãî ñîñòîÿíèÿ ñîñòàâà */
|
||||
CREATE FUNCTION proverka_sostav (@serial int)
|
||||
RETURNS INT AS
|
||||
BEGIN
|
||||
DECLARE @kod int
|
||||
SET @kod=0;
|
||||
IF (SELECT probeg FROM psostav WHERE serial=@serial) > (SELECT krit FROM spravka WHERE kod=2)
|
||||
SET @kod=2;
|
||||
ELSE IF (SELECT iznos_motor FROM psostav WHERE serial=@serial) > (SELECT krit FROM spravka WHERE kod=3)
|
||||
SET @kod=3;
|
||||
ELSE IF (SELECT iznos_tk FROM psostav WHERE serial=@serial) > (SELECT krit FROM spravka WHERE kod=1)
|
||||
SET @kod=1;
|
||||
RETURN @kod
|
||||
END
|
||||
GO
|
||||
|
||||
/* îïðåäåëåíèå ñëåäóþùåãî ñîñòàâà */
|
||||
CREATE FUNCTION sled_sostav (@ser int, @time time)
|
||||
RETURNS INT AS
|
||||
BEGIN
|
||||
DECLARE @vetka nvarchar(20), @nap int, @stanciya int
|
||||
SELECT @stanciya=start_kod, @vetka=vetka, @nap=naprav FROM raspisanie WHERE serial=@ser and start_vremya<DATEADD(SECOND,15,@time) and finish_vremya>DATEADD(SECOND,-15,@time)
|
||||
DECLARE @temp int;
|
||||
SELECT TOP 1 @temp=serial
|
||||
FROM raspisanie
|
||||
WHERE start_vremya<DATEADD(SECOND,15,@time) and finish_vremya>DATEADD(SECOND,-15,@time) and serial!=@ser
|
||||
ORDER BY dbo.dlina(@stanciya,start_kod,@nap,naprav) ASC
|
||||
RETURN @temp
|
||||
END
|
||||
GO
|
||||
|
||||
/*
|
||||
PRINT dbo.sled_sostav (20, '19:43')
|
||||
GO
|
||||
*/
|
709
SQL/Procedure.sql
Normal file
709
SQL/Procedure.sql
Normal file
@ -0,0 +1,709 @@
|
||||
USE Metro
|
||||
GO
|
||||
|
||||
/* ôîðìèðîâàíèå ðàñïèñàíèÿ äëÿ îäíîãî ñîñòàâà */
|
||||
CREATE PROCEDURE onesostav (@ser int, @vetka varchar(20), @start_time time, @k_time time, @serialpas float)
|
||||
AS
|
||||
BEGIN
|
||||
DECLARE @rab int, @t_vremya time, @typ int, @stanciya int, @next_stanciya int, @p int, @finish_time time
|
||||
SELECT @typ=typkod FROM psostav WHERE serial=@ser
|
||||
SET @rab=NULL;
|
||||
SELECT @stanciya=start_stanciya FROM vetka WHERE name=@vetka
|
||||
SET @p=0
|
||||
SET @finish_time=@start_time
|
||||
WHILE @finish_time<@k_time
|
||||
BEGIN
|
||||
IF @p=0
|
||||
BEGIN
|
||||
SELECT @next_stanciya=kod_vpered FROM stanciya WHERE kod=@stanciya
|
||||
IF @next_stanciya is NULL
|
||||
BEGIN
|
||||
SELECT @next_stanciya=kod_nazad FROM stanciya WHERE kod=@stanciya
|
||||
SET @p=1
|
||||
END
|
||||
END
|
||||
ELSE
|
||||
BEGIN
|
||||
SELECT @next_stanciya=kod_nazad FROM stanciya WHERE kod=@stanciya
|
||||
IF (@next_stanciya is NULL)
|
||||
BEGIN
|
||||
SELECT @next_stanciya=kod_vpered FROM stanciya WHERE kod=@stanciya
|
||||
SET @p=0
|
||||
END
|
||||
END
|
||||
SELECT @finish_time=DATEADD(SECOND,dbo.adtime(@typ, @stanciya, @p),@start_time)
|
||||
IF (SELECT finish_time FROM stanciya WHERE kod=@next_stanciya) > @finish_time and (SELECT start_time FROM stanciya WHERE kod=@stanciya) < @start_time
|
||||
BEGIN
|
||||
IF ((SELECT stat FROM stanciya WHERE kod=@next_stanciya) = 1) or (@finish_time<@k_time)
|
||||
BEGIN
|
||||
IF @rab IS NULL
|
||||
INSERT INTO raspisanie
|
||||
VALUES (@start_time, @stanciya, @finish_time, @next_stanciya, @p, @vetka, @ser, @serialpas)
|
||||
ELSE
|
||||
BEGIN
|
||||
UPDATE raspisanie
|
||||
SET finish_vremya=@finish_time, finish_kod=@next_stanciya, naprav=@p
|
||||
WHERE start_vremya=@t_vremya and start_kod=@rab and vetka=@vetka
|
||||
SET @rab = NULL
|
||||
SET @t_vremya=NULL
|
||||
END
|
||||
END
|
||||
ELSE
|
||||
BEGIN
|
||||
IF @rab IS NULL
|
||||
BEGIN
|
||||
INSERT INTO raspisanie (start_vremya, start_kod, vetka, serial, serialpas)
|
||||
VALUES (@start_time, @stanciya, @vetka, @ser, @serialpas)
|
||||
SET @rab=@stanciya
|
||||
SET @t_vremya=@start_time
|
||||
END
|
||||
END
|
||||
END
|
||||
SET @start_time=@finish_time
|
||||
SELECT @start_time=DATEADD(SECOND,15,@start_time)
|
||||
SET @stanciya=@next_stanciya
|
||||
END
|
||||
UPDATE psostav
|
||||
SET stat = (SELECT start_status FROM vetka WHERE name=@vetka)
|
||||
WHERE serial=@ser
|
||||
END
|
||||
GO
|
||||
|
||||
/* ôîðìèðîâàíèå îïòèìàëüíîãî ðàññïèñàíèÿ */
|
||||
CREATE PROCEDURE sostav_raspisanie @vetka nvarchar(20), @n_time time, @k_time time, @kol int, @typ int, @serialpas float
|
||||
AS
|
||||
BEGIN
|
||||
DECLARE @depo int, @maxi int, @paspotok int, @pasvmestdepo int, @kol_sostav int, @interval int
|
||||
SELECT @depo=depo_status FROM vetka WHERE name=@vetka
|
||||
SET @maxi=dbo.maxi_sostav(@vetka, @typ)
|
||||
SET @paspotok=dbo.paspotok_vetki(@vetka)
|
||||
DECLARE @sostavi_depo TABLE (serial int, stat int, kolmest int, typkod int)
|
||||
INSERT INTO @sostavi_depo
|
||||
SELECT serial, stat, kolmest, typsostav.typkod
|
||||
FROM psostav INNER JOIN typsostav ON psostav.typkod=typsostav.typkod
|
||||
WHERE stat=@depo and kolmest!=0 and psostav.typkod=@typ
|
||||
DELETE @sostavi_depo
|
||||
WHERE dbo.proverka_sostav(serial)!=0 or serial not in (SELECT serial FROM mashinist)
|
||||
SELECT @pasvmestdepo=SUM(kolmest) FROM @sostavi_depo
|
||||
IF (@kol=0)
|
||||
SET @kol_sostav = CEILING(@paspotok/(SELECT kolmest FROM typsostav WHERE typkod=@typ))
|
||||
ELSE
|
||||
SET @kol_sostav=@kol
|
||||
IF (@kol_sostav>@maxi)
|
||||
BEGIN
|
||||
PRINT 'Íà âåòêó áóäåò âûâåäåíî ìàêñèìàëüíîå êîëè÷åñòâî ñîñòàâîâ!'
|
||||
SET @kol_sostav=@maxi
|
||||
END
|
||||
SET @interval = dbo.start_interval(@vetka, @typ, @kol_sostav)
|
||||
DECLARE @CURSOR CURSOR, @t_ser int, @t_kol int, @k int
|
||||
SET @k=0
|
||||
SET @CURSOR = CURSOR SCROLL
|
||||
FOR
|
||||
SELECT serial, kolmest
|
||||
FROM @sostavi_depo
|
||||
OPEN @CURSOR
|
||||
FETCH NEXT FROM @CURSOR INTO @t_ser, @t_kol
|
||||
WHILE (@@FETCH_STATUS = 0 and @k<@kol_sostav)
|
||||
BEGIN
|
||||
DECLARE @start_time time
|
||||
SET @start_time=@n_time
|
||||
SELECT @start_time=DATEADD(SECOND,@interval*@k,@n_time)
|
||||
IF (@start_time<@k_time)
|
||||
EXEC onesostav @t_ser, @vetka, @start_time, @k_time, @serialpas
|
||||
ELSE BREAK;
|
||||
SET @k=@k+1
|
||||
FETCH NEXT FROM @CURSOR INTO @t_ser, @t_kol
|
||||
END
|
||||
CLOSE @CURSOR
|
||||
END
|
||||
GO
|
||||
|
||||
/*
|
||||
EXEC sostav_raspisanie 'Êðàñíàÿ', '7:00', '7:01', 0, 1, 123456
|
||||
*/
|
||||
|
||||
/* ïðîâåðêà ââåäåíîé èíôîðìàöèè, ïåðåä ôîðìèðâîàíèåì îïòèìàëüíîãî ðàñïèñàíèÿ */
|
||||
CREATE PROC prov_raspisanie @vetka nvarchar(20), @n_time time, @k_time time, @kol int, @typ int, @serialpas float
|
||||
AS
|
||||
BEGIN
|
||||
IF @vetka in (SELECT name FROM vetka)
|
||||
IF NOT EXISTS (SELECT DISTINCT vetka FROM raspisanie WHERE vetka=@vetka)
|
||||
IF (@n_time<@k_time)
|
||||
IF (@kol>=0)
|
||||
IF @typ in (SELECT typkod FROM typsostav)
|
||||
IF EXISTS(SELECT serial FROM psostav WHERE stat=(SELECT depo_status FROM vetka WHERE name=@vetka) and typkod=@typ)
|
||||
EXEC sostav_raspisanie @vetka, @n_time, @k_time, @kol, @typ, @serialpas
|
||||
ELSE PRINT 'Ñîñòàâîâ äàííîãî òèïà íåò â äåïî ýòîé ñòàíöèè'
|
||||
ELSE PRINT 'Òàêîãî òèïà ñîñòàâîâ íå ñóùåñòâóåò'
|
||||
ELSE PRINT 'Êîëè÷åñòâî ñîñòàâîâ íå ìîæåò áûòü îòðèöàòåëüíûì'
|
||||
ELSE PRINT 'Çàäàéòå ïðàâèëüíî âðåìÿ'
|
||||
ELSE PRINT 'Ðàñïèñàíèå äëÿ ýòîé âåòêè óæå ñîñòàâëåíî'
|
||||
ELSE PRINT 'Òàêîé âåòêè íå ñóùåñòâóåò'
|
||||
END
|
||||
GO
|
||||
|
||||
/* îïòèìàëüíûå èíòåðâàëû äëÿ ðàñïèñàíèÿ */
|
||||
CREATE PROCEDURE alignment_interval (@time time, @vetka nvarchar(20), @typ int, @kol_sostav int)
|
||||
AS
|
||||
BEGIN
|
||||
DECLARE @CURSOR CURSOR, @t_ser int, @vremya time, @stanciya int
|
||||
SELECT @vremya=@time
|
||||
SET @CURSOR = CURSOR SCROLL
|
||||
FOR
|
||||
SELECT DISTINCT serial
|
||||
FROM raspisanie
|
||||
WHERE start_vremya>=@vremya and vetka=@vetka
|
||||
OPEN @CURSOR
|
||||
FETCH NEXT FROM @CURSOR INTO @t_ser
|
||||
WHILE @@FETCH_STATUS=0
|
||||
BEGIN
|
||||
DECLARE @new_interval int, @sled_sostav int, @interval int, @sled_time time, @prom int
|
||||
SET @new_interval=dbo.start_interval(@vetka, @typ, @kol_sostav)
|
||||
SET @sled_sostav=dbo.sled_sostav (@t_ser, @vremya)
|
||||
SELECT @stanciya=start_kod FROM raspisanie WHERE start_vremya<DATEADD(SECOND,15,@vremya) and finish_vremya>DATEADD(SECOND,-15,@vremya) and serial=@sled_sostav
|
||||
SELECT TOP 1 @sled_time=start_vremya FROM raspisanie WHERE serial=@t_ser and start_vremya>@vremya and start_kod=@stanciya ORDER BY start_vremya ASC
|
||||
SET @interval=DATEDIFF(SECOND,@vremya,@sled_time)
|
||||
IF (@interval<@new_interval) SET @prom=-1 ELSE SET @prom=1
|
||||
DECLARE @CURSOR2 CURSOR, @t_svremya time, @t_fvremya time, @dob int, @dob2 int
|
||||
SET @dob=0 SET @dob2=20
|
||||
SET @CURSOR2 = CURSOR SCROLL
|
||||
FOR
|
||||
SELECT start_vremya, finish_vremya FROM raspisanie WHERE serial=@sled_sostav and start_vremya>@sled_time ORDER BY start_vremya ASC
|
||||
OPEN @CURSOR2
|
||||
FETCH NEXT FROM @CURSOR2 INTO @t_svremya, @t_fvremya
|
||||
WHILE @@FETCH_STATUS=0
|
||||
BEGIN
|
||||
IF (@prom=-1)
|
||||
BEGIN
|
||||
IF(@interval<@new_interval)
|
||||
BEGIN
|
||||
SET @interval=@interval+20
|
||||
SET @dob=@dob+20
|
||||
SET @vremya=DATEADD(SECOND,-@dob+@dob2,@t_svremya)
|
||||
END ELSE SET @dob2=0
|
||||
UPDATE raspisanie
|
||||
SET start_vremya=DATEADD(SECOND,-@dob+@dob2,start_vremya), finish_vremya=DATEADD(SECOND,-@dob,finish_vremya)
|
||||
WHERE start_vremya=@t_svremya and serial=@sled_sostav and finish_vremya=@t_fvremya
|
||||
END
|
||||
ELSE
|
||||
BEGIN
|
||||
IF(@interval>@new_interval)
|
||||
BEGIN
|
||||
SET @interval=@interval-20
|
||||
SET @dob=@dob+20
|
||||
SET @vremya=DATEADD(SECOND,@dob+@dob2,@t_svremya)
|
||||
END ELSE SET @dob2=0
|
||||
UPDATE raspisanie
|
||||
SET start_vremya=DATEADD(SECOND,@dob,start_vremya), finish_vremya=DATEADD(SECOND,@dob-@dob2,finish_vremya)
|
||||
WHERE start_vremya=@t_svremya and serial=@sled_sostav and finish_vremya=@t_fvremya
|
||||
END
|
||||
FETCH NEXT FROM @CURSOR2 INTO @t_svremya, @t_fvremya
|
||||
END
|
||||
CLOSE @CURSOR2
|
||||
FETCH NEXT FROM @CURSOR INTO @t_ser
|
||||
END
|
||||
CLOSE @CURSOR
|
||||
END
|
||||
GO
|
||||
|
||||
/* óäàëåíèå ñîñòàâà èç ðàñïèñàíèÿ */
|
||||
CREATE PROCEDURE del_sostav_raspisanie (@ser int, @start_time time)
|
||||
AS
|
||||
BEGIN
|
||||
DECLARE @vetka varchar(20), @typ int
|
||||
SELECT @typ=typkod FROM psostav WHERE serial=@ser
|
||||
SELECT TOP 1 @vetka=vetka FROM raspisanie WHERE serial=@ser
|
||||
IF (SELECT stat FROM psostav WHERE serial=@ser) IN (SELECT start_status FROM vetka WHERE name=@vetka UNION SELECT finish_status FROM vetka WHERE name=@vetka)
|
||||
BEGIN
|
||||
DECLARE @kol_sostav int
|
||||
SELECT @kol_sostav=COUNT(serial) FROM psostav WHERE stat IN (SELECT start_status FROM vetka WHERE name=@vetka UNION SELECT finish_status FROM vetka WHERE name=@vetka)
|
||||
SELECT TOP 1 @start_time=start_vremya
|
||||
FROM raspisanie
|
||||
WHERE start_vremya>=@start_time and start_kod=(SELECT start_stanciya FROM vetka WHERE name=@vetka) and serial=@ser
|
||||
ORDER BY start_vremya ASC
|
||||
DELETE FROM raspisanie
|
||||
WHERE serial=@ser and start_vremya>=@start_time
|
||||
SET @kol_sostav=@kol_sostav-1
|
||||
EXEC alignment_interval @start_time, @vetka, @typ, @kol_sostav
|
||||
UPDATE psostav
|
||||
SET stat = (SELECT depo_status FROM vetka WHERE name=@vetka)
|
||||
END
|
||||
ELSE PRINT 'Ñîñòàâ íå íàõîäèòñÿ íà âåòêå'
|
||||
END
|
||||
GO
|
||||
|
||||
/* äîáàâëåíèå ñîñòàâà â ðàññïèñàíèå */
|
||||
CREATE PROCEDURE add_sostav_raspis (@ser int, @vetka varchar(20), @time time, @serialpas float)
|
||||
AS
|
||||
BEGIN
|
||||
IF EXISTS (SELECT vetka FROM raspisanie WHERE vetka=@vetka)
|
||||
IF @time> (SELECT MIN(start_vremya) FROM raspisanie) and @time< (SELECT MAX(finish_vremya) FROM raspisanie)
|
||||
BEGIN
|
||||
DECLARE @typ int, @depo int, @kol_sostav int, @depo_stanciya int, @k_time time
|
||||
SELECT @depo_stanciya=start_stanciya FROM vetka WHERE name=@vetka
|
||||
SELECT @typ=typkod FROM psostav WHERE serial=@ser
|
||||
SELECT @depo=depo_status FROM vetka WHERE name=@vetka
|
||||
SELECT TOP 1 @k_time=start_vremya FROM raspisanie ORDER BY start_vremya DESC
|
||||
SELECT @kol_sostav=COUNT(serial) FROM psostav WHERE stat IN (SELECT start_status FROM vetka WHERE name=@vetka UNION SELECT finish_status FROM vetka WHERE name=@vetka)
|
||||
IF EXISTS (SELECT serial FROM mashinist WHERE serial=@ser)
|
||||
IF (dbo.proverka_sostav(@ser)=0)
|
||||
IF (SELECT stat FROM psostav WHERE serial=@ser) = @depo
|
||||
IF EXISTS (SELECT * FROM raspisanie)
|
||||
BEGIN
|
||||
IF NOT EXISTS (SELECT * FROM raspisanie WHERE start_vremya <= DATEADD(SECOND,90,@time) and start_vremya > DATEADD(SECOND,-90,@time) and vetka=@vetka and start_kod=@depo_stanciya)
|
||||
IF (SELECT DISTINCT typkod FROM psostav WHERE serial = (SELECT TOP 1 serial FROM raspisanie)) = @typ
|
||||
IF ((SELECT COUNT(DISTINCT serial) FROM raspisanie WHERE vetka=@vetka) < dbo.maxi_sostav(@vetka, @typ))
|
||||
BEGIN
|
||||
EXEC onesostav @ser, @vetka, @time, @k_time, @serialpas
|
||||
SET @kol_sostav=@kol_sostav+1
|
||||
EXEC alignment_interval @time, @vetka, @typ, @kol_sostav
|
||||
END
|
||||
ELSE PRINT 'Íà âåòêå íàõîäèòñÿ ìàêèñìàëüíî äîïóñòèìîå êîëè÷åñòâî ñîñòàâîâ'
|
||||
ELSE PRINT 'Òèï ñîñòàâà íå ñîîòâåòñòâóåò òèïó ñîñòàâîâ, êîòîðûå íàõîäÿòñÿ íà âåòêå'
|
||||
ELSE PRINT 'Íåëüçÿ ïóñòèòü ñîñòàâ â ýòî âðåìÿ, âûáåðåòå äðóãîå'
|
||||
END
|
||||
ELSE EXEC onesostav @ser, @vetka, @time, @k_time, @serialpas
|
||||
ELSE PRINT 'Ñîñòàâ íå íàõîäèòñÿ â äåïî âåòêè, ïåðåâåäèòå ïîåçä â äåïî'
|
||||
ELSE PRINT 'Ñîñòàâ íóæäàåòñÿ â òåõíè÷åñêîì îáñëóæèâàíèè'
|
||||
ELSE PRINT 'Íà äàííûé ñîñòàâ íå íàçíà÷åí ìàøèíèñò'
|
||||
END
|
||||
ELSE PRINT 'Íåëüçÿ äîáàâèòü ñîñòàâ â ýòî âðåìÿ'
|
||||
ELSE PRINT 'Äëÿ ýòîé âåòêè íå ñôîðìèðîâàíî ðàñïèñàíèå. Äîáàâëåíèå íå âîçìîæíî!'
|
||||
END
|
||||
GO
|
||||
|
||||
/* óäàëåíèå ðàñïèñàíèÿ äëÿ âåòêè */
|
||||
CREATE PROC del_rasp @vetka nvarchar(20)
|
||||
AS
|
||||
BEGIN
|
||||
IF @vetka in (SELECT name FROM vetka)
|
||||
IF EXISTS (SELECT vetka FROM raspisanie WHERE vetka=@vetka)
|
||||
BEGIN
|
||||
UPDATE psostav
|
||||
SET stat=(SELECT depo_status FROM vetka WHERE name=@vetka)
|
||||
WHERE serial in (SELECT serial FROM raspisanie WHERE vetka=@vetka)
|
||||
DELETE raspisanie
|
||||
WHERE vetka=@vetka
|
||||
END
|
||||
ELSE PRINT 'Äëÿ ýòîé âåòêè íåò ðàñïèñàíèÿ'
|
||||
ELSE PRINT 'Òàêîé âåòêè íå ñóùåñòâóåò'
|
||||
END
|
||||
GO
|
||||
|
||||
|
||||
/* Äîáàâëåíèå ñòàíöèè */
|
||||
CREATE PROCEDURE add_stanciya (@kod int, @name nvarchar(20), @paspotok int, @kod_nazad int, @rast_nazad int, @rast_vpered int, @stat int, @start_time time, @finish_time time)
|
||||
AS
|
||||
BEGIN
|
||||
IF (@kod!=0)
|
||||
IF NOT EXISTS (SELECT * FROM stanciya WHERE @kod=kod)
|
||||
IF (EXISTS (SELECT * FROM stanciya WHERE @kod_nazad=kod) or @kod_nazad IS NULL or @kod_nazad=0)
|
||||
IF (@kod_nazad is not NULL or @kod_nazad!=0) and ((SELECT kod_vpered FROM stanciya WHERE kod=@kod_nazad) is not NULL) and (@rast_vpered is null or @rast_vpered=0)
|
||||
PRINT 'Íåâîçìîæíî äîáàâèòü ñòàíöèþ áåç ðàññòîÿíèÿ âïåðåä, åñëè îíà íå êîíå÷íàÿ.'
|
||||
ELSE
|
||||
IF (@start_time<@finish_time)
|
||||
IF (@kod_nazad is not null and @kod_nazad!=0) and (@rast_nazad=0 or @rast_nazad is null)
|
||||
PRINT 'Äîáàâëüòå ðàññòîÿíèå íàçàä'
|
||||
ELSE
|
||||
INSERT INTO stanciya
|
||||
VALUES (@kod, @name, @paspotok, NULL, @rast_vpered, @kod_nazad, @rast_nazad, @stat, @start_time, @finish_time)
|
||||
ELSE PRINT 'Èñïðàâüòå âðåìÿ îòêðûòèÿ/çàêðûòèÿ ñòàíöèè'
|
||||
ELSE PRINT 'Íå ñóùåñòâóåò ñòàíöèè ñ êîäîì: ' + cast(@kod_nazad as nvarchar(10))
|
||||
ELSE PRINT 'Ñòàíöèÿ ñ òàêèì êîäîì óæå ñóùåñòâóåò'
|
||||
ELSE PRINT 'Êîä ñòàíöèè íå ìîæåò áûòü 0'
|
||||
END
|
||||
GO
|
||||
|
||||
/* ðåäàêòèðîâàíèå ñòàíöèè */
|
||||
CREATE PROCEDURE edit_stanciya (@kod int, @name nvarchar(20), @paspotok int, @rast_nazad int, @rast_vpered int, @stat int, @start_time time, @finish_time time)
|
||||
AS
|
||||
BEGIN
|
||||
IF EXISTS (SELECT kod FROM stanciya WHERE kod=@kod)
|
||||
IF @paspotok>=0
|
||||
IF @rast_nazad>=0 or @rast_nazad is NULL
|
||||
IF @rast_vpered>=0 or @rast_vpered is NULL
|
||||
IF (@finish_time>@start_time)
|
||||
IF (SELECT kod_nazad FROM stanciya WHERE kod=@kod) is not null and (@rast_nazad>0 or @rast_nazad is not null)
|
||||
BEGIN
|
||||
UPDATE stanciya
|
||||
SET paspotok=@paspotok, name=@name, rast_nazad=@rast_nazad, rast_vpered=@rast_vpered, stat=@stat, start_time=@start_time, finish_time=@finish_time
|
||||
WHERE kod=@kod
|
||||
UPDATE stanciya
|
||||
SET rast_vpered=@rast_nazad
|
||||
WHERE kod=(SELECT kod_nazad FROM stanciya WHERE kod=@kod)
|
||||
UPDATE stanciya
|
||||
SET rast_nazad=@rast_vpered
|
||||
WHERE kod=(SELECT kod_vpered FROM stanciya WHERE kod=@kod)
|
||||
END
|
||||
ELSE PRINT 'Íåëüçÿ äîáàâèòü ðàññòîÿíèå íàçàä'
|
||||
ELSE PRINT 'Íåêîððåêòíîå âðåìÿ ðàáîòû ñòàíöèè'
|
||||
ELSE PRINT 'Ðàññòîÿíèå âïåðåä íå ìîæåò áûòü îòðèöàòåëüíûì'
|
||||
ELSE PRINT 'Ðàññòîÿíèå íàçàä íå ìîæåò áûòü îòðèöàòåëüíûì'
|
||||
ELSE PRINT 'Ïàññàæèðîïîòîê íå ìîæåò áûòü îòðèöàòåëüíûì'
|
||||
ELSE PRINT 'Ñòàíöèè ñ òàêèì êîäîì íå ñóùåñòâóåò'
|
||||
END
|
||||
GO
|
||||
|
||||
/* óäàëåíèå ñòàíöèè */
|
||||
CREATE PROC del_stanciya (@kod int)
|
||||
AS
|
||||
BEGIN
|
||||
IF EXISTS (SELECT kod FROM stanciya WHERE kod=@kod)
|
||||
IF NOT EXISTS (SELECT start_kod FROM raspisanie WHERE start_kod=@kod)
|
||||
DELETE stanciya
|
||||
WHERE kod=@kod
|
||||
ELSE PRINT 'Íåëüçÿ óäàëèòü ñòàíöèþ, ïîêà îíà â ðàñïèñàíèè'
|
||||
ELSE PRINT 'Ñòàíöèè ñ òàêèì êîäîì íåò'
|
||||
END
|
||||
GO
|
||||
|
||||
/* Äîáàâëåíèå âåòêè */
|
||||
CREATE PROCEDURE add_vetka (@name varchar(20), @start_stanciya int, @depo_status int, @start_status int, @finish_status int)
|
||||
AS
|
||||
BEGIN
|
||||
IF NOT EXISTS (SELECT name FROM vetka WHERE name=@name)
|
||||
IF @start_stanciya not in (SELECT start_stanciya FROM vetka) and (SELECT kod_vpered FROM stanciya WHERE kod=@start_stanciya) is NOT NULL
|
||||
IF EXISTS (SELECT * FROM stanciya WHERE kod=@start_stanciya)
|
||||
IF ((SELECT kod_nazad FROM stanciya WHERE kod=@start_stanciya) is null)
|
||||
IF @depo_status NOT IN (SELECT depo_status FROM vetka)
|
||||
IF @start_status NOT IN (SELECT start_status FROM vetka)
|
||||
IF @finish_status NOT IN (SELECT finish_status FROM vetka)
|
||||
IF @finish_status!=@start_status and @start_status!=@depo_status and @depo_status!=@finish_status
|
||||
BEGIN
|
||||
DECLARE @finish_stanciya int
|
||||
SELECT @finish_stanciya=kod_vpered FROM stanciya WHERE kod=@start_stanciya
|
||||
WHILE (SELECT kod_vpered FROM stanciya WHERE kod=@finish_stanciya) is NOT NULL
|
||||
SELECT @finish_stanciya=kod_vpered FROM stanciya WHERE kod=@finish_stanciya
|
||||
INSERT INTO vetka (name, start_stanciya, finish_stanciya, depo_status, start_status, finish_status)
|
||||
VALUES (@name, @start_stanciya, @finish_stanciya, @depo_status, @start_status, @finish_status)
|
||||
END
|
||||
ELSE PRINT 'Çíà÷åíèÿ ñòàòóñîâ äîëæíû áûòü îòëè÷íûìè äðóã îò äðóãà'
|
||||
ELSE PRINT 'Âûáåðåòå äðóãîé ñòàòóñ äâèæåíèÿ ñîñòàâà ê äåïî'
|
||||
ELSE PRINT 'Âûáåðåòå äðóãîé ñòàòóñ äâèæåíèÿ ñîñòàâà îò äåïî'
|
||||
ELSE PRINT 'Âûáåðåòå äðóãîé èäåíòèôèêàòîð ñòàòóñà äåïî'
|
||||
ELSE PRINT 'Ñòàíöèÿ íå ìîæåò áûòü äåïî. Âûáåðåòå èëè ñîçäàéòå äðóãóþ ñòàíöèþ'
|
||||
ELSE PRINT 'Ñòàíöèè äëÿ äåïî íåò, ñîçäàéòå ñòàíöèþ äåïî'
|
||||
ELSE PRINT 'Âûáåðåòå äðóãóþ ñòàíöèþ äëÿ äåïî'
|
||||
ELSE PRINT 'Òàêàÿ âåòêà óæå ñóùåñòâóåò'
|
||||
END
|
||||
GO
|
||||
|
||||
/* Óäàëåíèå âåòêè */
|
||||
CREATE PROC del_vetka (@name nvarchar(20), @name2 nvarchar(20))
|
||||
AS
|
||||
BEGIN
|
||||
IF EXISTS (SELECT name FROM vetka WHERE name=@name)
|
||||
BEGIN
|
||||
DECLARE @depo int, @depo2 int
|
||||
SELECT @depo=depo_status FROM vetka WHERE name=@name
|
||||
SELECT @depo2=depo_status FROM vetka WHERE name=@name2
|
||||
IF @name in (SELECT vetka FROM raspisanie WHERE vetka=@name)
|
||||
EXEC del_rasp @name
|
||||
IF EXISTS (SELECT serial FROM psostav WHERE typkod=@depo) and @name2 is not null
|
||||
UPDATE psostav SET stat = @depo2 WHERE stat = @depo
|
||||
ELSE
|
||||
UPDATE psostav SET stat = NULL WHERE stat = @depo
|
||||
DELETE vetka
|
||||
WHERE name=@name
|
||||
END
|
||||
ELSE PRINT 'Âåòêè ñ òàêèì íàçâàíèåì íå ñóùåòñâóåò'
|
||||
END
|
||||
GO
|
||||
|
||||
/* äîáàâëåíèå ñîñòàâà â òàáëèöó */
|
||||
CREATE PROCEDURE add_sostav (@serial int, @typkod int, @vetka nvarchar(20), @probeg float, @iznos_motor float, @iznos_tk float)
|
||||
AS
|
||||
BEGIN
|
||||
IF NOT EXISTS (SELECT * FROM psostav WHERE serial=@serial)
|
||||
IF @typkod IN (SELECT typkod FROM typsostav)
|
||||
IF EXISTS (SELECT name FROM vetka WHERE name=@vetka)
|
||||
INSERT INTO psostav
|
||||
VALUES (@serial, @typkod, (SELECT depo_status FROM vetka WHERE name=@vetka), @probeg, @iznos_motor, @iznos_tk)
|
||||
ELSE PRINT 'Òàêîé âåòêè íå ñóùåñòâåò'
|
||||
ELSE PRINT 'Òàêîãî òèïà ñîñòàâà íå ñóùåñòâóåò'
|
||||
ELSE PRINT 'Òàêîé ñåðèéíûé íîìåð óæå ñóùåñòâóåò'
|
||||
END
|
||||
GO
|
||||
|
||||
/* óäàëåíèå ñîñòàâà èç òàáëèöû */
|
||||
CREATE PROCEDURE del_sostav (@serial int)
|
||||
AS
|
||||
BEGIN
|
||||
IF EXISTS (SELECT serial FROM psostav WHERE serial=@serial)
|
||||
IF NOT EXISTS (SELECT serial FROM raspisanie WHERE serial=@serial)
|
||||
BEGIN
|
||||
IF EXISTS (SELECT serial FROM remont WHERE serial=@serial)
|
||||
UPDATE remont
|
||||
SET serial=NULL, start=NULL, kod=NULL
|
||||
WHERE serial=@serial
|
||||
IF EXISTS (SELECT serial FROM mashinist WHERE serial=@serial)
|
||||
UPDATE mashinist
|
||||
SET serial=NULL
|
||||
WHERE serial=@serial
|
||||
DELETE psostav
|
||||
WHERE serial=@serial
|
||||
END
|
||||
ELSE PRINT 'Íåâîçìîæíî óäàëèòü ñîñòàâ, òàê êàê îí ÷èñëèòñÿ â ðàñïèñàíèè'
|
||||
ELSE PRINT 'Ñîñòàâà ñ òàêèì ñåðèéíûì íîìåðîì íåò'
|
||||
END
|
||||
GO
|
||||
|
||||
/* èçìåíåíèå ñîñòàâà */
|
||||
CREATE PROC edit_psostav (@serial int, @typkod int, @vetka nvarchar(20), @probeg float, @iznos_motor float, @iznos_tk float)
|
||||
AS
|
||||
BEGIN
|
||||
IF EXISTS (SELECT name FROM vetka WHERE name=@vetka)
|
||||
IF (@probeg>=0 and @iznos_motor>=0 and @iznos_tk>=0)
|
||||
IF EXISTS (SELECT * FROM psostav WHERE serial=@serial)
|
||||
IF @typkod IN (SELECT typkod FROM typsostav)
|
||||
IF ((SELECT stat FROM psostav WHERE serial=@serial) in (SELECT depo_status FROM vetka)) or (SELECT stat FROM psostav WHERE serial=@serial) is NULL
|
||||
UPDATE psostav
|
||||
SET typkod=@typkod, stat=(SELECT depo_status FROM vetka WHERE name=@vetka), probeg=@probeg, iznos_motor=@iznos_motor, iznos_tk=@iznos_tk
|
||||
WHERE serial=@serial
|
||||
ELSE PRINT 'Íåëüçÿ ïîìåíÿòü ñòàòóñ äàííîãî ñîñòàâà'
|
||||
ELSE PRINT 'Òàêîãî òèïà ñîñòàâà íå ñóùåñòâóåò'
|
||||
ELSE PRINT 'Òàêîãî ñåðèéíîãî íîìåðà íå ñóùåñòâóåò'
|
||||
ELSE PRINT 'Ââåäèòå êîððåêòíûå äàííûå'
|
||||
ELSE PRINT 'Òàêîé âåòêè íå ñóùåñòâåò'
|
||||
END
|
||||
GO
|
||||
|
||||
/* îòïðàâëåíèå ñîñòàâà íà ðåìîíò */
|
||||
CREATE PROCEDURE add_remont (@typik int, @serial int, @date datetime, @serialpass float, @zametka nvarchar(100))
|
||||
AS
|
||||
BEGIN
|
||||
IF EXISTS (SELECT typik FROM remont WHERE typik=@typik)
|
||||
IF EXISTS (SELECT serial FROM psostav WHERE serial=@serial)
|
||||
BEGIN
|
||||
DECLARE @kod int
|
||||
SET @kod=dbo.proverka_sostav(@serial)
|
||||
IF (@kod!=0)
|
||||
IF (SELECT stat FROM psostav WHERE serial=@serial) IN (SELECT depo_status FROM vetka)
|
||||
IF EXISTS (SELECT typik FROM remont WHERE serial IS NULL and typik=@typik)
|
||||
BEGIN
|
||||
UPDATE remont
|
||||
SET kod=@kod, serial=@serial, start=@date
|
||||
WHERE typik=@typik
|
||||
INSERT INTO jurnal
|
||||
VALUES (@date, @serialpass, @serial, @typik, @zametka)
|
||||
UPDATE psostav SET stat=0 WHERE serial=@serial
|
||||
END
|
||||
ELSE PRINT 'Ýòîò òóïèê óæå çàíÿò!'
|
||||
ELSE PRINT 'Ïîåçä íàõîäèòñÿ íå â äåïî. Ñíà÷àëà âåðíèòå åãî â äåïî'
|
||||
ELSE PRINT 'Ñîñòàâ íå íóæäàåòñÿ â òåõíè÷åñêîì îáñëóæèâàíèè'
|
||||
END
|
||||
ELSE PRINT 'Òàêîãî ñîñòàâà íå ñóùåñòâóåò'
|
||||
ELSE PRINT 'Òàêîãî òóïèêà íå ñóùåñòâóåò. Âûáåðåòå äðóãîé.'
|
||||
END
|
||||
GO
|
||||
|
||||
/* Óäàëåíèå èç ðåìîíòà */
|
||||
CREATE PROC del_remont (@serial int, @vetka nvarchar(20), @serialpass float)
|
||||
AS
|
||||
BEGIN
|
||||
IF EXISTS (SELECT serial FROM psostav WHERE serial=@serial)
|
||||
IF EXISTS (SELECT name FROM vetka WHERE name=@vetka)
|
||||
IF EXISTS (SELECT serialpas FROM dispetcher WHERE serialpas=@serialpass)
|
||||
IF EXISTS (SELECT serial FROM remont WHERE serial=@serial)
|
||||
BEGIN
|
||||
UPDATE remont
|
||||
SET serial=NULL, start=NULL, kod=NULL
|
||||
WHERE serial=@serial
|
||||
UPDATE psostav
|
||||
SET stat=(SELECT depo_status FROM vetka WHERE name=@vetka)
|
||||
WHERE serial=@serial
|
||||
END
|
||||
ELSE PRINT 'Äàííûé ñîñòàâ íå íàõîäèòñÿ íà ðåìîíòíîé ñòàíöèè'
|
||||
ELSE PRINT 'Òàêîãî äèñïåò÷åðà íå ñóùåñòâóåò'
|
||||
ELSE PRINT 'Òàêîé âåòêè íå ñóùåñòâóåò'
|
||||
ELSE PRINT 'Òàêîãî ñîñòàâà íå ñóùåñòâóåò'
|
||||
END
|
||||
GO
|
||||
|
||||
/* äîáàâëåíèå íîâîãî òóïèêà äëÿ ðåìîíòà */
|
||||
CREATE PROC add_typik (@typik int)
|
||||
AS
|
||||
BEGIN
|
||||
IF NOT EXISTS (SELECT typik FROM remont WHERE typik=@typik)
|
||||
INSERT INTO remont
|
||||
VALUES (@typik, NULL, NULL, NULL)
|
||||
ELSE PRINT 'Òóïèê ñ òàêèì íîìåðîì óæå ñóùåñòâóåò'
|
||||
END
|
||||
GO
|
||||
|
||||
/* óäàëåíèå òóïèêà */
|
||||
CREATE PROC del_typik (@typik int)
|
||||
AS
|
||||
BEGIN
|
||||
IF EXISTS (SELECT typik FROM remont WHERE typik=@typik)
|
||||
IF EXISTS (SELECT typik FROM remont WHERE serial is NULL and typik=@typik)
|
||||
DELETE remont
|
||||
WHERE typik=@typik
|
||||
ELSE PRINT 'Òóïèê íå ïóñò, ïåðåâåäèòå ïîåçä â äåïî'
|
||||
ELSE PRINT 'Òóïèêà ñ òàêèì êîäîì íåò'
|
||||
END
|
||||
GO
|
||||
|
||||
/* äîáàâëåíèå äèñïåò÷åðà */
|
||||
CREATE PROCEDURE add_dispetcher (@serialpas float, @fio t_fio, @tel nvarchar(16), @doljnost nvarchar(20), @pas varchar(1000))
|
||||
AS
|
||||
BEGIN
|
||||
IF NOT EXISTS (SELECT serialpas FROM dispetcher WHERE serialpas=@serialpas)
|
||||
IF (@fio like '% %')
|
||||
IF @doljnost in ('Ñòàæåð', 'Äèñïåò÷åð', 'Ñòàðøèé äèñïåò÷åð')
|
||||
INSERT INTO dispetcher
|
||||
VALUES (@serialpas, @fio, @tel, @doljnost, HASHBYTES('MD5', @pas))
|
||||
ELSE PRINT 'Ââåäèòå êîððåêòíóþ äîëæíîñòü!'
|
||||
ELSE PRINT 'Ââåäèòå êîððåêòíûå çíà÷åíèÿ ÔÈÎ'
|
||||
ELSE PRINT 'Òàêîé íîìåð ïàñïîðòà óæå åñòü â áàçå!'
|
||||
END
|
||||
GO
|
||||
|
||||
/* îáíîâëåíèå äèñïåò÷åðîâ */
|
||||
CREATE PROC edit_dispetcher (@serialpas float, @fio t_fio, @tel nvarchar(16), @doljnost nvarchar(20), @pas varchar(1000))
|
||||
AS
|
||||
BEGIN
|
||||
IF EXISTS (SELECT serialpas FROM dispetcher WHERE serialpas=@serialpas)
|
||||
IF @doljnost in ('Ñòàæåð', 'Äèñïåò÷åð', 'Ñòàðøèé äèñïåò÷åð')
|
||||
IF (@fio like '% %')
|
||||
BEGIN
|
||||
UPDATE dispetcher
|
||||
SET fio=@fio, tel=@tel, doljnost=@doljnost
|
||||
WHERE serialpas=@serialpas
|
||||
IF (@pas IS NOT NULL)
|
||||
UPDATE dispetcher
|
||||
SET pas=HASHBYTES('MD5',@pas)
|
||||
WHERE serialpas=@serialpas
|
||||
END
|
||||
ELSE PRINT 'Ââåäèòå êîððåêòíûå çíà÷åíèÿ ÔÈÎ'
|
||||
ELSE PRINT 'Ââåäèòå êîððåêòíóþ äîëæíîñòü!'
|
||||
ELSE PRINT 'Äèñïåò÷åðà ñ òàêèìè ïàñïîðòíûìè äàííûìè íå ñóùåñòâóåò'
|
||||
END
|
||||
GO
|
||||
|
||||
/* óäàëåíèå äèñïåò÷åðà */
|
||||
CREATE PROC del_dispetcher (@serialpas float)
|
||||
AS
|
||||
BEGIN
|
||||
IF EXISTS (SELECT serialpas FROM dispetcher WHERE serialpas=@serialpas)
|
||||
DELETE dispetcher
|
||||
WHERE serialpas=@serialpas
|
||||
ELSE PRINT 'Äèñïåò÷åðà ñ òàêèìè ïàñîðòíûìè äàííûìè íåò â áàçå'
|
||||
END
|
||||
GO
|
||||
|
||||
/* äîáàâëåíèå ìàøèíèñòà */
|
||||
CREATE PROCEDURE add_mashinist @serialpas float, @serial int, @fio nvarchar(20), @tel nvarchar(16), @staj int, @kvalif nvarchar(10)
|
||||
AS
|
||||
BEGIN
|
||||
IF NOT EXISTS (SELECT serialpas FROM mashinist WHERE serialpas=@serialpas)
|
||||
IF EXISTS (SELECT serial FROM psostav WHERE serial=@serial)
|
||||
IF (@fio like '% %')
|
||||
IF @kvalif in ('Ïåðâàÿ', 'Âòîðàÿ', 'Òðåòüÿ')
|
||||
IF (@staj>=0)
|
||||
INSERT INTO mashinist
|
||||
VALUES (@serialpas, @serial, @fio, @tel, @staj, @kvalif)
|
||||
ELSE PRINT 'Ñòàæ íå ìîæåò áûòü îòðèöàòåëüíûì!'
|
||||
ELSE PRINT 'Ââåäèòå êîððåêòíûå äàííûå äëÿ êâàëèôèêàöèè!'
|
||||
ELSE PRINT 'Ââåäèòå êîðåêòíûå çíà÷åíèÿ ÔÈÎ'
|
||||
ELSE PRINT 'Ñîñòàâà ñ òàêèì ñåðèéíûì íîìåðîì â áàçå íåò!'
|
||||
ELSE PRINT 'Òàêîé íîìåð ïàñïîðòà óæå åñòü'
|
||||
END
|
||||
GO
|
||||
|
||||
/* îáíîâëåíèå ìàøèíèñòîâ */
|
||||
CREATE PROC edit_mashinist (@serialpas float, @serial int, @fio t_fio, @tel nvarchar(16), @staj int, @kvalif nvarchar(10))
|
||||
AS
|
||||
BEGIN
|
||||
IF EXISTS (SELECT serialpas FROM mashinist WHERE serialpas=@serialpas)
|
||||
IF @serial IN (SELECT serial FROM psostav)
|
||||
IF @kvalif in ('Ïåðâàÿ', 'Âòîðàÿ', 'Òðåòüÿ')
|
||||
IF (@staj>=0)
|
||||
UPDATE mashinist
|
||||
SET serial=@serial, fio=@fio, tel=@tel, staj=@staj, kvalif=@kvalif
|
||||
WHERE serialpas=@serialpas
|
||||
ELSE PRINT 'Ñòàæ íå ìîæåò áûòü îòðèöàòåëüíûì!'
|
||||
ELSE PRINT 'Ââåäèòå êîððåêòíûå äàííûå äëÿ êâàëèôèêàöèè!'
|
||||
ELSE PRINT 'Ñîñòàâà, êîòîðûì óïðàâëÿåò ìàøèíèñò, íå ñóùåñòâóåò'
|
||||
ELSE PRINT 'Ìàøèíèñòà ñ òàêèìè ïàñïîðòàìè äàííûìè íåò â áàçå'
|
||||
END
|
||||
GO
|
||||
|
||||
/* Óäàëåíèå ìàøèíèñòà */
|
||||
CREATE PROC del_mashinist (@serialpas float)
|
||||
AS
|
||||
BEGIN
|
||||
IF EXISTS (SELECT serialpas FROM mashinist WHERE serialpas=@serialpas)
|
||||
IF ((SELECT stat FROM psostav WHERE serial=(SELECT serial FROM mashinist WHERE serialpas=@serialpas)) IN (SELECT depo_status FROM vetka) or EXISTS (SELECT serial FROM mashinist WHERE serialpas!=@serialpas and serial=(SELECT serial FROM mashinist WHERE serialpas=@serialpas)))
|
||||
DELETE mashinist
|
||||
WHERE serialpas=@serialpas
|
||||
ELSE PRINT 'Ïåðåâåäèòå ñîñòàâ â äåïî ñòàíöèè, ïåðåä óäàëåíèåì ìàøèíèñòà'
|
||||
ELSE PRINT 'Ìàøèíèñòà ñ òàêèìè ïàñïîðòíûìè äàííûìè íåò â áàçå!'
|
||||
END
|
||||
GO
|
||||
|
||||
/* Äîáàëâåíèå òèïà ñîñòâàâîâ */
|
||||
CREATE PROCEDURE add_typsostav (@typkod int, @name nvarchar(20), @kolmest int, @dlina float, @shirina float, @visota float, @koleya int, @naznachenie nvarchar(20), @speed int)
|
||||
AS
|
||||
BEGIN
|
||||
IF NOT EXISTS (SELECT typkod FROM typsostav WHERE typkod=@typkod)
|
||||
IF (@dlina>0 and @shirina>0 and @visota>0 and @koleya>0 and @kolmest>0)
|
||||
IF @dlina < 200
|
||||
IF @shirina < 3000
|
||||
IF @visota < 5000
|
||||
IF @koleya=1520
|
||||
IF @speed>0
|
||||
INSERT INTO typsostav
|
||||
VALUES (@typkod, @name, @kolmest, @dlina, @shirina, @visota, @naznachenie, @koleya, @speed)
|
||||
ELSE PRINT 'Ñêîðîñòü íå ìîæåò áûòü îòðèöàòåëüíîé'
|
||||
ELSE PRINT 'Êîëåÿ ñîñòàâà íå ñîîòâåòñòâóåò òðåáîâàíèÿì ìåòðî'
|
||||
ELSE PRINT 'Ñîñòàâ ñëèøêîì âûñîêèé'
|
||||
ELSE PRINT 'Ñîñòàâ ñëèøêîì øèðîêèé'
|
||||
ELSE PRINT 'Ñîñòàâ ñëèøêîì äëèííûé'
|
||||
ELSE PRINT 'Ââåäèòå êîððåêòíûå çíà÷åíèÿ'
|
||||
ELSE PRINT 'Òèï ñ òàêèì êîäîì óæå ñóùåñòâóåò!'
|
||||
END
|
||||
GO
|
||||
|
||||
/* èçìåíåíèå òèïà ñîñòàâîâ */
|
||||
CREATE PROC edit_typsostav (@typkod int, @name nvarchar(20), @kolmest int, @dlina float, @shirina float, @visota float, @koleya int, @naznachenie nvarchar(20), @speed int)
|
||||
AS
|
||||
BEGIN
|
||||
IF EXISTS (SELECT typkod FROM typsostav WHERE typkod=@typkod)
|
||||
IF (@dlina>0 and @shirina>0 and @visota>0 and @koleya>0 and @kolmest>0)
|
||||
IF @dlina < 200
|
||||
IF @shirina < 3000
|
||||
IF @visota < 5000
|
||||
IF @koleya=1520
|
||||
IF @speed>0
|
||||
UPDATE typsostav
|
||||
SET name=@name, kolmest=@kolmest, dlina=@dlina, shirina=@shirina, visota=@visota, koleya=@koleya, naznachenie=@naznachenie, speed=@speed
|
||||
WHERE typkod=@typkod
|
||||
ELSE PRINT 'Ñêîðîñòü íå ìîæåò áûòü îòðèöàòåëüíîé'
|
||||
ELSE PRINT 'Êîëåÿ ñîñòàâà íå ñîîòâåòñòâóåò òðåáîâàíèÿì ìåòðî'
|
||||
ELSE PRINT 'Ñîñòàâ ñëèøêîì âûñîêèé'
|
||||
ELSE PRINT 'Ñîñòàâ ñëèøêîì øèðîêèé'
|
||||
ELSE PRINT 'Ñîñòàâ ñëèøêîì äëèííûé'
|
||||
ELSE PRINT 'Ââåäèòå êîððåêòíûå çíà÷åíèÿ'
|
||||
ELSE PRINT 'Òèïà ñ òàêèì êîäîì íå ñóùåñòâóåò!'
|
||||
END
|
||||
GO
|
||||
|
||||
/* Óäàëåíèå òèïà ñîñòàâîâ */
|
||||
CREATE PROC del_typsostav (@typkod int)
|
||||
AS
|
||||
BEGIN
|
||||
IF EXISTS (SELECT typkod FROM typsostav WHERE typkod=@typkod)
|
||||
IF NOT EXISTS (SELECT serial FROM raspisanie WHERE serial=(SELECT TOP 1 serial FROM psostav WHERE typkod=@typkod))
|
||||
DELETE typsostav
|
||||
WHERE typkod=@typkod
|
||||
ELSE PRINT 'Óäàëåíèå íåâîçìîæíî, òàê êàê ïîåçäà äàíîãî òèïà ïðèñóòñòâóþò â ðàñïèñàíèè!'
|
||||
ELSE PRINT 'Òàêîãî òèïà ñîñòàâîâ íå ñóùåñòâóåò'
|
||||
END
|
||||
GO
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
92
SQL/Triggers.sql
Normal file
92
SQL/Triggers.sql
Normal file
@ -0,0 +1,92 @@
|
||||
USE Metro
|
||||
GO
|
||||
|
||||
|
||||
CREATE TRIGGER t_add_stanciya
|
||||
ON stanciya INSTEAD OF INSERT
|
||||
AS
|
||||
DECLARE @kod int, @name varchar(20), @paspotok int, @kod_nazad int, @rast_vpered int, @rast_nazad int, @stat int, @start_time time, @finish_time time
|
||||
SELECT @kod = kod, @name=name, @paspotok=paspotok, @kod_nazad = kod_nazad, @rast_vpered = rast_vpered, @rast_nazad = rast_nazad, @stat=stat, @start_time=start_time, @finish_time=finish_time
|
||||
FROM inserted
|
||||
IF (@kod_nazad IS NULL or @kod_nazad=0)
|
||||
INSERT INTO stanciya
|
||||
VALUES (@kod, @name, @paspotok, NULL, NULL, NULL, NULL, @stat, @start_time, @finish_time)
|
||||
ELSE
|
||||
BEGIN
|
||||
DECLARE @s_kod int, @s_kod_vpered int, @s_kod_nazad int, @s_rast_vpered int, @s_rast_nazad int
|
||||
DECLARE @CURSOR CURSOR
|
||||
SET @CURSOR = CURSOR SCROLL
|
||||
FOR
|
||||
SELECT kod, kod_vpered, kod_nazad, rast_vpered, rast_nazad
|
||||
FROM stanciya
|
||||
OPEN @CURSOR
|
||||
FETCH NEXT FROM @CURSOR INTO @s_kod, @s_kod_vpered, @s_kod_nazad, @s_rast_vpered, @s_rast_nazad
|
||||
WHILE @@FETCH_STATUS = 0
|
||||
BEGIN
|
||||
IF (@s_kod=@kod_nazad)
|
||||
BEGIN
|
||||
IF @rast_vpered IS NOT NULL
|
||||
BEGIN
|
||||
DECLARE @kod_vpered int
|
||||
SELECT @kod_vpered = kod_vpered
|
||||
FROM stanciya
|
||||
WHERE kod=@s_kod
|
||||
UPDATE stanciya SET kod_nazad = @kod WHERE kod = @kod_vpered
|
||||
UPDATE stanciya SET rast_nazad = @rast_vpered WHERE kod = @kod_vpered
|
||||
END
|
||||
UPDATE stanciya SET kod_vpered = @kod WHERE kod=@s_kod
|
||||
UPDATE stanciya SET rast_vpered = @rast_nazad WHERE kod=@s_kod
|
||||
INSERT INTO stanciya
|
||||
VALUES (@kod, @name, @paspotok, @kod_vpered, @rast_vpered, @kod_nazad, @rast_nazad, @stat, @start_time, @finish_time)
|
||||
BREAK
|
||||
END
|
||||
FETCH NEXT FROM @CURSOR INTO @s_kod, @s_kod_vpered, @s_kod_nazad, @s_rast_vpered, @s_rast_nazad
|
||||
END
|
||||
CLOSE @CURSOR
|
||||
END
|
||||
GO
|
||||
|
||||
CREATE TRIGGER t_del_typsostav
|
||||
ON typsostav INSTEAD OF DELETE
|
||||
AS
|
||||
DECLARE @typkod INT
|
||||
SELECT @typkod=typkod
|
||||
FROM deleted
|
||||
UPDATE mashinist
|
||||
SET serial=NULL
|
||||
WHERE serial IN (SELECT serial FROM psostav WHERE typkod=@typkod)
|
||||
DELETE psostav
|
||||
WHERE typkod=@typkod
|
||||
DELETE typsostav
|
||||
WHERE typkod=@typkod
|
||||
GO
|
||||
|
||||
CREATE TRIGGER t_del_stanciya
|
||||
ON stanciya INSTEAD OF DELETE
|
||||
AS
|
||||
DECLARE @kod int, @d_kod_vpered int, @d_kod_nazad int, @d_rast_vpered int, @d_rast_nazad int
|
||||
SELECT @kod=kod, @d_kod_nazad=kod_nazad, @d_kod_vpered=kod_vpered, @d_rast_vpered=rast_vpered, @d_rast_nazad=rast_nazad FROM deleted
|
||||
DECLARE @s_kod int, @s_kod_vpered int, @s_kod_nazad int, @s_rast_vpered int, @s_rast_nazad int
|
||||
DECLARE @CURSOR CURSOR
|
||||
SET @CURSOR = CURSOR SCROLL
|
||||
FOR
|
||||
SELECT kod, kod_vpered, kod_nazad, rast_vpered, rast_nazad
|
||||
FROM stanciya
|
||||
OPEN @CURSOR
|
||||
FETCH NEXT FROM @CURSOR INTO @s_kod, @s_kod_vpered, @s_kod_nazad, @s_rast_vpered, @s_rast_nazad
|
||||
WHILE @@FETCH_STATUS = 0
|
||||
BEGIN
|
||||
IF @s_kod=@d_kod_nazad
|
||||
UPDATE stanciya
|
||||
SET kod_vpered=@d_kod_vpered, rast_vpered=rast_vpered+@d_rast_vpered
|
||||
WHERE kod=@s_kod
|
||||
IF @s_kod=@d_kod_vpered
|
||||
UPDATE stanciya
|
||||
SET kod_nazad=@d_kod_nazad, rast_nazad=rast_nazad+@d_rast_nazad
|
||||
WHERE kod=@s_kod
|
||||
FETCH NEXT FROM @CURSOR INTO @s_kod, @s_kod_vpered, @s_kod_nazad, @s_rast_vpered, @s_rast_nazad
|
||||
END
|
||||
DELETE stanciya
|
||||
WHERE kod=@kod
|
||||
CLOSE @CURSOR
|
||||
GO
|
16
SQL/View.sql
Normal file
16
SQL/View.sql
Normal file
@ -0,0 +1,16 @@
|
||||
USE
|
||||
Metro
|
||||
GO
|
||||
|
||||
CREATE VIEW v_raspisanie
|
||||
AS
|
||||
SELECT start_vremya AS 'Îòïðàâëåíèå', s1.name AS 'Ñî ñòàíöèè', finish_vremya AS 'Ïðèáûòèå', s2.name AS 'Íà ñòàíöèþ', vetka AS 'Âåòêà'
|
||||
FROM (raspisanie inner join stanciya s1 on start_kod=kod) inner join stanciya s2 on finish_kod=s2.kod
|
||||
GO
|
||||
|
||||
|
||||
CREATE VIEW v_remont
|
||||
AS
|
||||
SELECT typik AS 'Òóïèê', serial AS 'Ñîñòàâ', name AS 'Íåèñïðàâíîñòü', start AS 'Âðåìÿ íà÷àëà', DATEADD(DAY,srok_dos_det+vremya_remonta,start) AS 'Ïðåäïîëîæèòåëüíîå îêîí÷àíèå'
|
||||
FROM (remont inner join spravka on remont.kod=spravka.kod)
|
||||
GO
|
BIN
Пояснительная Записка.pdf
Normal file
BIN
Пояснительная Записка.pdf
Normal file
Binary file not shown.
Reference in New Issue
Block a user