table.py 36 KB

12345678910111213141516171819202122232425262728293031323334353637383940414243444546474849505152535455565758596061626364656667686970717273747576777879808182838485868788899091929394959697989910010110210310410510610710810911011111211311411511611711811912012112212312412512612712812913013113213313413513613713813914014114214314414514614714814915015115215315415515615715815916016116216316416516616716816917017117217317417517617717817918018118218318418518618718818919019119219319419519619719819920020120220320420520620720820921021121221321421521621721821922022122222322422522622722822923023123223323423523623723823924024124224324424524624724824925025125225325425525625725825926026126226326426526626726826927027127227327427527627727827928028128228328428528628728828929029129229329429529629729829930030130230330430530630730830931031131231331431531631731831932032132232332432532632732832933033133233333433533633733833934034134234334434534634734834935035135235335435535635735835936036136236336436536636736836937037137237337437537637737837938038138238338438538638738838939039139239339439539639739839940040140240340440540640740840941041141241341441541641741841942042142242342442542642742842943043143243343443543643743843944044144244344444544644744844945045145245345445545645745845946046146246346446546646746846947047147247347447547647747847948048148248348448548648748848949049149249349449549649749849950050150250350450550650750850951051151251351451551651751851952052152252352452552652752852953053153253353453553653753853954054154254354454554654754854955055155255355455555655755855956056156256356456556656756856957057157257357457557657757857958058158258358458558658758858959059159259359459559659759859960060160260360460560660760860961061161261361461561661761861962062162262362462562662762862963063163263363463563663763863964064164264364464564664764864965065165265365465565665765865966066166266366466566666766866967067167267367467567667767867968068168268368468568668768868969069169269369469569669769869970070170270370470570670770870971071171271371471571671771871972072172272372472572672772872973073173273373473573673773873974074174274374474574674774874975075175275375475575675775875976076176276376476576676776876977077177277377477577677777877978078178278378478578678778878979079179279379479579679779879980080180280380480580680780880981081181281381481581681781881982082182282382482582682782882983083183283383483583683783883984084184284384484584684784884985085185285385485585685785885986086186286386486586686786886987087187287387487587687787887988088188288388488588688788888989089189289389489589689789889990090190290390490590690790890991091191291391491591691791891992092192292392492592692792892993093193293393493593693793893994094194294394494594694794894995095195295395495595695795895996096196296396496596696796896997097197297397497597697797897998098198298398498598698798898999099199299399499599699799899910001001100210031004100510061007100810091010
  1. # -*- coding: utf-8 -*-
  2. """
  3. Created on Wed Aug 8 15:29:21 2012
  4. @author: pietro
  5. """
  6. import os
  7. import ctypes
  8. import numpy as np
  9. from sqlite3 import OperationalError
  10. try:
  11. from collections import OrderedDict
  12. except:
  13. from grass.pygrass.orderdict import OrderedDict
  14. import grass.lib.vector as libvect
  15. from grass.pygrass.gis import Mapset
  16. from grass.pygrass.errors import DBError
  17. from grass.pygrass.functions import table_exist
  18. from grass.script.db import db_table_in_vector
  19. from grass.script.core import warning
  20. import sql
  21. DRIVERS = ('sqlite', 'pg')
  22. def get_path(path):
  23. """Return the full path to the database; replacing environment variable
  24. with real values ::
  25. >>> path = '$GISDBASE/$LOCATION_NAME/$MAPSET/sqlite/sqlite.db'
  26. >>> new_path = get_path(path)
  27. >>> from grass.script.core import gisenv
  28. >>> import os
  29. >>> new_path2 = os.path.join(gisenv()['GISDBASE'], gisenv()['LOCATION_NAME'],
  30. ... gisenv()['MAPSET'], 'sqlite', 'sqlite.db')
  31. >>> new_path == new_path2
  32. True
  33. """
  34. if "$" not in path:
  35. return path
  36. else:
  37. mapset = Mapset()
  38. path = path.replace('$GISDBASE', mapset.gisdbase)
  39. path = path.replace('$LOCATION_NAME', mapset.location)
  40. path = path.replace('$MAPSET', mapset.name)
  41. return path
  42. class Filters(object):
  43. """Help user to build a simple sql query. ::
  44. >>> filter = Filters('table')
  45. >>> filter.get_sql()
  46. 'SELECT * FROM table;'
  47. >>> filter.where("area<10000").get_sql()
  48. 'SELECT * FROM table WHERE area<10000;'
  49. >>> filter.select("cat", "area").get_sql()
  50. 'SELECT cat, area FROM table WHERE area<10000;'
  51. >>> filter.order_by("area").limit(10).get_sql()
  52. 'SELECT cat, area FROM table WHERE area<10000 ORDER BY area LIMIT 10;'
  53. ..
  54. """
  55. def __init__(self, tname):
  56. self.tname = tname
  57. self._select = None
  58. self._where = None
  59. self._orderby = None
  60. self._limit = None
  61. self._groupby = None
  62. def __repr__(self):
  63. return "Filters(%r)" % self.get_sql()
  64. def select(self, *args):
  65. """Create the select query"""
  66. cols = ', '.join(args) if args else '*'
  67. select = sql.SELECT[:-1]
  68. self._select = select.format(cols=cols, tname=self.tname)
  69. return self
  70. def where(self, condition):
  71. """Create the where condition"""
  72. self._where = 'WHERE {condition}'.format(condition=condition)
  73. return self
  74. def order_by(self, orderby):
  75. """Create the order by condition"""
  76. if not isinstance(orderby, str):
  77. orderby = ', '.join(orderby)
  78. self._orderby = 'ORDER BY {orderby}'.format(orderby=orderby)
  79. return self
  80. def limit(self, number):
  81. """Create the limit condition"""
  82. if not isinstance(number, int):
  83. raise ValueError("Must be an integer.")
  84. else:
  85. self._limit = 'LIMIT {number}'.format(number=number)
  86. return self
  87. def group_by(self, groupby):
  88. """Create the group by condition"""
  89. if not isinstance(groupby, str):
  90. groupby = ', '.join(groupby)
  91. self._groupby = 'GROUP BY {groupby}'.format(groupby=groupby)
  92. return self
  93. def get_sql(self):
  94. """Return the SQL query"""
  95. sql_list = list()
  96. if self._select is None:
  97. self.select()
  98. sql_list.append(self._select)
  99. if self._where is not None:
  100. sql_list.append(self._where)
  101. if self._groupby is not None:
  102. sql_list.append(self._groupby)
  103. if self._orderby is not None:
  104. sql_list.append(self._orderby)
  105. if self._limit is not None:
  106. sql_list.append(self._limit)
  107. return "%s;" % ' '.join(sql_list)
  108. def reset(self):
  109. """Clean internal variables"""
  110. self._select = None
  111. self._where = None
  112. self._orderby = None
  113. self._limit = None
  114. self._groupby = None
  115. class Columns(object):
  116. """Object to work with columns table.
  117. It is possible to instantiate a Columns object given the table name and
  118. the database connection.
  119. For a sqlite table: ::
  120. >>> import sqlite3
  121. >>> path = '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db'
  122. >>> cols_sqlite = Columns('census',
  123. ... sqlite3.connect(get_path(path)))
  124. >>> cols_sqlite.tname
  125. 'census'
  126. For a postgreSQL table: ::
  127. >>> import psycopg2 as pg #doctest: +SKIP
  128. >>> cols_pg = Columns('boundary_municp_pg',
  129. ... pg.connect('host=localhost dbname=grassdb')) #doctest: +SKIP
  130. >>> cols_pg.tname #doctest: +SKIP
  131. 'boundary_municp_pg' #doctest: +SKIP
  132. ..
  133. """
  134. def __init__(self, tname, connection, key='cat'):
  135. self.tname = tname
  136. self.conn = connection
  137. self.key = key
  138. self.odict = None
  139. self.update_odict()
  140. def __contains__(self, item):
  141. return item in self.names()
  142. def __repr__(self):
  143. return "Columns(%r)" % self.items()
  144. def __getitem__(self, key):
  145. return self.odict[key]
  146. def __setitem__(self, name, new_type):
  147. self.cast(name, new_type)
  148. self.update_odict(self)
  149. def __iter__(self):
  150. return self.odict.__iter__()
  151. def __len__(self):
  152. return self.odict.__len__()
  153. def __eq__(self, obj):
  154. return obj.tname == self.tname and obj.odict == self.odict
  155. def is_pg(self):
  156. """Return True if is a psycopg connection. ::
  157. >>> import sqlite3
  158. >>> path = '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db'
  159. >>> cols_sqlite = Columns('census',
  160. ... sqlite3.connect(get_path(path)))
  161. >>> cols_sqlite.is_pg()
  162. False
  163. >>> import psycopg2 as pg #doctest: +SKIP
  164. >>> cols_pg = Columns('boundary_municp_pg',
  165. ... pg.connect('host=localhost dbname=grassdb')) #doctest: +SKIP
  166. >>> cols_pg.is_pg() #doctest: +SKIP
  167. True
  168. ..
  169. """
  170. return hasattr(self.conn, 'xid')
  171. def update_odict(self):
  172. """Read columns name and types from table and update the odict
  173. attribute.
  174. """
  175. if self.is_pg():
  176. # is a postgres connection
  177. cur = self.conn.cursor()
  178. cur.execute("SELECT oid,typname FROM pg_type")
  179. diz = dict(cur.fetchall())
  180. odict = OrderedDict()
  181. import psycopg2 as pg
  182. try:
  183. cur.execute(sql.SELECT.format(cols='*', tname=self.tname))
  184. descr = cur.description
  185. for column in descr:
  186. name, ctype = column[:2]
  187. odict[name] = diz[ctype]
  188. except pg.ProgrammingError:
  189. pass
  190. self.odict = odict
  191. else:
  192. # is a sqlite connection
  193. cur = self.conn.cursor()
  194. cur.execute(sql.PRAGMA.format(tname=self.tname))
  195. descr = cur.fetchall()
  196. odict = OrderedDict()
  197. for column in descr:
  198. name, ctype = column[1:3]
  199. odict[name] = ctype
  200. self.odict = odict
  201. values = ','.join(['?', ] * self.__len__())
  202. kv = ','.join(['%s=?' % k for k in self.odict.keys()])
  203. where = "%s=?" % self.key
  204. self.insert_str = sql.INSERT.format(tname=self.tname, values=values)
  205. self.update_str = sql.UPDATE_WHERE.format(tname=self.tname,
  206. values=kv, condition=where)
  207. def sql_descr(self, remove=None):
  208. """Return a string with description of columns.
  209. Remove it is used to remove a columns.::
  210. >>> import sqlite3
  211. >>> path = '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db'
  212. >>> cols_sqlite = Columns('census',
  213. ... sqlite3.connect(get_path(path)))
  214. >>> cols_sqlite.sql_descr() # doctest: +ELLIPSIS
  215. u'cat INTEGER, OBJECTID INTEGER, AREA DOUBLE PRECISION, ...'
  216. >>> import psycopg2 as pg # doctest: +SKIP
  217. >>> cols_pg = Columns('boundary_municp_pg',
  218. ... pg.connect('host=localhost dbname=grassdb')) # doctest: +SKIP
  219. >>> cols_pg.sql_descr() # doctest: +ELLIPSIS +SKIP
  220. 'cat int4, objectid int4, area float8, perimeter float8, ...'
  221. """
  222. if remove:
  223. return ', '.join(['%s %s' % (key, val) for key, val in self.items()
  224. if key != remove])
  225. else:
  226. return ', '.join(['%s %s' % (key, val)
  227. for key, val in self.items()])
  228. def types(self):
  229. """Return a list with the column types. ::
  230. >>> import sqlite3
  231. >>> path = '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db'
  232. >>> cols_sqlite = Columns('census',
  233. ... sqlite3.connect(get_path(path)))
  234. >>> cols_sqlite.types() # doctest: +ELLIPSIS
  235. [u'INTEGER', u'INTEGER', ...]
  236. >>> import psycopg2 as pg # doctest: +SKIP
  237. >>> cols_pg = Columns('boundary_municp_pg',
  238. ... pg.connect('host=localhost dbname=grassdb')) # doctest: +SKIP
  239. >>> cols_pg.types() # doctest: +ELLIPSIS +SKIP
  240. ['int4', 'int4', 'float8', 'float8', 'float8', ...]
  241. ..
  242. """
  243. return self.odict.values()
  244. def names(self, remove=None, unicod=True):
  245. """Return a list with the column names.
  246. Remove it is used to remove a columns.::
  247. >>> import sqlite3
  248. >>> path = '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db'
  249. >>> cols_sqlite = Columns('census',
  250. ... sqlite3.connect(get_path(path)))
  251. >>> cols_sqlite.names() # doctest: +ELLIPSIS
  252. [u'cat', u'OBJECTID', u'AREA', u'PERIMETER', ...]
  253. >>> import psycopg2 as pg # doctest: +SKIP
  254. >>> cols_pg = Columns('boundary_municp_pg', # doctest: +SKIP
  255. ... pg.connect('host=localhost dbname=grassdb'))
  256. >>> cols_pg.names() # doctest: +ELLIPSIS +SKIP
  257. ['cat', 'objectid', 'area', 'perimeter', ...]
  258. ..
  259. """
  260. if remove:
  261. nams = self.odict.keys()
  262. nams.remove(remove)
  263. else:
  264. nams = self.odict.keys()
  265. if unicod:
  266. return nams
  267. else:
  268. return [str(name) for name in nams]
  269. def items(self):
  270. """Return a list of tuple with column name and column type. ::
  271. >>> import sqlite3
  272. >>> path = '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db'
  273. >>> cols_sqlite = Columns('census',
  274. ... sqlite3.connect(get_path(path)))
  275. >>> cols_sqlite.items() # doctest: +ELLIPSIS
  276. [(u'cat', u'INTEGER'), ...]
  277. >>> import psycopg2 as pg # doctest: +SKIP
  278. >>> cols_pg = Columns('boundary_municp_pg',
  279. ... pg.connect('host=localhost dbname=grassdb')) # doctest: +SKIP
  280. >>> cols_pg.items() # doctest: +ELLIPSIS +SKIP
  281. [('cat', 'int4'), ('objectid', 'int4'), ('area', 'float8'), ...]
  282. ..
  283. """
  284. return self.odict.items()
  285. def add(self, col_name, col_type):
  286. """Add a new column to the table. ::
  287. >>> import sqlite3
  288. >>> path = '$GISDBASE/$LOCATION_NAME/$MAPSET/sqlite/sqlite.db'
  289. >>> from grass.pygrass.functions import copy, remove
  290. >>> copy('census','mycensus','vect')
  291. >>> cols_sqlite = Columns('mycensus',
  292. ... sqlite3.connect(get_path(path)))
  293. >>> cols_sqlite.add('n_pizza', 'INT')
  294. >>> 'n_pizza' in cols_sqlite
  295. True
  296. >>> import psycopg2 as pg # doctest: +SKIP
  297. >>> cols_pg = Columns('boundary_municp_pg',
  298. ... pg.connect('host=localhost dbname=grassdb')) #doctest: +SKIP
  299. >>> cols_pg.add('n_pizza', 'INT') # doctest: +SKIP
  300. >>> 'n_pizza' in cols_pg # doctest: +SKIP
  301. True
  302. >>> remove('mycensus', 'vect')
  303. ..
  304. """
  305. def check_col(col_type):
  306. valid_type = ('DOUBLE PRECISION', 'DOUBLE', 'INT', 'INTEGER',
  307. 'DATE')
  308. if 'VARCHAR' in col_type or col_type.upper() not in valid_type:
  309. str_err = "Type is not supported, supported types are: %s"
  310. raise TypeError(str_err % ", ".join(valid_type))
  311. if isinstance(col_name, str):
  312. check_col(col_type)
  313. else:
  314. if len(col_name) == len(col_type):
  315. cvars = []
  316. for name, ctype in zip(col_name, col_type):
  317. check_col(ctype)
  318. cvars.append('%s %s' % (name, ctype))
  319. col_name = ''
  320. col_type = ','.join(cvars)
  321. else:
  322. str_err = "The lenghts of the columns are different:\n%r\n%r"
  323. raise TypeError(str_err % (col_name, col_type))
  324. cur = self.conn.cursor()
  325. cur.execute(sql.ADD_COL.format(tname=self.tname,
  326. cname=col_name,
  327. ctype=col_type))
  328. self.conn.commit()
  329. cur.close()
  330. self.update_odict()
  331. def rename(self, old_name, new_name):
  332. """Rename a column of the table. ::
  333. >>> import sqlite3
  334. >>> path = '$GISDBASE/$LOCATION_NAME/$MAPSET/sqlite/sqlite.db'
  335. >>> from grass.pygrass.functions import copy, remove
  336. >>> copy('census','mycensus','vect')
  337. >>> cols_sqlite = Columns('mycensus',
  338. ... sqlite3.connect(get_path(path)))
  339. >>> cols_sqlite.add('n_pizza', 'INT')
  340. >>> 'n_pizza' in cols_sqlite
  341. True
  342. >>> cols_sqlite.rename('n_pizza', 'n_pizzas') # doctest: +ELLIPSIS
  343. >>> 'n_pizza' in cols_sqlite
  344. False
  345. >>> 'n_pizzas' in cols_sqlite
  346. True
  347. >>> import psycopg2 as pg # doctest: +SKIP
  348. >>> cols_pg = Columns('boundary_municp_pg',
  349. ... pg.connect('host=localhost dbname=grassdb')) # doctest: +SKIP
  350. >>> cols_pg.rename('n_pizza', 'n_pizzas') # doctest: +SKIP
  351. >>> 'n_pizza' in cols_pg # doctest: +SKIP
  352. False
  353. >>> 'n_pizzas' in cols_pg # doctest: +SKIP
  354. True
  355. >>> remove('mycensus', 'vect')
  356. ..
  357. """
  358. cur = self.conn.cursor()
  359. if self.is_pg():
  360. cur.execute(sql.RENAME_COL.format(tname=self.tname,
  361. old_name=old_name,
  362. new_name=new_name))
  363. self.conn.commit()
  364. cur.close()
  365. self.update_odict()
  366. else:
  367. cur.execute(sql.ADD_COL.format(tname=self.tname,
  368. cname=new_name,
  369. ctype=str(self.odict[old_name])))
  370. cur.execute(sql.UPDATE.format(tname=self.tname,
  371. new_col=new_name,
  372. old_col=old_name))
  373. self.conn.commit()
  374. cur.close()
  375. self.update_odict()
  376. self.drop(old_name)
  377. def cast(self, col_name, new_type):
  378. """Change the column type. ::
  379. >>> import sqlite3
  380. >>> path = '$GISDBASE/$LOCATION_NAME/$MAPSET/sqlite/sqlite.db'
  381. >>> from grass.pygrass.functions import copy, remove
  382. >>> copy('census','mycensus','vect')
  383. >>> cols_sqlite = Columns('mycensus',
  384. ... sqlite3.connect(get_path(path)))
  385. >>> cols_sqlite.add('n_pizzas', 'INT')
  386. >>> cols_sqlite.cast('n_pizzas', 'float8') # doctest: +ELLIPSIS
  387. Traceback (most recent call last):
  388. ...
  389. DBError: 'SQLite does not support to cast columns.'
  390. >>> import psycopg2 as pg # doctest: +SKIP
  391. >>> cols_pg = Columns('boundary_municp_pg',
  392. ... pg.connect('host=localhost dbname=grassdb')) # doctest: +SKIP
  393. >>> cols_pg.cast('n_pizzas', 'float8') # doctest: +SKIP
  394. >>> cols_pg['n_pizzas'] # doctest: +SKIP
  395. 'float8'
  396. >>> remove('mycensus', 'vect')
  397. .. warning ::
  398. It is not possible to cast a column with sqlite
  399. ..
  400. """
  401. if self.is_pg():
  402. cur = self.conn.cursor()
  403. cur.execute(sql.CAST_COL.format(tname=self.tname, col=col_name,
  404. ctype=new_type))
  405. self.conn.commit()
  406. cur.close()
  407. self.update_odict()
  408. else:
  409. # sqlite does not support rename columns:
  410. raise DBError('SQLite does not support to cast columns.')
  411. def drop(self, col_name):
  412. """Drop a column from the table. ::
  413. >>> import sqlite3
  414. >>> path = '$GISDBASE/$LOCATION_NAME/$MAPSET/sqlite/sqlite.db'
  415. >>> from grass.pygrass.functions import copy, remove
  416. >>> copy('census','mycensus','vect')
  417. >>> cols_sqlite = Columns('mycensus',
  418. ... sqlite3.connect(get_path(path)))
  419. >>> cols_sqlite.drop('CHILD') # doctest: +ELLIPSIS
  420. >>> 'CHILD' in cols_sqlite
  421. False
  422. >>> import psycopg2 as pg # doctest: +SKIP
  423. >>> cols_pg = Columns('boundary_municp_pg',
  424. ... pg.connect('host=localhost dbname=grassdb')) # doctest: +SKIP
  425. >>> cols_pg.drop('CHILD') # doctest: +SKIP
  426. >>> 'CHILD' in cols_pg # doctest: +SKIP
  427. False
  428. >>> remove('mycensus','vect')
  429. ..
  430. """
  431. cur = self.conn.cursor()
  432. if self.is_pg():
  433. cur.execute(sql.DROP_COL.format(tname=self.tname,
  434. cname=col_name))
  435. else:
  436. desc = str(self.sql_descr(remove=col_name))
  437. names = ', '.join(self.names(remove=col_name, unicod=False))
  438. queries = sql.DROP_COL_SQLITE.format(tname=self.tname,
  439. keycol=self.key,
  440. coldef=desc,
  441. colnames=names).split('\n')
  442. for query in queries:
  443. cur.execute(query)
  444. self.conn.commit()
  445. cur.close()
  446. self.update_odict()
  447. class Link(object):
  448. """Define a Link between vector map and the attributes table.
  449. It is possible to define a Link object or given all the information
  450. (layer, name, table name, key, database, driver): ::
  451. >>> link = Link(1, 'link0', 'census', 'cat',
  452. ... '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db', 'sqlite')
  453. >>> link.number # doctest: +SKIP
  454. 1
  455. >>> link.name
  456. 'link0'
  457. >>> link.table_name
  458. 'census'
  459. >>> link.key
  460. 'cat'
  461. >>> link.database
  462. '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db'
  463. >>> link.driver
  464. 'sqlite'
  465. >>> link
  466. Link(1, link0, sqlite)
  467. It is possible to change parameters with: ::
  468. >>> link.driver = 'pg' # doctest: +SKIP
  469. >>> link.driver # doctest: +SKIP
  470. 'pg'
  471. >>> link.driver = 'postgres' # doctest: +ELLIPSIS +SKIP
  472. Traceback (most recent call last):
  473. ...
  474. TypeError: Driver not supported, use: sqlite, pg.
  475. >>> link.driver # doctest: +SKIP
  476. 'pg'
  477. >>> link.number = 0 # doctest: +ELLIPSIS +SKIP
  478. Traceback (most recent call last):
  479. ...
  480. TypeError: Number must be positive and greater than 0.
  481. Or given a c_fieldinfo object that is a ctypes pointer to the field_info C
  482. struct. ::
  483. >>> link = Link(c_fieldinfo = ctypes.pointer(libvect.field_info()))
  484. ..
  485. """
  486. def _get_layer(self):
  487. return self.c_fieldinfo.contents.number
  488. def _set_layer(self, number):
  489. if number <= 0:
  490. raise TypeError("Number must be positive and greater than 0.")
  491. self.c_fieldinfo.contents.number = number
  492. layer = property(fget=_get_layer, fset=_set_layer)
  493. def _get_name(self):
  494. return self.c_fieldinfo.contents.name
  495. def _set_name(self, name):
  496. self.c_fieldinfo.contents.name = name
  497. name = property(fget=_get_name, fset=_set_name)
  498. def _get_table(self):
  499. return self.c_fieldinfo.contents.table
  500. def _set_table(self, new_name):
  501. self.c_fieldinfo.contents.table = new_name
  502. table_name = property(fget=_get_table, fset=_set_table)
  503. def _get_key(self):
  504. return self.c_fieldinfo.contents.key
  505. def _set_key(self, key):
  506. self.c_fieldinfo.contents.key = key
  507. key = property(fget=_get_key, fset=_set_key)
  508. def _get_database(self):
  509. return self.c_fieldinfo.contents.database
  510. def _set_database(self, database):
  511. self.c_fieldinfo.contents.database = database
  512. database = property(fget=_get_database, fset=_set_database)
  513. def _get_driver(self):
  514. return self.c_fieldinfo.contents.driver
  515. def _set_driver(self, driver):
  516. if driver not in ('sqlite', 'pg'):
  517. str_err = "Driver not supported, use: %s." % ", ".join(DRIVERS)
  518. raise TypeError(str_err)
  519. self.c_fieldinfo.contents.driver = driver
  520. driver = property(fget=_get_driver, fset=_set_driver)
  521. def __init__(self, layer=1, name=None, table=None, key='cat',
  522. database='$GISDBASE/$LOCATION_NAME/'
  523. '$MAPSET/sqlite/sqlite.db',
  524. driver='sqlite', c_fieldinfo=None):
  525. if c_fieldinfo is not None:
  526. self.c_fieldinfo = c_fieldinfo
  527. else:
  528. self.c_fieldinfo = ctypes.pointer(libvect.field_info())
  529. self.layer = layer
  530. self.name = name
  531. self.table_name = table
  532. self.key = key
  533. self.database = database
  534. self.driver = driver
  535. def __repr__(self):
  536. return "Link(%d, %s, %s)" % (self.layer, self.name, self.driver)
  537. def __eq__(self, link):
  538. attrs = ['layer', 'name', 'table_name', 'key', 'driver']
  539. for attr in attrs:
  540. if getattr(self, attr) != getattr(link, attr):
  541. return False
  542. return True
  543. def connection(self):
  544. """Return a connection object. ::
  545. >>> link = Link(1, 'link0', 'census', 'cat',
  546. ... '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db',
  547. ... 'sqlite')
  548. >>> conn = link.connection()
  549. >>> cur = conn.cursor()
  550. >>> cur.execute("SELECT cat,TOTAL_POP,PERIMETER FROM %s" %
  551. ... link.table_name) # doctest: +ELLIPSIS
  552. <sqlite3.Cursor object at ...>
  553. >>> cur.fetchone()
  554. (1, 44, 757.669)
  555. >>> cur.close()
  556. >>> conn.close()
  557. ...
  558. """
  559. if self.driver == 'sqlite':
  560. import sqlite3
  561. # Numpy is using some custom integer data types to efficiently
  562. # pack data into memory. Since these types aren't familiar to
  563. # sqlite, you'll have to tell it about how to handle them.
  564. for t in (np.int8, np.int16, np.int32, np.int64, np.uint8,
  565. np.uint16, np.uint32, np.uint64):
  566. sqlite3.register_adapter(t, long)
  567. dbpath = get_path(self.database)
  568. dbdirpath = os.path.split(dbpath)[0]
  569. if not os.path.exists(dbdirpath):
  570. os.mkdir(dbdirpath)
  571. return sqlite3.connect(dbpath)
  572. elif self.driver == 'pg':
  573. try:
  574. import psycopg2
  575. psycopg2.paramstyle = 'qmark'
  576. db = ' '.join(self.database.split(','))
  577. return psycopg2.connect(db)
  578. except ImportError:
  579. er = "You need to install psycopg2 to connect with this table."
  580. raise ImportError(er)
  581. else:
  582. str_err = "Driver is not supported yet, pleas use: sqlite or pg"
  583. raise TypeError(str_err)
  584. def table(self):
  585. """Return a Table object. ::
  586. >>> link = Link(1, 'link0', 'census', 'cat',
  587. ... '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db',
  588. ... 'sqlite')
  589. >>> table = link.table()
  590. >>> table.filters.select('cat', 'TOTAL_POP', 'PERIMETER')
  591. Filters('SELECT cat, TOTAL_POP, PERIMETER FROM census;')
  592. >>> cur = table.execute()
  593. >>> cur.fetchone()
  594. (1, 44, 757.669)
  595. >>> cur.close()
  596. ..
  597. """
  598. return Table(self.table_name, self.connection(), self.key)
  599. def info(self):
  600. """Print information of the link. ::
  601. >>> link = Link(1, 'link0', 'census', 'cat',
  602. ... '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db',
  603. ... 'sqlite')
  604. >>> link.info()
  605. layer: 1
  606. name: link0
  607. table: census
  608. key: cat
  609. database: $GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db
  610. driver: sqlite
  611. ..
  612. """
  613. print "layer: ", self.layer
  614. print "name: ", self.name
  615. print "table: ", self.table_name
  616. print "key: ", self.key
  617. print "database: ", self.database
  618. print "driver: ", self.driver
  619. class DBlinks(object):
  620. """Interface containing link to the table DB. ::
  621. >>> from grass.pygrass.vector import VectorTopo
  622. >>> cens = VectorTopo('census')
  623. >>> cens.open()
  624. >>> dblinks = DBlinks(cens.c_mapinfo)
  625. >>> dblinks
  626. DBlinks([Link(1, census, sqlite)])
  627. >>> dblinks[0]
  628. Link(1, census, sqlite)
  629. >>> dblinks['census']
  630. Link(1, census, sqlite)
  631. ..
  632. """
  633. def __init__(self, c_mapinfo):
  634. self.c_mapinfo = c_mapinfo
  635. def __len__(self):
  636. return self.num_dblinks()
  637. def __iter__(self):
  638. return (self.by_index(i)
  639. for i in xrange(self.num_dblinks()))
  640. def __getitem__(self, item):
  641. """
  642. """
  643. if isinstance(item, int):
  644. return self.by_index(item)
  645. else:
  646. return self.by_name(item)
  647. def __repr__(self):
  648. return "DBlinks(%r)" % [link for link in self.__iter__()]
  649. def by_index(self, indx):
  650. """Return a Link object by index"""
  651. nlinks = self.num_dblinks()
  652. if nlinks == 0:
  653. raise IndexError
  654. if indx < 0:
  655. indx += nlinks
  656. if indx > nlinks:
  657. raise IndexError
  658. c_fieldinfo = libvect.Vect_get_dblink(self.c_mapinfo, indx)
  659. return Link(c_fieldinfo=c_fieldinfo) if c_fieldinfo else None
  660. def by_layer(self, layer):
  661. c_fieldinfo = libvect.Vect_get_field(self.c_mapinfo, layer)
  662. return Link(c_fieldinfo=c_fieldinfo) if c_fieldinfo else None
  663. def by_name(self, name):
  664. c_fieldinfo = libvect.Vect_get_field_by_name(self.c_mapinfo, name)
  665. return Link(c_fieldinfo=c_fieldinfo) if c_fieldinfo else None
  666. def num_dblinks(self):
  667. return libvect.Vect_get_num_dblinks(self.c_mapinfo)
  668. def add(self, link):
  669. """Add a new link.
  670. Need to open vector map in write mode::
  671. >>> from grass.pygrass.vector import VectorTopo
  672. >>> municip = VectorTopo('census')
  673. >>> municip.open()
  674. >>> dblinks = DBlinks(municip.c_mapinfo)
  675. >>> dblinks
  676. DBlinks([Link(1, census, sqlite)])
  677. >>> link = Link(2, 'pg_link', 'boundary_municp_pg', 'cat',
  678. ... 'host=localhost dbname=grassdb', 'pg') # doctest: +SKIP
  679. >>> dblinks.add(link) # doctest: +SKIP
  680. >>> dblinks # doctest: +SKIP
  681. DBlinks([Link(1, boundary_municp, sqlite)])
  682. ..
  683. """
  684. #TODO: check if open in write mode or not.
  685. libvect.Vect_map_add_dblink(self.c_mapinfo,
  686. link.layer, link.name, link.table_name,
  687. link.key, link.database, link.driver)
  688. def remove(self, key, force=False):
  689. """Remove a link. If force set to true remove also the table ::
  690. >>> from grass.pygrass.vector import VectorTopo
  691. >>> municip = VectorTopo('census')
  692. >>> municip.open()
  693. >>> dblinks = DBlinks(municip.c_mapinfo)
  694. >>> dblinks
  695. DBlinks([Link(1, census, sqlite)])
  696. >>> dblinks.remove('pg_link') # doctest: +SKIP
  697. >>> dblinks # need to open vector map in write mode
  698. DBlinks([Link(1, census, sqlite)])
  699. ..
  700. """
  701. if force:
  702. link = self.by_name(key)
  703. table = link.table()
  704. table.drop(force=force)
  705. if isinstance(key, str):
  706. key = self.from_name_to_num(key)
  707. libvect.Vect_map_del_dblink(self.c_mapinfo, key)
  708. def from_name_to_num(self, name):
  709. """
  710. Vect_get_field_number
  711. """
  712. return libvect.Vect_get_field_number(self.c_mapinfo, name)
  713. class Table(object):
  714. """::
  715. >>> import sqlite3
  716. >>> path = '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db'
  717. >>> tab_sqlite = Table(name='census',
  718. ... connection=sqlite3.connect(get_path(path)))
  719. >>> tab_sqlite.name
  720. 'census'
  721. >>> import psycopg2 # doctest: +SKIP
  722. >>> tab_pg = Table('boundary_municp_pg',
  723. ... psycopg2.connect('host=localhost dbname=grassdb',
  724. ... 'pg')) # doctest: +SKIP
  725. >>> tab_pg.columns # doctest: +ELLIPSIS +SKIP
  726. Columns([('cat', 'int4'), ...])
  727. ..
  728. """
  729. def _get_name(self):
  730. """Private method to return the name of table"""
  731. return self._name
  732. def _set_name(self, new_name):
  733. """Private method to set the name of table"""
  734. old_name = self._name
  735. cur = self.conn.cursor()
  736. cur.execute(sql.RENAME_TAB.format(old_name=old_name,
  737. new_name=new_name))
  738. self.conn.commit()
  739. cur.close()
  740. name = property(fget=_get_name, fset=_set_name)
  741. def __init__(self, name, connection, key='cat'):
  742. self._name = name
  743. self.conn = connection
  744. self.key = key
  745. self.columns = Columns(self.name,
  746. self.conn,
  747. self.key)
  748. self.filters = Filters(self.name)
  749. def __repr__(self):
  750. """::
  751. >>> import sqlite3
  752. >>> path = '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db'
  753. >>> tab_sqlite = Table(name='census',
  754. ... connection=sqlite3.connect(get_path(path)))
  755. >>> tab_sqlite
  756. Table('census')
  757. ..
  758. """
  759. return "Table(%r)" % (self.name)
  760. def __iter__(self):
  761. cur = self.execute()
  762. return (cur.fetchone() for _ in xrange(self.__len__()))
  763. def __len__(self):
  764. """Return the number of rows"""
  765. return self.n_rows()
  766. def drop(self, cursor=None, force=False):
  767. """Private method to drop table from database"""
  768. cur = cursor if cursor else self.conn.cursor()
  769. if self.exist(cursor=cur):
  770. used = db_table_in_vector(self.name)
  771. if len(used) > 0 and not force:
  772. print(_("Deleting table <%s> which is attached"
  773. " to following map(s):") % self.name)
  774. for vect in used:
  775. warning("%s" % vect)
  776. print(_("You must use the force flag to actually"
  777. " remove it. Exiting."))
  778. else:
  779. cur.execute(sql.DROP_TAB.format(tname=self.name))
  780. def n_rows(self):
  781. """Return the number of rows
  782. >>> import sqlite3
  783. >>> path = '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db'
  784. >>> tab_sqlite = Table(name='census',
  785. ... connection=sqlite3.connect(get_path(path)))
  786. >>> tab_sqlite.n_rows()
  787. 2537
  788. """
  789. cur = self.conn.cursor()
  790. cur.execute(sql.SELECT.format(cols='Count(*)', tname=self.name))
  791. number = cur.fetchone()[0]
  792. cur.close()
  793. return number
  794. def execute(self, sql_code=None, cursor=None, many=False, values=None):
  795. """Execute SQL code from a given string or build with filters and
  796. return a cursor object. ::
  797. >>> import sqlite3
  798. >>> path = '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db'
  799. >>> tab_sqlite = Table(name='census',
  800. ... connection=sqlite3.connect(get_path(path)))
  801. >>> tab_sqlite.filters.select('cat', 'TOTAL_POP').order_by('AREA')
  802. Filters('SELECT cat, TOTAL_POP FROM census ORDER BY AREA;')
  803. >>> cur = tab_sqlite.execute()
  804. >>> cur.fetchone()
  805. (1856, 0)
  806. ..
  807. """
  808. try:
  809. sqlc = sql_code if sql_code else self.filters.get_sql()
  810. cur = cursor if cursor else self.conn.cursor()
  811. if many and values:
  812. return cur.executemany(sqlc, values)
  813. return cur.execute(sqlc)
  814. except:
  815. raise ValueError("The SQL is not correct:\n%r" % sqlc)
  816. def exist(self, cursor=None):
  817. """Return True if the table already exist in the DB, False otherwise"""
  818. cur = cursor if cursor else self.conn.cursor()
  819. return table_exist(cur, self.name)
  820. def insert(self, values, cursor=None, many=False):
  821. """Insert a new row"""
  822. cur = cursor if cursor else self.conn.cursor()
  823. if many:
  824. return cur.executemany(self.columns.insert_str, values)
  825. return cur.execute(self.columns.insert_str, values)
  826. def update(self, key, values, cursor=None, many=False):
  827. """Update a column for each row"""
  828. cur = cursor if cursor else self.conn.cursor()
  829. vals = list(values)
  830. vals.append(key)
  831. return cur.execute(self.columns.update_str, vals)
  832. def create(self, cols, name=None, overwrite=False, cursor=None):
  833. """Create a new table"""
  834. cur = cursor if cursor else self.conn.cursor()
  835. coldef = ',\n'.join(['%s %s' % col for col in cols])
  836. if name:
  837. newname = name
  838. else:
  839. newname = self.name
  840. try:
  841. cur.execute(sql.CREATE_TAB.format(tname=newname, coldef=coldef))
  842. self.conn.commit()
  843. except OperationalError: # OperationalError
  844. if overwrite:
  845. self.drop(force=True)
  846. cur.execute(sql.CREATE_TAB.format(tname=newname,
  847. coldef=coldef))
  848. self.conn.commit()
  849. else:
  850. print "The table: %s already exist." % self.name
  851. cur.close()
  852. self.columns.update_odict()