You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.

542 line
19KB

  1. <?php
  2. /**
  3. * @link http://www.yiiframework.com/
  4. * @copyright Copyright (c) 2008 Yii Software LLC
  5. * @license http://www.yiiframework.com/license/
  6. */
  7. namespace yii\db\pgsql;
  8. use yii\db\Expression;
  9. use yii\db\TableSchema;
  10. use yii\db\ColumnSchema;
  11. /**
  12. * Schema is the class for retrieving metadata from a PostgreSQL database
  13. * (version 9.x and above).
  14. *
  15. * @property string[] $viewNames All view names in the database. This property is read-only.
  16. *
  17. * @author Gevik Babakhani <gevikb@gmail.com>
  18. * @since 2.0
  19. */
  20. class Schema extends \yii\db\Schema
  21. {
  22. /**
  23. * @var string the default schema used for the current session.
  24. */
  25. public $defaultSchema = 'public';
  26. /**
  27. * @var array mapping from physical column types (keys) to abstract
  28. * column types (values)
  29. * @see http://www.postgresql.org/docs/current/static/datatype.html#DATATYPE-TABLE
  30. */
  31. public $typeMap = [
  32. 'bit' => self::TYPE_INTEGER,
  33. 'bit varying' => self::TYPE_INTEGER,
  34. 'varbit' => self::TYPE_INTEGER,
  35. 'bool' => self::TYPE_BOOLEAN,
  36. 'boolean' => self::TYPE_BOOLEAN,
  37. 'box' => self::TYPE_STRING,
  38. 'circle' => self::TYPE_STRING,
  39. 'point' => self::TYPE_STRING,
  40. 'line' => self::TYPE_STRING,
  41. 'lseg' => self::TYPE_STRING,
  42. 'polygon' => self::TYPE_STRING,
  43. 'path' => self::TYPE_STRING,
  44. 'character' => self::TYPE_CHAR,
  45. 'char' => self::TYPE_CHAR,
  46. 'bpchar' => self::TYPE_CHAR,
  47. 'character varying' => self::TYPE_STRING,
  48. 'varchar' => self::TYPE_STRING,
  49. 'text' => self::TYPE_TEXT,
  50. 'bytea' => self::TYPE_BINARY,
  51. 'cidr' => self::TYPE_STRING,
  52. 'inet' => self::TYPE_STRING,
  53. 'macaddr' => self::TYPE_STRING,
  54. 'real' => self::TYPE_FLOAT,
  55. 'float4' => self::TYPE_FLOAT,
  56. 'double precision' => self::TYPE_DOUBLE,
  57. 'float8' => self::TYPE_DOUBLE,
  58. 'decimal' => self::TYPE_DECIMAL,
  59. 'numeric' => self::TYPE_DECIMAL,
  60. 'money' => self::TYPE_MONEY,
  61. 'smallint' => self::TYPE_SMALLINT,
  62. 'int2' => self::TYPE_SMALLINT,
  63. 'int4' => self::TYPE_INTEGER,
  64. 'int' => self::TYPE_INTEGER,
  65. 'integer' => self::TYPE_INTEGER,
  66. 'bigint' => self::TYPE_BIGINT,
  67. 'int8' => self::TYPE_BIGINT,
  68. 'oid' => self::TYPE_BIGINT, // should not be used. it's pg internal!
  69. 'smallserial' => self::TYPE_SMALLINT,
  70. 'serial2' => self::TYPE_SMALLINT,
  71. 'serial4' => self::TYPE_INTEGER,
  72. 'serial' => self::TYPE_INTEGER,
  73. 'bigserial' => self::TYPE_BIGINT,
  74. 'serial8' => self::TYPE_BIGINT,
  75. 'pg_lsn' => self::TYPE_BIGINT,
  76. 'date' => self::TYPE_DATE,
  77. 'interval' => self::TYPE_STRING,
  78. 'time without time zone' => self::TYPE_TIME,
  79. 'time' => self::TYPE_TIME,
  80. 'time with time zone' => self::TYPE_TIME,
  81. 'timetz' => self::TYPE_TIME,
  82. 'timestamp without time zone' => self::TYPE_TIMESTAMP,
  83. 'timestamp' => self::TYPE_TIMESTAMP,
  84. 'timestamp with time zone' => self::TYPE_TIMESTAMP,
  85. 'timestamptz' => self::TYPE_TIMESTAMP,
  86. 'abstime' => self::TYPE_TIMESTAMP,
  87. 'tsquery' => self::TYPE_STRING,
  88. 'tsvector' => self::TYPE_STRING,
  89. 'txid_snapshot' => self::TYPE_STRING,
  90. 'unknown' => self::TYPE_STRING,
  91. 'uuid' => self::TYPE_STRING,
  92. 'json' => self::TYPE_STRING,
  93. 'jsonb' => self::TYPE_STRING,
  94. 'xml' => self::TYPE_STRING,
  95. ];
  96. /**
  97. * @var array list of ALL view names in the database
  98. */
  99. private $_viewNames = [];
  100. /**
  101. * Creates a query builder for the PostgreSQL database.
  102. * @return QueryBuilder query builder instance
  103. */
  104. public function createQueryBuilder()
  105. {
  106. return new QueryBuilder($this->db);
  107. }
  108. /**
  109. * Resolves the table name and schema name (if any).
  110. * @param TableSchema $table the table metadata object
  111. * @param string $name the table name
  112. */
  113. protected function resolveTableNames($table, $name)
  114. {
  115. $parts = explode('.', str_replace('"', '', $name));
  116. if (isset($parts[1])) {
  117. $table->schemaName = $parts[0];
  118. $table->name = $parts[1];
  119. } else {
  120. $table->schemaName = $this->defaultSchema;
  121. $table->name = $name;
  122. }
  123. $table->fullName = $table->schemaName !== $this->defaultSchema ? $table->schemaName . '.' . $table->name : $table->name;
  124. }
  125. /**
  126. * Quotes a table name for use in a query.
  127. * A simple table name has no schema prefix.
  128. * @param string $name table name
  129. * @return string the properly quoted table name
  130. */
  131. public function quoteSimpleTableName($name)
  132. {
  133. return strpos($name, '"') !== false ? $name : '"' . $name . '"';
  134. }
  135. /**
  136. * Loads the metadata for the specified table.
  137. * @param string $name table name
  138. * @return TableSchema|null driver dependent table metadata. Null if the table does not exist.
  139. */
  140. public function loadTableSchema($name)
  141. {
  142. $table = new TableSchema();
  143. $this->resolveTableNames($table, $name);
  144. if ($this->findColumns($table)) {
  145. $this->findConstraints($table);
  146. return $table;
  147. } else {
  148. return null;
  149. }
  150. }
  151. /**
  152. * Returns all schema names in the database, including the default one but not system schemas.
  153. * This method should be overridden by child classes in order to support this feature
  154. * because the default implementation simply throws an exception.
  155. * @return array all schema names in the database, except system schemas
  156. * @since 2.0.4
  157. */
  158. protected function findSchemaNames()
  159. {
  160. $sql = <<<SQL
  161. SELECT ns.nspname AS schema_name
  162. FROM pg_namespace ns
  163. WHERE ns.nspname != 'information_schema' AND ns.nspname NOT LIKE 'pg_%'
  164. ORDER BY ns.nspname
  165. SQL;
  166. return $this->db->createCommand($sql)->queryColumn();
  167. }
  168. /**
  169. * Returns all table names in the database.
  170. * @param string $schema the schema of the tables. Defaults to empty string, meaning the current or default schema.
  171. * @return array all table names in the database. The names have NO schema name prefix.
  172. */
  173. protected function findTableNames($schema = '')
  174. {
  175. if ($schema === '') {
  176. $schema = $this->defaultSchema;
  177. }
  178. $sql = <<<SQL
  179. SELECT c.relname AS table_name
  180. FROM pg_class c
  181. INNER JOIN pg_namespace ns ON ns.oid = c.relnamespace
  182. WHERE ns.nspname = :schemaName AND c.relkind IN ('r','v','m','f')
  183. ORDER BY c.relname
  184. SQL;
  185. $command = $this->db->createCommand($sql, [':schemaName' => $schema]);
  186. $rows = $command->queryAll();
  187. $names = [];
  188. foreach ($rows as $row) {
  189. $names[] = $row['table_name'];
  190. }
  191. return $names;
  192. }
  193. /**
  194. * Returns all views names in the database.
  195. * @param string $schema the schema of the views. Defaults to empty string, meaning the current or default schema.
  196. * @return array all views names in the database. The names have NO schema name prefix.
  197. * @since 2.0.9
  198. */
  199. protected function findViewNames($schema = '')
  200. {
  201. if ($schema === '') {
  202. $schema = $this->defaultSchema;
  203. }
  204. $sql = <<<SQL
  205. SELECT c.relname AS table_name
  206. FROM pg_class c
  207. INNER JOIN pg_namespace ns ON ns.oid = c.relnamespace
  208. WHERE ns.nspname = :schemaName AND c.relkind = 'v'
  209. ORDER BY c.relname
  210. SQL;
  211. $command = $this->db->createCommand($sql, [':schemaName' => $schema]);
  212. $rows = $command->queryAll();
  213. $names = [];
  214. foreach ($rows as $row) {
  215. $names[] = $row['table_name'];
  216. }
  217. return $names;
  218. }
  219. /**
  220. * Returns all view names in the database.
  221. * @param string $schema the schema of the views. Defaults to empty string, meaning the current or default schema name.
  222. * If not empty, the returned view names will be prefixed with the schema name.
  223. * @param boolean $refresh whether to fetch the latest available view names. If this is false,
  224. * view names fetched previously (if available) will be returned.
  225. * @return string[] all view names in the database.
  226. * @since 2.0.9
  227. */
  228. public function getViewNames($schema = '', $refresh = false)
  229. {
  230. if (!isset($this->_viewNames[$schema]) || $refresh) {
  231. $this->_viewNames[$schema] = $this->findViewNames($schema);
  232. }
  233. return $this->_viewNames[$schema];
  234. }
  235. /**
  236. * Collects the foreign key column details for the given table.
  237. * @param TableSchema $table the table metadata
  238. */
  239. protected function findConstraints($table)
  240. {
  241. $tableName = $this->quoteValue($table->name);
  242. $tableSchema = $this->quoteValue($table->schemaName);
  243. //We need to extract the constraints de hard way since:
  244. //http://www.postgresql.org/message-id/26677.1086673982@sss.pgh.pa.us
  245. $sql = <<<SQL
  246. select
  247. ct.conname as constraint_name,
  248. a.attname as column_name,
  249. fc.relname as foreign_table_name,
  250. fns.nspname as foreign_table_schema,
  251. fa.attname as foreign_column_name
  252. from
  253. (SELECT ct.conname, ct.conrelid, ct.confrelid, ct.conkey, ct.contype, ct.confkey, generate_subscripts(ct.conkey, 1) AS s
  254. FROM pg_constraint ct
  255. ) AS ct
  256. inner join pg_class c on c.oid=ct.conrelid
  257. inner join pg_namespace ns on c.relnamespace=ns.oid
  258. inner join pg_attribute a on a.attrelid=ct.conrelid and a.attnum = ct.conkey[ct.s]
  259. left join pg_class fc on fc.oid=ct.confrelid
  260. left join pg_namespace fns on fc.relnamespace=fns.oid
  261. left join pg_attribute fa on fa.attrelid=ct.confrelid and fa.attnum = ct.confkey[ct.s]
  262. where
  263. ct.contype='f'
  264. and c.relname={$tableName}
  265. and ns.nspname={$tableSchema}
  266. order by
  267. fns.nspname, fc.relname, a.attnum
  268. SQL;
  269. $constraints = [];
  270. foreach ($this->db->createCommand($sql)->queryAll() as $constraint) {
  271. if ($constraint['foreign_table_schema'] !== $this->defaultSchema) {
  272. $foreignTable = $constraint['foreign_table_schema'] . '.' . $constraint['foreign_table_name'];
  273. } else {
  274. $foreignTable = $constraint['foreign_table_name'];
  275. }
  276. $name = $constraint['constraint_name'];
  277. if (!isset($constraints[$name])) {
  278. $constraints[$name] = [
  279. 'tableName' => $foreignTable,
  280. 'columns' => [],
  281. ];
  282. }
  283. $constraints[$name]['columns'][$constraint['column_name']] = $constraint['foreign_column_name'];
  284. }
  285. foreach ($constraints as $constraint) {
  286. $table->foreignKeys[] = array_merge([$constraint['tableName']], $constraint['columns']);
  287. }
  288. }
  289. /**
  290. * Gets information about given table unique indexes.
  291. * @param TableSchema $table the table metadata
  292. * @return array with index and column names
  293. */
  294. protected function getUniqueIndexInformation($table)
  295. {
  296. $sql = <<<SQL
  297. SELECT
  298. i.relname as indexname,
  299. pg_get_indexdef(idx.indexrelid, k + 1, TRUE) AS columnname
  300. FROM (
  301. SELECT *, generate_subscripts(indkey, 1) AS k
  302. FROM pg_index
  303. ) idx
  304. INNER JOIN pg_class i ON i.oid = idx.indexrelid
  305. INNER JOIN pg_class c ON c.oid = idx.indrelid
  306. INNER JOIN pg_namespace ns ON c.relnamespace = ns.oid
  307. WHERE idx.indisprimary = FALSE AND idx.indisunique = TRUE
  308. AND c.relname = :tableName AND ns.nspname = :schemaName
  309. ORDER BY i.relname, k
  310. SQL;
  311. return $this->db->createCommand($sql, [
  312. ':schemaName' => $table->schemaName,
  313. ':tableName' => $table->name,
  314. ])->queryAll();
  315. }
  316. /**
  317. * Returns all unique indexes for the given table.
  318. * Each array element is of the following structure:
  319. *
  320. * ```php
  321. * [
  322. * 'IndexName1' => ['col1' [, ...]],
  323. * 'IndexName2' => ['col2' [, ...]],
  324. * ]
  325. * ```
  326. *
  327. * @param TableSchema $table the table metadata
  328. * @return array all unique indexes for the given table.
  329. */
  330. public function findUniqueIndexes($table)
  331. {
  332. $uniqueIndexes = [];
  333. $rows = $this->getUniqueIndexInformation($table);
  334. foreach ($rows as $row) {
  335. $column = $row['columnname'];
  336. if (!empty($column) && $column[0] === '"') {
  337. // postgres will quote names that are not lowercase-only
  338. // https://github.com/yiisoft/yii2/issues/10613
  339. $column = substr($column, 1, -1);
  340. }
  341. $uniqueIndexes[$row['indexname']][] = $column;
  342. }
  343. return $uniqueIndexes;
  344. }
  345. /**
  346. * Collects the metadata of table columns.
  347. * @param TableSchema $table the table metadata
  348. * @return boolean whether the table exists in the database
  349. */
  350. protected function findColumns($table)
  351. {
  352. $tableName = $this->db->quoteValue($table->name);
  353. $schemaName = $this->db->quoteValue($table->schemaName);
  354. $sql = <<<SQL
  355. SELECT
  356. d.nspname AS table_schema,
  357. c.relname AS table_name,
  358. a.attname AS column_name,
  359. t.typname AS data_type,
  360. a.attlen AS character_maximum_length,
  361. pg_catalog.col_description(c.oid, a.attnum) AS column_comment,
  362. a.atttypmod AS modifier,
  363. a.attnotnull = false AS is_nullable,
  364. CAST(pg_get_expr(ad.adbin, ad.adrelid) AS varchar) AS column_default,
  365. coalesce(pg_get_expr(ad.adbin, ad.adrelid) ~ 'nextval',false) AS is_autoinc,
  366. array_to_string((select array_agg(enumlabel) from pg_enum where enumtypid=a.atttypid)::varchar[],',') as enum_values,
  367. CASE atttypid
  368. WHEN 21 /*int2*/ THEN 16
  369. WHEN 23 /*int4*/ THEN 32
  370. WHEN 20 /*int8*/ THEN 64
  371. WHEN 1700 /*numeric*/ THEN
  372. CASE WHEN atttypmod = -1
  373. THEN null
  374. ELSE ((atttypmod - 4) >> 16) & 65535
  375. END
  376. WHEN 700 /*float4*/ THEN 24 /*FLT_MANT_DIG*/
  377. WHEN 701 /*float8*/ THEN 53 /*DBL_MANT_DIG*/
  378. ELSE null
  379. END AS numeric_precision,
  380. CASE
  381. WHEN atttypid IN (21, 23, 20) THEN 0
  382. WHEN atttypid IN (1700) THEN
  383. CASE
  384. WHEN atttypmod = -1 THEN null
  385. ELSE (atttypmod - 4) & 65535
  386. END
  387. ELSE null
  388. END AS numeric_scale,
  389. CAST(
  390. information_schema._pg_char_max_length(information_schema._pg_truetypid(a, t), information_schema._pg_truetypmod(a, t))
  391. AS numeric
  392. ) AS size,
  393. a.attnum = any (ct.conkey) as is_pkey
  394. FROM
  395. pg_class c
  396. LEFT JOIN pg_attribute a ON a.attrelid = c.oid
  397. LEFT JOIN pg_attrdef ad ON a.attrelid = ad.adrelid AND a.attnum = ad.adnum
  398. LEFT JOIN pg_type t ON a.atttypid = t.oid
  399. LEFT JOIN pg_namespace d ON d.oid = c.relnamespace
  400. LEFT join pg_constraint ct on ct.conrelid=c.oid and ct.contype='p'
  401. WHERE
  402. a.attnum > 0 and t.typname != ''
  403. and c.relname = {$tableName}
  404. and d.nspname = {$schemaName}
  405. ORDER BY
  406. a.attnum;
  407. SQL;
  408. $columns = $this->db->createCommand($sql)->queryAll();
  409. if (empty($columns)) {
  410. return false;
  411. }
  412. foreach ($columns as $column) {
  413. $column = $this->loadColumnSchema($column);
  414. $table->columns[$column->name] = $column;
  415. if ($column->isPrimaryKey) {
  416. $table->primaryKey[] = $column->name;
  417. if ($table->sequenceName === null && preg_match("/nextval\\('\"?\\w+\"?\.?\"?\\w+\"?'(::regclass)?\\)/", $column->defaultValue) === 1) {
  418. $table->sequenceName = preg_replace(['/nextval/', '/::/', '/regclass/', '/\'\)/', '/\(\'/'], '', $column->defaultValue);
  419. }
  420. $column->defaultValue = null;
  421. } elseif ($column->defaultValue) {
  422. if ($column->type === 'timestamp' && $column->defaultValue === 'now()') {
  423. $column->defaultValue = new Expression($column->defaultValue);
  424. } elseif ($column->type === 'boolean') {
  425. $column->defaultValue = ($column->defaultValue === 'true');
  426. } elseif (stripos($column->dbType, 'bit') === 0 || stripos($column->dbType, 'varbit') === 0) {
  427. $column->defaultValue = bindec(trim($column->defaultValue, 'B\''));
  428. } elseif (preg_match("/^'(.*?)'::/", $column->defaultValue, $matches)) {
  429. $column->defaultValue = $matches[1];
  430. } elseif (preg_match('/^(?:\()?(.*?)(?(1)\))(?:::.+)?$/', $column->defaultValue, $matches)) {
  431. if ($matches[1] === 'NULL') {
  432. $column->defaultValue = null;
  433. } else {
  434. $column->defaultValue = $column->phpTypecast($matches[1]);
  435. }
  436. } else {
  437. $column->defaultValue = $column->phpTypecast($column->defaultValue);
  438. }
  439. }
  440. }
  441. return true;
  442. }
  443. /**
  444. * Loads the column information into a [[ColumnSchema]] object.
  445. * @param array $info column information
  446. * @return ColumnSchema the column schema object
  447. */
  448. protected function loadColumnSchema($info)
  449. {
  450. $column = $this->createColumnSchema();
  451. $column->allowNull = $info['is_nullable'];
  452. $column->autoIncrement = $info['is_autoinc'];
  453. $column->comment = $info['column_comment'];
  454. $column->dbType = $info['data_type'];
  455. $column->defaultValue = $info['column_default'];
  456. $column->enumValues = ($info['enum_values'] !== null) ? explode(',', str_replace(["''"], ["'"], $info['enum_values'])) : null;
  457. $column->unsigned = false; // has no meaning in PG
  458. $column->isPrimaryKey = $info['is_pkey'];
  459. $column->name = $info['column_name'];
  460. $column->precision = $info['numeric_precision'];
  461. $column->scale = $info['numeric_scale'];
  462. $column->size = $info['size'] === null ? null : (int) $info['size'];
  463. if (isset($this->typeMap[$column->dbType])) {
  464. $column->type = $this->typeMap[$column->dbType];
  465. } else {
  466. $column->type = self::TYPE_STRING;
  467. }
  468. $column->phpType = $this->getColumnPhpType($column);
  469. return $column;
  470. }
  471. /**
  472. * @inheritdoc
  473. */
  474. public function insert($table, $columns)
  475. {
  476. $params = [];
  477. $sql = $this->db->getQueryBuilder()->insert($table, $columns, $params);
  478. $returnColumns = $this->getTableSchema($table)->primaryKey;
  479. if (!empty($returnColumns)) {
  480. $returning = [];
  481. foreach ((array) $returnColumns as $name) {
  482. $returning[] = $this->quoteColumnName($name);
  483. }
  484. $sql .= ' RETURNING ' . implode(', ', $returning);
  485. }
  486. $command = $this->db->createCommand($sql, $params);
  487. $command->prepare(false);
  488. $result = $command->queryOne();
  489. return !$command->pdoStatement->rowCount() ? false : $result;
  490. }
  491. }