選択できるのは25トピックまでです。 トピックは、先頭が英数字で、英数字とダッシュ('-')を使用した35文字以内のものにしてください。

10_init.sql 18KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650
  1. --
  2. -- PostgreSQL database dump
  3. --
  4. -- Dumped from database version 11.2 (Debian 11.2-1.pgdg90+1)
  5. -- Dumped by pg_dump version 11.2 (Debian 11.2-1.pgdg90+1)
  6. SET statement_timeout = 0;
  7. SET lock_timeout = 0;
  8. SET idle_in_transaction_session_timeout = 0;
  9. SET client_encoding = 'UTF8';
  10. SET standard_conforming_strings = on;
  11. SELECT pg_catalog.set_config('search_path', '', false);
  12. SET check_function_bodies = false;
  13. SET client_min_messages = warning;
  14. SET row_security = off;
  15. --
  16. -- Name: merge_quota(); Type: FUNCTION; Schema: public; Owner: -
  17. --
  18. CREATE FUNCTION public.merge_quota() RETURNS trigger
  19. LANGUAGE plpgsql
  20. AS $$
  21. BEGIN
  22. UPDATE quota SET current = NEW.current + current WHERE username = NEW.username AND path = NEW.path;
  23. IF found THEN
  24. RETURN NULL;
  25. ELSE
  26. RETURN NEW;
  27. END IF;
  28. END;
  29. $$;
  30. --
  31. -- Name: merge_quota2(); Type: FUNCTION; Schema: public; Owner: -
  32. --
  33. CREATE FUNCTION public.merge_quota2() RETURNS trigger
  34. LANGUAGE plpgsql
  35. AS $$
  36. BEGIN
  37. IF NEW.messages < 0 OR NEW.messages IS NULL THEN
  38. -- ugly kludge: we came here from this function, really do try to insert
  39. IF NEW.messages IS NULL THEN
  40. NEW.messages = 0;
  41. ELSE
  42. NEW.messages = -NEW.messages;
  43. END IF;
  44. return NEW;
  45. END IF;
  46. LOOP
  47. UPDATE quota2 SET bytes = bytes + NEW.bytes,
  48. messages = messages + NEW.messages
  49. WHERE username = NEW.username;
  50. IF found THEN
  51. RETURN NULL;
  52. END IF;
  53. BEGIN
  54. IF NEW.messages = 0 THEN
  55. INSERT INTO quota2 (bytes, messages, username) VALUES (NEW.bytes, NULL, NEW.username);
  56. ELSE
  57. INSERT INTO quota2 (bytes, messages, username) VALUES (NEW.bytes, -NEW.messages, NEW.username);
  58. END IF;
  59. return NULL;
  60. EXCEPTION WHEN unique_violation THEN
  61. -- someone just inserted the record, update it
  62. END;
  63. END LOOP;
  64. END;
  65. $$;
  66. SET default_tablespace = '';
  67. SET default_with_oids = false;
  68. --
  69. -- Name: admin; Type: TABLE; Schema: public; Owner: -
  70. --
  71. CREATE TABLE public.admin (
  72. username character varying(255) NOT NULL,
  73. password character varying(255) DEFAULT ''::character varying NOT NULL,
  74. created timestamp with time zone DEFAULT now(),
  75. modified timestamp with time zone DEFAULT now(),
  76. active boolean DEFAULT true NOT NULL,
  77. superadmin boolean DEFAULT false NOT NULL,
  78. phone character varying(30) DEFAULT ''::character varying NOT NULL,
  79. email_other character varying(255) DEFAULT ''::character varying NOT NULL,
  80. token character varying(255) DEFAULT ''::character varying NOT NULL,
  81. token_validity timestamp with time zone DEFAULT '2000-01-01 00:00:00+00'::timestamp with time zone
  82. );
  83. --
  84. -- Name: TABLE admin; Type: COMMENT; Schema: public; Owner: -
  85. --
  86. COMMENT ON TABLE public.admin IS 'Postfix Admin - Virtual Admins';
  87. --
  88. -- Name: alias; Type: TABLE; Schema: public; Owner: -
  89. --
  90. CREATE TABLE public.alias (
  91. address character varying(255) NOT NULL,
  92. goto text NOT NULL,
  93. domain character varying(255) NOT NULL,
  94. created timestamp with time zone DEFAULT now(),
  95. modified timestamp with time zone DEFAULT now(),
  96. active boolean DEFAULT true NOT NULL
  97. );
  98. --
  99. -- Name: TABLE alias; Type: COMMENT; Schema: public; Owner: -
  100. --
  101. COMMENT ON TABLE public.alias IS 'Postfix Admin - Virtual Aliases';
  102. --
  103. -- Name: alias_domain; Type: TABLE; Schema: public; Owner: -
  104. --
  105. CREATE TABLE public.alias_domain (
  106. alias_domain character varying(255) NOT NULL,
  107. target_domain character varying(255) NOT NULL,
  108. created timestamp with time zone DEFAULT now(),
  109. modified timestamp with time zone DEFAULT now(),
  110. active boolean DEFAULT true NOT NULL
  111. );
  112. --
  113. -- Name: TABLE alias_domain; Type: COMMENT; Schema: public; Owner: -
  114. --
  115. COMMENT ON TABLE public.alias_domain IS 'Postfix Admin - Domain Aliases';
  116. --
  117. -- Name: config; Type: TABLE; Schema: public; Owner: -
  118. --
  119. CREATE TABLE public.config (
  120. id integer NOT NULL,
  121. name character varying(20) NOT NULL,
  122. value character varying(20) NOT NULL
  123. );
  124. --
  125. -- Name: config_id_seq; Type: SEQUENCE; Schema: public; Owner: -
  126. --
  127. CREATE SEQUENCE public.config_id_seq
  128. AS integer
  129. START WITH 1
  130. INCREMENT BY 1
  131. NO MINVALUE
  132. NO MAXVALUE
  133. CACHE 1;
  134. --
  135. -- Name: config_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: -
  136. --
  137. ALTER SEQUENCE public.config_id_seq OWNED BY public.config.id;
  138. --
  139. -- Name: domain; Type: TABLE; Schema: public; Owner: -
  140. --
  141. CREATE TABLE public.domain (
  142. domain character varying(255) NOT NULL,
  143. description character varying(255) DEFAULT ''::character varying NOT NULL,
  144. aliases integer DEFAULT 0 NOT NULL,
  145. mailboxes integer DEFAULT 0 NOT NULL,
  146. maxquota bigint DEFAULT 0 NOT NULL,
  147. quota bigint DEFAULT 0 NOT NULL,
  148. transport character varying(255) DEFAULT NULL::character varying,
  149. backupmx boolean DEFAULT false NOT NULL,
  150. created timestamp with time zone DEFAULT now(),
  151. modified timestamp with time zone DEFAULT now(),
  152. active boolean DEFAULT true NOT NULL
  153. );
  154. --
  155. -- Name: TABLE domain; Type: COMMENT; Schema: public; Owner: -
  156. --
  157. COMMENT ON TABLE public.domain IS 'Postfix Admin - Virtual Domains';
  158. --
  159. -- Name: domain_admins; Type: TABLE; Schema: public; Owner: -
  160. --
  161. CREATE TABLE public.domain_admins (
  162. username character varying(255) NOT NULL,
  163. domain character varying(255) NOT NULL,
  164. created timestamp with time zone DEFAULT now(),
  165. active boolean DEFAULT true NOT NULL
  166. );
  167. --
  168. -- Name: TABLE domain_admins; Type: COMMENT; Schema: public; Owner: -
  169. --
  170. COMMENT ON TABLE public.domain_admins IS 'Postfix Admin - Domain Admins';
  171. --
  172. -- Name: fetchmail; Type: TABLE; Schema: public; Owner: -
  173. --
  174. CREATE TABLE public.fetchmail (
  175. id integer NOT NULL,
  176. mailbox character varying(255) DEFAULT ''::character varying NOT NULL,
  177. src_server character varying(255) DEFAULT ''::character varying NOT NULL,
  178. src_auth character varying(15) NOT NULL,
  179. src_user character varying(255) DEFAULT ''::character varying NOT NULL,
  180. src_password character varying(255) DEFAULT ''::character varying NOT NULL,
  181. src_folder character varying(255) DEFAULT ''::character varying NOT NULL,
  182. poll_time integer DEFAULT 10 NOT NULL,
  183. fetchall boolean DEFAULT false NOT NULL,
  184. keep boolean DEFAULT false NOT NULL,
  185. protocol character varying(15) NOT NULL,
  186. extra_options text,
  187. returned_text text,
  188. mda character varying(255) DEFAULT ''::character varying NOT NULL,
  189. date timestamp with time zone DEFAULT now(),
  190. usessl boolean DEFAULT false NOT NULL,
  191. sslcertck boolean DEFAULT false NOT NULL,
  192. sslcertpath character varying(255) DEFAULT ''::character varying,
  193. sslfingerprint character varying(255) DEFAULT ''::character varying,
  194. domain character varying(255) DEFAULT ''::character varying,
  195. active boolean DEFAULT false NOT NULL,
  196. created timestamp with time zone DEFAULT '2000-01-01 00:00:00+00'::timestamp with time zone,
  197. modified timestamp with time zone DEFAULT now(),
  198. CONSTRAINT fetchmail_protocol_check CHECK (((protocol)::text = ANY ((ARRAY['POP3'::character varying, 'IMAP'::character varying, 'POP2'::character varying, 'ETRN'::character varying, 'AUTO'::character varying])::text[]))),
  199. CONSTRAINT fetchmail_src_auth_check CHECK (((src_auth)::text = ANY ((ARRAY['password'::character varying, 'kerberos_v5'::character varying, 'kerberos'::character varying, 'kerberos_v4'::character varying, 'gssapi'::character varying, 'cram-md5'::character varying, 'otp'::character varying, 'ntlm'::character varying, 'msn'::character varying, 'ssh'::character varying, 'any'::character varying])::text[])))
  200. );
  201. --
  202. -- Name: fetchmail_id_seq; Type: SEQUENCE; Schema: public; Owner: -
  203. --
  204. CREATE SEQUENCE public.fetchmail_id_seq
  205. AS integer
  206. START WITH 1
  207. INCREMENT BY 1
  208. NO MINVALUE
  209. NO MAXVALUE
  210. CACHE 1;
  211. --
  212. -- Name: fetchmail_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: -
  213. --
  214. ALTER SEQUENCE public.fetchmail_id_seq OWNED BY public.fetchmail.id;
  215. --
  216. -- Name: log; Type: TABLE; Schema: public; Owner: -
  217. --
  218. CREATE TABLE public.log (
  219. "timestamp" timestamp with time zone DEFAULT now(),
  220. username character varying(255) DEFAULT ''::character varying NOT NULL,
  221. domain character varying(255) DEFAULT ''::character varying NOT NULL,
  222. action character varying(255) DEFAULT ''::character varying NOT NULL,
  223. data text DEFAULT ''::text NOT NULL,
  224. id integer NOT NULL
  225. );
  226. --
  227. -- Name: TABLE log; Type: COMMENT; Schema: public; Owner: -
  228. --
  229. COMMENT ON TABLE public.log IS 'Postfix Admin - Log';
  230. --
  231. -- Name: log_id_seq; Type: SEQUENCE; Schema: public; Owner: -
  232. --
  233. CREATE SEQUENCE public.log_id_seq
  234. AS integer
  235. START WITH 1
  236. INCREMENT BY 1
  237. NO MINVALUE
  238. NO MAXVALUE
  239. CACHE 1;
  240. --
  241. -- Name: log_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: -
  242. --
  243. ALTER SEQUENCE public.log_id_seq OWNED BY public.log.id;
  244. --
  245. -- Name: mailbox; Type: TABLE; Schema: public; Owner: -
  246. --
  247. CREATE TABLE public.mailbox (
  248. username character varying(255) NOT NULL,
  249. password character varying(255) DEFAULT ''::character varying NOT NULL,
  250. name character varying(255) DEFAULT ''::character varying NOT NULL,
  251. maildir character varying(255) DEFAULT ''::character varying NOT NULL,
  252. quota bigint DEFAULT 0 NOT NULL,
  253. created timestamp with time zone DEFAULT now(),
  254. modified timestamp with time zone DEFAULT now(),
  255. active boolean DEFAULT true NOT NULL,
  256. domain character varying(255),
  257. local_part character varying(255) NOT NULL,
  258. phone character varying(30) DEFAULT ''::character varying NOT NULL,
  259. email_other character varying(255) DEFAULT ''::character varying NOT NULL,
  260. token character varying(255) DEFAULT ''::character varying NOT NULL,
  261. token_validity timestamp with time zone DEFAULT '2000-01-01 00:00:00+00'::timestamp with time zone
  262. );
  263. --
  264. -- Name: TABLE mailbox; Type: COMMENT; Schema: public; Owner: -
  265. --
  266. COMMENT ON TABLE public.mailbox IS 'Postfix Admin - Virtual Mailboxes';
  267. --
  268. -- Name: quota; Type: TABLE; Schema: public; Owner: -
  269. --
  270. CREATE TABLE public.quota (
  271. username character varying(255) NOT NULL,
  272. path character varying(100) NOT NULL,
  273. current bigint DEFAULT 0 NOT NULL
  274. );
  275. --
  276. -- Name: quota2; Type: TABLE; Schema: public; Owner: -
  277. --
  278. CREATE TABLE public.quota2 (
  279. username character varying(100) NOT NULL,
  280. bytes bigint DEFAULT 0 NOT NULL,
  281. messages integer DEFAULT 0 NOT NULL
  282. );
  283. --
  284. -- Name: vacation; Type: TABLE; Schema: public; Owner: -
  285. --
  286. CREATE TABLE public.vacation (
  287. email character varying(255) NOT NULL,
  288. subject character varying(255) NOT NULL,
  289. body text DEFAULT ''::text NOT NULL,
  290. created timestamp with time zone DEFAULT now(),
  291. active boolean DEFAULT true NOT NULL,
  292. domain character varying(255),
  293. modified timestamp with time zone DEFAULT now(),
  294. activefrom timestamp with time zone DEFAULT '2000-01-01 00:00:00+00'::timestamp with time zone,
  295. activeuntil timestamp with time zone DEFAULT '2038-01-18 00:00:00+00'::timestamp with time zone,
  296. interval_time integer DEFAULT 0 NOT NULL
  297. );
  298. --
  299. -- Name: vacation_notification; Type: TABLE; Schema: public; Owner: -
  300. --
  301. CREATE TABLE public.vacation_notification (
  302. on_vacation character varying(255) NOT NULL,
  303. notified character varying(255) NOT NULL,
  304. notified_at timestamp with time zone DEFAULT now() NOT NULL
  305. );
  306. --
  307. -- Name: config id; Type: DEFAULT; Schema: public; Owner: -
  308. --
  309. ALTER TABLE ONLY public.config ALTER COLUMN id SET DEFAULT nextval('public.config_id_seq'::regclass);
  310. --
  311. -- Name: fetchmail id; Type: DEFAULT; Schema: public; Owner: -
  312. --
  313. ALTER TABLE ONLY public.fetchmail ALTER COLUMN id SET DEFAULT nextval('public.fetchmail_id_seq'::regclass);
  314. --
  315. -- Name: log id; Type: DEFAULT; Schema: public; Owner: -
  316. --
  317. ALTER TABLE ONLY public.log ALTER COLUMN id SET DEFAULT nextval('public.log_id_seq'::regclass);
  318. --
  319. -- Name: admin admin_key; Type: CONSTRAINT; Schema: public; Owner: -
  320. --
  321. ALTER TABLE ONLY public.admin
  322. ADD CONSTRAINT admin_key PRIMARY KEY (username);
  323. --
  324. -- Name: alias_domain alias_domain_pkey; Type: CONSTRAINT; Schema: public; Owner: -
  325. --
  326. ALTER TABLE ONLY public.alias_domain
  327. ADD CONSTRAINT alias_domain_pkey PRIMARY KEY (alias_domain);
  328. --
  329. -- Name: alias alias_key; Type: CONSTRAINT; Schema: public; Owner: -
  330. --
  331. ALTER TABLE ONLY public.alias
  332. ADD CONSTRAINT alias_key PRIMARY KEY (address);
  333. --
  334. -- Name: config config_name_key; Type: CONSTRAINT; Schema: public; Owner: -
  335. --
  336. ALTER TABLE ONLY public.config
  337. ADD CONSTRAINT config_name_key UNIQUE (name);
  338. --
  339. -- Name: config config_pkey; Type: CONSTRAINT; Schema: public; Owner: -
  340. --
  341. ALTER TABLE ONLY public.config
  342. ADD CONSTRAINT config_pkey PRIMARY KEY (id);
  343. --
  344. -- Name: domain domain_key; Type: CONSTRAINT; Schema: public; Owner: -
  345. --
  346. ALTER TABLE ONLY public.domain
  347. ADD CONSTRAINT domain_key PRIMARY KEY (domain);
  348. --
  349. -- Name: fetchmail fetchmail_pkey; Type: CONSTRAINT; Schema: public; Owner: -
  350. --
  351. ALTER TABLE ONLY public.fetchmail
  352. ADD CONSTRAINT fetchmail_pkey PRIMARY KEY (id);
  353. --
  354. -- Name: log log_pkey; Type: CONSTRAINT; Schema: public; Owner: -
  355. --
  356. ALTER TABLE ONLY public.log
  357. ADD CONSTRAINT log_pkey PRIMARY KEY (id);
  358. --
  359. -- Name: mailbox mailbox_key; Type: CONSTRAINT; Schema: public; Owner: -
  360. --
  361. ALTER TABLE ONLY public.mailbox
  362. ADD CONSTRAINT mailbox_key PRIMARY KEY (username);
  363. --
  364. -- Name: quota2 quota2_pkey; Type: CONSTRAINT; Schema: public; Owner: -
  365. --
  366. ALTER TABLE ONLY public.quota2
  367. ADD CONSTRAINT quota2_pkey PRIMARY KEY (username);
  368. --
  369. -- Name: quota quota_pkey; Type: CONSTRAINT; Schema: public; Owner: -
  370. --
  371. ALTER TABLE ONLY public.quota
  372. ADD CONSTRAINT quota_pkey PRIMARY KEY (username, path);
  373. --
  374. -- Name: vacation_notification vacation_notification_pkey; Type: CONSTRAINT; Schema: public; Owner: -
  375. --
  376. ALTER TABLE ONLY public.vacation_notification
  377. ADD CONSTRAINT vacation_notification_pkey PRIMARY KEY (on_vacation, notified);
  378. --
  379. -- Name: vacation vacation_pkey; Type: CONSTRAINT; Schema: public; Owner: -
  380. --
  381. ALTER TABLE ONLY public.vacation
  382. ADD CONSTRAINT vacation_pkey PRIMARY KEY (email);
  383. --
  384. -- Name: alias_address_active; Type: INDEX; Schema: public; Owner: -
  385. --
  386. CREATE INDEX alias_address_active ON public.alias USING btree (address, active);
  387. --
  388. -- Name: alias_domain_active; Type: INDEX; Schema: public; Owner: -
  389. --
  390. CREATE INDEX alias_domain_active ON public.alias_domain USING btree (alias_domain, active);
  391. --
  392. -- Name: alias_domain_idx; Type: INDEX; Schema: public; Owner: -
  393. --
  394. CREATE INDEX alias_domain_idx ON public.alias USING btree (domain);
  395. --
  396. -- Name: domain_domain_active; Type: INDEX; Schema: public; Owner: -
  397. --
  398. CREATE INDEX domain_domain_active ON public.domain USING btree (domain, active);
  399. --
  400. -- Name: log_domain_timestamp_idx; Type: INDEX; Schema: public; Owner: -
  401. --
  402. CREATE INDEX log_domain_timestamp_idx ON public.log USING btree (domain, "timestamp");
  403. --
  404. -- Name: mailbox_domain_idx; Type: INDEX; Schema: public; Owner: -
  405. --
  406. CREATE INDEX mailbox_domain_idx ON public.mailbox USING btree (domain);
  407. --
  408. -- Name: mailbox_username_active; Type: INDEX; Schema: public; Owner: -
  409. --
  410. CREATE INDEX mailbox_username_active ON public.mailbox USING btree (username, active);
  411. --
  412. -- Name: vacation_email_active; Type: INDEX; Schema: public; Owner: -
  413. --
  414. CREATE INDEX vacation_email_active ON public.vacation USING btree (email, active);
  415. --
  416. -- Name: quota mergequota; Type: TRIGGER; Schema: public; Owner: -
  417. --
  418. CREATE TRIGGER mergequota BEFORE INSERT ON public.quota FOR EACH ROW EXECUTE PROCEDURE public.merge_quota();
  419. --
  420. -- Name: quota2 mergequota2; Type: TRIGGER; Schema: public; Owner: -
  421. --
  422. CREATE TRIGGER mergequota2 BEFORE INSERT ON public.quota2 FOR EACH ROW EXECUTE PROCEDURE public.merge_quota2();
  423. --
  424. -- Name: alias_domain alias_domain_alias_domain_fkey; Type: FK CONSTRAINT; Schema: public; Owner: -
  425. --
  426. ALTER TABLE ONLY public.alias_domain
  427. ADD CONSTRAINT alias_domain_alias_domain_fkey FOREIGN KEY (alias_domain) REFERENCES public.domain(domain) ON DELETE CASCADE;
  428. --
  429. -- Name: alias alias_domain_fkey; Type: FK CONSTRAINT; Schema: public; Owner: -
  430. --
  431. ALTER TABLE ONLY public.alias
  432. ADD CONSTRAINT alias_domain_fkey FOREIGN KEY (domain) REFERENCES public.domain(domain);
  433. --
  434. -- Name: alias_domain alias_domain_target_domain_fkey; Type: FK CONSTRAINT; Schema: public; Owner: -
  435. --
  436. ALTER TABLE ONLY public.alias_domain
  437. ADD CONSTRAINT alias_domain_target_domain_fkey FOREIGN KEY (target_domain) REFERENCES public.domain(domain) ON DELETE CASCADE;
  438. --
  439. -- Name: domain_admins domain_admins_domain_fkey; Type: FK CONSTRAINT; Schema: public; Owner: -
  440. --
  441. ALTER TABLE ONLY public.domain_admins
  442. ADD CONSTRAINT domain_admins_domain_fkey FOREIGN KEY (domain) REFERENCES public.domain(domain);
  443. --
  444. -- Name: mailbox mailbox_domain_fkey1; Type: FK CONSTRAINT; Schema: public; Owner: -
  445. --
  446. ALTER TABLE ONLY public.mailbox
  447. ADD CONSTRAINT mailbox_domain_fkey1 FOREIGN KEY (domain) REFERENCES public.domain(domain);
  448. --
  449. -- Name: vacation vacation_domain_fkey1; Type: FK CONSTRAINT; Schema: public; Owner: -
  450. --
  451. ALTER TABLE ONLY public.vacation
  452. ADD CONSTRAINT vacation_domain_fkey1 FOREIGN KEY (domain) REFERENCES public.domain(domain);
  453. --
  454. -- Name: vacation_notification vacation_notification_on_vacation_fkey; Type: FK CONSTRAINT; Schema: public; Owner: -
  455. --
  456. ALTER TABLE ONLY public.vacation_notification
  457. ADD CONSTRAINT vacation_notification_on_vacation_fkey FOREIGN KEY (on_vacation) REFERENCES public.vacation(email) ON DELETE CASCADE;
  458. --
  459. -- PostgreSQL database dump complete
  460. --