table.py 42 KB

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