1CREATE SCHEMA global ; 2CREATE SCHEMA dns ; 3CREATE SCHEMA topo ; 4CREATE SCHEMA pgauth ; 5 6--------------------------------------------------------------------------- 7-- global schema 8--------------------------------------------------------------------------- 9 10-- Netmagis users and groups 11-- We can't use names "user" and "group" since they are reserved SQL words 12-- and using them would mean quoting every request. 13 14CREATE SEQUENCE global.seq_nmgroup START 1 ; 15CREATE TABLE global.nmgroup ( 16 idgrp INT -- group id 17 DEFAULT NEXTVAL ('global.seq_nmgroup'), 18 name TEXT, -- group name 19 p_admin INT DEFAULT 0, -- 1 if root, 0 if normal user 20 p_smtp INT DEFAULT 0, -- 1 if right to manage SMTP senders 21 p_ttl INT DEFAULT 0, -- 1 if right to edit TTL for a host 22 p_mac INT DEFAULT 0, -- 1 if right to access MAC module 23 p_genl INT DEFAULT 0, -- 1 if right to generate a link number 24 25 UNIQUE (name), 26 PRIMARY KEY (idgrp) 27) ; 28 29CREATE SEQUENCE global.seq_nmuser START 1 ; 30CREATE TABLE global.nmuser ( 31 idcor INT -- user id 32 DEFAULT NEXTVAL ('global.seq_nmuser'), 33 login TEXT, -- user name 34 present INT, -- 1 if present, 0 if no longer here 35 idgrp INT, -- group 36 37 UNIQUE (login), 38 FOREIGN KEY (idgrp) REFERENCES global.nmgroup (idgrp), 39 PRIMARY KEY (idcor) 40) ; 41 42-- Netmagis configuration parameters (those which are not in the 43-- configuration file) 44CREATE TABLE global.config ( 45 key TEXT, -- configuration key 46 value TEXT, -- key value 47 48 PRIMARY KEY (key) 49) ; 50 51-- log 52CREATE TABLE global.log ( 53 date TIMESTAMP (0) WITHOUT TIME ZONE 54 DEFAULT CURRENT_TIMESTAMP 55 NOT NULL, 56 subsys TEXT NOT NULL, -- subsystem ("dns", "topo", etc.) 57 event TEXT NOT NULL, -- "addhost", "delalias", etc. 58 login TEXT, -- user login 59 ip INET, -- IP address 60 msg TEXT -- log message 61) ; 62 63--------------------------------------------------------------------------- 64-- dns schema 65--------------------------------------------------------------------------- 66 67-- domains 68 69CREATE SEQUENCE dns.seq_domain START 1 ; 70CREATE TABLE dns.domain ( 71 iddom INT -- domain id 72 DEFAULT NEXTVAL ('dns.seq_domain'), 73 name TEXT, -- domain name (ex: "example.com") 74 75 UNIQUE (name), 76 PRIMARY KEY (iddom) 77) ; 78 79-- network, communities and organization descriptions 80 81CREATE SEQUENCE dns.seq_organization START 1 ; 82CREATE TABLE dns.organization ( 83 idorg INT -- organization id 84 DEFAULT NEXTVAL ('dns.seq_organization'), 85 name TEXT, -- "Example Corp." 86 87 PRIMARY KEY (idorg) 88) ; 89 90CREATE SEQUENCE dns.seq_community START 1 ; 91CREATE TABLE dns.community ( 92 idcomm INT -- community id 93 DEFAULT NEXTVAL ('dns.seq_community'), 94 name TEXT, -- "Administration" 95 96 PRIMARY KEY (idcomm) 97) ; 98 99CREATE SEQUENCE dns.seq_network START 1 ; 100CREATE TABLE dns.network ( 101 idnet INT -- network id 102 DEFAULT NEXTVAL ('dns.seq_network'), 103 name TEXT, -- name (ex: "Servers") 104 location TEXT, -- location if any 105 addr4 CIDR, -- IPv4 address range 106 addr6 CIDR, -- IPv6 address range 107 idorg INT, -- organization this network belongs to 108 idcomm INT, -- administration, R&D, etc. 109 comment TEXT, -- comment 110 dhcp INT DEFAULT 0, -- activate DHCP (1) or no (0) 111 gw4 INET, -- default network IPv4 gateway 112 gw6 INET, -- default network IPv6 gateway 113 114 CONSTRAINT at_least_one_prefix_v4_or_v6 115 CHECK (addr4 IS NOT NULL OR addr6 IS NOT NULL), 116 CONSTRAINT gw4_in_net CHECK (gw4 <<= addr4), 117 CONSTRAINT gw6_in_net CHECK (gw6 <<= addr6), 118 CONSTRAINT dhcp_needs_ipv4_gateway 119 CHECK (dhcp = 0 OR (dhcp != 0 AND gw4 IS NOT NULL)), 120 FOREIGN KEY (idorg) REFERENCES dns.organization (idorg), 121 FOREIGN KEY (idcomm) REFERENCES dns.community (idcomm), 122 PRIMARY KEY (idnet) 123) ; 124 125 126-- DNS views 127-- There is one entry for each observation point, which means 128-- a class of clients allowed to see informations. For example: 129-- "internal" and "external" 130 131CREATE SEQUENCE dns.seq_view START 1 ; 132CREATE TABLE dns.view ( 133 idview INT -- view id 134 DEFAULT NEXTVAL ('dns.seq_view'), 135 name TEXT, -- e.g.: "internal", "external"... 136 gendhcp INT, -- 1 if dhcp conf must be generated 137 138 UNIQUE (name), 139 PRIMARY KEY (idview) 140) ; 141 142-- DNS zone generation 143 144CREATE SEQUENCE dns.seq_zone START 1 ; 145CREATE TABLE dns.zone ( 146 idzone INT -- zone id 147 DEFAULT NEXTVAL ('dns.seq_zone'), 148 name TEXT, -- zone name and name of generated file 149 idview INT, -- view id 150 version INT, -- version number 151 prologue TEXT, -- zone prologue (with %ZONEVERSION% pattern) 152 rrsup TEXT, -- added to each generated host 153 gen INT -- modified since last generation 154) ; 155 156CREATE TABLE dns.zone_forward ( 157 selection TEXT, -- criterion to select names 158 159 UNIQUE (name), 160 FOREIGN KEY (idview) REFERENCES dns.view (idview), 161 PRIMARY KEY (idzone) 162) INHERITS (dns.zone) ; 163 164CREATE TABLE dns.zone_reverse4 ( 165 selection CIDR, -- criterion to select addresses 166 167 UNIQUE (name), 168 FOREIGN KEY (idview) REFERENCES dns.view (idview), 169 PRIMARY KEY (idzone) 170) INHERITS (dns.zone) ; 171 172CREATE TABLE dns.zone_reverse6 ( 173 selection CIDR, -- criterion to select addresses 174 175 UNIQUE (name), 176 FOREIGN KEY (idview) REFERENCES dns.view (idview), 177 PRIMARY KEY (idzone) 178) INHERITS (dns.zone) ; 179 180-- host types 181 182CREATE SEQUENCE dns.seq_hinfo MINVALUE 0 START 0 ; 183CREATE TABLE dns.hinfo ( 184 idhinfo INT -- host type id 185 DEFAULT NEXTVAL ('dns.seq_hinfo'), 186 name TEXT, -- type as text 187 sort INT, -- sort class 188 present INT, -- present or not 189 PRIMARY KEY (idhinfo) 190) ; 191 192-- ranges allowed to groups 193 194CREATE TABLE dns.p_network ( 195 idgrp INT, -- the group which manages this network 196 idnet INT, -- the network 197 sort INT, -- sort class 198 dhcp INT DEFAULT 0, -- perm to manage DHCP ranges 199 acl INT DEFAULT 0, -- perm to manage ACL (later...) 200 201 FOREIGN KEY (idgrp) REFERENCES global.nmgroup (idgrp), 202 FOREIGN KEY (idnet) REFERENCES dns.network (idnet), 203 PRIMARY KEY (idgrp, idnet) 204) ; 205 206-- domains allowed to groups 207 208CREATE TABLE dns.p_dom ( 209 idgrp INT, -- group 210 iddom INT, -- domain id 211 sort INT, -- sort class 212 mailrole INT DEFAULT 0, -- perm to manage mail roles 213 214 FOREIGN KEY (idgrp) REFERENCES global.nmgroup (idgrp), 215 PRIMARY KEY (idgrp, iddom) 216) ; 217 218-- IP ranges allowed to groups 219 220CREATE TABLE dns.p_ip ( 221 idgrp INT, -- group 222 addr CIDR, -- network range 223 allow_deny INT, -- 1 = allow, 0 = deny 224 225 FOREIGN KEY (idgrp) REFERENCES global.nmgroup (idgrp), 226 PRIMARY KEY (idgrp, addr) 227) ; 228 229-- views allowed to groups 230 231CREATE TABLE dns.p_view ( 232 idgrp INT, -- group 233 idview INT, -- the view 234 sort INT, -- sort class 235 selected INT, -- selected by default in menus 236 237 FOREIGN KEY (idgrp) REFERENCES global.nmgroup (idgrp), 238 FOREIGN KEY (idview) REFERENCES dns.view (idview), 239 PRIMARY KEY (idgrp, idview) 240) ; 241 242 243-- DHCP profiles 244 245CREATE SEQUENCE dns.seq_dhcpprofile START 1 ; 246CREATE TABLE dns.dhcpprofile ( 247 iddhcpprof INT -- DHCP profile id 248 DEFAULT NEXTVAL ('dns.seq_dhcpprofile'), 249 name TEXT UNIQUE, -- DHCP profile name 250 text TEXT, -- text to add before host declarations 251 252 CHECK (iddhcpprof >= 1), 253 PRIMARY KEY (iddhcpprof) 254) ; 255 256-- DHCP profiles allowed to groups 257 258CREATE TABLE dns.p_dhcpprofile ( 259 idgrp INT, -- group 260 iddhcpprof INT, -- DHCP profile 261 sort INT, -- sort class 262 263 FOREIGN KEY (idgrp) REFERENCES global.nmgroup (idgrp), 264 FOREIGN KEY (iddhcpprof) REFERENCES dns.dhcpprofile (iddhcpprof), 265 PRIMARY KEY (idgrp, iddhcpprof) 266) ; 267 268-- DHCP dynamic ranges 269 270CREATE SEQUENCE dns.seq_dhcprange START 1 ; 271CREATE TABLE dns.dhcprange ( 272 iddhcprange INT -- for store-tabular use 273 DEFAULT NEXTVAL ('dns.seq_dhcprange'), 274 min INET UNIQUE, -- min address of range 275 max INET UNIQUE, -- max address of range 276 iddom INT, -- domain returned by DHCP server 277 default_lease_time INT DEFAULT 0, -- unit = second 278 max_lease_time INT DEFAULT 0, -- unit = second 279 iddhcpprof INT, -- DHCP profile for this range 280 281 CHECK (min <= max), 282 FOREIGN KEY (iddom) REFERENCES dns.domain (iddom), 283 FOREIGN KEY (iddhcpprof) REFERENCES dns.dhcpprofile (iddhcpprof), 284 PRIMARY KEY (iddhcprange) 285) ; 286 287-- Resource records 288 289CREATE SEQUENCE dns.seq_rr START 1 ; 290CREATE TABLE dns.rr ( 291 idrr INT -- RR id 292 DEFAULT NEXTVAL ('dns.seq_rr'), 293 name TEXT, -- name of RR (first component) 294 iddom INT, -- domain name of RR 295 idview INT, -- view id 296 297 mac MACADDR, -- MAC address or NULL 298 iddhcpprof INT, -- DHCP profile or NULL 299 300 idhinfo INT DEFAULT 0, -- host type 301 comment TEXT, -- comment 302 respname TEXT, -- name of responsible person 303 respmail TEXT, -- mail address of responsible person 304 305 idcor INT, -- last mod author 306 date TIMESTAMP (0) WITHOUT TIME ZONE -- last mod date 307 DEFAULT CURRENT_TIMESTAMP, 308 sendsmtp INT DEFAULT 0, -- 1 if this host may emit with SMTP 309 ttl INT DEFAULT -1, -- TTL if different from zone TTL 310 311 FOREIGN KEY (idcor) REFERENCES global.nmuser (idcor), 312 FOREIGN KEY (iddom) REFERENCES dns.domain (iddom), 313 FOREIGN KEY (idview) REFERENCES dns.view (idview), 314 FOREIGN KEY (iddhcpprof) REFERENCES dns.dhcpprofile (iddhcpprof), 315 FOREIGN KEY (idhinfo) REFERENCES dns.hinfo (idhinfo), 316 UNIQUE (name, iddom, idview), 317 -- MAC address should be unique in a view 318 UNIQUE (mac, idview), 319 PRIMARY KEY (idrr) 320) ; 321 322CREATE TABLE dns.rr_ip ( 323 idrr INT, -- RR 324 addr INET, -- IP (v4 or v6) address 325 326 FOREIGN KEY (idrr) REFERENCES dns.rr (idrr), 327 PRIMARY KEY (idrr, addr) 328) ; 329 330CREATE TABLE dns.rr_cname ( 331 idrr INT, -- RR 332 cname INT, -- pointed RR id 333 334 FOREIGN KEY (idrr) REFERENCES dns.rr (idrr), 335 FOREIGN KEY (cname) REFERENCES dns.rr (idrr), 336 PRIMARY KEY (idrr, cname) 337) ; 338 339CREATE TABLE dns.rr_mx ( 340 idrr INT, -- RR 341 prio INT, -- priority 342 mx INT, -- pointed RR id 343 344 FOREIGN KEY (idrr) REFERENCES dns.rr (idrr), 345 FOREIGN KEY (mx) REFERENCES dns.rr (idrr), 346 PRIMARY KEY (idrr, mx) 347) ; 348 349-- Mail roles 350CREATE TABLE dns.mail_role ( 351 mailaddr INT, -- id of "mail address" 352 mboxhost INT, -- RR holding mboxes for this address 353 354 FOREIGN KEY (mailaddr) REFERENCES dns.rr (idrr), 355 FOREIGN KEY (mboxhost) REFERENCES dns.rr (idrr), 356 PRIMARY KEY (mailaddr) 357) ; 358 359-- Mail relays for a domain 360CREATE TABLE dns.relay_dom ( 361 iddom INT, -- domain id 362 prio INT, -- MX priority 363 mx INT, -- relay host for this domain 364 365 FOREIGN KEY (iddom) REFERENCES dns.domain (iddom), 366 FOREIGN KEY (mx) REFERENCES dns.rr (idrr), 367 PRIMARY KEY (iddom, mx) 368) ; 369 370--------------------------------------------------------------------------- 371-- topo schema 372--------------------------------------------------------------------------- 373 374-- Modified equipement spool 375 376CREATE TABLE topo.modeq ( 377 eq TEXT, -- fully qualified equipement name 378 date TIMESTAMP (0) -- detection date 379 WITHOUT TIME ZONE 380 DEFAULT CURRENT_TIMESTAMP, 381 login TEXT, -- detected user 382 processed INT DEFAULT 0 383) ; 384 385CREATE INDEX modeq_index ON topo.modeq (eq) ; 386 387-- Interface change request spool 388 389CREATE TABLE topo.ifchanges ( 390 login TEXT, -- requesting user 391 reqdate TIMESTAMP (0) -- request date 392 WITHOUT TIME ZONE 393 DEFAULT CURRENT_TIMESTAMP, 394 eq TEXT, -- fully qualified equipement name 395 iface TEXT, -- interface name 396 ifdesc TEXT, -- interface description 397 ethervlan INT, -- access vlan id 398 voicevlan INT, -- voice vlan id 399 processed INT DEFAULT 0, -- modification processed 400 moddate TIMESTAMP (0) -- modification (or last attempt) date 401 WITHOUT TIME ZONE, 402 modlog TEXT, -- modification (or last attempt) log 403 404 PRIMARY KEY (eq, reqdate, iface) 405) ; 406 407-- Last rancid run 408 409CREATE TABLE topo.lastrun ( 410 date TIMESTAMP (0) -- detection date 411 WITHOUT TIME ZONE 412) ; 413 414-- Keepstate events 415 416CREATE TABLE topo.keepstate ( 417 type TEXT, -- "rancid", "anaconf" 418 message TEXT, -- last message 419 date TIMESTAMP (0) -- first occurrence of this message 420 WITHOUT TIME ZONE 421 DEFAULT CURRENT_TIMESTAMP, 422 423 PRIMARY KEY (type) 424) ; 425 426-- Users to ignore : don't log any event in the modified equipement spool 427-- for these users because we know they have only a read-only access to the 428-- equipements 429 430CREATE TABLE topo.ignoreequsers ( 431 login TEXT UNIQUE NOT NULL -- user login 432) ; 433 434-- Access rights to equipements 435 436CREATE TABLE topo.p_eq ( 437 idgrp INT, -- group upon which this access right applies 438 rw INT, -- 0 : read, 1 : write 439 pattern TEXT NOT NULL, -- regular expression 440 allow_deny INT, -- 1 = allow, 0 = deny 441 442 FOREIGN KEY (idgrp) REFERENCES global.nmgroup (idgrp) 443) ; 444 445-- Access rights to L2-only networks 446 447CREATE TABLE topo.p_l2only ( 448 idgrp INT, -- group upon which this access right applies 449 vlanid INT, -- 1...4094 450 451 PRIMARY KEY (idgrp, vlanid), 452 FOREIGN KEY (idgrp) REFERENCES global.nmgroup (idgrp) 453) ; 454 455-- Sensor definition 456 457-- type trafic 458-- iface = iface[.vlan] 459-- param = NULL 460-- type number of assoc wifi 461-- iface = iface 462-- ssid 463-- type number of auth wifi 464-- iface = iface 465-- param = ssid 466-- type broadcast traffic 467-- iface = iface[.vlan] 468-- param = NULL 469-- type multicast traffic 470-- iface = iface[.vlan] 471-- param = NULL 472 473CREATE TABLE topo.sensor ( 474 id TEXT, -- M1234 475 type TEXT, -- trafic, nbassocwifi, nbauthwifi, etc. 476 eq TEXT, -- fqdn 477 comm TEXT, -- snmp communuity 478 iface TEXT, 479 param TEXT, 480 lastmod TIMESTAMP (0) -- last modification date 481 WITHOUT TIME ZONE 482 DEFAULT CURRENT_TIMESTAMP, 483 lastseen TIMESTAMP (0) -- last detection date 484 WITHOUT TIME ZONE 485 DEFAULT CURRENT_TIMESTAMP, 486 487 PRIMARY KEY (id) 488) ; 489 490 491-- Topod file monitor 492 493CREATE TABLE topo.filemonitor ( 494 path TEXT, -- path to file or directory 495 date TIMESTAMP (0) -- last modification date 496 WITHOUT TIME ZONE 497 DEFAULT CURRENT_TIMESTAMP, 498 499 PRIMARY KEY (path) 500) ; 501 502-- Vlan table 503 504CREATE TABLE topo.vlan ( 505 vlanid INT, -- 1..4094 506 descr TEXT, -- description 507 voip INT DEFAULT 0, -- 1 if VoIP vlan, 0 if standard vlan 508 509 PRIMARY KEY (vlanid) 510) ; 511 512-- Equipment types and equipment list to create rancid router.db file 513 514CREATE SEQUENCE topo.seq_eqtype START 1 ; 515 516CREATE TABLE topo.eqtype ( 517 idtype INTEGER -- type id 518 DEFAULT NEXTVAL ('topo.seq_eqtype'), 519 type TEXT, -- cisco, hp, juniper, etc. 520 521 UNIQUE (type), 522 PRIMARY KEY (idtype) 523) ; 524 525CREATE SEQUENCE topo.seq_eq START 1 ; 526 527CREATE TABLE topo.eq ( 528 ideq INTEGER -- equipment id 529 DEFAULT NEXTVAL ('topo.seq_eq'), 530 eq TEXT, -- fqdn 531 idtype INTEGER, 532 up INTEGER, -- 1 : up, 0 : 0 533 534 FOREIGN KEY (idtype) REFERENCES topo.eqtype (idtype), 535 UNIQUE (eq), 536 PRIMARY KEY (ideq) 537) ; 538 539CREATE SEQUENCE topo.seq_confcmd START 1 ; 540 541CREATE TABLE topo.confcmd ( 542 idccmd INTEGER -- entry id 543 DEFAULT NEXTVAL ('topo.seq_confcmd'), 544 idtype INTEGER, -- equipment type 545 action TEXT, -- action selector : prologue, ifreset 546 rank INTEGER, -- sort order 547 model TEXT, -- regexp matching equipment model 548 command TEXT, -- command to send 549 550 FOREIGN KEY (idtype) REFERENCES topo.eqtype (idtype), 551 PRIMARY KEY (idccmd) 552) ; 553 554-- graphviz attributes for equipements in L2 graphs 555CREATE TABLE topo.dotattr ( 556 rank INTEGER, -- sort order 557 type INTEGER, -- 2: l2, 3: l3 graph 558 regexp TEXT, -- regexp 559 gvattr TEXT, -- graphviz node attributes 560 png BYTEA, -- PNG generated by graphviz 561 562 PRIMARY KEY (rank) 563) ; 564 565-- link number and description 566CREATE SEQUENCE topo.seq_link START 1 ; 567CREATE TABLE topo.link ( 568 idlink INT -- group id 569 DEFAULT NEXTVAL ('topo.seq_link'), 570 descr TEXT, -- link description 571 572 PRIMARY KEY (idlink) 573) ; 574 575--------------------------------------------------------------------------- 576-- pgauth schema 577--------------------------------------------------------------------------- 578 579CREATE TABLE pgauth.user ( 580 login TEXT, -- login name 581 password TEXT, -- crypted password 582 lastname TEXT, -- last name 583 firstname TEXT, -- first name 584 mail TEXT, -- mail address 585 phone TEXT, -- telephone number 586 mobile TEXT, -- mobile phone number 587 fax TEXT, -- facsimile number 588 addr TEXT, -- postal address 589 -- columns automatically managed by triggers 590 phlast TEXT, -- phonetical last name 591 phfirst TEXT, -- phonetical first name 592 593 PRIMARY KEY (login) 594) ; 595 596CREATE TABLE pgauth.realm ( 597 realm TEXT, -- realm name 598 descr TEXT, -- realm description 599 admin INT, -- 1 if admin 600 601 PRIMARY KEY (realm) 602) ; 603 604CREATE TABLE pgauth.member ( 605 login TEXT, -- login name 606 realm TEXT, -- realm of this login 607 608 FOREIGN KEY (login) REFERENCES pgauth.user (login), 609 FOREIGN KEY (realm) REFERENCES pgauth.realm (realm), 610 PRIMARY KEY (login, realm) 611) ; 612