table.py 33 KB

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