src/Palete/RooDatabase.vala
[app.Builder.js] / src / Palete / RooDatabase.vala
1 /*
2  * Renderer for Roo Database code
3  * 
4  * - Concept - this code does the SQL queries
5  *   pulls data from information_schema (on mysql only at present..)
6  *   Sends it down the line to the Javascript code. to generate structures 
7  * 
8  */
9  
10  // should this be in palete...
11 namespace Palete {
12
13   
14     public class RooDatabase : Object 
15     {
16         public Project.Project project;
17
18                 public string DBTYPE;
19                 public string DBNAME;
20                  
21         public Gda.Connection cnc;
22         
23                 public RooDatabase.from_project (Project.Project project)
24         {
25             this.project = project;
26                         this.DBTYPE = this.project.get_string_member("DBTYPE");
27                         this.DBNAME = this.project.get_string_member("DBNAME");
28                         if (this.DBTYPE.length < 1) {
29                                 return;
30                         }
31                         
32                         
33                         try {
34                                 
35                                         this.cnc = Gda.Connection.open_from_string (
36                                         this.DBTYPE,
37                                         "DB_NAME=" + this.DBNAME, 
38                                         "USERNAME=" + this.project.get_string_member("DBUSERNAME") + 
39                                         ";PASSWORD=" + this.project.get_string_member("DBPASSWORD"),
40                                         Gda.ConnectionOptions.NONE
41                                 );
42                         } catch(Gda.ConfigError e) {
43                                 GLib.warning("%s\n", e.message);
44                                 this.cnc  = null;
45                                 this.DBTYPE = "";
46                         } catch(Gda.ConnectionError e) {
47                                 GLib.warning("%s\n", e.message);
48                                 this.cnc  = null;
49                                 this.DBTYPE = "";
50                         }
51             
52         }
53        
54                 public RooDatabase.from_cfg (string dbtype, string dbname, string dbuser, string dbpass)
55                 {
56                         this.DBTYPE = dbtype;
57                         this.DBNAME = dbname;
58                         try {
59                                  this.cnc = Gda.Connection.open_from_string (
60                                         this.DBTYPE,
61                                         "DB_NAME=" + dbname, 
62                                         "USERNAME=" + dbuser + 
63                                         ";PASSWORD=" + dbpass,
64                                         Gda.ConnectionOptions.NONE
65                                 );
66                         } catch(Gda.ConfigError e) {
67                                 this.cnc  = null;
68                                 this.DBTYPE = "";
69                         } catch(Gda.ConnectionError e) {
70                                 this.cnc  = null;
71                                 this.DBTYPE = "";
72                         }
73
74             
75         }
76           
77         
78         public Json.Array readTables()
79         {
80                         try {
81                                 if (this.DBTYPE == "PostgreSQL") {
82                                 
83                                         return this.fetchAll(this.cnc.execute_select_command( 
84                                                 """select c.relname FROM pg_catalog.pg_class c 
85                                                         LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace 
86                                                         WHERE c.relkind IN ('r','') AND n.nspname NOT IN ('pg_catalog', 'pg_toast')
87                                                         AND pg_catalog.pg_table_is_visible(c.oid) 
88                                                 """));
89                                 
90                                 }
91                                 if (this.DBTYPE == "MySQL") { 
92                                         return this.fetchAll(this.cnc.execute_select_command( "SHOW TABLES" ));
93                                 }
94                         } catch (GLib.Error e) {
95                         }
96                         GLib.warning("Read tables failed DBTYPE = %s\n", this.DBTYPE);
97                         return new Json.Array();
98                         
99                 }
100                 public Gee.ArrayList readTablesGee()
101                 {
102                         var ret = new Gee.ArrayList<string>();
103                         var ar = this.readTables();
104                         for(var i = 0; i < ar.get_length(); i++) {
105                                 ret.add(ar.get_string_element(i));
106                         }
107                         return ret;
108                         
109                 }
110                 
111                 public Json.Object readTable(string tablename) 
112                 {
113                         
114                         Json.Array res_ar;
115                         var res = new Json.Object();
116                         try {
117                                 switch (this.DBTYPE ) {
118                                         case "PostgreSQL":
119                                 
120                                                 res_ar =   this.fetchAll(this.cnc.execute_select_command( 
121                                                 """
122                                         
123                                                  SELECT 
124                                                         f.attnum AS number, 
125                                                         f.attname AS Field, 
126                                                         f.attnum, 
127                                                         CASE WHEN f.attnotnull = 't' THEN 'NO' ELSE 'YES' END AS isNull,  
128                                                         pg_catalog.format_type(f.atttypid,f.atttypmod) AS Type, 
129                                                         CASE WHEN p.contype = 'p' THEN 't' ELSE 'f' END AS primarykey, 
130                                                         CASE WHEN p.contype = 'u' THEN 't' ELSE 'f' END AS uniquekey, 
131                                                         CASE WHEN p.contype = 'f' THEN g.relname END AS foreignkey, 
132                                                         CASE WHEN p.contype = 'f' THEN p.confkey END AS foreignkey_fieldnum, 
133                                                         CASE WHEN p.contype = 'f' THEN g.relname END AS foreignkey, 
134                                                         CASE WHEN p.contype = 'f' THEN p.conkey END AS foreignkey_connnum, 
135                                                         CASE WHEN f.atthasdef = 't' THEN d.adsrc END AS default 
136                                                         FROM pg_attribute f JOIN pg_class c ON c.oid = f.attrelid 
137                                                                         JOIN pg_type t ON t.oid = f.atttypid 
138                                                                         LEFT JOIN pg_attrdef d ON d.adrelid = c.oid AND d.adnum = f.attnum 
139                                                                         LEFT JOIN pg_namespace n ON n.oid = c.relnamespace 
140                                                                         LEFT JOIN pg_constraint p ON p.conrelid = c.oid AND f.attnum = ANY ( p.conkey ) 
141                                                                         LEFT JOIN pg_class AS g ON p.confrelid = g.oid 
142                                                         WHERE c.relkind = 'r'::char AND n.nspname = 'public' 
143                                                         AND c.relname = '""" + tablename + """' AND f.attnum > 0 ORDER BY number;
144                                                         
145                                                 """));
146                                                 break;
147                                         
148                                         case  "MySQL":
149                                                 res_ar = this.fetchAll(this.cnc.execute_select_command( "DESCRIBE " + tablename ));
150                                                 break;
151                                 
152                                         default: 
153                                                 return res;
154  
155                                 }
156                          } catch (GLib.Error e) {
157                          }
158                         
159                         for (var i =0; i < res_ar.get_length(); i++) {
160                                 var el = res_ar.get_object_element(i);
161                                 res.set_object_member( el.get_string_member("Field"), el);
162                         }
163                         return res;
164                         
165                         
166                 }
167                 
168          
169                         
170                 
171                 
172                 public Json.Object readForeignKeys(string table)
173         { 
174                         
175                         
176                         var ret =   this.readTable(table);
177                         // technically we should use FK stuff in mysql, but for the momemnt use my hacky FK()
178                         if (this.DBTYPE != "MySQL") { 
179                                 return  ret;
180                         }
181                         
182                         var query = """
183                                 SELECT 
184                                 TABLE_COMMENT 
185                                 FROM
186                                 information_schema.TABLES
187                                 WHERE
188                                 TABLE_NAME = '""" + table + """'
189                                 AND
190                                 TABLE_SCHEMA = '""" + this.DBNAME + """'
191                         """;
192                         
193                         var jarr = this.fetchAll(this.cnc.execute_select_command( 
194                                         query
195                                         ));
196                         if (jarr.get_length() < 1) {
197                                 return  ret;
198                         }
199                         
200                         var contents = jarr.get_string_element(0);
201                         GLib.debug(contents);
202                         if (contents == null) {
203                                 return ret;
204                         }
205                         
206                          GLib.Regex exp = /FK\(([^\)]+)\)/;
207                          string str = "";
208                          try {
209                                 GLib.MatchInfo mi;
210                                 if ( exp.match (contents, 0, out mi) ) {
211                                         
212                                         str = mi.fetch(1);
213                                         GLib.debug("match = %s", str);
214                                 }
215                         } catch (GLib.Error e) {
216                                 return  ret;
217                         }
218                         var ar = str.split("\n");
219                         for (var i = 0; i < ar.length; i++) {
220                                 var kv = ar[i].split("=");
221                                 if (!ret.has_member(kv[0].strip())) { 
222                                         continue;
223                                 }
224                                 var o = ret.get_object_member(kv[0].strip());
225                                 
226                                 //o.set_string_member("key", kv[0].strip());
227                                 var lr = kv[1].split(":");
228                                 o.set_string_member("relates_to_table", lr[0].strip());
229                                 o.set_string_member("relates_to_col", lr[1].strip());
230                                 o.set_object_member("relates_to_schema", this.readTable(lr[0].strip()));
231                                 //ret.set_object_member(kv[0].strip(),o);
232                                 
233                                 
234                         }
235                         return ret;
236                                  
237                 }
238         public Json.Array fetchAll(Gda.DataModel qnr)
239                 {
240                         var cols = new Gee.ArrayList<string>();
241                         
242                         for (var i =0;i < qnr.get_n_columns(); i++) {
243                                 cols.add(qnr.get_column_name(i));
244                         }
245                         //print(Json.stringify(cols, null,4));
246                         var iter = qnr.create_iter();
247                         var res = new Json.Array();
248                          //print("ROWS %d\n", qnr.get_n_rows());
249                         
250                         for (var r = 0; r < qnr.get_n_rows(); r++) {
251                                 
252                                 // single clo..
253                                 //print("GOT ROW");
254                                 //print("COLS  %d\n", cols.size);
255                                 if (cols.size == 1) {
256                                         var str = qnr.get_value_at(0,r).get_string();
257                                         //print("GOT %s\n",str);
258                                         res.add_string_element(qnr.get_value_at(0,r).get_string());
259                                         continue;
260                                 }
261                                 
262                                 var add = new Json.Object();
263                                 
264                                 for (var i = 0; i < cols.size; i++) { 
265                                         var n = cols.get(i);
266                                         var val = qnr.get_value_at(i,r);
267                                         var type = val.type().name();
268                                         //print("%s\n",type);
269                                         switch(type) {
270                                                 case "GdaBinary":
271                                                 case "GdaBlob":
272                                                         add.set_string_member(n, "?? big string ??");
273                                                         break;
274                                                         
275                                                 case  "GdaNull":
276                                                         add.set_null_member(n);
277                                                         break;
278                                                 
279                                                 default:
280                                                         add.set_string_member(n, val.get_string());
281                                                         break;
282                                         }
283                                         
284                                 }
285                                 
286                                 res.add_object_element(add);
287                                 
288                         }
289                         return res;
290
291                 }
292                 
293                 
294                 
295         }
296         
297         
298 }
299 // valac --pkg libgda-5.0 --pkg gee-1.0 --pkg json-glib-1.0  --pkg libxml-2.0   RooDatabase.vala  -o /tmp/rdtest
300 /*
301  void main() {
302      var x = new JsRender.RooDatabase.from_cfg("MySQL", "hydra", "root", "");
303     // var res = x.readTables();
304     //var res= x.readTable("Person");
305     var res= x.readForeignKeys("Person");
306     
307         var  generator = new Json.Generator ();
308     var  root = new Json.Node(Json.NodeType.OBJECT);
309     root.init_object(res);
310     generator.set_root (root);
311     
312             generator.pretty = true;
313             generator.indent = 4;
314     
315
316     print("%s\n", generator.to_data (null));
317  }
318 */