GHTDB.PostgreSQL.sql 13 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576
  1. DROP FUNCTION GHSP_TYPES_SIMPLE_1(BOOL, INT2, INT4, INT8, NUMERIC, FLOAT4, FLOAT8, VARCHAR, CHAR, NCHAR);
  2. DROP FUNCTION GHSP_TYPES_SIMPLE_4(VARCHAR);
  3. DROP FUNCTION GHSP_TYPES_SIMPLE_5();
  4. DROP FUNCTION GH_DUMMY(NUMERIC);
  5. DROP FUNCTION GH_REFCURSOR1();
  6. DROP FUNCTION GH_REFCURSOR2(integer);
  7. DROP FUNCTION GH_REFCURSOR3(varchar);
  8. DROP FUNCTION gh_createtable();
  9. DROP FUNCTION GH_MULTIRECORDSETS();
  10. DROP VIEW products_above_average_price;
  11. DROP VIEW current_product_list;
  12. DROP TABLE categories;
  13. DROP TABLE customercustomerdemo;
  14. DROP TABLE customerdemographics;
  15. DROP TABLE customers;
  16. DROP TABLE employees;
  17. DROP TABLE employeeterritories;
  18. DROP TABLE gh_emptytable;
  19. DROP TABLE "Order Details";
  20. DROP TABLE orders;
  21. DROP TABLE products;
  22. DROP TABLE region;
  23. DROP TABLE Results;
  24. DROP TABLE shippers;
  25. DROP TABLE shoppingcart;
  26. DROP TABLE suppliers;
  27. DROP TABLE territories;
  28. DROP TABLE TYPES_SIMPLE;
  29. DROP TABLE TYPES_EXTENDED;
  30. DROP TABLE TYPES_SPECIFIC;
  31. -- Create tables
  32. ----------------------------------------------------------------
  33. CREATE TABLE categories (
  34. categoryid serial unique NOT NULL,
  35. categoryname VARCHAR(30) NOT NULL,
  36. description VARCHAR(4000) NULL
  37. )
  38. WITHOUT OIDS;
  39. CREATE INDEX categoryname
  40. ON categories (
  41. categoryname
  42. );
  43. CREATE TABLE customercustomerdemo (
  44. customerid CHAR(10) NOT NULL,
  45. customertypeid CHAR(20) NOT NULL
  46. )
  47. WITHOUT OIDS;
  48. ALTER TABLE customercustomerdemo
  49. ADD CONSTRAINT pk_customercustomerdemo UNIQUE (
  50. customerid,
  51. customertypeid
  52. );
  53. CREATE TABLE customerdemographics (
  54. customertypeid CHAR(20) NOT NULL,
  55. customerdesc VARCHAR(4000) NULL
  56. )
  57. WITHOUT OIDS;
  58. ALTER TABLE customerdemographics
  59. ADD CONSTRAINT pk_customerdemographics UNIQUE (
  60. customertypeid
  61. );
  62. CREATE TABLE customers (
  63. customerid CHAR(10) NOT NULL,
  64. companyname VARCHAR(80) NOT NULL,
  65. contactname VARCHAR(60) NULL,
  66. contacttitle VARCHAR(60) NULL,
  67. address VARCHAR(120) NULL,
  68. city VARCHAR(30) NULL,
  69. region VARCHAR(30) NULL,
  70. postalcode VARCHAR(20) NULL,
  71. country VARCHAR(30) NULL,
  72. phone VARCHAR(48) NULL,
  73. fax VARCHAR(48) NULL
  74. )
  75. WITHOUT OIDS;
  76. CREATE INDEX city
  77. ON customers (
  78. city
  79. );
  80. CREATE INDEX companyname_1
  81. ON customers (
  82. companyname
  83. );
  84. CREATE INDEX postalcode_2
  85. ON customers (
  86. postalcode
  87. );
  88. CREATE INDEX ix_region
  89. ON customers (
  90. region
  91. );
  92. ALTER TABLE customers
  93. ADD CONSTRAINT uk_customers_customerid UNIQUE (
  94. customerid
  95. );
  96. CREATE TABLE employees (
  97. employeeid numeric(10,0) NOT NULL,
  98. lastname VARCHAR(40) NOT NULL,
  99. firstname VARCHAR(20) NOT NULL,
  100. title VARCHAR(60) NULL,
  101. titleofcourtesy VARCHAR(50) NULL,
  102. birthdate Timestamp NULL,
  103. hiredate Timestamp NULL,
  104. address VARCHAR(120) NULL,
  105. city VARCHAR(30) NULL,
  106. region VARCHAR(30) NULL,
  107. postalcode VARCHAR(20) NULL,
  108. country VARCHAR(30) NULL,
  109. homephone VARCHAR(48) NULL,
  110. extension VARCHAR(8) NULL,
  111. notes VARCHAR(4000) NULL,
  112. reportsto numeric(10,0) NULL,
  113. photopath VARCHAR(510) NULL,
  114. mycolumn numeric(10,0) NULL
  115. )
  116. WITHOUT OIDS;
  117. CREATE INDEX lastname
  118. ON employees (
  119. lastname
  120. );
  121. CREATE INDEX postalcode_1
  122. ON employees (
  123. postalcode
  124. );
  125. ALTER TABLE employees
  126. ADD CONSTRAINT pk_employees UNIQUE (
  127. employeeid
  128. );
  129. CREATE TABLE employeeterritories (
  130. employeeid numeric(10,0) NOT NULL,
  131. territoryid VARCHAR(40) NOT NULL
  132. )
  133. WITHOUT OIDS;
  134. CREATE TABLE gh_emptytable (
  135. col1 INTEGER NULL,
  136. col2 VARCHAR(50) NULL
  137. )
  138. WITHOUT OIDS;
  139. CREATE TABLE "Order Details" (
  140. orderid numeric(10,0) NOT NULL,
  141. productid numeric(10,0) NOT NULL,
  142. unitprice numeric(19,4) NOT NULL,
  143. quantity numeric(5,0) NOT NULL,
  144. discount FLOAT(53) NOT NULL
  145. )
  146. WITHOUT OIDS;
  147. CREATE TABLE orders (
  148. orderid numeric(10,0) NOT NULL,
  149. customerid NCHAR(5) NULL,
  150. employeeid numeric(10,0) NULL,
  151. orderdate DATE NULL,
  152. requireddate DATE NULL,
  153. shippeddate DATE NULL,
  154. shipvia numeric(10,0) NULL,
  155. freight numeric(19,4) NULL,
  156. shipname VARCHAR(40) NULL,
  157. shipaddress VARCHAR(60) NULL,
  158. shipcity VARCHAR(15) NULL,
  159. shipregion VARCHAR(15) NULL,
  160. shippostalcode VARCHAR(10) NULL,
  161. shipcountry VARCHAR(15) NULL
  162. )
  163. WITHOUT OIDS;
  164. ALTER TABLE orders
  165. ADD CONSTRAINT orders_uk11075049410018 UNIQUE (
  166. orderid
  167. );
  168. ALTER TABLE orders
  169. ADD CONSTRAINT orders_fk21075049699981 FOREIGN KEY (
  170. orderid
  171. ) REFERENCES orders (
  172. orderid
  173. );
  174. CREATE TABLE products (
  175. productid serial unique NOT NULL,
  176. productname VARCHAR(80) NOT NULL,
  177. supplierid numeric(10,0) NULL,
  178. categoryid numeric(10,0) NULL,
  179. quantityperunit VARCHAR(40) NULL,
  180. unitprice numeric(19,4) DEFAULT (0) NULL,
  181. unitsinstock numeric(5,0) DEFAULT (0) NULL,
  182. unitsonorder numeric(5,0) DEFAULT (0) NULL,
  183. reorderlevel numeric(5,0) DEFAULT (0) NULL,
  184. discontinued numeric(1,0) DEFAULT (0) NOT NULL
  185. )
  186. WITHOUT OIDS;
  187. ALTER TABLE products
  188. ADD CONSTRAINT ck_products_unitprice CHECK (
  189. UnitPrice >= 0
  190. );
  191. ALTER TABLE products
  192. ADD CONSTRAINT ck_reorderlevel CHECK (
  193. ReorderLevel >= 0
  194. );
  195. ALTER TABLE products
  196. ADD CONSTRAINT ck_unitsinstock CHECK (
  197. UnitsInStock >= 0
  198. );
  199. ALTER TABLE products
  200. ADD CONSTRAINT ck_unitsonorder CHECK (
  201. UnitsOnOrder >= 0
  202. );
  203. CREATE INDEX categoryid
  204. ON products (
  205. categoryid
  206. );
  207. CREATE INDEX productname
  208. ON products (
  209. productname
  210. );
  211. CREATE INDEX suppliersproducts
  212. ON products (
  213. supplierid
  214. );
  215. CREATE TABLE region (
  216. regionid numeric(10,0) NOT NULL,
  217. regiondescription CHAR(100) NOT NULL
  218. )
  219. WITHOUT OIDS;
  220. CREATE TABLE Results (
  221. employeeid numeric(10,0) NOT NULL,
  222. lastname VARCHAR(20) NOT NULL,
  223. firstname VARCHAR(10) NOT NULL,
  224. title VARCHAR(30) NULL,
  225. titleofcourtesy VARCHAR(25) NULL,
  226. birthdate DATE NULL,
  227. hiredate DATE NULL,
  228. address VARCHAR(60) NULL,
  229. city VARCHAR(15) NULL,
  230. region VARCHAR(15) NULL,
  231. postalcode VARCHAR(10) NULL,
  232. country VARCHAR(15) NULL,
  233. homephone VARCHAR(24) NULL,
  234. extension VARCHAR(4) NULL,
  235. notes VARCHAR(4000) NULL,
  236. reportsto numeric(10,0) NULL,
  237. photopath VARCHAR(255) NULL,
  238. mycolumn numeric(10,0) NULL
  239. )
  240. WITHOUT OIDS;
  241. CREATE TABLE shippers (
  242. shipperid serial unique NOT NULL,
  243. companyname VARCHAR(80) NOT NULL,
  244. phone VARCHAR(48) NULL
  245. )
  246. WITHOUT OIDS;
  247. CREATE TABLE shoppingcart (
  248. recordid serial unique NOT NULL,
  249. cartid VARCHAR(100) NULL,
  250. quantity numeric(10,0) DEFAULT (1) NOT NULL,
  251. productid numeric(10,0) NOT NULL,
  252. datecreated TIMESTAMP DEFAULT (CURRENT_TIMESTAMP) NOT NULL
  253. )
  254. WITHOUT OIDS;
  255. CREATE TABLE suppliers (
  256. supplierid serial unique NOT NULL,
  257. companyname VARCHAR(80) NOT NULL,
  258. contactname VARCHAR(60) NULL,
  259. contacttitle VARCHAR(60) NULL,
  260. address VARCHAR(120) NULL,
  261. city VARCHAR(30) NULL,
  262. region VARCHAR(30) NULL,
  263. postalcode VARCHAR(20) NULL,
  264. country VARCHAR(30) NULL,
  265. phone VARCHAR(48) NULL,
  266. fax VARCHAR(48) NULL,
  267. homepage VARCHAR(4000) NULL
  268. )
  269. WITHOUT OIDS;
  270. CREATE INDEX companyname
  271. ON suppliers (
  272. companyname
  273. );
  274. CREATE INDEX postalcode
  275. ON suppliers (
  276. postalcode
  277. );
  278. CREATE TABLE territories (
  279. territoryid VARCHAR(40) NOT NULL,
  280. territorydescription CHAR(100) NOT NULL,
  281. regionid numeric(10,0) NOT NULL
  282. )
  283. WITHOUT OIDS;
  284. CREATE TABLE TYPES_SIMPLE (
  285. id char(10),
  286. t_bool bool,
  287. t_int2 int2,
  288. t_int4 int4,
  289. t_int8 int8,
  290. t_numeric numeric(10),
  291. t_float4 float4,
  292. t_float8 float8,
  293. t_varchar varchar(50),
  294. t_char char(10),
  295. t_nchar char(10)
  296. )
  297. WITHOUT OIDS;
  298. CREATE TABLE TYPES_EXTENDED (
  299. id char(10),
  300. t_bytea bytea,
  301. t_date date,
  302. t_text text,
  303. t_time time,
  304. t_timestamp timestamp
  305. )
  306. WITHOUT OIDS;
  307. CREATE TABLE TYPES_SPECIFIC (
  308. id char(10),
  309. t_bit bit(1),
  310. t_box box,
  311. t_cidr cidr,
  312. t_circle circle,
  313. t_inet inet,
  314. t_interval interval (6),
  315. t_line line,
  316. t_lseg lseg,
  317. t_macaddr macaddr,
  318. t_money money,
  319. t_path path,
  320. t_point point,
  321. t_polygon polygon,
  322. t_serial serial,
  323. t_bigserial bigserial,
  324. t_timetz timetz,
  325. t_timestamptz timestamptz
  326. )
  327. WITHOUT OIDS;
  328. -- Create views
  329. ----------------------------------------------------------------
  330. CREATE OR REPLACE VIEW products_above_average_price (
  331. productname,
  332. unitprice
  333. ) AS
  334. SELECT Products.ProductName, Products.UnitPrice
  335. FROM Products
  336. WHERE Products.UnitPrice > (
  337. SELECT AVG(UnitPrice)
  338. FROM Products );
  339. CREATE OR REPLACE VIEW current_product_list (
  340. productid,
  341. productname
  342. ) AS
  343. SELECT Product_List.ProductID, Product_List.ProductName
  344. FROM Products Product_List
  345. WHERE
  346. (
  347. (( Product_List.Discontinued ) = 0));
  348. -- Create functions
  349. ----------------------------------------------------------------
  350. CREATE FUNCTION GH_MULTIRECORDSETS() RETURNS SETOF refcursor AS $$
  351. DECLARE
  352. rct1 refcursor;
  353. rct2 refcursor;
  354. rct3 refcursor;
  355. BEGIN
  356. OPEN rct1 FOR
  357. SELECT EmployeeId, LastName FROM Employees where EmployeeId in (1,2) ORDER BY EMPLOYEEID ASC;
  358. RETURN NEXT rct1;
  359. OPEN rct2 FOR
  360. SELECT CustomerId, CompanyName,ContactName FROM Customers where CustomerId in ('MORGK','NORTS') ORDER BY CustomerId ASC;
  361. RETURN NEXT rct2;
  362. OPEN rct3 FOR
  363. SELECT OrderId, ShipAddress,ShipVia, ShipCity FROM Orders where OrderId=-1 ;
  364. RETURN NEXT rct3;
  365. RETURN;
  366. END;
  367. $$ LANGUAGE 'plpgsql';
  368. CREATE FUNCTION gh_createtable() RETURNS void AS $$
  369. BEGIN
  370. --craete a temporary table
  371. execute 'Create Table temp_tbl (Col1 int,Col2 int)';
  372. --insert values to the table
  373. execute 'insert into temp_tbl values (11,12)';
  374. execute 'insert into temp_tbl values (21,22)';
  375. execute 'insert into temp_tbl values (31,32)';
  376. --execute select on the created table
  377. execute 'select col1 as Value1, col2 as Value2 from temp_tbl';
  378. execute 'drop table temp_tbl';
  379. RETURN;
  380. END;
  381. $$ LANGUAGE 'plpgsql';
  382. CREATE FUNCTION GH_REFCURSOR1() RETURNS refcursor AS $$
  383. DECLARE
  384. rct1 refcursor;
  385. BEGIN
  386. OPEN rct1 FOR
  387. SELECT EmployeeId, LastName FROM Employees where EmployeeId = 1;
  388. RETURN rct1;
  389. END;
  390. $$ LANGUAGE 'plpgsql';
  391. CREATE FUNCTION GH_REFCURSOR2(integer) RETURNS refcursor AS $$
  392. DECLARE
  393. rct1 refcursor;
  394. BEGIN
  395. OPEN rct1 FOR
  396. SELECT EmployeeId, LastName FROM Employees where EmployeeId = $1;
  397. RETURN rct1;
  398. END;
  399. $$ LANGUAGE 'plpgsql';
  400. CREATE FUNCTION GH_REFCURSOR3(varchar) RETURNS refcursor AS $$
  401. DECLARE
  402. rct1 refcursor;
  403. BEGIN
  404. OPEN rct1 FOR
  405. SELECT EmployeeId, LastName FROM Employees where LastName = $1;
  406. RETURN rct1;
  407. END;
  408. $$ LANGUAGE 'plpgsql';
  409. CREATE FUNCTION GHSP_TYPES_SIMPLE_1(BOOL, INT2, INT4, INT8, NUMERIC, FLOAT4, FLOAT8, VARCHAR, CHAR, NCHAR) RETURNS refcursor AS $$
  410. DECLARE
  411. rct1 refcursor;
  412. BEGIN
  413. OPEN rct1 FOR
  414. SELECT $1 as T_BOOL, $2 as T_INT2, $3 as T_INT4, $4 as T_INT8, $5 as T_NUMERIC, $6 as T_FLOAT4, $7 as T_FLOAT8, $8 as T_VARCHAR, $9 as T_CHAR, $10 as T_NCHAR;
  415. RETURN rct1;
  416. END
  417. $$ LANGUAGE 'plpgsql';
  418. CREATE FUNCTION GHSP_TYPES_SIMPLE_4(VARCHAR) RETURNS SETOF refcursor AS $$
  419. DECLARE
  420. rct1 refcursor;
  421. rct2 refcursor;
  422. rct3 refcursor;
  423. BEGIN
  424. insert into TYPES_SIMPLE(ID,t_numeric) values ($1,50);
  425. OPEN rct1 FOR
  426. SELECT * FROM TYPES_SIMPLE where ID = $1;
  427. RETURN NEXT rct1;
  428. update TYPES_SIMPLE set t_numeric=60 where Id = $1;
  429. OPEN rct2 FOR
  430. SELECT * FROM TYPES_SIMPLE where ID = $1;
  431. RETURN NEXT rct2;
  432. delete from TYPES_SIMPLE where ID = $1;
  433. OPEN rct3 FOR
  434. SELECT * FROM TYPES_SIMPLE where ID = $1;
  435. RETURN NEXT rct3;
  436. RETURN;
  437. END;
  438. $$ LANGUAGE 'plpgsql';
  439. CREATE FUNCTION GHSP_TYPES_SIMPLE_5() RETURNS refcursor AS $$
  440. DECLARE
  441. rct1 refcursor;
  442. T_BOOL boolean :=true;
  443. T_INT2 int2 := 21;
  444. T_INT4 int4 := 30000;
  445. T_INT8 int8 := 30001;
  446. T_NUMERIC NUMERIC(10) := 100000;
  447. T_FLOAT4 FLOAT4 := 7.23157;
  448. T_FLOAT8 FLOAT8 := 7.123456;
  449. T_VARCHAR VARCHAR(10) := 'qwertasdfg';
  450. T_CHAR CHAR(10) := 'abcdefghij';
  451. T_NCHAR NCHAR(10) := 'klmnopqrst';
  452. BEGIN
  453. OPEN rct1 FOR
  454. SELECT T_BOOL, T_INT2, T_INT4, T_INT8, T_NUMERIC, T_FLOAT4, T_FLOAT8, T_VARCHAR, T_CHAR, T_NCHAR;
  455. RETURN rct1;
  456. END;
  457. $$ LANGUAGE 'plpgsql';
  458. CREATE FUNCTION GH_DUMMY(NUMERIC) RETURNS refcursor AS $$
  459. DECLARE
  460. rct1 refcursor;
  461. BEGIN
  462. OPEN rct1 FOR
  463. SELECT EMPLOYEEID,
  464. LASTNAME,
  465. FIRSTNAME,
  466. TITLE,
  467. TITLEOFCOURTESY,
  468. BIRTHDATE,
  469. HIREDATE,
  470. ADDRESS,
  471. CITY,
  472. REGION,
  473. POSTALCODE,
  474. COUNTRY,
  475. HOMEPHONE,
  476. EXTENSION,
  477. REPORTSTO,
  478. PHOTOPATH,
  479. MYCOLUMN
  480. FROM EMPLOYEES where EmployeeID > $1;
  481. RETURN rct1;
  482. END;
  483. $$ LANGUAGE 'plpgsql';