TWGCB 資料庫建立腳本

2024-04-06 TWGCB TWGCB 資安

最近在整理 GCB 的相關資料,想說把它匯入資料庫後,未來會比較好管理導入的主機

資料庫環境

  • OS: Debian 12
  • DB: postgresql

資料庫 schema

  1. 進入資料庫
sudo su - postgres
psql
  1. 建立資料庫
create database twgcb_db;
CREATE ROLE twgcb_role NOINHERIT;
GRANT ConNECT on DATABASE twgcb_db TO twgcb_role;
CREATE USER twgcbu WITH PASSWORD 'PASSWORD';
GRANT twgcbu TO twgcb_role;
  1. 建立 table
  • TWGCB 資料表
create table twgcb  (
    id bigint generated always as identity,
    version int default 0,
    issure int default 2,
    note varchar(100),
    date_created timestamp default CURRENT_TIMESTAMP not null,
    man_created varchar(20) not null,
    last_updated timestamp,
    man_last_updated varchar(20),
    twgcb_id char(17) not null ,
    type smallint,
    cname varchar(50), 
    explanation text,
    instructions text,
    default_value varchar(100),
    remark varchar(100),
    primary key (id)
);

CREATE UNIQUE INDEX twgcb_un1 ON twgcb (twgcb_id);

comment on table  twgcb is 'TWGCB';
comment on column twgcb.id IS '資料流水號';
comment on column twgcb.version IS '版本,每修改一次就是加1';
comment on column twgcb.issure IS '0:刪除、1:新增中、2:使用中';
comment on column twgcb.note IS '資料註記';
comment on column twgcb.date_created IS '資料建立時間';
comment on column twgcb.man_created IS '資料建立者';
comment on column twgcb.last_updated IS '資料更新時間';
comment on column twgcb.man_last_updated IS '資料更新者';
comment on column twgcb.twgcb_id IS 'TWGCB-ID';
comment on column twgcb.type IS '類別';
comment on column twgcb.cname IS '原則設定名稱';
comment on column twgcb.explanation IS '說明';
comment on column twgcb.instructions IS '設定方法';
comment on column twgcb.default_value IS 'GCB設定值';
comment on column twgcb.remark IS '備註';
  • 類別對照表
create table bs_select  (
    id bigint generated always as identity,
    type varchar(10) not null,
    code smallint not null,
    cdesc varchar(100) not null,
    primary key (id)
);

comment on table  bs_select is '選單代號對照表';
comment on column bs_select.id IS '資料流水號';
comment on column bs_select.type IS '類別';
comment on column bs_select.code IS '選單代號';
comment on column bs_select.cdesc IS '代號敘述';
CREATE UNIQUE INDEX bs_select_un1 ON bs_select (type,code);
  • TWGCB 匯入暫存表
create table twgcb_imp_tmp  (
    twgcb_id char(17),
    type varchar(20),
    cname varchar(50), 
    explanation text,
    instructions text,
    default_value varchar(100),
    remark varchar(100)
);

comment on table  twgcb_imp_tmp is 'TWGCB 匯入暫存';
comment on column twgcb_imp_tmp.twgcb_id IS 'TWGCB-ID';
comment on column twgcb_imp_tmp.type IS '類別';
comment on column twgcb_imp_tmp.cname IS '原則設定名稱';
comment on column twgcb_imp_tmp.explanation IS '說明';
comment on column twgcb_imp_tmp.instructions IS '設定方法';
comment on column twgcb_imp_tmp.default_value IS 'GCB設定值';
comment on column twgcb_imp_tmp.remark IS '備註';

匯入方式

  1. 整理 GCB 資料成 excel
  2. 用 ETL 工具 匯入 twgcb_imp_tmp
  3. 執行下列 SQL
  • 類別資料
INSERT INTO bs_select ("type", code, cdesc)VALUES( 'twgcb_type',5, '系統服務');
INSERT INTO bs_select ("type", code, cdesc)VALUES( 'twgcb_type',10, '日誌與稽核');
INSERT INTO bs_select ("type", code, cdesc)VALUES( 'twgcb_type',15, '帳號與存取控制');
INSERT INTO bs_select ("type", code, cdesc)VALUES( 'twgcb_type',20, '系統設定與維護');
INSERT INTO bs_select ("type", code, cdesc)VALUES( 'twgcb_type',25, '基礎服務');
INSERT INTO bs_select ("type", code, cdesc)VALUES( 'twgcb_type',30, '網路設定');
INSERT INTO bs_select ("type", code, cdesc)VALUES( 'twgcb_type',35, 'Firewalld配置');
INSERT INTO bs_select ("type", code, cdesc)VALUES( 'twgcb_type',40, '網路配置與防火牆');
INSERT INTO bs_select ("type", code, cdesc)VALUES( 'twgcb_type',45, 'SELinux');
INSERT INTO bs_select ("type", code, cdesc)VALUES( 'twgcb_type',50, '安裝與軟體維護');
INSERT INTO bs_select ("type", code, cdesc)VALUES( 'twgcb_type',55, '過時服務');
INSERT INTO bs_select ("type", code, cdesc)VALUES( 'twgcb_type',60, 'SSH設定');
INSERT INTO bs_select ("type", code, cdesc)VALUES( 'twgcb_type',65, '檔案權限與遮罩');
INSERT INTO bs_select ("type", code, cdesc)VALUES( 'twgcb_type',70, '安裝與維護軟體');
INSERT INTO bs_select ("type", code, cdesc)VALUES( 'twgcb_type',75, 'cron設定');
INSERT INTO bs_select ("type", code, cdesc)VALUES( 'twgcb_type',80, '磁碟與檔案系統');
INSERT INTO bs_select ("type", code, cdesc)VALUES( 'twgcb_type',85, 'Iptables配置');
INSERT INTO bs_select ("type", code, cdesc)VALUES( 'twgcb_type',90, 'Nftables配置');
  • 匯入 sql
INSERT INTO twgcb (man_created, twgcb_id, "type", cname, explanation, instructions, default_value, remark)
select
'批次匯入' man_created,
twgcb_id,
(select t.code from bs_select t where t.type = 'twgcb_type' and t.cdesc = tit.type ) type,
cname,
explanation,
instructions,
default_value,
remark
from twgcb_imp_tmp tit ;

整理好的 excel 資料

為了匯入方便,我這邊已經整理好 xlsx 版本的資料