作者 主題: [分享] MySQL 一道Query跨不同主機查詢的方法  (閱讀 6658 次)

0 會員 與 1 訪客 正在閱讀本文。

bunko

  • 懷疑的國中生
  • **
  • 文章數: 67
    • 檢視個人資料
http://phorum.study-area.org/index.php/topic,63768.0.html
討論中,有提到MySQL 一道Query是否能夠跨不同主機來進行查詢呢?
以下是一個簡單的範例,提供大家參考:

MySQL Federated storage engine 簡單範例
----------------------------------------
1.環境介紹
  Mysql #1 Name: Akira
  Mysql #2 Name: Bunko

2.首先先在 Akira 裡面建一個叫test1219a的database

create database test1219a;
use test1219a;
grant all on test1219a.* to 'akira'@'%' identified by 'akiraxyz';
flush privileges;
-------------------
然後再用akira登入

建立一個叫Author的Table
akira@[test1219a] Akira
==>CREATE TABLE Author
    -> (AuthorID smallint PRIMARY KEY,
    -> AuthorName varchar(255)
    -> );



3.然後在Bunko 建立一個叫 test1219b的database

create database test1219b;
use test1219b;
grant all on test1219b.* to 'bunko'@'%' identified by 'bunkonao';
flush privileges;
---------------------
接著用bunko登入,建立一個叫 rAuthor的table


bunko@[test1219b] Bunko
==>CREATE TABLE rAuthor
    -> (AuthorID smallint PRIMARY KEY,
    -> AuthorName varchar(255))
    -> engine=FEDERATED
    -> connection='mysql://akira:akiraxyz@192.168.0.100:3307/test1219a/Author';
Query OK, 0 rows affected (0.07 sec)

可以看到上面要指定engine=FEDERATED ,還有連結的資料.包含登入user,password,host ip,port,
database,table組成.

現在select看看...
bunko@[test1219b] Bunko
==>select * from rAuthor;
Empty set (0.01 sec)

空的....正確!因為我們原始的Table也沒有資料.

4.回到Akira

akira@[test1219a] Akira
==>insert into Author values(1, 'Agatha Christie');

akira@[test1219a] Akira
==>select * from Author;
+----------+-----------------+
| AuthorID | AuthorName      |
+----------+-----------------+
|        1 | Agatha Christie |
+----------+-----------------+

已插入一筆資料
--------------------------------------
到Bunko看看

bunko@[test1219b] Bunko
==>select * from rAuthor;
+----------+-----------------+
| AuthorID | AuthorName      |
+----------+-----------------+
|        1 | Agatha Christie |
+----------+-----------------+

可以順利的看到Akira裡面剛加入的資料.
現在我們在Bunko rAuthor新增資料.

bunko@[test1219b] Bunko
==>insert into rAuthor values(2, 'Stephen King');

到Akira

akira@[test1219a] Akira
==>select * from Author;
+----------+-----------------+
| AuthorID | AuthorName      |
+----------+-----------------+
|        1 | Agatha Christie |
|        2 | Stephen King    |
+----------+-----------------+

到此可以看到Akira/Bunko兩個MySQL透過Federated storage engine
讓兩邊都能輕易的存取到實際上存在Akira上的Table.

5. Join

在Bunko裡面,再建立一個新Table : Books

bunko@[test1219b] Bunko
==>CREATE TABLE Books
    -> (BookID smallint NOT NULL AUTO_INCREMENT PRIMARY KEY,
    -> BookName varchar(255),
    -> AuthorID smallint NOT NULL,
    -> INDEX (AuthorID)
    -> );

插入4筆資料:

bunko@[test1219b] Bunko
==>INSERT INTO Books Values(NULL, 'Murder on the Orient Express', 1);

bunko@[test1219b] Bunko
==>INSERT INTO Books Values(NULL, 'Death on the Nile', 1);

bunko@[test1219b] Bunko
==>INSERT INTO Books Values(NULL, 'Different Seasons', 2);

bunko@[test1219b] Bunko
==>INSERT INTO Books Values(NULL, 'The Green Mile', 2);

然後Join

bunko@[test1219b] Bunko
==>SELECT b.BookID,b.BookName,a.AuthorName
    -> FROM Books b, rAuthor a
    -> where b.AuthorID = a.AuthorID;
+--------+------------------------------+-----------------+
| BookID | BookName                     | AuthorName      |
+--------+------------------------------+-----------------+
|      1 | Murder on the Orient Express | Agatha Christie |
|      2 | Death on the Nile            | Agatha Christie |
|      3 | Different Seasons            | Stephen King    |
|      4 | The Green Mile               | Stephen King    |
+--------+------------------------------+-----------------+

基本上到此已經運用Federated storage engine 在一道SQL Command裡面進行
兩個不同MySQL的Join查詢.

6. 補充

回到Akira 用root登入,建立另一個user.只有對 test1219a.Author 有select權限.

root@[test1219a] Akira
==>grant select on test1219a.Author to 'selauthor'@'%' identified by 'authorsel';

root@[test1219a] Akira
==>flush privileges;

---------------------------------------------
一樣在Bunko建立第二個 Table rAuthor2.

bunko@[test1219b] Bunko
==>CREATE TABLE rAuthor2
    -> (AuthorID smallint PRIMARY KEY,
    -> AuthorName varchar(255))
    -> engine=FEDERATED
    -> connection='mysql://selauthor:authorsel@192.168.0.100:3307/test1219a/Author';

bunko@[test1219b] Bunko
==>select * from rAuthor2;
+----------+-----------------+
| AuthorID | AuthorName      |
+----------+-----------------+
|        1 | Agatha Christie |
|        2 | Stephen King    |
+----------+-----------------+


一樣可以查詢.....但是試試看INSERT INTO

bunko@[test1219b] Bunko
==>insert into rAuthor2 values(3, 'Louis Cha');
ERROR 1296 (HY000): Got error 10000 'Error on remote system: 1142: INSERT command denied to user 'selauthor'@'192.168.0.100' for table 'A' from FEDERATED


無法INSERT INTO.
可以視實際的需求,選擇適當的方式來連線作業.