PostgreSQL Array类型示例

SQL方式使用Array类型

可以将字段定义为变长的多组数组.

DDL定义

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
create table postgres_survey.array_samp
(
id bigint
constraint array_samp_pk
primary key,
classifies bigint[] not null,
role_matrix text[][] not null
);

comment on table postgres_survey.array_samp is 'Array类型调研';

comment on column postgres_survey.array_samp.id is '主键';

comment on column postgres_survey.array_samp.classifies is '分类ID数组';

comment on column postgres_survey.array_samp.role_matrix is '权限矩阵';

插入值

1
2
3
4
5
insert into array_samp(id, classifies, role_matrix)
values ('1', '{10, 11}', '{{"r","w","x"}}');

insert into array_samp(id, classifies, role_matrix)
values ('2', '{13, 14}', '{ {"r","w","x"}, {"r","w","x"}, {"r","w","x"}}');

查询

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
--- 显示classfies中第1个值与第2个值不一样的记录条目
select * from array_samp
where classifies[1] <> array_samp.classifies[2];

--- 显示classfies中第1个值与第2个值一样的记录条目
select * from array_samp
where classifies[1] = array_samp.classifies[2];

--- 查询字段array中指定列为10的记录
select * from array_samp
where classifies[1] = 10 or
classifies[2] = 10 or
classifies[3] = 10;

--- 查询字段array中指定列为10的记录
select * from array_samp
where classifies[1] = 10 or
classifies[2] = 10 or
classifies[3] = 10;

--- classifies字段中的所有值均为10的记录
select * from array_samp where 10 = All (classifies);

--- classifies字段中的任意值为10的记录
select * from array_samp where 10 = ANY (classifies);

--- classifies字段中的任意值为10和13的记录
select * from array_samp where classifies @> '{10,13}';

Array Function And Operators

https://www.postgresql.org/docs/9.1/functions-array.html

Array Function And Operators

Array Functions

Array Functions

Java ORM框架对PG的支持

https://dzone.com/articles/best-java-orm-frameworks-for-postgresql

Java ORM框架对PG的支持

在MyBatisPlus中的使用

添加依赖

1
2
3
4
5
6
7
8
9
<dependency>
<groupId>com.baomidou</groupId>
<artifactId>mybatis-plus-boot-starter</artifactId>
</dependency>
<dependency>
<groupId>com.baomidou</groupId>
<artifactId>mybatis-plus-core</artifactId>
<optional>true</optional>
</dependency>

配置postgres地址

1
2
3
4
5
spring:
datasource:
url: jdbc:postgresql://localhost:5432/mydatabase
username: postgres
password: password

添加 bigint[] 类型的TypeHandler

配置Mybatis Plus的TypeHander的包地址

1
2
3
mybatis-plus:
mapper-locations: classpath:mapper/*/*.xml
type-handlers-package: com.myproject.common.mybatis.typehandler

参照 https://github.com/gbif/common-mybatis

代码实现 LongArrayTypeHandler.java

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
package com.myproject.common.mybatis.typehandler;
import com.google.common.collect.Lists;
import org.apache.ibatis.type.BaseTypeHandler;
import org.apache.ibatis.type.JdbcType;

import java.sql.*;
import java.util.List;

public class LongArrayTypeHandler extends BaseTypeHandler<List<Long>> {

@Override
public void setNonNullParameter(PreparedStatement preparedStatement, int i, List<Long> longs, JdbcType jdbcType) throws SQLException {
Array array = preparedStatement.getConnection().createArrayOf("bigint", longs.toArray());
preparedStatement.setArray(i, array);
}

@Override
public List<Long> getNullableResult(ResultSet resultSet, String columnName) throws SQLException {
return toList(resultSet.getArray(columnName));
}

@Override
public List<Long> getNullableResult(ResultSet resultSet, int i) throws SQLException {
return null;
}

@Override
public List<Long> getNullableResult(CallableStatement callableStatement, int i) throws SQLException {
return null;
}

private List<Long> toList(Array pgArray) throws SQLException {
if (pgArray == null) return Lists.newArrayList();
Long[] longs = (Long[]) pgArray.getArray();
return containsOnlyNulls(longs) ? Lists.<Long>newArrayList() : Lists.newArrayList(longs);
}

private boolean containsOnlyNulls(Long[] longs) {
for (Long l : longs) {
if (l != null) {
return false;
}
}
return true;
}
}

实现 Model TableModel.java

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
import com.baomidou.mybatisplus.annotation.IdType;
import com.baomidou.mybatisplus.annotation.TableField;
import com.baomidou.mybatisplus.annotation.TableId;
import com.baomidou.mybatisplus.annotation.TableName;
import com.seaboxdata.mds.common.mybatis.typehandler.LongArrayTypeHandler;
import lombok.AllArgsConstructor;
import lombok.Builder;
import lombok.Data;
import lombok.NoArgsConstructor;
import lombok.experimental.Accessors;

import java.util.List;

@TableName(value = "array_samp", autoResultMap = true)
@Data
@Builder
@NoArgsConstructor
@AllArgsConstructor
@Accessors(chain = true)
public class TableModel {
@TableId(type = IdType.INPUT)
private Long id;
@TableField(typeHandler = LongArrayTypeHandler.class)
private List<Long> classifies;
}

实现 TableRepository.java

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
import com.baomidou.mybatisplus.core.mapper.BaseMapper;
import org.apache.ibatis.annotations.Mapper;
import org.apache.ibatis.annotations.Param;
import org.apache.ibatis.annotations.Select;
import org.springframework.stereotype.Repository;

import java.time.LocalDateTime;
import java.util.List;

/**
* @author hualong.jia(at)seaboxdata.com
* @since 1.0
*/
@Mapper
@Repository
public interface TableRepository extends BaseMapper<TableModel> {

@Select("select * from array_samp where classifies @> CAST( #{idList} AS bigint[])")
List<TableModel> queryByInCondition(@Param("idList") String idList);

}

Test方法

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
@ActiveProfiles("local")
@SpringBootTest(classes = App.class, webEnvironment = SpringBootTest.WebEnvironment.DEFINED_PORT)
@RunWith(SpringRunner.class)
public class TableModelTest {
@Autowired
TableRepository tableRepository;

@Test
public void insert() {
tableRepository.insert(
TableModel.builder()
.id(20L)
.classifies(Arrays.asList(10L, 13L, 15L))
.build()
);
}

@Test
public void findById() {
System.out.println(tableRepository.selectById(20L));
}

@Test
public void findByListCondition() {
System.out.println(tableRepository.queryByInCondition("{10,13}"));
}
}

在JPA中的使用Array

添加依赖

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
<dependency>
<groupId>org.springframework.boot</groupId>
<artifactId>spring-boot-starter-data-jpa</artifactId>
</dependency>
<dependency>
<groupId>org.postgresql</groupId>
<artifactId>postgresql</artifactId>
<version>42.2.19</version>
</dependency>
<!-- springboot2.1.4需要提升hibernate-core版本-->
<dependency>
<groupId>org.hibernate</groupId>
<artifactId>hibernate-core</artifactId>
<version>5.4.2.Final</version>
</dependency>
<!-- 让jpa支持pg jsonb array等类型 -->
<dependency>
<groupId>com.vladmihalcea</groupId>
<artifactId>hibernate-types-52</artifactId>
<version>2.10.3</version>
</dependency>

配置Postgresql地址

1
2
3
4
5
spring:
datasource:
url: jdbc:postgresql://localhost:5432/mydatabase
username: postgres
password: password

添加Model ArraySampleModel.java

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
import com.vladmihalcea.hibernate.type.array.ListArrayType;
import lombok.AllArgsConstructor;
import lombok.Builder;
import lombok.Data;
import lombok.NoArgsConstructor;
import org.hibernate.annotations.Type;
import org.hibernate.annotations.TypeDef;
import org.jetbrains.annotations.NotNull;

import javax.persistence.Column;
import javax.persistence.Entity;
import javax.persistence.Id;
import javax.persistence.Table;
import java.util.List;

@Entity
@Table(name = "array_samp")
@TypeDef(
name = "list-array",
typeClass = ListArrayType.class
)
@Data
@Builder
@NoArgsConstructor
@AllArgsConstructor
public class ArraySampleModel {
@Id
private Long id;
@Type(type = "list-array")
@Column( name = "classifies", columnDefinition = "bigint[]")
private List<Long> classifies;

}

配置Repository ArraySampleRepository.java

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
import org.springframework.data.jpa.repository.JpaRepository;
import org.springframework.data.jpa.repository.Query;

import java.util.List;

public interface ArraySampleRepository extends JpaRepository<ArraySampleModel, Long> {

/**
* 通过LongArr进行查询
* @param inCondition 要查询的数组 {1L,2L}
* @return 查询到的数组
*/
//PGSQL为 select a from array_samp a where classifies @> '{10,13}'
//?1为JPA传参1 @Query(value = "select a from array_samp a where classifies @> ?1")
// nativeQuery需要为true , json需要用CAST包装
@Query(value = "select * from array_samp where classifies @> CAST(?1 AS bigint[])", nativeQuery = true)
List<ArraySampleModel> queryByInCondition(String inCondition);

}

测试类 PgArrayTest

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
import com.seaboxdata.mds.MdsServiceApp;
import com.seaboxdata.mds.test.AbstractSpringTest;
import org.junit.Test;
import org.junit.runner.RunWith;
import org.springframework.beans.factory.annotation.Autowired;
import org.springframework.boot.test.context.SpringBootTest;
import org.springframework.test.context.ActiveProfiles;
import org.springframework.test.context.junit4.SpringRunner;

import java.util.Arrays;
import java.util.List;
import java.util.Optional;

import static java.util.stream.Collectors.joining;
import static org.junit.Assert.assertTrue;

@ActiveProfiles("local")
@SpringBootTest(classes = MdsServiceApp.class, webEnvironment = SpringBootTest.WebEnvironment.DEFINED_PORT)
@RunWith(SpringRunner.class)
public class PgArrayTest extends AbstractSpringTest {

@Autowired
ArraySampleRepository arraySampleRepository;

@Test
public void insertTest() {
ArraySampleModel model = ArraySampleModel.builder()
.id(9L)
.classifies(Arrays.asList(100L, 200L))
.build();
arraySampleRepository.save(model);
}

@Test
public void findByIdTest() {
Optional<ArraySampleModel> model = arraySampleRepository.findById(9L);
assertTrue(model.isPresent());
System.out.println(model.get());
}

@Test
public void findByListTest() {
List<Long> classId = Arrays.asList(10L, 13L);
String inCondition = classId.stream().map(e -> e.toString()).collect(joining(",", "{", "}"));
System.out.println(inCondition);
System.out.println(arraySampleRepository.queryByInCondition(inCondition));
}

}