Home | 簡體中文 | 繁體中文 | 雜文 | 知乎專欄 | Github | OSChina 博客 | 雲社區 | 雲棲社區 | Facebook | Linkedin | 視頻教程 | 打賞(Donations) | About
知乎專欄多維度架構 微信號 netkiller-ebook | QQ群:128659835 請註明“讀者”

21.23. PostgreSQL 所特有資料庫設計

PostgreSQL 資料庫 ORDBMS / OODBMS 等特有屬性

對象相關資料庫管理系統(ORDBMS Object – Oriented Relative DBMS)

21.23.1. 國家地區表的設計

			
 +-----------+
 | city      |
 |-----------|
 |id         | <---+
 |name       |     |
 |description|    1:n
 |status     |     |
 |parent_id  | o---+
 +-----------+
			
			

例 21.5. 遞歸查詢實例 city 表

定義結構

	    	
CREATE TABLE city
(
  id serial NOT NULL,
  name character varying,
  parent_id integer,
  status boolean,
  CONSTRAINT city_pkey PRIMARY KEY (id),
  CONSTRAINT city_parent_id_fkey FOREIGN KEY (parent_id)
      REFERENCES city (id) MATCH SIMPLE
      ON UPDATE NO ACTION ON DELETE NO ACTION
)
WITH (
  OIDS=FALSE
);
ALTER TABLE city
  OWNER TO sys;
	    	
	    	

插入數據

	    	
INSERT INTO city (id, name, parent_id, status) VALUES (1, '廣東', NULL, NULL);
INSERT INTO city (id, name, parent_id, status) VALUES (2, '湖南', NULL, NULL);
INSERT INTO city (id, name, parent_id, status) VALUES (3, '深圳', 1, NULL);
INSERT INTO city (id, name, parent_id, status) VALUES (4, '東莞', 1, NULL);
INSERT INTO city (id, name, parent_id, status) VALUES (5, '福田', 3, NULL);
INSERT INTO city (id, name, parent_id, status) VALUES (6, '南山', 3, NULL);
INSERT INTO city (id, name, parent_id, status) VALUES (7, '寶安', 3, NULL);
INSERT INTO city (id, name, parent_id, status) VALUES (8, '西鄉', 7, NULL);
INSERT INTO city (id, name, parent_id, status) VALUES (9, '福永', 7, NULL);
INSERT INTO city (id, name, parent_id, status) VALUES (10, '龍華', 7, NULL);
INSERT INTO city (id, name, parent_id, status) VALUES (11, '長沙', 2, NULL);
INSERT INTO city (id, name, parent_id, status) VALUES (12, '湘潭', 2, NULL);
INSERT INTO city (id, name, parent_id, status) VALUES (13, '常德', 2, NULL);
INSERT INTO city (id, name, parent_id, status) VALUES (14, '桃源', 13, NULL);
INSERT INTO city (id, name, parent_id, status) VALUES (15, '漢壽', 13, NULL);
INSERT INTO city (id, name, parent_id, status) VALUES (16, '黑龍江', NULL, NULL);
INSERT INTO city (id, name, parent_id, status) VALUES (17, '伊春', 16, NULL);
INSERT INTO city (id, name, parent_id, status) VALUES (18, '哈爾濱', 16, NULL);
INSERT INTO city (id, name, parent_id, status) VALUES (19, '齊齊哈爾', 16, NULL);
INSERT INTO city (id, name, parent_id, status) VALUES (20, '牡丹江', 16, NULL);
INSERT INTO city (id, name, parent_id, status) VALUES (21, '佳木斯', 16, NULL);
INSERT INTO city (id, name, parent_id, status) VALUES (22, '民治', 10, NULL);
INSERT INTO city (id, name, parent_id, status) VALUES (23, '上塘', 10, NULL);
	    	
	    	

查詢

	    	
WITH RECURSIVE path(id, name, path, idpath, parent_id, status) AS (
  SELECT id, name, '/' || name , '/' || id , parent_id, status FROM city WHERE parent_id is null
  UNION
  SELECT
    city.id,
    city.name,
    parentpath.path ||
      CASE parentpath.path
	WHEN '/' THEN ''
	ELSE '/'
      END || city.name,
    parentpath.idpath ||
     CASE parentpath.idpath
	WHEN '/' THEN ''
	ELSE '/'
      END || city.id,
    city.parent_id, city.status
  FROM city, path as parentpath
  WHERE city.parent_id = parentpath.id
)

SELECT * FROM path;
	    	
	    	

結果輸出

	    	
 id |   name   |           path            |    idpath    | parent_id | status
----+----------+---------------------------+--------------+-----------+--------
  1 | 廣東     | /廣東                     | /1           |           |
  2 | 湖南     | /湖南                     | /2           |           |
 16 | 黑龍江   | /黑龍江                   | /16          |           |
  3 | 深圳     | /廣東/深圳                | /1/3         |         1 |
  4 | 東莞     | /廣東/東莞                | /1/4         |         1 |
 11 | 長沙     | /湖南/長沙                | /2/11        |         2 |
 12 | 湘潭     | /湖南/湘潭                | /2/12        |         2 |
 13 | 常德     | /湖南/常德                | /2/13        |         2 |
 17 | 伊春     | /黑龍江/伊春              | /16/17       |        16 |
 18 | 哈爾濱   | /黑龍江/哈爾濱            | /16/18       |        16 |
 19 | 齊齊哈爾 | /黑龍江/齊齊哈爾          | /16/19       |        16 |
 20 | 牡丹江   | /黑龍江/牡丹江            | /16/20       |        16 |
 21 | 佳木斯   | /黑龍江/佳木斯            | /16/21       |        16 |
  5 | 福田     | /廣東/深圳/福田           | /1/3/5       |         3 |
  6 | 南山     | /廣東/深圳/南山           | /1/3/6       |         3 |
  7 | 寶安     | /廣東/深圳/寶安           | /1/3/7       |         3 |
 14 | 桃源     | /湖南/常德/桃源           | /2/13/14     |        13 |
 15 | 漢壽     | /湖南/常德/漢壽           | /2/13/15     |        13 |
  8 | 西鄉     | /廣東/深圳/寶安/西鄉      | /1/3/7/8     |         7 |
  9 | 福永     | /廣東/深圳/寶安/福永      | /1/3/7/9     |         7 |
 10 | 龍華     | /廣東/深圳/寶安/龍華      | /1/3/7/10    |         7 |
 22 | 民治     | /廣東/深圳/寶安/龍華/民治 | /1/3/7/10/22 |        10 |
 23 | 上塘     | /廣東/深圳/寶安/龍華/上塘 | /1/3/7/10/23 |        10 |
(23 rows)
	    	
	    	

21.23.2. 話題討論表的設計

例 21.6. 話題討論表的設計

http://justcramer.com/2010/05/30/scaling-threaded-comments-on-django-at-disqus/

	        
create table comments (
    id SERIAL PRIMARY KEY,
    message VARCHAR,
    author VARCHAR,
    parent_id INTEGER REFERENCES comments(id)
);
insert into comments (message, author, parent_id)
    values ('This thread is really cool!', 'David', NULL), ('Ya David, we love it!', 'Jason', 1), ('I agree David!', 'Daniel', 1), ('gift Jason', 'Anton', 2),
    ('Very interesting post!', 'thedz', NULL), ('You sir, are wrong', 'Chris', 5), ('Agreed', 'G', 5), ('Fo sho, Yall', 'Mac', 5);
			
	        
			
WITH RECURSIVE cte (id, message, author, path, parent_id, depth)  AS (
    SELECT  id,
        message,
        author,
        array[id] AS path,
        parent_id,
        1 AS depth
    FROM    comments
    WHERE   parent_id IS NULL

    UNION ALL

    SELECT  comments.id,
        comments.message,
        comments.author,
        cte.path || comments.id,
        comments.parent_id,
        cte.depth + 1 AS depth
    FROM    comments
    JOIN cte ON comments.parent_id = cte.id
    )
    SELECT id, message, author, path, depth FROM cte ORDER BY path;
	    	
			

輸出結果

 id |           message           | author |  path   | depth
----+-----------------------------+--------+---------+-------
  1 | This thread is really cool! | David  | {1}     |     1
  2 | Ya David, we love it!       | Jason  | {1,2}   |     2
  4 | gift Jason                  | Anton  | {1,2,4} |     3
  3 | I agree David!              | Daniel | {1,3}   |     2
  5 | Very interesting post!      | thedz  | {5}     |     1
  6 | You sir, are wrong          | Chris  | {5,6}   |     2
  7 | Agreed                      | G      | {5,7}   |     2
  8 | Fo sho, Yall                | Mac    | {5,8}   |     2
(8 rows)
		    

21.23.3. 賬戶表/餘額表/消費儲蓄表

此表適用於購物車等金錢來往賬面等等。

		
-- Table: account

-- DROP TABLE account;

CREATE TABLE account
(
  id integer NOT NULL DEFAULT nextval('trade_id_seq'::regclass),
  no character varying(10) NOT NULL, -- 賬號
  balance money NOT NULL DEFAULT 0.00, -- 餘額
  datetime timestamp without time zone NOT NULL DEFAULT (now())::timestamp(0) without time zone,
  CONSTRAINT account_pkey PRIMARY KEY (id)
)
WITH (
  OIDS=FALSE
);
ALTER TABLE account
  OWNER TO dba;
COMMENT ON COLUMN account.no IS '賬號';
COMMENT ON COLUMN account.balance IS '餘額';


-- Index: account_no_idx

-- DROP INDEX account_no_idx;

CREATE INDEX account_no_idx
  ON account
  USING btree
  (no COLLATE pg_catalog."default");
		
		
		

賬戶結餘計算

		
select acc.*, (select sum(balance)+acc.balance from account as ac where ac.id < acc.id) as profit from account as acc;

test=# select acc.*, (select sum(balance)+acc.balance from account as ac where ac.id < acc.id) as profit from account as acc;
 id |  no  | balance  |      datetime       | profit
----+------+----------+---------------------+---------
  1 | 1000 |    $0.00 | 2013-10-09 10:51:10 |
  2 | 1000 |   $12.60 | 2013-10-09 10:51:22 |  $12.60
  4 | 1000 |   $16.80 | 2013-10-09 10:51:42 |  $29.40
  5 | 1000 |  $100.00 | 2013-10-09 10:51:49 | $129.40
  6 | 1000 |  $200.00 | 2013-10-09 10:56:35 | $329.40
  7 | 1000 |   $50.45 | 2013-10-09 10:57:23 | $379.85
  8 | 1000 |   $75.50 | 2013-10-09 10:57:31 | $455.35
  9 | 1000 |  -$55.30 | 2013-10-09 10:59:28 | $400.05
 10 | 1000 | -$200.00 | 2013-10-09 10:59:44 | $200.05
(9 rows)